Base Guide 7.2
Appendix B
Comparison of HSQLDB and Firebird
Data Types and Functions
This document is Copyright © 2021 by the LibreOffice Documentation Team. Contributors are listed below. You may distribute it and/or modify it under the terms of either the GNU General Public License (https://www.gnu.org/licenses/gpl.html), version 3 or later, or the Creative Commons Attribution License (https://creativecommons.org/licenses/by/4.0/), version 4.0 or later.
All trademarks within this guide belong to their legitimate owners.
Pulkit Krishna |
|
|
Randolph Gamo |
Robert Großkopf |
Pulkit Krishna |
Jost Lange |
Hazel Russman |
Jochen Schiffers |
Jean Hollis Weber |
|
|
Please direct any comments or suggestions about this document to the Documentation Team’s mailing list: documentation@global.libreoffice.org.
Note
Everything you send to a mailing list, including your email address and any other personal information that is written in the message, is publicly archived and cannot be deleted.
Published December 2021. Based on LibreOffice 7.2 Community.
Other versions of LibreOffice may differ in appearance and functionality.
The tables in this Appendix are taken from the manuals for HSQLDB and Firebird.
The information for internal HSQLDB is the same as in Appendix A of this book.
The additional internal database Firebird is classified as experimental.
The tables first provide a comparison of the functions, especially the functions that are popular in forums, such as:
Add a certain number of days to a date (DATEADD)
Values from multiple data lines grouped together in one data line (LIST)
are currently only available in the external Firebird database, but not in the internal version.
The following functions are available in the built-in databases. Unfortunately one or two functions can only be used when Run SQL command directly is chosen. While in that mode, queries cannot be edited.
Functions that work with the graphical user interface are marked [works in the GUI]. Functions that work only in direct SQL commands are marked [does not work in the GUI].
As we are dealing here with floating point numbers, be sure to take care with the settings of the fields in queries. Mostly the display of decimal places is restricted, which can result in unexpected behavior in some cases. For example, column 1 might show 0.00 but actually contain 0.001, and column 2, 1000. If column 3 is set to show Column 1 * Column 2, it would actually show 1.
HSQLDB |
Firebird |
||
ABS(d) |
Returns the absolute value of a number. [works in the GUI] |
ABS(d) |
|
ACOS(d) |
Returns the arccosine. [works in the GUI] |
ACOS(d) |
|
ASIN(d) |
Returns the arcsine. [works in the GUI] |
ASIN(d) |
|
ATAN(d) |
Returns the arctangent. [works in the GUI] |
ATAN(d) |
|
ATAN2(a,b) |
Returns the arctangent via coordinates. 'a' is the value of the x-axis, 'b' is the value of the y-axis. |
ATAN2(x,y) |
|
BITAND(a,b) |
Both the binary notation of 'a' and the binary notation of 'b.' Must have a '1' in the same position to yield '1' in the result. |
BIN_AND(x,y [,z...]) |
|
BITOR(a,b) |
Either the binary notation of 'a' or the binary notation of 'b.' Must have a '1' in the same position to yield '1' in the result. |
BIN_OR(x,y [,z...]) |
|
|
|
BIN_SHL(n,exp) |
n · 2 exp [works in the GUI] |
|
|
BIN_SHR(n,exp) |
n / 2 exp |
|
|
BIN_XOR(x,y [,z...]) |
Either the binary notation of 'a' or the binary notation of 'b.' Must have a '1' in the same position to yield '1' in the result. |
CEILING(d) |
Specifies the smallest integer that is not less than d. [works in the GUI] |
CEIL(d) CEILING(d) |
|
COS(d) |
Returns the cosine. [works in the GUI] |
COS(radians) |
The radians can also be represented using the angle (here for the unit circle): |
|
|
COSH(d) |
|
COT(d) |
Returns the cotangent. [works in the GUI] |
COT(d) |
|
DEGREES(d) |
Converts radians to degrees. [works in the GUI] |
|
|
EXP(d) |
Returns e d (e: (2.718 ...)). [works in the GUI] |
EXP(d) |
|
FLOOR(d) |
Returns the largest integer that is not greater than d. [works in the GUI] |
FLOOR(d) |
|
LOG(d) |
Returns the natural logarithm of base 'e'. |
LN(d) |
|
LOG10(d) |
Returns the base 10 logarithm. [works in the GUI] |
LOG10(d) |
|
|
|
LOG(base,d) |
Returns the log at any Basis again. |
MOD(a,b) |
Returns the remainder as an integer that results from dividing 2 integers. |
MOD(a,b) |
|
PI() |
Returns π (3.1415...) [works in the GUI] |
PI() |
|
POWER(a,b) |
ab , POWER (2,3) = 8, because 23 = 8 |
POWER(x,y) |
|
RADIANS(d) |
Converts degrees to radians. [works in the GUI] |
|
|
EDGE() |
Returns a random number x greater than or equal to 0.0 and less than 1.0. [works in the GUI] |
EDGE( ) |
|
ROUND(a,b) |
Rounds a to b digits after the decimal point. [works in the GUI] |
ROUND(d [, places]) |
Rounds after the specified number of digits from the decimal point. |
ROUNDMAGIC (d) |
Solves rounding problems caused by floating point numbers. 3.11–3.1–0.01 may not be exactly 0, but is displayed as 0 in the GUI. ROUNDMAGIC turns it into an actual 0 value. [works in the GUI] |
|
|
SIGN(d) |
Returns –1 if 'd' is less than 0, 0 if 'd' is equal to 0, and 1 if 'd' is greater than 0. [works in the GUI] |
SIGN(d) |
|
SIN(A) |
Returns the sine of an angle in radians. |
SIN(radians) |
|
|
|
Sinh(d) |
|
SQRT(d) |
Returns the square root. [works in the GUI] |
SQRT(d) |
|
TAN(A) |
Returns the tangent of an angle in radians. |
TAN(radians) |
|
|
|
TANH(d) |
|
TRUNCATE (a,b) |
Cuts 'a' to 'b' characters after the decimal point. TRUNCATE(2.37456.2) = 2.37 [works in the GUI] |
TRUNC(d[,jobs]) |
Sets to 0 after the specified number of digits from the decimal point . |
HSQLDB |
Firebird |
||
|
|
DATEADD ( n DAY TO date ) DATEADD (DAY, n, date) |
n is an integer and can also be negative for subtraction. |
DATEDIFF (string, datetime1, datetime2) |
Date difference between two dates or times. The entry in string decides in which unit the difference is shown: 'ms' = 'millisecond', 'ss' = 'second', 'mi' = 'minute', 'hh' = 'hour', 'dd' = 'day', 'mm' = 'month', 'yy' = 'year'. Both the long version and the short version of the string can be used. [works in the GUI] |
DATEDIFF ( DAY FROM date TO date ) DATEDIFF (DAY, date, date) |
See DATEADD. |
EXTRACT ({YEAR|MONTH |DAY|HOUR| MINUTE| SECOND} FROM <date or time value>) |
Can replace many of the date and time functions. Returns the year, month, day, etc. from a date or time of day value. |
EXTRACT ({YEAR| MONTH | WEEK | DAY | WEEKDAY | YEARDAY | HOUR | MINUTE | SECOND | MILLISECOND } FROM <date or time value>) |
WEEKDAY Sunday = 0 YEARDAY January 1st = 0 WEEK 1st week: min. 4 days a year |
DAY(date) |
Returns the day of the month (1-31). [works in the GUI] |
|
|
DAYNAME (date) |
Returns the English name of the day. [works in the GUI] |
|
|
DAYOFMONTH (date) |
Returns the day of the month (1-31), synonym for DAY(). [works in the GUI] |
|
|
DAYOFWEEK (date) |
Returns the day of the week as a number (1 means Sunday.) [works in the GUI] |
|
|
DAYOFYEAR (date) |
Returns the day of the year (1-366). [works in the GUI] |
|
|
HOUR(time) |
Returns the hour (0-23). [works in the GUI] |
|
|
MINUTE(time) |
Returns the minute (0-59). [works in the GUI] |
|
|
MONTH(date) |
Returns the month (1-12). [works in the GUI] |
|
|
MONTHNAME (date) |
Returns the English name of the month. [works in the GUI] |
|
|
QUARTER (date) |
Returns the quarter of the year (1-4). [works in the GUI] |
|
|
SECOND(time) |
Returns the seconds of a time (0-59). [works in the GUI] |
|
|
WEEK(date) |
Returns the week of the year (1-53). [works in the GUI] |
|
|
YEAR(date) |
Returns the year from a date input. [works in the GUI] |
|
|
HSQLDB |
Firebird |
||
DATABASE() |
Returns the path and name of the database belonging to this connection. [works in the GUI] |
|
|
|
|
CURRENT_TRANSACTION |
SELECT CURRENT_T RANSACTION FROM RDB $ DATABASE returns the unique identifier of the transaction as an integer. |
|
|
CURRENT_CONNECTION |
SELECT CURRENT_CONNECTION FROM RDB $ DATABASE returns an integer value for the current connection. |
|
|
CURRENT_ROLE |
SELECT CURRENT_ROLE FROM RDB $ DATABASE reflects the role of the current user. If no role is defined, the result is NONE. |
|
|
RDB $ SET_CONTEXT ('<namespace>', '<variable name>', value | NULL ) |
Namespace: USER_SESSION | USER_TRANSACTION The variable name can have a maximum of 80 characters, and the value can have a maximum of 255 characters. |
CURRENT_USER |
SQL standard function, synonym for USER(). It should be noted that there are no parentheses here. [works in the GUI] |
CURRENT_USER |
|
USER() |
Returns the username of this connection. The username is important if the database is to be converted into an external database. |
USER |
|
IDENTITY() |
Returns the last value for an autovalue field that was created in the current connection. This is used in macro programming to create a foreign key for another table from a primary key created for one table. [works in the GUI] |
GEN_ID (generator name, <step>) |
Autovalues are created with a generator. The step size should be given here as 1. In principle, any integer value is possible. new.rec_id = gen_id (gen_recnum, 1); |
HSQLDB |
Firebird |
|||
IFNULL (exp, value) |
If exp is NULL, value is returned, otherwise exp. Instead, COALESCE () can also be used as an extension. Exp and value must have the same data type. |
|
|
|
CASE WHEN (exp, v1, v2) |
If exp is true v1 is returned, otherwise v2. CASE WHEN can also be used instead. |
IIF (<condition>, v1, v2) |
|
|
CONVERT (term, type) |
Converts term to another data type. |
|
|
|
CAST (term AS type) |
Synonym to CONVERT () |
CAST (term AS type) |
From |
To |
Numeric types |
Numeric types [VAR] CHAR |
|||
[VAR] CHAR |
[VAR] CHAR |
|||
DATE |
[VAR] CHAR |
|||
TIMESTAMP |
[VAR] CHAR |
|||
COALESCE (expr1, expr2, expr3, ...) |
If expr1 is not NULL, expr1 is displayed, otherwise expr2 is checked, then expr3, etc. All expressions must have at least a similar data type. This is the alternative representation of integers and floating point numbers, but not also of a date or time value. |
COALESCE (expr1, expr2 [, expr3 ...] |
|
|
NULLIF (v1, v2) |
If v1 is equal to v2, null is returned, otherwise value of v1 is returned. The data must be comparable in type. |
NULLIF (v1, v2) |
|
|
CASE v1 WHEN v2 THEN v3 [ELSE v4] END |
If v1 is equal to v2, v3 is executed. Otherwise v4 is executed or NULL if no ELSE is formulated. |
DECODE ( test expression , expression , result [, expression2 , Earnings2 ...] [, default expression ]) |
DECODE (UPPER ("gender"), 'M', 'male', 'F', 'female', 'unknown') |
|
CASE WHEN expr1 THEN v1 [WHEN expr2 THEN v2] [ELSE v4] END |
If expr1 is true, v1 is returned [Optionally, further cases can be specified]. Otherwise v4 is reproduced or NULL if no ELSE is formulated. |
|
DECODE (EXTRACT ( WEEK DAY FROM "date"), 0 , ' Sunday ', 1 , ' Monday ', ' etc. ') |
|
|
|
GEN_UUID () |
Returns a unique ID as a 16-byte character set. |
|
|
|
HASH (s) |
Returns the hash value of an arbitrarily long string. Hash values of the same character strings must be the same. |
|
|
|
MAXVALUE (expr [, expr ...]) |
Returns the maximum value of a list of values. Works with strings, numeric values, date or time values. |
|
|
|
MINVALUE (expr [, expr ...]) |
Returns the minimum value of a list of values. Works with strings, numeric values, date or time values. |
HSQLDB |
Firebird |
||
|
|
MAX (expr) |
Maximum value of a field in a table. |
|
|
MIN (expr) |
Minimum value of a field in a table. |
|
|
LIST ( [ALL | DISTINCT] 's' , [ ' s2'] ) |
Connects fields of several data records to one field with the corresponding connection term 's2'. [works in the GUI] |
HSQLDB |
Firebird |
||
CURRENT_TIME |
Synonym for CURTIME (), SQL standard. |
CURRENT_TIME |
Time in hours, minutes and seconds. |
CURTIME () |
Returns the current time. [works in the GUI] |
|
|
CURRENT_TIMESTAMP |
Synonym for NOW (), SQL standard. |
CURRENT_TIMESTAMP [(accuracy)] |
Time specification with date and milliseconds. SELECT CURRENT_TIMESTAMP (2) FROM RDB $ DATABASE |
NOW () |
Returns the current date and time together as a timestamp. CURRENT_TIMESTAMP can also be used instead. [works in the GUI] |
CAST ('NOW' AS DATE | TIME | TIMESTAMP) or DATE 'NOW' |
'NOW', written alone, is understood as a string. With the appropriate conversion, it becomes a date, a time, or a time stamp (each with 1/1000 s). The short form does not work in the GUI. |
CURRENT_DATE |
Synonym for CURDATE (), SQL standard. [works in the GUI] |
CURRENT_DATE |
|
CURDATE () |
Returns the current date. [works in the GUI] |
|
|
HSQLDB |
Firebird |
||
'str1' || 'str2' || 'str3' or 'str1' + 'str2' + 'str3' |
Connects str1 + str2 + str3; simpler alternative to CONCAT. [works in the GUI] |
's1' || ' s 2 ' [ ||' s3 '... ] |
Connects s1, s2 etc. to a new string [works in the GUI] |
|
|
ALL |
|
|
|
ANY / SOME |
|
|
|
IN ( ) |
|
|
|
IS [NOT] DISTINCT FROM |
Result is 'yes' or 'no'. |
|
|
NEXT VALUE FOR sequence name |
See GEN_ID (), but does not allow any steps other than 1. |
|
|
SOME |
|
Type |
Option |
HSQLDB |
Firebird |
Range |
Storage Space |
Tiny integer |
TINYINT |
TINYINT |
|
28 = 256 | – 128 to + 127 |
1 byte |
Small integer |
SMALLINT |
SMALLINT |
SMALLINT |
216 = 65536 | – 32768 to + 32767 |
2 bytes |
integer |
INTEGER |
INTEGER | INT |
INTEGER |
232 = 4294967296 | – 2147483648 to + 2147483647 |
4 bytes |
BigInt |
BIGINT |
BIGINT |
BIGINT |
264 (–263 to +263 ) |
8 bytes |
Type |
Option |
HSQLDB |
Firebird |
Scope |
Memory requirements |
Decimal |
DECIMAL |
DECIMAL |
DECIMAL (n, m) |
Unlimited, through GUI to 50 digits, adjustable, fixed decimal places, exact accuracy |
2, 4 or 8 Byte |
Number |
NUMERIC |
NUMERIC |
NUMERIC (n, m) |
Unlimited, through GUI to 50 digits, adjustable, fixed decimal places, exact accuracy |
2, 4 or 8 Byte |
Float |
FLOAT |
(DOUBLE is used instead) |
FLOAT |
3.4 * 10–38 to 3.4 * 1038 |
4 Byte |
Real |
REAL |
REAL |
|
|
|
Double |
DOUBLE |
DOUBLE [PRECISION] | FLOAT |
DOUBLE PRECISION |
1 , 7 * 10–308 to 1 , 7 * 10308 adjustable, not exact, 15 decimal places maximum |
8 bytes |
Type |
Option |
HSQLDB |
Firebird |
Scope |
Memory requirements |
Text |
VARCHAR |
VARCHAR |
VARCHAR (n) |
Adjustable |
Variable |
Text |
VARCHAR_IGNORECASE |
VARCHAR_IGNORECASE |
|
Adjustable, affect sorting, ignores differences between upper and lower case |
variable |
Text (fixed) |
CHAR |
CHAR | CHARACTER |
|
Adjustable, rest of the actual text is filled with spaces |
fixed |
Memo |
LONGVARCHAR |
LONGVARCHAR |
BLOB (BLOB SUB_TYPE 1) |
|
variable |
Type |
Option |
HSQLDB |
Firebird |
Scope |
Memory requirements |
Date |
DATE |
DATE |
DATE |
|
4 bytes |
Time |
TIME |
TIME |
TIME |
Firebird: 0:00 to 23:59,9999 |
4 bytes |
Date/Time |
TIME STAMP |
TIMESTAMP | DATE TIME |
TIME STAMP |
Adjustable ( HSQLDB: 0, 6 - 6 means with milliseconds) |
8 bytes |
Type |
Option |
HSQLDB |
Firebird |
Scope |
Memory requirements |
Yes No |
BOOLEAN |
BOOLEAN | BIT |
|
|
|
Binary field (fixed) |
BINARY |
BINARY |
|
Like integer |
fixed |
Binary field |
VARBINARY |
VARBINARY |
|
Like integer |
variable |
Image |
LONGVARBINARY |
LONGVARBINARY |
BLOB SUB_TYPE 0 |
Like integer |
variable, intended for larger images |
OTHER |
OTHER |
OTHER | OBJECT |
|
|
|