UPPER Examples
select 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
Functions for Sequences (Generators)
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.
UUID_TO_CHAR Examplesselect uuid_to_char(x'876C45F4569B320DBCB4735AC3509E5F') from rdb$database
-- returns '876C45F4-569B-320D-BCB4-735AC3509E5F'
select uuid_to_char(gen_uuid()) from rdb$database
-- returns e.g. '680D946B-45FF-DB4E-B103-BB5711529B86'
select uuid_to_char('Firebird swings!') from rdb$database
-- returns '46697265-6269-7264-2073-77696E677321'
GEN_ID()Increments a sequence (generator) value and returns its new value
BIGINT — dialect 2 and 3INTEGER — dialect 1
GEN_ID (generator-name, step)
| Parameter | Description |
|---|---|
generator-name |
Identifier name of a generator (sequence) |
step |
An integer expression of the increment |
If step equals 0, the function will leave the value of the generator unchanged and return its current value.
The SQL-compliant NEXT VALUE FOR syntax is preferred, except when an increment other than the configured increment of the sequence is needed.
|
Warning
|
If the value of the step parameter is less than zero, it will decrease the value of the generator.You should be cautious with such manipulations in the database, as they could compromise data integrity (meaning, subsequent insert statements could fail due to generating of duplicate id values). |
|
Note
|
In dialect 1, the result type is |
GEN_ID Examplenew.rec_id = gen_id(gen_recnum, 1);
COALESCE()Returns the first non-NULL argument
Depends on input
COALESCE (<exp1>, <exp2> [, <expN> ... ])
| Parameter | Description |
|---|---|
exp1, exp2 … expN |
A list of expressions of compatible types |
The COALESCE function takes two or more arguments and returns the value of the first non-NULL argument.If all the arguments evaluate to NULL, the result is NULL.
COALESCE ExamplesThis example picks the Nickname from the Persons table.If it happens to be NULL, it goes on to FirstName.If that too is NULL, “'Mr./Mrs.'” is used.Finally, it adds the family name.All in all, it tries to use the available data to compose a full name that is as informal as possible.This scheme only works if absent nicknames and first names are NULL: if one of them is an empty string, COALESCE will happily return that to the caller.That problem can be fixed by using [fblangref50-scalarfuncs-nullif].
select
coalesce (Nickname, FirstName, 'Mr./Mrs.') || ' ' || LastName
as FullName
from Persons
DECODE()Shorthand “simple CASE”-equivalent function
Depends on input
DECODE(<testexpr>, <expr1>, <result1> [<expr2>, <result2> ...] [, <defaultresult>])
| Parameter | Description |
|---|---|
testexpr |
An expression of any compatible type that is compared to the expressions expr1, expr2 … exprN |
expr1, expr2, … exprN |
Expressions of any compatible types, to which the testexpr expression is compared |
result1, result2, … resultN |
Returned values of any type |
defaultresult |
The expression to be returned if none of the conditions is met |
DECODE is a shorthand for the so-called “simple CASE” construct, in which a given expression is compared to a number of other expressions until a match is found.The result is determined by the value listed after the matching expression.If no match is found, the default result is returned, if present, otherwise NULL is returned.
The equivalent CASE construct:
CASE <testexpr> WHEN <expr1> THEN <result1> [WHEN <expr2> THEN <result2> ...] [ELSE <defaultresult>] END
|
Caution
|
Matching is done with the ‘ |
DECODE Examplesselect name,
age,
decode(upper(sex),
'M', 'Male',
'F', 'Female',
'Unknown'),
religion
from people
IIF()Ternary conditional function
Depends on input
IIF (<condition>, ResultT, ResultF)
| Parameter | Description |
|---|---|
condition |
A true|false expression |
resultT |
The value returned if the condition is true |
resultF |
The value returned if the condition is false |
IIF takes three arguments.If the first evaluates to true, the second argument is returned;otherwise the third is returned.
IIF could be likened to the ternary “<condition> ? resultT : resultF” operator in C-like languages.
|
Note
|
|
IIF Examplesselect iif( sex = 'M', 'Sir', 'Madam' ) from Customers
MAXVALUE()Returns the maximum value of its arguments
Varies according to input — result will be of the same data type as the first expression in the list (expr1).
MAXVALUE (<expr1> [, ... , <exprN> ])
| Parameter | Description |
|---|---|
expr1 … exprN |
List of expressions of compatible types |
Returns the maximum value from a list of numerical, string, or date/time expressions.This function fully supports text BLOBs of any length and character set.
If one or more expressions resolve to NULL, MAXVALUE returns NULL.This behaviour differs from the aggregate function MAX.
MAXVALUE ExamplesSELECT MAXVALUE(PRICE_1, PRICE_2) AS PRICE
FROM PRICELIST
MINVALUE()Returns the minimum value of its arguments
Varies according to input — result will be of the same data type as the first expression in the list (expr1).
MINVALUE (<expr1> [, ... , <exprN> ])
| Parameter | Description |
|---|---|
expr1 … exprN |
List of expressions of compatible types |
Returns the minimum value from a list of numerical, string, or date/time expressions.This function fully supports text BLOBs of any length and character set.
If one or more expressions resolve to NULL, MINVALUE returns NULL.This behaviour differs from the aggregate function MIN.
MINVALUE ExamplesSELECT MINVALUE(PRICE_1, PRICE_2) AS PRICE
FROM PRICELIST
NULLIF()Conditional NULL function
Depends on input
NULLIF (<exp1>, <exp2>)
| Parameter | Description |
|---|---|
exp1 |
An expression |
exp2 |
Another expression of a data type compatible with exp1 |
NULLIF returns the value of the first argument, unless it is equal to the second.In that case, NULL is returned.
NULLIF Exampleselect avg( nullif(Weight, -1) ) from FatPeople
This will return the average weight of the persons listed in FatPeople, excluding those having a weight of -1, since AVG skips NULL data.Presumably, -1 indicates “weight unknown” in this table.A plain AVG(Weight) would include the -1 weights, thus skewing the result.