3.9Conversion of Data Types

When composing an expression or specifying an operation, the aim should be to use compatible data types for the operands. When a need arises to use a mixture of data types, it should prompt you to look for a way to convert incompatible operands before subjecting them to the operation. The ability to convert data may well be an issue if you are working with Dialect 1 data.

3.9.1Explicit Data Type Conversion

The CAST function enables explicit conversion between many pairs of data types.

Syntax

  |CAST (<expression> AS <target_type>)
  | 
  |<target_type> ::= <domain_or_non_array_type> | <array_datatype>
  | 
  |<domain_or_non_array_type> ::=
  |  !! See Scalar Data Types Syntax !!
  | 
  |<array_datatype> ::=
  |  !! See Array Data Types Syntax !!

See also CAST() in Chapter Built-in Scalar Functions.

3.9.1.1Casting to a Domain

When you cast to a domain, any constraints declared for it are taken into account, i.e., NOT NULL or CHECK constraints. If the value does not pass the check, the cast will fail.

If TYPE OF is additionally specified — casting to its base type — any domain constraints are ignored during the cast. If TYPE OF is used with a character type (CHAR/VARCHAR), the character set and collation are retained.

3.9.1.2Casting to TYPE OF COLUMN

When operands are cast to the type of a column, the specified column may be from a table or a view.

Only the type of the column itself is used. For character types, the cast includes the character set, but not the collation. The constraints and default values of the source column are not applied.

Example

  |CREATE TABLE TTT (
  |  S VARCHAR (40)
  |  CHARACTER SET UTF8 COLLATE UNICODE_CI_AI
  |);
  |COMMIT;
  | 
  |SELECT
  |  CAST ('I have many friends' AS TYPE OF COLUMN TTT.S)
  |FROM RDB$DATABASE;

3.9.1.3Conversions Possible for the CAST Function

Table 3.8Conversions with CAST
From Data TypeTo Data Type

Numeric types

Numeric types, [VAR]CHAR, BLOB

[VAR]CHAR

[VAR]CHAR, BLOB, Numeric types, DATE, TIME, TIMESTAMP, BOOLEAN

BLOB

[VAR]CHAR, BLOB, Numeric types, DATE, TIME, TIMESTAMP, BOOLEAN

DATE, TIME

[VAR]CHAR, BLOB, TIMESTAMP

TIMESTAMP

[VAR]CHAR, BLOB, DATE, TIME

BOOLEAN

BOOLEAN, [VAR]CHAR, BLOB

To convert string data types to the BOOLEAN type, the value must be (case-insensitive) 'true' or 'false', or NULL.

Important

Keep in mind that partial information loss is possible. For instance, when you cast the TIMESTAMP data type to the DATE data type, the time-part is lost.

3.9.1.4Literal Formats

To cast string data types to the DATE, TIME or TIMESTAMP data types, you need the string argument to be one of the predefined date and time literals (see Table 3.9, “Date and Time Literal Format Arguments”) or a representation of the date in one of the allowed date-time literal formats:

   |<timestamp_format> ::=
   |    { [YYYY<p>]MM<p>DD[<p>HH[<p>mm[<p>SS[<p>NNNN]]]]
   |    | MM<p>DD[<p>YYYY[<p>HH[<p>mm[<p>SS[<p>NNNN]]]]]
   |    | DD<p>MM[<p>YYYY[<p>HH[<p>mm[<p>SS[<p>NNNN]]]]]
   |    | MM<p>DD[<p>YY[<p>HH[<p>mm[<p>SS[<p>NNNN]]]]]
   |    | DD<p>MM[<p>YY[<p>HH[<p>mm[<p>SS[<p>NNNN]]]]]
   |    | NOW
   |    | TODAY
   |    | TOMORROW
   |    | YESTERDAY }
   | 
   |<date_format> ::=
   |    { [YYYY<p>]MM<p>DD
   |    | MM<p>DD[<p>YYYY]
   |    | DD<p>MM[<p>YYYY]
   |    | MM<p>DD[<p>YY]
   |    | DD<p>MM[<p>YY]
   |    | TODAY
   |    | TOMORROW
   |    | YESTERDAY }
   | 
   |<time_format> :=
   |    { HH[<p>mm[<p>SS[<p>NNNN]]]
   |    | NOW }
   | 
   |<p> ::= whitespace | . | : | , | - | /
Table 3.9Date and Time Literal Format Arguments
ArgumentDescription

timestamp_format

Format of timestamp literal

date_literal

Format of date literal

time_literal

Format of time literal

YYYY

Four-digit year

YY

Two-digit year

MM

Month. It may contain 1 or 2 digits (1-12 or 01-12). You can also specify the three-letter shorthand name or the full name of a month in English. Case-insensitive

DD

Day. It may contain 1 or 2 digits (1-31 or 01-31)

HH

Hour. It may contain 1 or 2 digits (0-23 or 00-23)

mm

Minutes. It may contain 1 or 2 digits (0-59 or 00-59)

SS

Seconds. It may contain 1 or 2 digits (0-59 or 00-59)

NNNN

Ten-thousandths of a second. It may contain from 1 to 4 digits (0-9999)

p

A separator, any of permitted characters. Leading and trailing spaces are ignored

Table 3.10Literals with Predefined Values of Date and Time

Literal

Description

Data Type

Dialect 1

Dialect 3

'NOW'

Current date and time

DATE

TIMESTAMP

'TODAY'

Current date

DATE with zero time

DATE

'TOMORROW'

Current date + 1 (day)

DATE with zero time

DATE

'YESTERDAY'

Current date - 1 (day)

DATE with zero time

DATE

Important

Use of the complete specification of the year in the four-digit form — YYYY — is strongly recommended, to avoid confusion in date calculations and aggregations.

Sample Date Literal Interpretations

   |select
   |  cast('04.12.2014' as date) as d1, -- DD.MM.YYYY
   |  cast('04 12 2014' as date) as d2, -- MM DD YYYY
   |  cast('4-12-2014' as date) as d3,  -- MM-DD-YYYY
   |  cast('04/12/2014' as date) as d4, -- MM/DD/YYYY
   |  cast('04,12,2014' as date) as d5, -- MM,DD,YYYY
   |  cast('04.12.14' as date) as d6,   -- DD.MM.YY
   |  -- DD.MM with current year
   |  cast('04.12' as date) as d7,
   |  -- MM/DD with current year
   |  cast('04/12' as date) as d8,
   |  cast('2014/12/04' as date) as d9, -- YYYY/MM/DD
   |  cast('2014 12 04' as date) as d10, -- YYYY MM DD
   |  cast('2014.12.04' as date) as d11, -- YYYY.MM.DD
   |  cast('2014-12-04' as date) as d12, -- YYYY-MM-DD
   |  cast('4 Jan 2014' as date) as d13, -- DD MM YYYY
   |  cast('2014 Jan 4' as date) as dt14, -- YYYY MM DD
   |  cast('Jan 4, 2014' as date) as dt15, -- MM DD, YYYY
   |  cast('11:37' as time) as t1, -- HH:mm
   |  cast('11:37:12' as time) as t2, -- HH:mm:ss
   |  cast('11:31:12.1234' as time) as t3, -- HH:mm:ss.nnnn
   |  cast('11.37.12' as time) as t4, -- HH.mm.ss
   |  -- DD.MM.YYYY HH:mm
   |  cast('04.12.2014 11:37' as timestamp) as dt1,
   |  -- MM/DD/YYYY HH:mm:ss
   |  cast('04/12/2014 11:37:12' as timestamp) as dt2,
   |  -- DD.MM.YYYY HH:mm:ss.nnnn
   |  cast('04.12.2014 11:31:12.1234' as timestamp) as dt3,
   |  -- MM/DD/YYYY HH.mm.ss
   |  cast('04/12/2014 11.37.12' as timestamp) as dt4
   |from rdb$database

3.9.1.5Shorthand Casts for Date and Time Data Types

Firebird allows the use of a shorthand C-style type syntax for casts from string to the types DATE, TIME and TIMESTAMP. The SQL standard calls these datetime literals.

Syntax

  |<data_type> 'date_literal_string'

Example

   |-- 1
   |  UPDATE PEOPLE
   |  SET AGECAT = 'SENIOR'
   |  WHERE BIRTHDATE < DATE '1-Jan-1943';
   |-- 2
   |  INSERT INTO APPOINTMENTS
   |  (EMPLOYEE_ID, CLIENT_ID, APP_DATE, APP_TIME)
   |  VALUES (973, 8804, DATE 'today' + 2, TIME '16:00');
   |-- 3
   |  NEW.LASTMOD = TIMESTAMP 'now';

Note

These shorthand expressions are evaluated directly during parsing, as though the statement were already prepared for execution. Thus, even if the query is run several times, the value of, for instance, timestamp 'now' remains the same no matter how much time passes.

If you need the time to be evaluated at each execution, use the full CAST syntax. An example of using such an expression in a trigger:

  |NEW.CHANGE_DATE = CAST('now' AS TIMESTAMP);

Firebird 4 will no longer allow these implicit datetime values like 'now', 'today', etc in these shorthand casts. It is advisable to switch to using the full CAST expression for implicit values.

3.9.2Implicit Data Type Conversion

Implicit data conversion is not possible in Dialect 3 — the CAST function is almost always required to avoid data type clashes.

In Dialect 1, in many expressions, one type is implicitly cast to another without the need to use the CAST function. For instance, the following statement in Dialect 1 is valid:

  |UPDATE ATABLE
  |  SET ADATE = '25.12.2016' + 1

and the date literal will be cast to the date type implicitly.

In Dialect 3, this statement will throw error 35544569, Dynamic SQL Error: expression evaluation not supported, Strings cannot be added or subtracted in dialect 3 — a cast will be needed:

  |UPDATE ATABLE
  |  SET ADATE = CAST ('25.12.2016' AS DATE) + 1

or, with the short cast:

  |UPDATE ATABLE
  |  SET ADATE = DATE '25.12.2016' + 1

In Dialect 1, mixing integer data and numeric strings is usually possible because the parser will try to cast the string implicitly. For example,

  |2 + '1'

will be executed correctly.

In Dialect 3, an expression like this will raise an error, so you will need to write it as a CAST expression:

  |2 + CAST('1' AS SMALLINT)

The exception to the rule is during string concatenation.

3.9.2.1Implicit Conversion During String Concatenation

When multiple data elements are being concatenated, all non-string data will undergo implicit conversion to string, if possible.

Example

  |SELECT 30||' days hath September, April, June and November' CONCAT$
  |  FROM RDB$DATABASE;
  | 
  |CONCAT$
  |------------------------------------------------
  |30 days hath September, April, June and November