Firebird Documentation IndexFirebird 2.5 Quick Start → Working with databases
Firebird Home Firebird Home Prev: Server configuration and managementFirebird Documentation IndexUp: Firebird 2.5 Quick StartNext: Protecting your data

Working with databases

Connection strings
Connecting to an existing database
Creating a database using isql
Firebird SQL

In this part of the manual you will learn:

In as much as remote connections are involved, we will use the recommended TCP/IP protocol.

Connection strings

If you want to connect to a database or create one you have to supply, amongst other things, a connection string to the client application (or, if you are a programmer, to the routines you are calling). A connection string uniquely identifies the location of the database on your computer, local network, or even the Internet.

Local connection strings

An explicit local connection string consists of the path + filename specification in the native format of the filesystem used on the server machine, for example

  • on a Linux or other Unix-like server:

    /opt/firebird/examples/empbuild/employee.fdb

  • on a Windows server:

    C:\Biology\Data\Primates\Apes\populations.fdb

Many clients also allow relative path strings (e.g. “..\examples\empbuild\employee.fdb”) but you should use them with caution, as it's not always obvious how they will be expanded. Getting an error message is annoying enough, but applying changes to another database than you thought you were connected to may be disastrous.

Instead of a file path, the local connection string may also be a database alias that is defined in aliases.conf, as mentioned earlier. The format of the alias depends only on how it's defined in the aliases file, not on the server filesystem. Examples are:

  • zappa

  • blackjack.fdb

  • poker

Tip

If your local connections fail, it may be because the local protocol isn't working properly on your machine. If you're running Windows Vista, 2003 or XP with terminal services enabled, this can often be fixed by setting IpcName to Global\FIREBIRD in the configuration file firebird.conf (don't forget to uncomment the parameter and restart the server).

If setting IpcName doesn't help and you don't get the local protocol enabled, you can always work around the problem by putting “localhost:” before your database paths or aliases, thus turning them into TCP/IP connection strings (discussed below).

TCP/IP connection strings

A TCP/IP connection string consists of:

  1. a server name or IP address

  2. a colon (“:”)

  3. either the absolute path + filename on the server machine, or an alias defined on the server machine.

Examples:

  • On Linux/Unix:

    pongo:/opt/firebird/examples/empbuild/employee.fdb

    bongo:fury

    112.179.0.1:/var/Firebird/databases/butterflies.fdb

    localhost:blackjack.fdb

  • On Windows:

    siamang:C:\Biology\Data\Primates\Apes\populations.fdb

    sofa:D:\Misc\Friends\Rich\Lenders.fdb

    127.0.0.1:Borrowers

Notice how the aliased connection strings don't give any clue about the server OS. And they don't have to, either: you talk to a Linux Firebird server just like you talk to a Windows Firebird server. In fact, specifying an explicit database path is one of the rare occasions where you have to be aware of the difference.

Third-party programs

Please note that some third-party client programs may have different requirements for the composition of connection strings. Refer to their documentation or online help to find out.

Connecting to an existing database

A sample database named employee.fdb is located in the examples/empbuild subdirectory of your Firebird installation. You can use this database to “try your wings”.

If you move or copy the sample database, be sure to place it on a hard disk that is physically attached to your server machine. Shares, mapped drives or (on Unix) mounted SMB (Samba) filesystems will not work. The same rule applies to any databases that you create or use.

Connecting to a Firebird database requires the user to authenticate with a user name and a valid password. In order to work with objects inside the database – such as tables, views, etc. – you also need explicit permissions on those objects, unless you own them (you own an object if you have created it) or if you're connected as SYSDBA. In the example database employee.fdb, sufficient permissions have been granted to PUBLIC (i.e. anybody who cares to connect) to enable you to view and modify data to your heart's content.

For simplicity here, we will look at authenticating as SYSDBA using the password masterkey. Also, to keep the lines in the examples from running off the right edge, we will work with local databases and use relative paths. Of course everything you'll learn in these sections can also be applied to remote databases, simply by supplying a full TCP/IP connection string.

Connecting with isql

Firebird ships with a text-mode client named isql (Interactive SQL utility). You can use it in several ways to connect to a database. One of them, shown below, is to start it in interactive mode. Go to the bin subdirectory of your Firebird installation and type isql (Windows) or ./isql (Linux) at the command prompt.

[In the following examples, ↵ means “hit Enter”]

C:\Program Files\Firebird\Firebird_2_5\bin>isql↵
Use CONNECT or CREATE DATABASE to specify a database
SQL>CONNECT ..\examples\empbuild\employee.fdb user SYSDBA password masterkey;↵

Important

  • In isql, every SQL statement must end with a semicolon. If you hit Enter and the line doesn't end with a semicolon, isql assumes that the statement continues on the next line and the prompt will change from SQL> to CON>. This enables you to split long statements over multiple lines. If you hit Enter after your statement and you've forgotten the semicolon, just type it after the CON> prompt on the next line and press Enter again.

  • If you run a (Super)Classic Server on Linux, a fast, direct local connection is attempted if the database path does not start with a hostname. This may fail if your Linux login doesn't have sufficient access rights to the database file. In that case, connect to localhost:<path>. Then the server process (usually running as user firebird) will open the file. On the other hand, network-style connections may fail if a user created the database in Classic local mode and the server doesn't have enough access rights.

Note

You can optionally enclose the path, the user name and/or the password in single (') or double (") quotes. If the path contains spaces, quoting is mandatory.

At this point, isql will inform you that you are connected:

Database:  ..\examples\empbuild\employee.fdb, User: sysdba
SQL>

You can now continue to play about with the employee.fdb database. With isql you can query data, get information about the metadata, create database objects, run data definition scripts and much more.

To get back to the command prompt, type:

SQL>QUIT;↵

You can also type EXIT instead of QUIT, the difference being that EXIT will first commit any open transactions, making your modifications permanent.

Connecting with a GUI client

GUI client tools usually take charge of composing the CONNECT string for you, using server, path (or alias), user name and password information that you type into prompting fields. Use the elements as described in the preceding topic.

Notes

  • It is quite common for such tools to expect the entire server + path/alias as a single connection string – just like isql does.

  • Remember that file names and commands on Linux and other “Unix-ish” platforms are case-sensitive.

Creating a database using isql

There is more than one way to create a database with isql. Here, we will look at one simple way to create a database interactively – although, for your serious database definition work, you should create and maintain your metadata objects using data definition scripts.

Starting isql

To create a database interactively using the isql command shell, get to a command prompt in Firebird's bin subdirectory and type isql (Windows) or ./isql (Linux):

[In the following examples, ↵ means “hit Enter”]

C:\Program Files\Firebird\Firebird_2_5\bin>isql↵
Use CONNECT or CREATE DATABASE to specify a database

The CREATE DATABASE statement

Now you can create your new database interactively. Let's suppose that you want to create a database named test.fdb and store it in a directory named data on your D drive:

SQL>CREATE DATABASE 'D:\data\test.fdb' page_size 8192↵
CON>user 'SYSDBA' password 'masterkey';↵

Important

  • In the CREATE DATABASE statement it is mandatory to place quote characters (single or double) around path, username and password. This is different from the CONNECT statement.

  • If you run a (Super)Classic Server on Linux and you don't start the database path with a hostname, creation of the database file is attempted with your Linux login as the owner. This may or may not be what you want (think of access rights if you want others to be able to connect). If you prepend localhost: to the path, the server process (usually running as user firebird) will create and own the file.

The database will be created and, after a few moments, the SQL prompt will reappear. You are now connected to the new database and can proceed to create some test objects in it.

But to verify that there really is a database there, let's first type in this query:

SQL>SELECT * FROM RDB$RELATIONS;↵

Although you haven't created any tables yet, the screen will fill up with a large amount of data! This query selects all of the rows in the system table RDB$RELATIONS, where Firebird stores the metadata for tables. An “empty” database is not really empty: it contains a number of system tables and other objects. The system tables will grow as you add more user objects to your database.

To get back to the command prompt type QUIT or EXIT, as explained in the section on connecting.

Firebird SQL

Every database management system has its own idiosyncrasies in the ways it implements SQL. Firebird adheres to the SQL standard more rigorously than most other RDBMSes. Developers migrating from products that are less standards-compliant often wrongly suppose that Firebird is quirky, whereas many of its apparent quirks are not quirky at all.

Division of an integer by an integer

Firebird accords with the SQL standard by truncating the result (quotient) of an integer/integer calculation to the next lower integer. This can have bizarre results unless you are aware of it.

For example, this calculation is correct in SQL:

1 / 3 = 0

If you are upgrading from an RDBMS which resolves integer/integer division to a float quotient, you will need to alter any affected expressions to use a float or scaled numeric type for either dividend, divisor, or both.

For example, the calculation above could be modified thus in order to produce a non-zero result:

1.000 / 3 = 0.333

Things to know about strings

String delimiter symbol

Strings in Firebird are delimited by a pair of single quote (apostrophe) symbols: 'I am a string' (ASCII code 39, not 96). If you used earlier versions of Firebird's relative, InterBase®, you might recall that double and single quotes were interchangeable as string delimiters. Double quotes cannot be used as string delimiters in Firebird SQL statements.

Apostrophes in strings

If you need to use an apostrophe inside a Firebird string, you can “escape” the apostrophe character by preceding it with another apostrophe.

For example, this string will give an error:

'Joe's Emporium'

because the parser encounters the apostrophe and interprets the string as 'Joe' followed by some unknown keywords. To make it a legal string, double the apostrophe character:

'Joe''s Emporium'

Notice that this is TWO single quotes, not one double-quote.

Concatenation of strings

The concatenation symbol in SQL is two “pipe” symbols (ASCII 124, in a pair with no space between). In SQL, the “+” symbol is an arithmetic operator and it will cause an error if you attempt to use it for concatenating strings. The following expression prefixes a character column value with the string “Reported by: ”:

'Reported by: ' || LastName

Firebird will raise an error if the result of a string concatenation exceeds the maximum (var)char size of 32 Kb. If only the potential result – based on variable or field size – is too long you'll get a warning, but the operation will be completed successfully. (In pre-2.0 Firebird, this too would cause an error and halt execution.)

See also the section below, Expressions involving NULL, about concatenating in expressions involving NULL.

Double-quoted identifiers

Before the SQL-92 standard, it was not legal to have object names (identifiers) in a database that duplicated keywords in the language, were case-sensitive or contained spaces. SQL-92 introduced a single new standard to make any of them legal, provided that the identifiers were defined within pairs of double-quote symbols (ASCII 34) and were always referred to using double-quote delimiters.

The purpose of this “gift” was to make it easier to migrate metadata from non-standard RDBMSes to standards-compliant ones. The down-side is that, if you choose to define an identifier in double quotes, its case-sensitivity and the enforced double-quoting will remain mandatory.

Firebird does permit a slight relaxation under a very limited set of conditions. If the identifier which was defined in double-quotes:

  1. was defined as all upper-case,

  2. is not a keyword, and

  3. does not contain any spaces,

...then it can be used in SQL unquoted and case-insensitively. (But as soon as you put double-quotes around it, you must match the case again!)

Warning

Don't get too smart with this! For instance, if you have tables "TESTTABLE" and "TestTable", both defined within double-quotes, and you issue the command:

SQL>select * from TestTable;

...you will get the records from "TESTTABLE", not "TestTable"!

Unless you have a compelling reason to define quoted identifiers, it is usually recommended that you avoid them. Firebird happily accepts a mix of quoted and unquoted identifiers – so there is no problem including that keyword which you inherited from a legacy database, if you need to.

Warning

Some database admin tools enforce double-quoting of all identifiers by default. Try to choose a tool which makes double-quoting optional.

Expressions involving NULL

In SQL, NULL is not a value. It is a condition, or state, of a data item, in which its value is unknown. Because it is unknown, NULL cannot behave like a value. When you try to perform arithmetic on NULL, or involve it with values in other expressions, the result of the operation will almost always be NULL. It is not zero or blank or an “empty string” and it does not behave like any of these values.

Below are some examples of the types of surprises you will get if you try to perform calculations and comparisons with NULL.

The following expressions all return NULL:

  • 1 + 2 + 3 + NULL

  • not (NULL)

  • 'Home ' || 'sweet ' || NULL

You might have expected 6 from the first expression and “Home sweet ” from the third, but as we just said, NULL is not like the number 0 or an empty string – it's far more destructive!

The following expression:

  • FirstName || ' ' || LastName

will return NULL if either FirstName or LastName is NULL. Otherwise it will nicely concatenate the two names with a space in between – even if any one of the variables is an empty string.

Tip

Think of NULL as UNKNOWN and these strange results suddenly start to make sense! If the value of Number is unknown, the outcome of '1 + 2 + 3 + Number' is also unknown (and therefore NULL). If the content of MyString is unknown, then so is 'MyString || YourString' (even if YourString is non-NULL). Etcetera.

Now let's examine some PSQL (Procedural SQL) examples with if-constructs:

  • if (a = b) then
      MyVariable = 'Equal';
    else
      MyVariable = 'Not equal';

    After executing this code, MyVariable will be 'Not equal' if both a and b are NULL. The reason is that 'a = b' yields NULL if at least one of them is NULL. If the test expression of an “if” statement is NULL, it behaves like false: the 'then' block is skipped, and the 'else' block executed.

    Warning

    Although the expression may behave like false in this case, it's still NULL. If you try to invert it using not(), what you get is another NULL – not “true”.

  • if (a <> b) then
      MyVariable = 'Not equal';
    else
      MyVariable = 'Equal';

    Here, MyVariable will be 'Equal' if a is NULL and b isn't, or vice versa. The explanation is analogous to that of the previous example.

The DISTINCT keyword comes to the rescue!

Firebird 2 and above implement a new use of the DISTINCT keyword allowing you to perform (in)equality tests that take NULL into account. The semantics are as follows:

  • Two expressions are DISTINCT if they have different values or if one is NULL and the other isn't;

  • They are NOT DISTINCT if they have the same value or if they are both NULL.

Notice that if neither operand is NULL, DISTINCT works exactly like the “<>” operator, and NOT DISTINCT like the “=” operator.

DISTINCT and NOT DISTINCT always return true or false, never NULL.

Using DISTINCT, you can rewrite the first PSQL example as follows:

if (a is not distinct from b) then
  MyVariable = 'Equal';
else
  MyVariable = 'Not equal';

And the second as:

if (a is distinct from b) then
  MyVariable = 'Not equal';
else
  MyVariable = 'Equal';

These versions will give you the results that a normal (i.e. not SQL-brainwashed) human being would expect, whether there are NULLs involved or not.

More about NULLs

A lot more information about NULL behaviour can be found in the Firebird Null Guide, at these locations:

Prev: Server configuration and managementFirebird Documentation IndexUp: Firebird 2.5 Quick StartNext: Protecting your data
Firebird Documentation IndexFirebird 2.5 Quick Start → Working with databases