Examples
select rdb$get_context('SYSTEM', 'DB_NAME') from rdb$database
New.UserAddr = rdb$get_context('SYSTEM', 'CLIENT_ADDRESS');
insert into MyTable (TestField)
values (rdb$get_context('USER_SESSION', 'MyVar'))
Functions for Sequences (Generators)
select rdb$get_context('SYSTEM', 'DB_NAME') from rdb$database
New.UserAddr = rdb$get_context('SYSTEM', 'CLIENT_ADDRESS');
insert into MyTable (TestField)
values (rdb$get_context('USER_SESSION', 'MyVar'))
RDB$SET_CONTEXT()
Creates, sets or clears a variable in one of the user-writable namespaces
INTEGER
RDB$SET_CONTEXT ('<namespace>', <varname>, <value> | NULL) <namespace> ::= USER_SESSION | USER_TRANSACTION <varname> ::= A case-sensitive quoted string of max. 80 characters <value> ::= A value of any type, as long as it's castable to a VARCHAR(255)
Parameter | Description |
---|---|
namespace |
Namespace |
varname |
Variable name.Case-sensitive.Maximum length is 80 characters |
value |
Data of any type provided it can be cast to |
The USER_SESSION
and USER_TRANSACTION
namespaces are initially empty.A user can create and set variables with RDB$SET_CONTEXT()
and retrieve them with [fblangref50-scalarfuncs-get-context].The USER_SESSION
context is bound to the current connection, the USER_TRANSACTION
context to the current transaction.
When a transaction ends, its USER_TRANSACTION
context is cleared.
When a connection is closed, its USER_SESSION
context is cleared.
When a connection is reset using ALTER SESSION RESET
, the USER_TRANSACTION
and USER_SESSION
contexts are cleared.
The function returns 1
when the variable already existed before the call and 0
when it didn’t.To remove a variable from a context, set it to NULL
.If the given namespace doesn’t exist, an error is raised.Both namespace and variable names must be entered as single-quoted, case-sensitive, non-NULL
strings.
Note
|
|
select rdb$set_context('USER_SESSION', 'MyVar', 493) from rdb$database
rdb$set_context('USER_SESSION', 'RecordsFound', RecCounter);
select rdb$set_context('USER_TRANSACTION', 'Savepoints', 'Yes')
from rdb$database
DECFLOAT
COMPARE_DECFLOAT()
Compares two DECFLOAT
values to be equal, different or unordered
SMALLINT
COMPARE_DECFLOAT (decfloat1, decfloat2)
Parameter | Description |
---|---|
decfloatn |
Value or expression of type |
The result is a SMALLINT
value, as follows:
0
|
Values are equal |
1
|
First value is less than second |
2
|
First value is greater than second |
3
|
Values are unordered, i.e. one or both is |
Unlike the comparison operators (‘<
’, ‘=
’, ‘>
’, etc.), comparison is exact: COMPARE_DECFLOAT(2.17, 2.170)
returns 2
not 0
.
NORMALIZE_DECFLOAT()
Returns the simplest, normalized form of a DECFLOAT
DECFLOAT
NORMALIZE_DECFLOAT (decfloat_value)
Parameter | Description |
---|---|
decfloat_value |
Value or expression of type |
For any non-zero value, trailing zeroes are removed with appropriate correction of the exponent.
NORMALIZE_DECFLOAT
-- will return 12
select normalize_decfloat(12.00)
from rdb$database;
-- will return 1.2E+2
select normalize_decfloat(120)
from rdb$database;
QUANTIZE()
Returns a value that is equal in value — except for rounding — to the first argument, but with the same exponent as the second argument
DECFLOAT
QUANTIZE (decfloat_value, exp_value)
Parameter | Description |
---|---|
decfloat_value |
Value or expression to quantize;needs to be of type |
exp_value |
Value or expression to use for its exponent;needs to be of type |
QUANTIZE
returns a DECFLOAT
value that is equal in value and sign (except for rounding) to decfloat_value, and that has an exponent equal to the exponent of exp_value.The type of the return value is DECFLOAT(16)
if both arguments are DECFLOAT(16)
, otherwise the result type is DECFLOAT(34)
.
Note
|
The target exponent is the exponent used in the |
If the exponent of decfloat_value is greater than the one of exp_value, the coefficient of decfloat_value is multiplied by a power of ten, and its exponent decreased.If the exponent is smaller, then its coefficient is rounded using the current decfloat rounding mode, and its exponent is increased.
When it is not possible to achieve the target exponent because the coefficient would exceed the target precision (16 or 34 decimal digits), either a “Decfloat float invalid operation” error is raised or NaN
is returned (depending on the current decfloat traps configuration).
There are almost no restrictions on the exp_value.However, in almost all usages, NaN
/sNaN
/Infinity
will produce an exception (unless allowed by the current decfloat traps configuration), NULL
will make the function return NULL
, and so on.
QUANTIZE
select v, pic, quantize(v, pic) from examples;
V PIC QUANTIZE
====== ====== ========
3.16 0.001 3.160
3.16 0.01 3.16
3.16 0.1 3.2
3.16 1 3
3.16 1E+1 0E+1
-0.1 1 -0
0 1E+5 0E+5
316 0.1 316.0
316 1 316
316 1E+1 3.2E+2
316 1E+2 3E+2
TOTALORDER()
Determines the total or linear order of its arguments
SMALLINT
TOTALORDER (decfloat1, decfloat2)
Parameter | Description |
---|---|
decfloatn |
Value or expression of type |
TOTALORDER
compares two DECFLOAT
values including any special values.The comparison is exact, and returns a SMALLINT
, one of:
-1
|
First value is less than second |
0
|
Values are equal |
1
|
First value is greater than second. |
For TOTALORDER
comparisons, DECFLOAT
values are ordered as follows:
-NaN < -sNaN < -INF < -0.1 < -0.10 < -0 < 0 < 0.10 < 0.1 < INF < sNaN < NaN
DECRYPT()
Decrypts data using a symmetric cipher
VARBINARY
or BLOB
DECRYPT ( encrypted_input
USING <algorithm> [MODE <mode>]
KEY key
[IV iv] [<ctr_type>] [CTR_LENGTH ctr_length]
[COUNTER initial_counter] )
!! See syntax of <<fblangref50-scalarfuncs-encrypt,ENCRYPT
>> for further rules !!
Parameter | Description |
---|---|
encrypted_input |
Encrypted input as a blob or (binary) string |
See [fblangref50-scalarfuncs-tbl-encrypt] for other parameters |
Note
|
|
DECRYPT
Examplesselect decrypt(x'0154090759DF' using sober128 key 'AbcdAbcdAbcdAbcd' iv '01234567')
from rdb$database;
select decrypt(secret_field using aes mode ofb key '0123456701234567' iv init_vector)
from secure_table;
ENCRYPT()
Encrypts data using a symmetric cipher
VARBINARY
or BLOB
ENCRYPT ( input USING <algorithm> [MODE <mode>] KEY key [IV iv] [<ctr_type>] [CTR_LENGTH ctr_length] [COUNTER initial_counter] ) <algorithm> ::= <block_cipher> | <stream_cipher> <block_cipher> ::= AES | ANUBIS | BLOWFISH | KHAZAD | RC5 | RC6 | SAFER+ | TWOFISH | XTEA <stream_cipher> ::= CHACHA20 | RC4 | SOBER128 <mode> ::= CBC | CFB | CTR | ECB | OFB <ctr_type> ::= CTR_BIG_ENDIAN | CTR_LITTLE_ENDIAN
Parameter | Description |
---|---|
input |
Input to encrypt as a blob or (binary) string |
algorithm |
The algorithm to use for decryption |
mode |
The algorithm mode;only for block ciphers |
key |
The encryption/decryption key |
iv |
Initialization vector or nonce;should be specified for block ciphers in all modes except |
ctr_type |
Endianness of the counter;only for |
ctr_length |
Counter length;only for |
initial_counter |
Initial counter value;only for |
Note
|
|
Algorithm | Key size (bytes) | Block size (bytes) | Notes |
---|---|---|---|
Block Ciphers |
|||
|
16, 24, 32 |
16 |
Key size determines the AES variant: |
|
16 - 40, in steps of 4 (4x) |
16 |
|
|
8 - 56 |
8 |
|
|
16 |
8 |
|
|
8 - 128 |
8 |
|
|
8 - 128 |
16 |
|
|
16, 24, 32 |
16 |
|
|
16, 24, 32 |
16 |
|
|
16 |
8 |
|
Stream Ciphers |
|||
|
16, 32 |
1 |
Nonce size (IV) is 8 or 12 bytes.For nonce size 8, initial_counter is a 64-bit integer, for size 12, 32-bit. |
|
5 - 256 |
1 |
|
|
4x |
1 |
Nonce size (IV) is 4y bytes, the length is independent of key size. |
ENCRYPT
Examplesselect encrypt('897897' using sober128 key 'AbcdAbcdAbcdAbcd' iv '01234567')
from rdb$database;
RSA_DECRYPT()
Decrypts data using an RSA private key and removes OAEP or PKCS 1.5 padding
VARBINARY
RSA_DECRYPT (encrypted_input KEY private_key [LPARAM tag_string] [HASH <hash>] [PKCS_1_5]) <hash> ::= MD5 | SHA1 | SHA256 | SHA512
Parameter | Description |
---|---|
encrypted_input |
Input data to decrypt |
private_key |
Private key to apply, PKCS#1 format |
tag_string |
An additional system-specific tag to identify which system encrypted the message;default is |
hash |
The hash used for OAEP padding;default is |
RSA_DECRYPT
decrypts encrypted_input using the RSA private key and then removes padding from the resulting data.
By default, OAEP padding is used.The PKCS_1_5
option will switch to the less secure PKCS 1.5 padding.
Warning
|
The |
Note
|
|
RSA_DECRYPT
Examples
Tip
|
Run the examples of the |
select cast(rsa_decrypt(rdb$get_context('USER_SESSION', 'msg')
key rdb$get_context('USER_SESSION', 'private_key')) as varchar(128))
from rdb$database;
RSA_ENCRYPT()
Pads data using OAEP or PKCS 1.5 and then encrypts it with an RSA public key
VARBINARY
RSA_ENCRYPT (input KEY public_key [LPARAM tag_string] [HASH <hash>] [PKCS_1_5]) <hash> ::= MD5 | SHA1 | SHA256 | SHA512
Parameter | Description |
---|---|
input |
Input data to encrypt |
public_key |
Public key to apply, PKCS#1 format |
tag_string |
An additional system-specific tag to identify which system encrypted the message;default is |
hash |
The hash used for OAEP padding;default is |
RSA_ENCRYPT
pads input using the OAEP or PKCS 1.5 padding scheme and then encrypts it using the specified RSA public key.This function is normally used to encrypt short symmetric keys which are then used in block ciphers to encrypt a message.
By default, OAEP padding is used.The PKCS_1_5
option will switch to the less secure PKCS 1.5 padding.
Warning
|
The |
RSA_ENCRYPT
Examples
Tip
|
Run the examples of the |
select rdb$set_context('USER_SESSION', 'msg', rsa_encrypt('Some message'
key rdb$get_context('USER_SESSION', 'public_key'))) from rdb$database;
RSA_PRIVATE()
Generates an RSA private key
VARBINARY
RSA_PRIVATE (key_length)
Parameter | Description |
---|---|
key_length |
Key length in bytes;minimum 4, maximum 1024.A size of 256 bytes (2048 bits) or larger is recommended. |
RSA_PRIVATE
generates an RSA private key of the specified length (in bytes) in PKCS#1 format.
Note
|
The larger the length specified, the longer it takes for the function to generate a private key. |
RSA_PRIVATE
Examplesselect rdb$set_context('USER_SESSION', 'private_key', rsa_private(256))
from rdb$database;
Warning
|
Putting private keys in the context variables is not secure;we’re doing it here for demonstration purposes.SYSDBA and users with the role |
RSA_PUBLIC()
Generates an RSA public key
VARBINARY
RSA_PUBLIC (private_key)
Parameter | Description |
---|---|
private_key |
RSA private key in PKCS#1 format |
RSA_PUBLIC
returns the RSA public key in PKCS#1 format for the provided RSA private key (also PKCS#1 format).
RSA_PUBLIC
Examples
Tip
|
Run the example of the |
select rdb$set_context('USER_SESSION', 'public_key',
rsa_public(rdb$get_context('USER_SESSION', 'private_key'))) from rdb$database;
RSA_SIGN_HASH()
PSS encodes a message hash and signs it with an RSA private key
VARBINARY
RSA_SIGN_HASH (message_digest KEY private_key [HASH <hash>] [SALT_LENGTH salt_length] [PKCS_1_5]) <hash> ::= MD5 | SHA1 | SHA256 | SHA512
Parameter | Description |
---|---|
message_digest |
Hash of message to sign.The hash algorithm used should match hash |
private_key |
RSA private key in PKCS#1 format |
hash |
Hash to generate PSS encoding;default is |
salt_length |
Length of the desired salt in bytes;default is 8;minimum 1, maximum 32.The recommended value is between 8 and 16. |
RSA_SIGN_HASH
performs PSS encoding of the message_digest to be signed, and signs using the RSA private key.
By default, OAEP padding is used.The PKCS_1_5
option will switch to the less secure PKCS 1.5 padding.
Warning
|
The |
Caution
|
This function expects the hash of a message (or message digest), not the actual message.The hash argument should specify the algorithm that was used to generate that hash. A function that accepts the actual message to hash might be introduced in a future version of Firebird. |
Probabilistic Signature Scheme (PSS) is a cryptographic signature scheme specifically developed to allow modern methods of security analysis to prove that its security directly relates to that of the RSA problem.There is no such proof for the traditional PKCS#1 v1.5 scheme.
RSA_SIGN_HASH
Examples
Tip
|
Run the example of the |
select rdb$set_context('USER_SESSION', 'msg',
rsa_sign_hash(crypt_hash('Test message' using sha256)
key rdb$get_context('USER_SESSION', 'private_key'))) from rdb$database;
RSA_VERIFY_HASH()
Verifies a message hash against a signature using an RSA public key
BOOLEAN
RSA_VERIFY_HASH (message_digest SIGNATURE signature KEY public_key [HASH <hash>] [SALT_LENGTH salt_length] [PKCS_1_5]) <hash> ::= MD5 | SHA1 | SHA256 | SHA512
Parameter | Description |
---|---|
message_digest |
Hash of message to verify.The hash algorithm used should match hash |
signature |
Expected signature of input generated by |
public_key |
RSA public key in PKCS#1 format matching the private key used to sign |
hash |
Hash to use for the message digest;default is |
salt_length |
Length of the salt in bytes;default is 8;minimum 1, maximum 32.Value must match the length used in |
RSA_VERIFY_HASH
performs PSS encoding of the message_digest to be verified, and verifies the digital signature using the provided RSA public key.
By default, OAEP padding is used.The PKCS_1_5
option will switch to the less secure PKCS 1.5 padding.
Warning
|
The |
Caution
|
This function expects the hash of a message (or message digest), not the actual message.The hash argument should specify the algorithm that was used to generate that hash. A function that accepts the actual message to hash might be introduced in a future version of Firebird. |
RSA_VERIFY_HASH
Examples
Tip
|
Run the examples of the |
select rsa_verify_hash(
crypt_hash('Test message' using sha256)
signature rdb$get_context('USER_SESSION', 'msg')
key rdb$get_context('USER_SESSION', 'public_key'))
from rdb$database
Functions that don’t fit in any other category.
MAKE_DBKEY()
Creates a DBKEY value
BINARY(8)
MAKE_DBKEY (relation, recnum [, dpnum [, ppnum]])
Parameter | Description |
---|---|
relation |
Relation name or relation id |
recnum |
Record number.Either absolute (if dpnum and ppnum are absent), or relative (if dpnum present) |
dpnum |
Data page number.Either absolute (if ppnum is absent) or relative (if ppnum present) |
ppnum |
Pointer page number. |
MAKE_DBKEY
creates a DBKEY value using a relation name or ID, record number, and (optionally) logical numbers of data page and pointer page.
Note
|
|
MAKE_DBKEY
Select record using relation name (note that relation name is uppercase)
select *
from rdb$relations
where rdb$db_key = make_dbkey('RDB$RELATIONS', 0)
Select record using relation ID
select *
from rdb$relations
where rdb$db_key = make_dbkey(6, 0)
Select all records physically residing on the first data page
select *
from rdb$relations
where rdb$db_key >= make_dbkey(6, 0, 0)
and rdb$db_key < make_dbkey(6, 0, 1)
Select all records physically residing on the first data page of 6th pointer page
select *
from SOMETABLE
where rdb$db_key >= make_dbkey('SOMETABLE', 0, 0, 5)
and rdb$db_key < make_dbkey('SOMETABLE', 0, 1, 5)
RDB$ERROR()
Returns PSQL error information inside a WHEN … DO
block
PSQL
Varies (see table below)
RDB$ERROR (<context>) <context> ::= GDSCODE | SQLCODE | SQLSTATE | EXCEPTION | MESSAGE
Context | Result type | Description |
---|---|---|
|
|
Firebird error code, see also |
|
|
(deprecated) SQL code, see also |
|
|
SQLstate, see also |
|
|
Name of the active user-defined exception or |
|
|
Message text of the active exception |
RDB$ERROR
returns data of the specified context about the active PSQL exception.Its scope is confined to exception-handling blocks in PSQL (WHEN … DO
).Outside the exception handling blocks, RDB$ERROR
always returns NULL
.This function cannot be called from DSQL.
BEGIN
...
WHEN ANY DO
EXECUTE PROCEDURE P_LOG_EXCEPTION(RDB$ERROR(MESSAGE));
END
RDB$GET_TRANSACTION_CN()
Returns the commit number (“CN”) of a transaction
BIGINT
RDB$GET_TRANSACTION_CN (transaction_id)
Parameter | Description |
---|---|
transaction_id |
Transaction id |
If the return value is greater than 1, it is the actual CN of the transaction if it was committed after the database was started.
The function can also return one of the following results, indicating the commit status of the transaction:
-2
|
Transaction is dead (rolled back) |
-1
|
Transaction is in limbo |
0
|
Transaction is still active |
1
|
Transaction committed before the database started or less than the Oldest Interesting Transaction for the database |
NULL
|
Transaction number supplied is NULL or greater than Next Transaction for the database |
Note
|
For more information about CN, consult theFirebird 4.0 Release Notes. |
RDB$GET_TRANSACTION_CN
Examplesselect rdb$get_transaction_cn(current_transaction) from rdb$database;
select rdb$get_transaction_cn(123) from rdb$database;
RDB$ROLE_IN_USE()
Checks if a role is active for the current connection
BOOLEAN
RDB$ROLE_IN_USE (role_name)
Parameter | Description |
---|---|
role_name |
String expression for the role to check.Case-sensitive, must match the role name as stored in |
RDB$ROLE_IN_USE
returns TRUE
if the specified role is active for the current connection, and FALSE
otherwise.Contrary to CURRENT_ROLE
— which only returns the explicitly specified role — this function can be used to check for roles that are active by default, or cumulative roles activated by an explicitly specified role.
RDB$ROLE_IN_USE
Examplesselect rdb$role_name
from rdb$roles
where rdb$role_in_use(rdb$role_name);
RDB$SYSTEM_PRIVILEGE()
Checks if the authorization of the current connection has a system privilege
BOOLEAN
RDB$SYSTEM_PRIVILEGE (<sys_privilege>)
<sys_privilege> ::=
!! See CREATE ROLE
!!
Parameter | Description |
---|---|
sys_privilege |
System privilege |
RDB$SYSTEM_PRIVILEGE
accepts a system privilege name and returns TRUE
if the current connection has the given system privilege, and FALSE
otherwise.
The authorization of the current connection is determined by privileges of the current user, the user PUBLIC
, and the currently active roles (explicitly set or activated by default).
RDB$SYSTEM_PRIVILEGE
Examplesselect rdb$system_privilege(user_management) from rdb$database;
ABS()
Absolute value
Numerical, matching input type
ABS (number)
Parameter | Description |
---|---|
number |
An expression of a numeric type |
COS()
Cosine
DOUBLE PRECISION
COS (angle)
Parameter | Description |
---|---|
angle |
An angle in radians |
The result is in the range [-1, 1].
COSH()
Hyperbolic cosine
DOUBLE PRECISION
COSH (number)
Parameter | Description |
---|---|
number |
A number of a numeric type |
The result is in the range [1, INF].
COT()
Cotangent
DOUBLE PRECISION
COT (angle)
Parameter | Description |
---|---|
angle |
An angle in radians |
EXP()
Natural exponent
DOUBLE PRECISION
EXP (number)
Parameter | Description |
---|---|
number |
A number of a numeric type |
Returns the natural exponential, enumber
FLOOR()
Floor of a number
BIGINT
or INT128
for exact numeric number, or DOUBLE PRECISION
or DECFLOAT
for floating point number
FLOOR (number)
Parameter | Description |
---|---|
number |
An expression of a numeric type |
Returns the largest whole number smaller than or equal to the argument.
LN()
Natural logarithm
DOUBLE PRECISION
LN (number)
Parameter | Description |
---|---|
number |
An expression of a numeric type |
An error is raised if the argument is negative or 0.
LOG()
Logarithm with variable base
DOUBLE PRECISION
LOG (x, y)
Parameter | Description |
---|---|
x |
Base.An expression of a numeric type |
y |
An expression of a numeric type |
Returns the x-based logarithm of y.
If either argument is 0 or below, an error is raised.
If both arguments are 1, NaN
is returned.
If x = 1 and y < 1, -INF
is returned.
If x = 1 and y > 1, INF
is returned.
LOG10()
Decimal (base-10) logarithm
DOUBLE PRECISION
LOG10 (number)
Parameter | Description |
---|---|
number |
An expression of a numeric type |
An error is raised if the argument is negative or 0.
MOD()
Remainder
SMALLINT
, INTEGER
or BIGINT
depending on the type of a.If a is a floating-point type, the result is a BIGINT
.
MOD (a, b)
Parameter | Description |
---|---|
a |
An expression of a numeric type |
b |
An expression of a numeric type |
Returns the remainder of an integer division.
Non-integer arguments are rounded before the division takes place.So, “mod(7.5, 2.5)
” gives 2 (“mod(8, 3)
”), not 0.
Do not confuse MOD()
with the mathematical modulus operator;e.g. mathematically, -21 mod 4
is 3, while Firebird’s MOD(-21, 4)
is -1.In other words, MOD()
behaves as %
in languages like C and Java.
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_DECODE
select 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_ENCODE
select 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 BLOB
s 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 BLOB
s 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 BLOB
s 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 BLOB
s 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 BLOB
s 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 BLOB
s 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 |
SUBSTRING
In 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 BLOB
s 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
SUBSTRING
In 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