FirebirdSQL logo

SQL Dialects

SQL dialect is a term that defines the specific features of the SQL language that are available when accessing a database.SQL dialects can be defined at the database level and specified at the connection level.Three dialects are available:

  • Dialect 1 is intended solely to allow backward compatibility with legacy databases from old InterBase versions, version 5 and below.A “Dialect 1” database retains certain language features that differ from Dialect 3, the default for Firebird databases.

    • Date and time information are stored in a DATE data type.A TIMESTAMP data type is also available, that is identical to this DATE implementation.

    • Double quotes may be used as an alternative to apostrophes for delimiting string data.This is contrary to the SQL standard — double quotes are reserved for a distinct syntactic purpose both in standard SQL and in Dialect 3.Double-quoting strings is therefore to be avoided.

    • The precision for NUMERIC and DECIMAL data types is smaller than in Dialect 3 and, if the precision of a fixed decimal number is greater than 9, Firebird stores it internally as a double-precision floating point value.

    • The BIGINT (64-bit integer) data type is not supported.

    • Identifiers are case-insensitive and must always comply with the rules for regular identifiers — see the section [fblangref50-structure-identifiers] below.

    • Although generator values are stored as 64-bit integers, a Dialect 1 client request, SELECT GEN_ID (MyGen, 1), for example, will return the generator value truncated to 32 bits.

  • Dialect 2 is available only on a Firebird client connection and cannot be set in a database.It is intended to assist debugging of possible problems with legacy data when migrating a database from dialect 1 to 3.

  • In Dialect 3 databases,

    • numbers (DECIMAL and NUMERIC data types) are stored as fixed-point values (scaled integers) for all precisions;depending on the type and precision, they are stored as a SMALLINT, INTEGER, BIGINT or INT128.

    • The TIME data type is available for storing time-of-day data.

    • The DATE data type stores only date information.

    • The TIMESTAMP data type stores date and time information.

    • The 64-bit integer data type BIGINT is available.

    • Double quotes are reserved for delimiting non-regular identifiers, enabling object names that are case-sensitive or that do not meet the requirements for regular identifiers in other ways.

    • Strings must be delimited with single quotes (apostrophes) or using Q-strings.

    • Generator values are stored as 64-bit integers.

Important

Use of Dialect 3 is strongly recommended for newly developed databases and applications.Both database and connection dialects should match, except under migration conditions with Dialect 2.

This reference describes the semantics of SQL Dialect 3 unless specified otherwise.

Error Conditions

Processing of every SQL statement either completes successfully or fails due to a specific error condition.Error handling can be done both client-side in the application, or server-side using PSQL.

Basic Elements: Statements, Clauses, Keywords

The primary construct in SQL is the statement.A statement defines what the database management system should do with a particular data or metadata object.More complex statements contain simpler constructs — clauses and options.

Clauses

A clause defines a certain type of directive in a statement.For instance, the WHERE clause in a SELECT statement and in other data manipulation statements (e.g. UPDATE, DELETE) specifies criteria for searching one or more tables for the rows that are to be selected, updated or deleted.The ORDER BY clause specifies how the output data — result set — should be sorted.

Options

Options, being the simplest constructs, are specified in association with specific keywords to provide qualification for clause elements.Where alternative options are available, it is usual for one of them to be the default, used if nothing is specified for that option.For instance, the SELECT statement will return all rows that match the search criteria unless the DISTINCT option restricts the output to non-duplicated rows.

Keywords

All words that are included in the SQL lexicon are keywords.Some keywords are reserved, meaning their usage as identifiers for database objects, parameter names or variables is prohibited in some or all contexts.Non-reserved keywords can be used as identifiers, although this is not recommended.From time to time, non-reserved keywords may become reserved, or new (reserved or non-reserved) keywords may be added when new language feature are introduced.Although unlikely, reserved words may also change to non-reserved keywords, or keywords may be removed entirely, for example when parser rules change.

For example, the following statement will be executed without errors because, although ABS is a keyword, it is not a reserved word.

CREATE TABLE T (ABS INT NOT NULL);

On the contrary, the following statement will return an error because ADD is both a keyword and a reserved word.

CREATE TABLE T (ADD INT NOT NULL);

Refer to the list of reserved words and keywords in the chapter Reserved Words and Keywords.

Identifiers

All database objects have names, often called identifiers.The maximum identifier length is 63 characters character set UTF8 (252 bytes).

Note

It is possible to restrict the actual maximum identifier length through configuration.Consult theFirebird 4.0 Release Notesfor details.In this language reference we assume the default configuration of 63 characters (252 bytes).

Two types of names are valid as identifiers: regular identifiers, similar to variable names in regular programming languages, and delimited identifiers that are specific to SQL.To be valid, each type of identifier must conform to a set of rules, as follows: