PI()
Approximation of pi.
DOUBLE PRECISION
PI ()
Functions for Sequences (Generators)
PI()Approximation of pi.
DOUBLE PRECISION
PI ()
ACOS()Arc cosine
DOUBLE PRECISION
ACOS (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type within the range [-1, 1] |
The result is an angle in the range [0, pi].
POWER()Power
DOUBLE PRECISION
POWER (x, y)
| Parameter | Description |
|---|---|
x |
An expression of a numeric type |
y |
An expression of a numeric type |
Returns x to the power of y (xy).
RAND()Generates a random number
DOUBLE PRECISION
RAND ()
Returns a random number between 0 and 1.
ROUND()single argument: integer type, DOUBLE PRECISION or DECFLOAT;
two arguments: numerical, matching first argument
ROUND (number [, scale])
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
scale |
An integer specifying the number of decimal places toward which rounding is to be performed, e.g.:
|
Rounds a number to the nearest integer.If the fractional part is exactly 0.5, rounding is upward for positive numbers and downward for negative numbers.With the optional scale argument, the number can be rounded to powers-of-ten multiples (tens, hundreds, tenths, hundredths, etc.).
|
Important
|
If you are used to the behaviour of the external function |
ROUND ExamplesIf the scale argument is present, the result usually has the same scale as the first argument:
ROUND(123.654, 1) -- returns 123.700 (not 123.7)
ROUND(8341.7, -3) -- returns 8000.0 (not 8000)
ROUND(45.1212, 0) -- returns 45.0000 (not 45)
Otherwise, the result scale is 0:
ROUND(45.1212) -- returns 45
SIGN()Sign or signum
SMALLINT
SIGN (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
Returns the sign of the argument: -1, 0 or 1
number < 0 → -1
number = 0 → 0
number > 0 → 1
SIN()Sine
DOUBLE PRECISION
SIN (angle)
| Parameter | Description |
|---|---|
angle |
An angle, in radians |
The result is in the range [-1, 1].
SINH()Hyperbolic sine
DOUBLE PRECISION
SINH (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
SQRT()Square root
DOUBLE PRECISION
SQRT (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
If number is negative, an error is raised.
TAN()Tangent
DOUBLE PRECISION
TAN (angle)
| Parameter | Description |
|---|---|
angle |
An angle, in radians |
TANH()Hyperbolic tangent
DOUBLE PRECISION
TANH (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
Due to rounding, the result is in the range [-1, 1] (mathematically, it’s <-1, 1>).
TRUNC()Truncate number
single argument: integer type, DOUBLE PRECISION or DECFLOAT;
two arguments: numerical, matching first argument
TRUNC (number [, scale])
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
scale |
An integer specifying the number of decimal places toward which truncating is to be performed, e.g.:
|
The single argument variant returns the integer part of a number.With the optional scale argument, the number can be truncated to powers-of-ten multiples (tens, hundreds, tenths, hundredths, etc.).
|
Note
|
|
|
Important
|
If you are used to the behaviour of the external function |
ACOSH()Inverse hyperbolic cosine
DOUBLE PRECISION
ACOSH (number)
| Parameter | Description |
|---|---|
number |
Any non- |
The result is in the range [0, INF].
ASIN()Arc sine
DOUBLE PRECISION
ASIN (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type within the range [-1, 1] |
The result is an angle in the range [-pi/2, pi/2].
ASINH()Inverse hyperbolic sine
DOUBLE PRECISION
ASINH (number)
| Parameter | Description |
|---|---|
number |
Any non- |
The result is in the range [-INF, INF].
ATAN()Arc tangent
DOUBLE PRECISION
ATAN (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
The result is an angle in the range <-pi/2, pi/2>.
ATAN2()Two-argument arc tangent
DOUBLE PRECISION
ATAN2 (y, x)
| Parameter | Description |
|---|---|
y |
An expression of a numeric type |
x |
An expression of a numeric type |
Returns the angle whose sine-to-cosine ratio is given by the two arguments, and whose sine and cosine signs correspond to the signs of the arguments.This allows results across the entire circle, including the angles -pi/2 and pi/2.
The result is an angle in the range [-pi, pi].
If x is negative, the result is pi if y is 0, and -pi if y is -0.
If both y and x are 0, the result is meaningless.An error will be raised if both arguments are 0.
A fully equivalent description of this function is the following: ATAN2(y, x) is the angle between the positive X-axis and the line from the origin to the point (x, y).This also makes it obvious that ATAN2(0, 0) is undefined.
If x is greater than 0, ATAN2(y, x) is the same as ATAN(y/x).
If both sine and cosine of the angle are already known, ATAN2(sin, cos) gives the angle.
ATANH()Inverse hyperbolic tangent
DOUBLE PRECISION
ATANH (number)
| Parameter | Description |
|---|---|
number |
Any non- |
The result is a number in the range [-INF, INF].
CEIL(), CEILING()Ceiling of a number
BIGINT or INT128 for exact numeric number, or DOUBLE PRECISION or DECFLOAT for floating point number
CEIL[ING] (number)
| Parameter | Description |
|---|---|
number |
An expression of a numeric type |
Returns the smallest whole number greater than or equal to the argument.
ASCII_CHAR()Character from ASCII code
CHAR(1) CHARACTER SET NONE
ASCII_CHAR (code)
| Parameter | Description |
|---|---|
code |
An integer within the range from 0 to 255 |
Returns the ASCII character corresponding to the number passed in the argument.
|
Important
|
|
HEX_DECODE()Decode a hexadecimal string to binary
VARBINARY or BLOB
HEX_DECODE (hex_data)
| Parameter | Description |
|---|---|
hex_data |
Hex encoded data |
HEX_DECODE decodes a string with hex-encoded data, and returns the decoded value as VARBINARY or BLOB as appropriate for the input.If the length of the type of hex_data is not a multiple of 2, an error is raised at prepare time.If the length of the value of hex_data is not a multiple of 2, an error is raised at execution time.
When the input is not BLOB, the length of the resulting type is calculated as type_length / 2, where type_length is the maximum length in characters of the input type.
HEX_DECODEselect cast(hex_decode('48657861646563696D616C') as varchar(12))
from rdb$database;
CAST
============
Hexadecimal
HEX_ENCODE()Encodes a (binary) value to a hexadecimal string
VARCHAR CHARACTER SET ASCII or BLOB SUB_TYPE TEXT CHARACTER SET ASCII
HEX_ENCODE (binary_data)
| Parameter | Description |
|---|---|
binary_data |
Binary data (or otherwise convertible to binary) to encode |
HEX_ENCODE encodes binary_data with hex, and returns the encoded value as a VARCHAR CHARACTER SET ASCII or BLOB SUB_TYPE TEXT CHARACTER SET ASCII as appropriate for the input.
When the input is not BLOB, the length of the resulting type is calculated as type_length * 2, where type_length is the maximum length in bytes of the input type.If this length exceeds the maximum length of VARCHAR, the function returns a BLOB.
HEX_ENCODEselect hex_encode('Hexadecimal')
from rdb$database;
HEX_ENCODE
======================
48657861646563696D616C
LEFT()Extracts the leftmost part of a string
VARCHAR or BLOB
LEFT (string, length)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
length |
Integer expression.The number of characters to return |
This function fully supports text BLOBs of any length, including those with a multi-byte character set.
If string is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(n) with n the length of the input string.
If the length argument exceeds the string length, the input string is returned unchanged.
If the length argument is not a whole number, bankers' rounding (round-to-even) is applied, i.e. 0.5 becomes 0, 1.5 becomes 2, 2.5 becomes 2, 3.5 becomes 4, etc.
LOWER()Converts a string to lowercase
(VAR)CHAR, (VAR)BINARY or BLOB
LOWER (string)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
Returns the lowercase equivalent of the input string.The exact result depends on the character set.With ASCII or NONE for instance, only ASCII characters are lowercased;with character set OCTETS/(VAR)BINARY, the entire string is returned unchanged.
LOWER Examplesselect Sheriff from Towns
where lower(Name) = 'cooper''s valley'
LPAD()Left-pads a string
VARCHAR or BLOB
LPAD (str, endlen [, padstr])
| Parameter | Description |
|---|---|
str |
An expression of a string type |
endlen |
Output string length |
padstr |
The character or string to be used to pad the source string up to the specified length.Default is space (“ |
Left-pads a string with spaces or with a user-supplied string until a given length is reached.
This function fully supports text BLOBs of any length and character set.
If str is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(endlen).
If padstr is given and equal to '' (empty string), no padding takes place.
If endlen is less than the current string length, the string is truncated to endlen, even if padstr is the empty string.
|
Warning
|
When used on a |
LPAD Exampleslpad ('Hello', 12) -- returns ' Hello'
lpad ('Hello', 12, '-') -- returns '-------Hello'
lpad ('Hello', 12, '') -- returns 'Hello'
lpad ('Hello', 12, 'abc') -- returns 'abcabcaHello'
lpad ('Hello', 12, 'abcdefghij') -- returns 'abcdefgHello'
lpad ('Hello', 2) -- returns 'He'
lpad ('Hello', 2, '-') -- returns 'He'
lpad ('Hello', 2, '') -- returns 'He'
OCTET_LENGTH()Length in bytes (octets) of a string or binary value
INTEGER, or BIGINT for BLOB
OCTET_LENGTH (string)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
Gives the length in bytes (octets) of the input string.For multi-byte character sets, this may be less than the number of characters times the “formal” number of bytes per character as found in RDB$CHARACTER_SETS.
|
Note
|
With arguments of type |
OCTET_LENGTH Examplesselect octet_length('Hello!') from rdb$database
-- returns 6
select octet_length(_iso8859_1 'Grüß di!') from rdb$database
-- returns 8: ü and ß take up one byte each in ISO8859_1
select octet_length
(cast (_iso8859_1 'Grüß di!' as varchar(24) character set utf8))
from rdb$database
-- returns 10: ü and ß take up two bytes each in UTF8
select octet_length
(cast (_iso8859_1 'Grüß di!' as char(24) character set utf8))
from rdb$database
-- returns 26: all 24 CHAR positions count, and two of them are 2-byte
OVERLAY()Overwrites part of, or inserts into, a string
VARCHAR or BLOB
OVERLAY (string PLACING replacement FROM pos [FOR length])
| Parameter | Description |
|---|---|
string |
The string into which the replacement takes place |
replacement |
Replacement string |
pos |
The position from which replacement takes place (starting position) |
length |
The number of characters that are to be overwritten |
By default, the number of characters removed from (overwritten in) the host string equals the length of the replacement string.With the optional fourth argument, a different number of characters can be specified for removal.
This function supports BLOBs of any length.
If string or replacement is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(n) with n the sum of the lengths of string and replacement.
As usual in SQL string functions, pos is 1-based.
If pos is beyond the end of string, replacement is placed directly after string.
If the number of characters from pos to the end of string is smaller than the length of replacement (or than the length argument, if present), string is truncated at pos and replacement placed after it.
The effect of a “FOR 0” clause is that replacement is inserted into string.
If any argument is NULL, the result is NULL.
If pos or length is not a whole number, bankers' rounding (round-to-even) is applied, i.e. 0.5 becomes 0, 1.5 becomes 2, 2.5 becomes 2, 3.5 becomes 4, etc.
|
Warning
|
When used on a |
OVERLAY Examplesoverlay ('Goodbye' placing 'Hello' from 2) -- returns 'GHelloe'
overlay ('Goodbye' placing 'Hello' from 5) -- returns 'GoodHello'
overlay ('Goodbye' placing 'Hello' from 8) -- returns 'GoodbyeHello'
overlay ('Goodbye' placing 'Hello' from 20) -- returns 'GoodbyeHello'
overlay ('Goodbye' placing 'Hello' from 2 for 0) -- r. 'GHellooodbye'
overlay ('Goodbye' placing 'Hello' from 2 for 3) -- r. 'GHellobye'
overlay ('Goodbye' placing 'Hello' from 2 for 6) -- r. 'GHello'
overlay ('Goodbye' placing 'Hello' from 2 for 9) -- r. 'GHello'
overlay ('Goodbye' placing '' from 4) -- returns 'Goodbye'
overlay ('Goodbye' placing '' from 4 for 3) -- returns 'Gooe'
overlay ('Goodbye' placing '' from 4 for 20) -- returns 'Goo'
overlay ('' placing 'Hello' from 4) -- returns 'Hello'
overlay ('' placing 'Hello' from 4 for 0) -- returns 'Hello'
overlay ('' placing 'Hello' from 4 for 20) -- returns 'Hello'
POSITION()Finds the position of the first or next occurrence of a substring in a string
INTEGER
POSITION (substr IN string) | POSITION (substr, string [, startpos])
| Parameter | Description |
|---|---|
substr |
The substring whose position is to be searched for |
string |
The string which is to be searched |
startpos |
The position in string where the search is to start |
Returns the (1-based) position of the first occurrence of a substring in a host string.With the optional third argument, the search starts at a given offset, disregarding any matches that may occur earlier in the string.If no match is found, the result is 0.
|
Note
|
|
|
Warning
|
When used on a |
POSITION Examplesposition ('be' in 'To be or not to be') -- returns 4
position ('be', 'To be or not to be') -- returns 4
position ('be', 'To be or not to be', 4) -- returns 4
position ('be', 'To be or not to be', 8) -- returns 17
position ('be', 'To be or not to be', 18) -- returns 0
position ('be' in 'Alas, poor Yorick!') -- returns 0
REPLACE()Replaces all occurrences of a substring in a string
VARCHAR or BLOB
REPLACE (str, find, repl)
| Parameter | Description |
|---|---|
str |
The string in which the replacement is to take place |
find |
The string to search for |
repl |
The replacement string |
This function fully supports text BLOBs of any length and character set.
If any argument is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(n) with n calculated from the lengths of str, find and repl in such a way that even the maximum possible number of replacements won’t overflow the field.
If find is the empty string, str is returned unchanged.
If repl is the empty string, all occurrences of find are deleted from str.
If any argument is NULL, the result is always NULL, even if nothing would have been replaced.
|
Warning
|
When used on a |
REPLACE Examplesreplace ('Billy Wilder', 'il', 'oog') -- returns 'Boogly Woogder'
replace ('Billy Wilder', 'il', '') -- returns 'Bly Wder'
replace ('Billy Wilder', null, 'oog') -- returns NULL
replace ('Billy Wilder', 'il', null) -- returns NULL
replace ('Billy Wilder', 'xyz', null) -- returns NULL (!)
replace ('Billy Wilder', 'xyz', 'abc') -- returns 'Billy Wilder'
replace ('Billy Wilder', '', 'abc') -- returns 'Billy Wilder'
REVERSE()Reverses a string
VARCHAR
REVERSE (string)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
REVERSE Examplesreverse ('spoonful') -- returns 'lufnoops'
reverse ('Was it a cat I saw?') -- returns '?was I tac a ti saW'
|
Tip
|
This function is useful if you want to group, search or order on string endings, e.g. when dealing with domain names or email addresses:
|
ASCII_VAL()ASCII code from string
SMALLINT
ASCII_VAL (ch)
| Parameter | Description |
|---|---|
ch |
A string of the |
Returns the ASCII code of the character passed in.
If the argument is a string with more than one character, the ASCII code of the first character is returned.
If the argument is an empty string, 0 is returned.
If the argument is NULL, NULL is returned.
If the first character of the argument string is multi-byte, an error is raised.
RIGHT()Extracts the rightmost part of a string
VARCHAR or BLOB
RIGHT (string, length)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
length |
Integer.The number of characters to return |
This function supports text BLOBs of any length.
If string is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(n) with n the length of the input string.
If the length argument exceeds the string length, the input string is returned unchanged.
If the length argument is not a whole number, bankers' rounding (round-to-even) is applied, i.e. 0.5 becomes 0, 1.5 becomes 2, 2.5 becomes 2, 3.5 becomes 4, etc.
|
Warning
|
When used on a |
RPAD()Right-pads a string
VARCHAR or BLOB
RPAD (str, endlen [, padstr])
| Parameter | Description |
|---|---|
str |
An expression of a string type |
endlen |
Output string length |
endlen |
The character or string to be used to pad the source string up to the specified length.Default is space ( |
Right-pads a string with spaces or with a user-supplied string until a given length is reached.
This function fully supports text BLOBs of any length and character set.
If str is a BLOB, the result is a BLOB.Otherwise, the result is a VARCHAR(endlen).
If padstr is given and equals '' (empty string), no padding takes place.
If endlen is less than the current string length, the string is truncated to endlen, even if padstr is the empty string.
|
Warning
|
When used on a |
RPAD Examplesrpad ('Hello', 12) -- returns 'Hello '
rpad ('Hello', 12, '-') -- returns 'Hello-------'
rpad ('Hello', 12, '') -- returns 'Hello'
rpad ('Hello', 12, 'abc') -- returns 'Helloabcabca'
rpad ('Hello', 12, 'abcdefghij') -- returns 'Helloabcdefg'
rpad ('Hello', 2) -- returns 'He'
rpad ('Hello', 2, '-') -- returns 'He'
rpad ('Hello', 2, '') -- returns 'He'
SUBSTRING()Extracts a substring by position and length, or by SQL regular expression
VARCHAR or BLOB
SUBSTRING ( <substring-args> )
<substring-args> ::=
str FROM startpos [FOR length]
| str SIMILAR <similar-pattern> ESCAPE <escape>
<similar-pattern> ::=
<similar-pattern-R1>
<escape> " <similar-pattern-R2> <escape> "
<similar-pattern-R3>
| Parameter | Description |
|---|---|
str |
An expression of a string type |
startpos |
Integer expression, the position from which to start retrieving the substring |
length |
The number of characters to retrieve after the startpos |
similar-pattern |
SQL regular expression pattern to search for the substring |
escape |
Escape character |
Returns a string’s substring starting at the given position, either to the end of the string or with a given length, or extracts a substring using an SQL regular expression pattern.
If any argument is NULL, the result is also NULL.
|
Warning
|
When used on a |
SUBSTRINGIn its simple, positional form (with FROM), this function returns the substring starting at character position startpos (the first character being 1).Without the FOR argument, it returns all the remaining characters in the string.With FOR, it returns length characters or the remainder of the string, whichever is shorter.
When startpos is smaller than 1, substring behaves as if the string has 1 - startpos extra positions before the actual first character at position 1.The length is considered from this imaginary start of the string, so the resulting string could be shorter than the specified length, or even empty.
The function fully supports binary and text BLOBs of any length, and with any character set.If str is a BLOB, the result is also a BLOB.For any other argument type, the result is a VARCHAR.
For non-BLOB arguments, the width of the result field is always equal to the length of str, regardless of startpos and length.So, substring('pinhead' from 4 for 2) will return a VARCHAR(7) containing the string 'he'.
insert into AbbrNames(AbbrName)
select substring(LongName from 1 for 3) from LongNames;
select substring('abcdef' from 1 for 2) from rdb$database;
-- result: 'ab'
select substring('abcdef' from 2) from rdb$database;
-- result: 'bcdef'
select substring('abcdef' from 0 for 2) from rdb$database;
-- result: 'a'
-- and NOT 'ab', because there is "nothing" at position 0
select substring('abcdef' from -5 for 2) from rdb$database;
-- result: ''
-- length ends before the actual start of the string
SUBSTRINGIn the regular expression form (with SIMILAR), the SUBSTRING function returns part of the string matching an SQL regular expression pattern.If no match is found, NULL is returned.
The SIMILAR pattern is formed from three SQL regular expression patterns, R1, R2 and R3.The entire pattern takes the form of R1 || '<escape>"' || R2 || '<escape>"' || R3, where <escape> is the escape character defined in the ESCAPE clause.R2 is the pattern that matches the substring to extract, and is enclosed between escaped double quotes (<escape>", e.g. “#"” with escape character ‘#’).R1 matches the prefix of the string, and R3 the suffix of the string.Both R1 and R3 are optional (they can be empty), but the pattern must match the entire string.In other words, it is not sufficient to specify a pattern that only finds the substring to extract.
|
Tip
|
The escaped double quotes around R2 can be compared to defining a single capture group in more common regular expression syntax like PCRE.That is, the full pattern is equivalent to |
|
Note
|
If any one of R1, R2, or R3 is not a zero-length string and does not have the format of an SQL regular expression, then an exception is raised. |
The full SQL regular expression format is described in Syntax: SQL Regular Expressions
substring('abcabc' similar 'a#"bcab#"c' escape '#') -- bcab
substring('abcabc' similar 'a#"%#"c' escape '#') -- bcab
substring('abcabc' similar '_#"%#"_' escape '#') -- bcab
substring('abcabc' similar '#"(abc)*#"' escape '#') -- abcabc
substring('abcabc' similar '#"abc#"' escape '#') -- <null>
TRIM()Trims leading and/or trailing spaces or other substrings from a string
VARCHAR or BLOB
TRIM ([<adjust>] str)
<adjust> ::= {[<where>] [what]} FROM
<where> ::= BOTH | LEADING | TRAILING
| Parameter | Description |
|---|---|
str |
An expression of a string type |
where |
The position the substring is to be removed from — |
what |
The substring that should be removed (multiple times if there are several matches) from the beginning, the end, or both sides of the input string str.By default, it is space ( |
Removes leading and/or trailing spaces (or optionally other strings) from the input string.
|
Note
|
If str is a |
|
Warning
|
When used on a |
TRIM Examplesselect trim (' Waste no space ') from rdb$database
-- returns 'Waste no space'
select trim (leading from ' Waste no space ') from rdb$database
-- returns 'Waste no space '
select trim (leading '.' from ' Waste no space ') from rdb$database
-- returns ' Waste no space '
select trim (trailing '!' from 'Help!!!!') from rdb$database
-- returns 'Help'
select trim ('la' from 'lalala I love you Ella') from rdb$database
-- returns ' I love you El'
select trim ('la' from 'Lalala I love you Ella') from rdb$database
-- returns 'Lalala I love you El'
UNICODE_CHAR()Character from Unicode code point
CHAR(1) CHARACTER SET UTF8
UNICODE_CHAR (code)
| Parameter | Description |
|---|---|
code |
The Unicode code point (range 0…0x10FFFF) |
Returns the character corresponding to the Unicode code point passed in the argument.
UNICODE_VAL()Unicode code point from string
INTEGER
UNICODE_VAL (ch)
| Parameter | Description |
|---|---|
ch |
A string of the |
Returns the Unicode code point (range 0…0x10FFFF) of the character passed in.
If the argument is a string with more than one character, the Unicode code point of the first character is returned.
If the argument is an empty string, 0 is returned.
If the argument is NULL, NULL is returned.
UPPER()Converts a string to uppercase
(VAR)CHAR, (VAR)BINARY or BLOB
UPPER (str)
| Parameter | Description |
|---|---|
str |
An expression of a string type |
Returns the uppercase equivalent of the input string.The exact result depends on the character set.With ASCII or NONE for instance, only ASCII characters are uppercased;with character set OCTETS/(VAR)BINARY, the entire string is returned unchanged.
UPPER Examplesselect upper(_iso8859_1 'Débâcle')
from rdb$database
-- returns 'DÉBÂCLE'
select upper(_iso8859_1 'Débâcle' collate fr_fr)
from rdb$database
-- returns 'DEBACLE', following French uppercasing rules
BASE64_DECODE()Decodes a base64 string to binary
VARBINARY or BLOB
BASE64_DECODE (base64_data)
| Parameter | Description |
|---|---|
base64_data |
Base64 encoded data, padded with |
BASE64_DECODE decodes a string with base64-encoded data, and returns the decoded value as VARBINARY or BLOB as appropriate for the input.If the length of the type of base64_data is not a multiple of 4, an error is raised at prepare time.If the length of the value of base64_data is not a multiple of 4, an error is raised at execution time.
When the input is not BLOB, the length of the resulting type is calculated as type_length * 3 / 4, where type_length is the maximum length in characters of the input type.
BASE64_DECODEselect cast(base64_decode('VGVzdCBiYXNlNjQ=') as varchar(12))
from rdb$database;
CAST
============
Test base64
BASE64_ENCODE()Encodes a (binary) value to a base64 string
VARCHAR CHARACTER SET ASCII or BLOB SUB_TYPE TEXT CHARACTER SET ASCII
BASE64_ENCODE (binary_data)
| Parameter | Description |
|---|---|
binary_data |
Binary data (or otherwise convertible to binary) to encode |
BASE64_ENCODE encodes binary_data with base64, and returns the encoded value as a VARCHAR CHARACTER SET ASCII or BLOB SUB_TYPE TEXT CHARACTER SET ASCII as appropriate for the input.The returned value is padded with ‘=’ so its length is a multiple of 4.
When the input is not BLOB, the length of the resulting type is calculated as type_length * 4 / 3 rounded up to a multiple of four, where type_length is the maximum length in bytes of the input type.If this length exceeds the maximum length of VARCHAR, the function returns a BLOB.
BASE64_ENCODEselect base64_encode('Test base64')
from rdb$database;
BASE64_ENCODE
================
VGVzdCBiYXNlNjQ=
BIT_LENGTH()String or binary length in bits
INTEGER, or BIGINT for BLOB
BIT_LENGTH (string)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
Gives the length in bits of the input string.For multi-byte character sets, this may be less than the number of characters times 8 times the “formal” number of bytes per character as found in RDB$CHARACTER_SETS.
|
Note
|
With arguments of type |
BIT_LENGTH Examplesselect bit_length('Hello!') from rdb$database
-- returns 48
select bit_length(_iso8859_1 'Grüß di!') from rdb$database
-- returns 64: ü and ß take up one byte each in ISO8859_1
select bit_length
(cast (_iso8859_1 'Grüß di!' as varchar(24) character set utf8))
from rdb$database
-- returns 80: ü and ß take up two bytes each in UTF8
select bit_length
(cast (_iso8859_1 'Grüß di!' as char(24) character set utf8))
from rdb$database
-- returns 208: all 24 CHAR positions count, and two of them are 16-bit
BLOB_APPEND()Efficient concatenation of blobs
BLOB
BLOB_APPEND(expr1, expr2 [, exprN ... ])
| Parameter | Description |
|---|---|
exprN |
An expression of a type convertible to |
The BLOB_APPEND function concatenates blobs without creating intermediate BLOBs, avoiding excessive memory consumption and growth of the database file.The BLOB_APPEND function takes two or more arguments and adds them to a BLOB which remains open for further modification by a subsequent BLOB_APPEND call.
The resulting BLOB is left open for writing instead of being closed when the function returns.In other words, the BLOB can be appended as many times as required.The engine marks the BLOB returned by BLOB_APPEND with an internal flag, BLB_close_on_read, and closes it automatically when needed.
The first argument determines the behaviour of the function:
NULL: new, empty BLOB SUB_TYPE TEXT is created, using the connection character set as the character set
permanent BLOB (from a table) or temporary BLOB which was already closed: new BLOB is created with the same subtype and, if subtype is TEXT the same character set, populated with the content of the original BLOB.
temporary unclosed BLOB with the BLB_close_on_read flag (e.g. created by another call to BLOB_APPEND): used as-is, remaining arguments are appended to this BLOB
other data types: a new BLOB SUB_TYPE TEXT is created, populated with the original argument converted to string.If the original value is a character type, its character set is used (for string literals, the connection character set), otherwise the connection character set.
Other arguments can be of any type.The following behavior is defined for them:
NULLs are ignored (behaves as empty string)
BLOBs, if necessary, are transliterated to the character set of the first argument and their contents are appended to the result
other data types are converted to strings (as usual) and appended to the result
The BLOB_APPEND function returns a temporary unclosed BLOB with the BLB_close_on_read flag.If the first argument is such a temporary unclosed BLOB (e.g. created by a previous call to BLOB_APPEND), it will be used as-is, otherwise a new BLOB is created.Thus, a series of operations like blob = BLOB_APPEND (blob, …) will result in the creation of at most one BLOB (unless you try to append a BLOB to itself).This blob will be automatically closed by the engine when the client reads it, assigns it to a table, or uses it in other expressions that require reading the content.
|
Warning
|
Important caveats for
BLOB_APPEND
|
|
Note
|
Testing a blob for |
|
Tip
|
Use |
BLOB_APPEND Examplesexecute block
returns (b blob sub_type text)
as
begin
-- creates a new temporary not closed BLOB
-- and writes the string from the 2nd argument into it
b = blob_append(null, 'Hello ');
-- adds two strings to the temporary BLOB without closing it
b = blob_append(b, 'World', '!');
-- comparing a BLOB with a string will close it, because the BLOB needs to be read
if (b = 'Hello World!') then
begin
-- ...
end
-- creates a temporary closed BLOB by adding a string to it
b = b || 'Close';
suspend;
end
CHAR_LENGTH(), CHARACTER_LENGTH()String length in characters
INTEGER, or BIGINT for BLOB
CHAR_LENGTH (string) | CHARACTER_LENGTH (string)
| Parameter | Description |
|---|---|
string |
An expression of a string type |
Gives the length in characters of the input string.
|
Note
|
|
CHAR_LENGTH Examplesselect char_length('Hello!') from rdb$database
-- returns 6
select char_length(_iso8859_1 'Grüß di!') from rdb$database
-- returns 8
select char_length
(cast (_iso8859_1 'Grüß di!' as varchar(24) character set utf8))
from rdb$database
-- returns 8; the fact that ü and ß take up two bytes each is irrelevant
select char_length
(cast (_iso8859_1 'Grüß di!' as char(24) character set utf8))
from rdb$database
-- returns 24: all 24 CHAR positions count
CRYPT_HASH()Cryptographic hash
VARBINARY
CRYPT_HASH (value USING <hash>) <hash> ::= MD5 | SHA1 | SHA256 | SHA512
| Parameter | Description |
|---|---|
value |
Expression of value of any type;non-string or non-binary types are converted to string |
hash |
Cryptographic hash algorithm to apply |
CRYPT_HASH returns a cryptographic hash calculated from the input argument using the specified algorithm.If the input argument is not a string or binary type, it is converted to string before hashing.
This function returns a VARBINARY with the length depending on the specified algorithm.
|
Note
|
|
CRYPT_HASHx with the SHA512 algorithmselect crypt_hash(x using sha512) from y;
HASH()Non-cryptographic hash
INTEGER, BIGINT
HASH (value [USING <hash>]) <hash> ::= CRC32
| Parameter | Description |
|---|---|
value |
Expression of value of any type;non-string or non-binary types are converted to string |
hash |
Non-cryptographic hash algorithm to apply |
HASH returns a hash value for the input argument.If the input argument is not a string or binary type, it is converted to string before hashing.
The optional USING clause specifies the non-cryptographic hash algorithm to apply.When the USING clause is absent, the legacy PJW algorithm is applied;this is identical to its behaviour in previous Firebird versions.
This function fully supports text BLOBs of any length and character set.
When no algorithm is specified, Firebird applies the 64-bit variant of the non-cryptographic PJW hash function (also known as ELF64).This is a fast algorithm for general purposes (hash tables, etc.), but its collision quality is suboptimal.Other hash functions — specified explicitly in the USING clause, or cryptographic hashes through [fblangref50-scalarfuncs-crypthash] — should be used for more reliable hashing.
The HASH function returns BIGINT for this algorithm
CRC32With CRC32, Firebird applies the CRC32 algorithm using the polynomial 0x04C11DB7.
The HASH function returns INTEGER for this algorithm.
HASHHashing x with the CRC32 algorithm
select hash(x using crc32) from y;
Hashing x with the legacy PJW algorithm
select hash(x) from y;
DATEADD()Adds or subtracts datetime units from a datetime value
DATE, TIME or TIMESTAMP
DATEADD (<args>)
<args> ::=
<amount> <unit> TO <datetime>
| <unit>, <amount>, <datetime>
<amount> ::= an integer expression (negative to subtract)
<unit> ::=
YEAR | MONTH | WEEK | DAY
| HOUR | MINUTE | SECOND | MILLISECOND
<datetime> ::= a DATE, TIME or TIMESTAMP expression
| Parameter | Description |
|---|---|
amount |
An integer expression of the |
unit |
Date/time unit |
datetime |
An expression of the |
Adds the specified number of years, months, weeks, days, hours, minutes, seconds or milliseconds to a date/time value.
The result type is determined by the third argument.
With TIMESTAMP and DATE arguments, all units can be used.
With TIME arguments, only HOUR, MINUTE, SECOND and MILLISECOND can be used.
DATEADDdateadd (28 day to current_date)
dateadd (-6 hour to current_time)
dateadd (month, 9, DateOfConception)
dateadd (-38 week to DateOfBirth)
dateadd (minute, 90, cast('now' as time))
dateadd (? year to date '11-Sep-1973')
select
cast(dateadd(-1 * extract(millisecond from ts) millisecond to ts) as varchar(30)) as t,
extract(millisecond from ts) as ms
from (
select timestamp '2014-06-09 13:50:17.4971' as ts
from rdb$database
) a
T MS ------------------------ ------ 2014-06-09 13:50:17.0000 497.1
DATEDIFF()Difference between two datetime values in a datetime unit
BIGINT, or NUMERIC(18,1) for MILLISECOND
DATEDIFF (<args>)
<args> ::=
<unit> FROM <moment1> TO <moment2>
| <unit>, <moment1>, <moment2>
<unit> ::=
YEAR | MONTH | WEEK | DAY
| HOUR | MINUTE | SECOND | MILLISECOND
<momentN> ::= a DATE, TIME or TIMESTAMP expression
| Parameter | Description |
|---|---|
unit |
Date/time unit |
moment1 |
An expression of the |
moment2 |
An expression of the |
Returns the number of years, months, weeks, days, hours, minutes, seconds or milliseconds elapsed between two date/time values.
DATE and TIMESTAMP arguments can be combined.No other mixes are allowed.
With TIMESTAMP and DATE arguments, all units can be used.
With TIME arguments, only HOUR, MINUTE, SECOND and MILLISECOND can be used.
DATEDIFF doesn’t look at any smaller units than the one specified in the first argument.As a result,
datediff (year, date '1-Jan-2009', date '31-Dec-2009') returns 0, but
datediff (year, date '31-Dec-2009', date '1-Jan-2010') returns 1
It does, however, look at all the bigger units. So:
datediff (day, date '26-Jun-1908', date '11-Sep-1973') returns 23818
A negative result value indicates that moment2 lies before moment1.
DATEDIFF Examplesdatediff (hour from current_timestamp to timestamp '12-Jun-2059 06:00')
datediff (minute from time '0:00' to current_time)
datediff (month, current_date, date '1-1-1900')
datediff (day from current_date to cast(? as date))
EXTRACT()Extracts a datetime unit from a datetime value
SMALLINT or NUMERIC
EXTRACT (<part> FROM <datetime>)
<part> ::=
YEAR | MONTH | QUARTER | WEEK
| DAY | WEEKDAY | YEARDAY
| HOUR | MINUTE | SECOND | MILLISECOND
| TIMEZONE_HOUR | TIMEZONE_MINUTE
<datetime> ::= a DATE, TIME or TIMESTAMP expression
| Parameter | Description |
|---|---|
part |
Date/time unit |
datetime |
An expression of the |
Extracts and returns an element from a DATE, TIME or TIMESTAMP expression.
The returned data types and possible ranges are shown in the table below.If you try to extract a part that isn’t present in the date/time argument (e.g. SECOND from a DATE or YEAR from a TIME), an error occurs.
| Part | Type | Range | Comment |
|---|---|---|---|
|
|
1-9999 |
|
|
|
1-12 |
|
|
|
1-4 |
|
|
|
1-53 |
|
|
|
1-31 |
|
|
|
0-6 |
0 = Sunday |
|
|
0-365 |
0 = January 1 |
|
|
0-23 |
|
|
|
0-59 |
|
|
|
0.0000-59.9999 |
includes millisecond as fraction |
|
|
0.0-999.9 |
|
|
|
-23 - +23 |
|
|
|
-59 - +59 |
|
MILLISECONDExtracts the millisecond value from a TIME or TIMESTAMP.The data type returned is NUMERIC(9,1).
|
Note
|
If you extract the millisecond from [fblangref50-contextvars-current-time], be aware that this variable defaults to seconds precision, so the result will always be 0.Extract from |
WEEKExtracts the ISO-8601 week number from a DATE or TIMESTAMP.ISO-8601 weeks start on a Monday and always have the full seven days.Week 1 is the first week that has a majority (at least 4) of its days in the new year.The first 1-3 days of the year may belong to the last week (52 or 53) of the previous year.Likewise, a year’s final 1-3 days may belong to week 1 of the following year.
|
Caution
|
Be careful when combining Please also notice that |
FIRST_DAY()Returns the first day of a time period containing a datetime value
DATE, TIMESTAMP (with or without time zone)
FIRST_DAY(OF <period> FROM date_or_timestamp) <period> ::= YEAR | MONTH | QUARTER | WEEK
| Parameter | Description |
|---|---|
date_or_timestamp |
Expression of type |
FIRST_DAY returns a date or timestamp (same as the type of date_or_timestamp) with the first day of the year, month or week of a given date or timestamp value.
|
Note
|
|
FIRST_DAYselect
first_day(of month from current_date),
first_day(of year from current_timestamp),
first_day(of week from date '2017-11-01'),
first_day(of quarter from date '2017-11-01')
from rdb$database;
LAST_DAY()Returns the last day of a time period containing a datetime value
DATE, TIMESTAMP (with or without time zone)
LAST_DAY(OF <period> FROM date_or_timestamp) <period> ::= YEAR | MONTH | QUARTER | WEEK
| Parameter | Description |
|---|---|
date_or_timestamp |
Expression of type |
LAST_DAY returns a date or timestamp (same as the type of date_or_timestamp) with the last day of the year, month or week of a given date or timestamp value.
|
Note
|
|
LAST_DAYselect
last_day(of month from current_date),
last_day(of year from current_timestamp),
last_day(of week from date '2017-11-01'),
last_day(of quarter from date '2017-11-01')
from rdb$database;
CAST()Converts a value from one data type to another
As specified by target_type
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 !!
| Parameter | Description |
|---|---|
expression |
SQL expression |
sql_datatype |
SQL data type |
CAST converts an expression to the desired data type or domain.If the conversion is not possible, an error is raised.
Alternative syntax, supported only when casting a string literal to a DATE, TIME or TIMESTAMP:
datatype 'date/timestring'
This syntax was already available in InterBase, but was never properly documented.In the SQL standard, this feature is called “datetime literals”.
|
Note
|
Since Firebird 4.0, the use of |
The following table shows the type conversions possible with CAST.
| From | To |
|---|---|
Numeric types |
Numeric types |
|
|
|
|
|
|
Keep in mind that sometimes information is lost, for instance when you cast a TIMESTAMP to a DATE.Also, the fact that types are CAST-compatible is in itself no guarantee that a conversion will succeed.“CAST(123456789 as SMALLINT)” will definitely result in an error, as will “CAST('Judgement Day' as DATE)”.
You can also cast statement parameters to a data type:
cast (? as integer)
This gives you control over the type of the parameter set up by the engine.Please notice that with statement parameters, you always need a full-syntax cast — shorthand casts are not supported.
Casting to a domain or its base type are supported.When casting to a domain, any constraints (NOT NULL and/or CHECK) declared for the domain must be satisfied, or the cast will fail.Please be aware that a CHECK passes if it evaluates to TRUE or NULL!So, given the following statements:
create domain quint as int check (value >= 5000);
select cast (2000 as quint) from rdb$database; -- (1)
select cast (8000 as quint) from rdb$database; -- (2)
select cast (null as quint) from rdb$database; -- (3)
only cast number 1 will result in an error.
When the TYPE OF modifier is used, the expression is cast to the base type of the domain, ignoring any constraints.With domain quint defined as above, the following two casts are equivalent and will both succeed:
select cast (2000 as type of quint) from rdb$database;
select cast (2000 as int) from rdb$database;
If TYPE OF is used with a (VAR)CHAR type, its character set and collation are retained:
create domain iso20 varchar(20) character set iso8859_1;
create domain dunl20 varchar(20) character set iso8859_1 collate du_nl;
create table zinnen (zin varchar(20));
commit;
insert into zinnen values ('Deze');
insert into zinnen values ('Die');
insert into zinnen values ('die');
insert into zinnen values ('deze');
select cast(zin as type of iso20) from zinnen order by 1;
-- returns Deze -> Die -> deze -> die
select cast(zin as type of dunl20) from zinnen order by 1;
-- returns deze -> Deze -> die -> Die
|
Warning
|
If a domain’s definition is changed, existing |
It is also possible to cast expressions to the type of an existing table or view column.Only the type itself is used;in the case of string types, this includes the character set but not the collation.Constraints and default values of the source column are not applied.
create table ttt (
s varchar(40) character set utf8 collate unicode_ci_ai
);
commit;
select cast ('Jag har många vänner' as type of column ttt.s)
from rdb$database;
|
Warning
|
Warnings
If a column’s definition is altered, existing |
A full-syntax cast:
select cast ('12' || '-June-' || '1959' as date) from rdb$database
A shorthand string-to-date cast:
update People set AgeCat = 'Old'
where BirthDate < date '1-Jan-1943'
Notice that you can drop even the shorthand cast from the example above, as the engine will understand from the context (comparison to a DATE field) how to interpret the string:
update People set AgeCat = 'Old'
where BirthDate < '1-Jan-1943'
However, this is not always possible.The cast below cannot be dropped, otherwise the engine would find itself with an integer to be subtracted from a string:
select cast('today' as date) - 7 from rdb$database
BIN_AND()Bitwise AND
integer type (the widest type of the arguments)
|
Note
|
|
BIN_AND (number, number [, number ...])
| Parameter | Description |
|---|---|
number |
A number of an integer type |
Returns the result of the bitwise AND operation on the argument(s).
BIN_NOT()Bitwise NOT
integer type matching the argument
|
Note
|
|
BIN_NOT (number)
| Parameter | Description |
|---|---|
number |
A number of an integer type |
Returns the result of the bitwise NOT operation on the argument, i.e. one’s complement.
[fblangref50-scalarfuncs-bin-or], [fblangref50-scalarfuncs-bin-xor] and others in this set.
BIN_OR()Bitwise OR
integer type (the widest type of the arguments)
|
Note
|
|
BIN_OR (number, number [, number ...])
| Parameter | Description |
|---|---|
number |
A number of an integer type |
Returns the result of the bitwise OR operation on the argument(s).
BIN_SHL()Bitwise left-shift
BIGINT or INT128 depending on the first argument
BIN_SHL (number, shift)
| Parameter | Description |
|---|---|
number |
A number of an integer type |
shift |
The number of bits the number value is shifted by |
Returns the first argument bitwise left-shifted by the second argument, i.e. a << b or a·2b.
BIN_SHR()Bitwise right-shift with sign extension
BIGINT or INT128 depending on the first argument
BIN_SHR (number, shift)
| Parameter | Description |
|---|---|
number |
A number of an integer type |
shift |
The number of bits the number value is shifted by |
Returns the first argument bitwise right-shifted by the second argument, i.e. a >> b or a/2b.
The operation performed is an arithmetic right shift (x86 SAR), meaning that the sign of the first operand is always preserved.
BIN_XOR()Bitwise XOR
integer type (the widest type of the arguments)
|
Note
|
|
BIN_XOR (number, number [, number ...])
| Parameter | Description |
|---|---|
number |
A number of an integer type |
Returns the result of the bitwise XOR operation on the argument(s).
CHAR_TO_UUID()Converts a string UUID to its binary representation
BINARY(16)
CHAR_TO_UUID (ascii_uuid)
| Parameter | Description |
|---|---|
ascii_uuid |
A 36-character representation of UUID.‘ |
Converts a human-readable 36-char UUID string to the corresponding 16-byte UUID.
CHAR_TO_UUID Examplesselect char_to_uuid('A0bF4E45-3029-2a44-D493-4998c9b439A3') from rdb$database
-- returns A0BF4E4530292A44D4934998C9B439A3 (16-byte string)
select char_to_uuid('A0bF4E45-3029-2A44-X493-4998c9b439A3') from rdb$database
-- error: -Human readable UUID argument for CHAR_TO_UUID must
-- have hex digit at position 20 instead of "X (ASCII 88)"
GEN_UUID()Generates a random binary UUID
BINARY(16)
GEN_UUID ()
Returns a universally unique ID as a 16-byte character string.
GEN_UUID Exampleselect gen_uuid() from rdb$database
-- returns e.g. 017347BFE212B2479C00FA4323B36320 (16-byte string)
UUID_TO_CHAR()Converts a binary UUID to its string representation
CHAR(36)
UUID_TO_CHAR (uuid)
| Parameter | Description |
|---|---|
uuid |
16-byte UUID |
Converts a 16-byte UUID to its 36-character, human-readable ASCII representation.