SQL Reference Manual

SQL Reference Manual mk Wed, 03/17/2010 - 23:36

The de facto language for database applications is SQL. It evolved through several phases of standardization to the version currently known as SQL:2016. The SQL standard provides an ideal language framework, in terms of standardization committee viewpoints. It is, however, hardly met by any of the existing (commercial) implementations. This is largely due to software legacy, backward compatibility requirements from their client base, and introduction of new features. See for instance the wikipedia on-line article on SQL standards and an overview of SQL features of main-stream systems.

In 2002 the first version of the SQL front end for MonetDB emerged. This late development made it possible to immediately start from the SQL'99 definition. As soon as the SQL'03 specifications became available, its content was taken as the frame of reference. The SQL development strategy is driven by immediate needs of the user base, so that less-frequently used features end up low on the development stack. Features beyond the standard are marked as non-standard SQL in their description.

The architecture is based on a compiler, which translates SQL statements into MAL (MonetDB Assembly Language) statements. In this process common optimization heuristics, specific to the relational algebra are performed. There are bindings for SQL with programming languages: C (ODBC, Mapi, MonetDB/e), Java (JDBC), Python, PHP, Ruby on Rails to integrate seamlessly in the existing application developments environments.

The remainder of this manual presents a synopsis of the language features. It provides a quick intro on the scope of the current implementation. Proficiency in elementary use of SQL is assumed. If you are new to this world then pick up any of the introduction books and study it carefully, e.g. J. Melton and A.R. Simon, SQL:1999 Understanding Relational Language Components, ISBN 1558604561.

The language features recognized are presented in simplified BNF notation. All reserved words are depicted in capitals. Language (non) terminals are depicted in lower case italics. Optional constructs are enclosed by squary brackets ('[',']') with alternative choices separated by a bar ('|'), at most one can be choosen. A set of options is enclosed by curly braces '{','}' and one must be choosen. Repetition of language structures is depicted by list structures, e.g. A ',' ...  denotes a sequence of at least one A separated by commas.

Identifiers are optional qualified with a semantic tag, e.g. authid means a name for an authorised user.

SQL Commands Overview

SQL Commands Overview dinther Fri, 05/25/2018 - 16:35

Data Definition Language (DDL)

CREATE SCHEMA         SET SCHEMA COMMENT ON SCHEMA ALTER SCHEMA DROP SCHEMA
 
CREATE SEQUENCE COMMENT ON SEQUENCE ALTER SEQUENCE DROP SEQUENCE
 
CREATE TABLE COMMENT ON TABLE COMMENT ON COLUMN DROP TABLE
CREATE TABLE AS ALTER TABLE ADD COLUMN ALTER TABLE ALTER COLUMN ALTER TABLE DROP COLUMN
CREATE TABLE FROM LOADER ALTER TABLE ADD CONSTRAINT   ALTER TABLE DROP CONSTRAINT
  ALTER TABLE RENAME TO ALTER TABLE RENAME COLUMN ALTER TABLE SET SCHEMA
  ALTER TABLE SET INSERT ONLY ALTER TABLE SET READ ONLY ALTER TABLE SET READ WRITE
 
CREATE MERGE TABLE ALTER TABLE ADD TABLE ALTER TABLE SET TABLE ALTER TABLE DROP TABLE
CREATE REMOTE TABLE
CREATE REPLICA TABLE
CREATE STREAM TABLE
CREATE TEMPORARY TABLE
 
CREATE INDEX
CREATE IMPRINTS INDEX
CREATE ORDERED INDEX
COMMENT ON INDEX DROP INDEX
 
CREATE TRIGGER   DROP TRIGGER
 
CREATE VIEW COMMENT ON VIEW DROP VIEW
 
CREATE FUNCTION
CREATE FUNCTION EXTERNAL
CREATE FUNCTION LANGUAGE
COMMENT ON FUNCTION DROP FUNCTION DROP ALL FUNCTION
CREATE PROCEDURE
CREATE PROCEDURE EXTERNAL
COMMENT ON PROCEDURE DROP PROCEDURE DROP ALL PROCEDURE
CREATE AGGREGATE EXTERNAL
CREATE AGGREGATE LANGUAGE
COMMENT ON AGGREGATE DROP AGGREGATE DROP ALL AGGREGATE
CREATE FILTER FUNCTION EXTERN COMMENT ON FILTER FUNCTION DROP FILTER FUNCTION DROP ALL FILTER FUNCTION
CREATE LOADER COMMENT ON LOADER DROP LOADER DROP ALL LOADER
CREATE WINDOW EXTERNAL COMMENT ON WINDOW DROP WINDOW DROP ALL WINDOW
 
CREATE TYPE EXTERNAL DROP TYPE
DECLARE

Data Manipulation Language (DML)

SELECT SELECT INTO WITH SELECT
INSERT VALUES INSERT SELECT
UPDATE
MERGE
DELETE
TRUNCATE
 
PREPARE EXECUTE DEALLOCATE
CALL
SET SET TIME ZONE SET CURRENT_TIMEZONE

Bulk Data Import Commands

COPY INTO FROM
COPY INTO FROM STDIN
COPY BINARY INTO FROM
COPY LOADER INTO FROM

Bulk Data Export Commands

COPY INTO
COPY INTO STDOUT

Authorization, Data Access Control Language

CREATE USER SET USER
SET CURRENT_USER
SET SESSION_USER
ALTER USER RENAME
ALTER USER SET PASSWORD
ALTER USER SET SCHEMA
DROP USER
GRANT PRIVILEGES REVOKE PRIVILEGES
CREATE ROLE SET ROLE SET SESSION AUTHORIZATION DROP ROLE
GRANT ROLE REVOKE ROLE

Transaction Control Commands

START TRANSACTION COMMIT ROLLBACK
SET TRANSACTION SET LOCAL TRANSACTION
SAVEPOINT RELEASE SAVEPOINT ROLLBACK TO SAVEPOINT

Commands to Analyse / Optimize SQL Execution

EXPLAIN
PLAN
TRACE
DEBUG
ANALYZE
SET OPTIMIZER

Pseudo Columns

CURRENT_SCHEMA
CURRENT_USER           USER           SESSION_USER
CURRENT_ROLE
CURRENT_DATE           NOW
CURRENT_TIME
CURRENT_TIMESTAMP
CURRENT_TIMEZONE
LOCALTIME
LOCALTIMESTAMP
NEXT VALUE FOR

Details

CREATE SCHEMA

   CREATE SCHEMA [ IF NOT EXISTS ] [ schema_name ]
    [ AUTHORIZATION auth_name ]
    [ DEFAULT CHARACTER SET character_set_name ]
    [ PATH schema_name [, schema_name] [, ... ] ]
    [ schema_element [, schema_element] [, ... ] ]

   schema_element:
        create_statement | alter_statement | drop_statement | grant | revoke

Define a new schema

Examples:

CREATE SCHEMA tst;
CREATE SCHEMA AUTHORIZATION hrm;
CREATE SCHEMA hr AUTHORIZATION hrm;
SET SCHEMA tst;
SELECT CURRENT_SCHEMA;


Note: You must specify either a schema_name or an auth_name or both, see examples.
The auth_name can be either an existing role or user name.
The ownership of a schema can be assigned to only one user/role, and it can not be modified after its creation. Therefore, to share the ownership of a schema, one must assign the ownership of a schema to a role at the creation of the schema. Subsequently, the role can be granted to multiple users to own the schema.
Only the 'monetdb' user and the 'sysadmin' role can create a new schema. Therefore, to allow other users to create schemas, the 'monetdb' user should assign the 'sysadmin' role to the intended users. The DEFAULT CHARACTER SET and PATH options are not (yet) implemented and here for compatibility reasons with the SQL standard. The default character set is UTF-8 and not changable.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLReference/DataDefinition/SchemaDefinitions
See also: SET SCHEMA   CURRENT_SCHEMA   COMMENT ON SCHEMA   DROP SCHEMA

Associated system table: sys.schemas

ALTER SCHEMA

   ALTER SCHEMA [ IF NOT EXISTS ] schema_name RENAME TO new_schema_name

Change the name of a schema

Example:

CREATE SCHEMA tst;
ALTER SCHEMA tst RENAME TO tst2;


It is only allowed to change the name of a schema if no objects exists which depend on the schema name, such as tables, views, functions, etc.
Note: This command is supported from release Apr2019 onwards.

For details see: Documentation/SQLReference/DataDefinition/SchemaDefinitions
See also: SET SCHEMA   CURRENT_SCHEMA   COMMENT ON SCHEMA   DROP SCHEMA

Associated system table: sys.schemas

CREATE SEQUENCE

   CREATE SEQUENCE [ schema_name . ] sequence_name
    [ AS datatype ]
    [ START WITH bigint# ]
    [ INCREMENT BY bigint# ]
    [ MINVALUE bigint# | NO MINVALUE ]
    [ MAXVALUE bigint# | NO MAXVALUE ]
    [ CACHE bigint# ]
    [ [ NO ] CYCLE ]

Define a new integer number sequence generator

For details see: Documentation/SQLreference/DataTypes/SerialDataTypes
See also: ALTER SEQUENCE   COMMENT ON SEQUENCE   NEXT VALUE FOR   DROP SEQUENCE

Associated system table: sys.sequences
 

CREATE TABLE

   CREATE TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    ( column_definition(s)_and_optional_table-constraints_list )

Define a new table including data integrity constraints

Note: WARNING: Column CHECK constraint definitions are accepted but not enforced! They are also not stored in the data dictionary, so will be lost when using msqldump.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
You can also use LIKE qname as part of the column definition to copy the column definitions of qname excluding their constraints. For instance CREATE TABLE webshop.products_new (LIKE webshop.products, descr VARCHAR(9999), pict BLOB);

For details see: Documentation/SQLReference/TableDefinitions and: Documentation/SQLreference/TableIdentityColumn
See also: ALTER TABLE ADD COLUMN   ALTER TABLE ADD CONSTRAINT   COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 0

CREATE TABLE AS

   CREATE TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    [ ( column_name [, column_name] [, ... ] ) ]
    AS SELECT_query
    [ WITH [ NO ] DATA ]

Define a new table from the results of a query. By default the table will be populated with the data of the query. Specify WITH NO DATA to only create the table.

Note: Default behavior is WITH DATA.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLReference/TableDefinitions
See also: ALTER TABLE ADD COLUMN   ALTER TABLE ADD CONSTRAINT   COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 0

CREATE TABLE FROM LOADER

   CREATE TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    FROM LOADER function_name ( [ arg1_val [ , arg2_val ] [, ... ] ] )
    [ WITH [ NO ] DATA ]

Define a new table from the results of a (Python) loader function. By default the table will be populated with the data of the loader function. Specify WITH NO DATA to only create the table.

Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: blog/monetdbpython-loader-functions
See also: CREATE LOADER   COPY LOADER INTO FROM      COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 0
 

CREATE MERGE TABLE

   CREATE MERGE TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    ( column_definition(s)_and_optional_table-constraints_list )
    [ PARTITION BY { RANGE | VALUES }  { ON ( column_name )  |  USING ( expression ) } ]

Define a new merge table to create a horizontally partitioned table.
A merge table logically combines the data of multiple other tables (called partition tables which are added via ALTER TABLE merge_table ADD TABLE partition_table) which all must have the exact same table definition. This merge table is easier to extend/change with new partitions than a view which combines multiple SELECT queries (via UNION ALL) and can processes queries faster. Also with "PARTITION BY" specified, the virtual merge table becomes updatable, so allow inserts, updates, deletes and truncate on the merge table directly instead of the partition tables.

Note: This command is MonetDB specific.
The "PARTITION BY" option is supported from release Apr2019 (11.33.3) onwards. See updatable-merge-tables for details.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
A merge table is removed (including all its partition table information, but not the partition tables) using the ordinary DROP TABLE statement. There is no DROP MERGE TABLE statement.

For details see: Documentation/ServerProgramming/SystemCatalog/TableDataPartitioning and updatable-merge-tables
and: Documentation/SQLReference/TableDefinitions
See also: ALTER TABLE ADD TABLE   ALTER TABLE DROP TABLE   COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system tables: sys.tables where type = 3;   sys.table_partitions

CREATE REMOTE TABLE

   CREATE REMOTE TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    ( column definition(s) )
    ON 'mapi:monetdb://host:port/dbname'
    [ WITH [ USER 'user_login_name_nm' ]   [ [ ENCRYPTED ] PASSWORD 'password' ] ]

Define an alias for a remote table. The remote table must be an existing table on another running MonetDB server
The definition of the remote table structure must match exactly the definition of its counterpart in the remote database, so the same schema name, same table name, same column names and same column data types.
The format of the remote server URL must conform to: 'mapi:monetdb://host:port/dbname', where all three parameters (host, port and dbname) must be specified.

Note: This command is MonetDB specific.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
The "WITH USER ... PASSWORD ..." option is supported from release Aug2018 (11.31.7) onwards. See this blog post for more information.
A remote table definition is removed using the ordinary DROP TABLE statement. There is no DROP REMOTE TABLE statement.

For details see: Documentation/ServerAdministration/DistributedQueryProcessing and: Documentation/SQLReference/TableDefinitions
See also: COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 5

CREATE REPLICA TABLE

   CREATE REPLICA TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    ( column_definition(s)_and_optional_table-constraints_list )

Define a new replica table

Note: This command is MonetDB specific.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
A replica table is removed using the ordinary DROP TABLE statement. There is no DROP REPLICA TABLE statement.

For details see: Documentation/SQLReference/TableDefinitions and: Documentation/SQLReference/TableDefinitions/TableIElements
See also: COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 6

CREATE STREAM TABLE

   CREATE STREAM TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    ( column_definition(s)_and_optional_table-constraints_list )

Define a new stream table

Example:

CREATE STREAM TABLE room_event (ts timestamp, room integer, payload decimal(8,2));


Note: This command is MonetDB specific.
The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
A stream table is removed using the ordinary DROP TABLE statement. There is no DROP STREAM TABLE statement.

For details see: Documentation/ServerProgramming/ExtendingSQL/Streams/Catalog
See also: COMMENT ON TABLE   COMMENT ON COLUMN   DROP TABLE

Associated system table: sys.tables where type = 4

CREATE TEMPORARY TABLE

   CREATE [ LOCAL | GLOBAL ] { TEMPORARY | TEMP } TABLE [ IF NOT EXISTS ] [ schema_name . ] table_name
    { ( column_definition(s)_and_optional_table-constraints_list )  |
      [ ( column_name [, column_name ] [, ... ] ) ] AS SELECT_query [ WITH [ NO ] DATA ] }
    [ ON COMMIT { DELETE ROWS | PRESERVE ROWS | DROP } ]

Define a new temporary table. The visibility of the table to other session users can be controlled by using GLOBAL. Default is LOCAL. A temporary table will be removed automatically after the user session is terminated.
When ON COMMIT clause is not specified then the default behavior is ON COMMIT DELETE ROWS, complying to the SQL standard.
When using AS SELECT ... the default is WITH DATA.

Example:

CREATE TEMP TABLE names (id int NOT NULL PRIMARY KEY, name VARCHAR(99) NOT NULL UNIQUE) ON COMMIT PRESERVE ROWS;
-- Note that temporary tables are implicitly assigned to schema: tmp
INSERT INTO tmp.names VALUES (1, 'one');
INSERT INTO tmp.names VALUES (2, 'two');
INSERT INTO tmp.names VALUES (2, 'dos');
-- Error: INSERT INTO: PRIMARY KEY constraint 'names.names_id_pkey' violated
INSERT INTO tmp.names VALUES (3, 'two');
-- Error: INSERT INTO: UNIQUE constraint 'names.names_name_unique' violated
INSERT INTO tmp.names VALUES (3, 'free');
SELECT * FROM tmp.names;
-- shows 3 rows
DROP TABLE tmp.names;

CREATE GLOBAL TEMP TABLE tmp.name_lengths (name, length)
 AS SELECT DISTINCT name, LENGTH(name) FROM sys.ids ORDER BY 1
 WITH DATA
 ON COMMIT PRESERVE ROWS;
SELECT * FROM tmp.name_lengths WHERE name ILIKE '%\\_id%' ESCAPE '\\';
SELECT COUNT(*) AS count_names, AVG(length) AS avg_name_length FROM tmp.name_lengths;
DROP TABLE tmp.name_lengths;


IMPORTANT: specify ON COMMIT PRESERVE ROWS to keep rows when working in autocommit mode, because default behavior is ON COMMIT DELETE ROWS.
Note: The "IF NOT EXISTS" option is supported from release Jul2017 (11.27.1) onwards.
It is not possible to add comments on temporary tables or columns thereof.
A temporary table is removed using the ordinary DROP TABLE statement. There is no DROP TEMPORARY TABLE statement.

For details see: Documentation/SQLReference/TableDefinitions and: Documentation/SQLreference/TableIdentityColumn
See also: ALTER TABLE ADD COLUMN   ALTER TABLE ADD CONSTRAINT   DROP TABLE

Associated system table: sys.tables where type in (20, 30)

CREATE INDEX

   CREATE [ UNIQUE ] INDEX index_name ON [ schema_name . ] table_name ( column_name [, column_name ] [, ... ] )

Define a new secondary index on one or more columns of a specific table

Note: Although CREATE INDEX commands are accepted by the MonetDB parser for SQL compliance purposes, it currently does not create a physical secondary index via this SQL command. Instead MonetDB internally decides which column search accelerator(s) to create, persist and use during SQL query execution.
The index name must be unique within the schema of the table. You can not specify the schema for the index. It will be placed in the same schema as the table.
WARNING: the UNIQUE keyword does NOT enforce a uniqueness constraint. To create a unique constraint use: ALTER TABLE s.t ADD CONSTRAINT t_uc UNIQUE (c1, c2) instead.

For details see: Documentation/SQLreference/TableDefinitions/IndexDefinitions
See also: CREATE ORDERED INDEX   ALTER TABLE ADD CONSTRAINT   COMMENT ON INDEX   DROP INDEX

Associated system table: sys.idxs

CREATE IMPRINTS INDEX

   CREATE IMPRINTS INDEX index_name ON [ schema_name . ] table_name ( column_name )

Define a new imprints index (a simple but efficient cache conscious secondary index) on one numerical column of a specific table. This index is a special single column index (for numeric columns only) which stores meta data (min, max, nulls) on segments of column data. An imprint is used during query evaluation to limit data access and thus minimize memory traffic. It can speedup queries which have a column selection condition (such as: AGE IS NULL OR AGE BETWEEN 25 AND 65). The storage overhead is just a few percent over the size of the columns being indexed.

Example:

CREATE IMPRINTS INDEX my_impr_idx ON myschema.mytable ( my_num_column );


Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
The imprints index is a new type of experimental column index.
Limitations are: Only 1 column can be indexed per index. Only columns of fixed size data type (so not on: char, varchar, clob, blob, url, json, inet and uuid) can be indexed.
The index name must be unique within the schema of the table. You can not specify the schema for the index. It will be placed in the same schema as the table.
Warning: The index is not maintained automatically and will become inactive after inserts, deletes or updates are done on the column data.
An imprints index is removed using the ordinary DROP INDEX statement. There is no DROP IMPRINTS INDEX statement.

For details see: Documentation/SQLreference/TableDefinitions/IndexDefinitions
and: Home/ScienceLibrary
See also: CREATE ORDERED INDEX   CREATE INDEX   COMMENT ON INDEX   DROP INDEX

Associated system table: sys.idxs   sys.storage

CREATE ORDERED INDEX

   CREATE ORDERED INDEX index_name ON [ schema_name . ] table_name ( column_name )

Define a new ordered index on one column of a specific table. This index is a special single column index where the values are stored in ascending order. It can speedup queries which have a column selection condition (such as: AGE >=18 or AGE BETWEEN 18 AND 30) or need sorting such as when GROUP BY is used.

Example:

CREATE ORDERED INDEX my_ord_idx ON myschema.mytable ( my_column );


Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
The ordered index is a new type of experimental column index.
Limitations: Only 1 column can be indexed per index.
The index name must be unique within the schema of the table. You can not specify the schema for the index. It will be placed in the same schema as the table.
Releases before Mar2018 (11.29.3) only allowed columns of fixed size data type (so not on: char, varchar, clob, blob, url, json, inet and uuid) could be indexed. This limitation has been removed in Mar2018 (and future) releases.
Warning: The index is not maintained automatically and will become inactive after inserts, deletes or updates are done on the column data.
A ordered index is removed using the ordinary DROP INDEX statement. There is no DROP ORDERED INDEX statement.

For details see: Documentation/SQLreference/TableDefinitions/IndexDefinitions
See also: CREATE IMPRINTS INDEX   CREATE INDEX   COMMENT ON INDEX   DROP INDEX

Associated system table: sys.idxs   sys.storage

CREATE VIEW

   CREATE [ OR REPLACE ] VIEW [ schema_name . ] view_name
    [ ( column_name [, column_name ] [, ... ] ) ]
    AS SELECT_query
    [ WITH CHECK OPTION ]

Define a new SQL view. A view is a virtual table based on the result set of a stored SELECT query. A view does not physically store data. It is useful to reduce query complexity as it can include joins, computations, unions, aggregations. It can increase standardisation and reusability and be used to control data access, provide an abstraction layer between applications and physical tables, simplify reporting.

Limitation: Views are not updatable. The "WITH CHECK OPTION" is accepted for compliance but has no effect.
Recursive views and reference-able views are not supported.
Note: An "ORDER BY" clause in the SELECT-query is supported from release Jul2017 (11.27.1) onwards.
The "OR REPLACE" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/ViewDefinitions
See also: COMMENT ON VIEW   COMMENT ON COLUMN   DROP VIEW

Associated system table: sys.tables where type = 1

CREATE AGGREGATE EXTERNAL

   CREATE [ OR REPLACE ] AGGREGATE [ FUNCTION ] [ schema_name . ] aggregate_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    EXTERNAL NAME  MAL_function_name

Define a new user-defined aggregation function for which the implementation is specified externally using MAL and C

Example:

CREATE AGGREGATE quantile(val bigint, q double) RETURNS bigint EXTERNAL NAME "aggr"."quantile";


Note: This command is MonetDB specific. External implies language MAL.
To allow other users to invoke a user-defined aggregate function, you must grant the other users (or PUBLIC) EXECUTE privilege for the aggregate function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For built-in aggregate functions see: Documentation/SQLReference/FunctionsAndOperators/AggregateFunctions
See also: COMMENT ON AGGREGATE   GRANT PRIVILEGES   DROP AGGREGATE   DROP ALL AGGREGATE

Associated system table: sys.functions where type = 3 and language = 1

CREATE AGGREGATE LANGUAGE

   CREATE [ OR REPLACE ] AGGREGATE [ FUNCTION ] [ schema_name . ] aggregate_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    LANGUAGE { C | CPP | R | PYTHON | PYTHON_MAP | PYTHON3 | PYTHON3_MAP }
    '{' function_body '}'

Define a new user-defined aggregation function for which the body implementation is specified in the specific script language

Example:

CREATE AGGREGATE python_aggregate(val INTEGER) 
RETURNS INTEGER 
LANGUAGE PYTHON {
    try:
        unique = numpy.unique(aggr_group)
        x = numpy.zeros(shape=(unique.size))
        for i in range(0, unique.size):
            x[i] = numpy.sum(val[aggr_group==unique[i]])
    except NameError:
        # aggr_group doesn't exist. no groups, aggregate on all data
        x = numpy.sum(val)
    return(x)
};


Note: This command is MonetDB specific. Supported languages are: C, C++, R and Python.
If your Python code requires Python 3 to work correctly use PYTHON3 instead of PYTHON. If your Python code can be executed in parallel (using multiple threads) without side effects, use PYTHON_MAP instead of PYTHON. Idem for PYTHON3_MAP.
Note: Python 2 and the language keywords PYTHON2 and PYTHON2_MAP are no longer supported from release Jun2020 (11.37.7) onwards.
For languages C and CPP a C/C++ compiler must be available on the deployment server and the MonetDB server started with option: --set embedded_c=true.
For language R the R script interpreter software must be available on the deployment server and the MonetDB server started with option: --set embedded_r=true.
For language PYTHON the Python script interpreter software must be available on the deployment server and the MonetDB server started with option: --set embedded_py=true  or --set embedded_py=3.
To allow other users to invoke a user-defined aggregate function, you must grant the other users (or PUBLIC) EXECUTE privilege for the aggregate function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For details see: JIT C/C++ UDFs and embedded-pythonnumpy-monetdb and embedded-r-monetdb
See also: COMMENT ON AGGREGATE   GRANT PRIVILEGES   DROP AGGREGATE   CREATE FUNCTION LANGUAGE

Associated system table: sys.functions where type = 3 and language > 2; sys.function_languages
 

CREATE FUNCTION

   CREATE [ OR REPLACE ] FUNCTION [ schema_name . ] function_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    BEGIN function_body END

Define a new user-defined function

Example:

CREATE FUNCTION heapspace(tpe string, i bigint, w int) returns bigint
begin
 if tpe <> 'varchar' and tpe <> 'clob' then return 0;
 end if;
 return 10240 + i * w;
end;


Note: Besides returning a scalar value (type = 1), functions can also be defined to return a Table as data type (type = 5).
To allow other users to invoke a user-defined function, you must grant the other users (or PUBLIC) EXECUTE privilege for the function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For built-in functions see: Documentation/SQLReference/FunctionsAndOperators
See also: COMMENT ON FUNCTION   GRANT PRIVILEGES   DROP FUNCTION   DROP ALL FUNCTION

Associated system table: sys.functions where type in (1,5) and language = 2

CREATE FUNCTION EXTERNAL

   CREATE [ OR REPLACE ] FUNCTION [ schema_name . ] function_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    EXTERNAL NAME  MAL_function_name

Define a new user-defined function for which the implementation is specified externally using MAL and C

Example:

CREATE FUNCTION isa_uuid(s string) RETURNS boolean EXTERNAL NAME uuid."isaUUID";

CREATE OR REPLACE FUNCTION pcre_match(s string, pattern string) RETURNS boolean EXTERNAL NAME pcre."match";
CREATE OR REPLACE FUNCTION pcre_imatch(s string, pattern string) RETURNS boolean EXTERNAL NAME pcre."imatch";
CREATE OR REPLACE FUNCTION pcre_replace(s string, pattern string, repl string, flags string)
 RETURNS string EXTERNAL NAME pcre."replace";
CREATE OR REPLACE FUNCTION pcre_replacefirst(s string, pattern string, repl string, flags string)
 RETURNS string EXTERNAL NAME pcre."replace_first";


Note: This command is MonetDB specific. External implies language MAL.
Besides returning a scalar value (type = 1), functions can also be defined to return a Table as data type (type = 5).
To allow other users to invoke a user-defined function, you must grant the other users (or PUBLIC) EXECUTE privilege for the function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.
The pcre example functions are copied from use PCRE pattern matching.

For built-in functions see: Documentation/SQLReference/FunctionsAndOperators
and: Documentation/ServerProgramming/ExtendingSQL/UserDefinedFunctions
See also: COMMENT ON FUNCTION   GRANT PRIVILEGES   DROP FUNCTION   CREATE FUNCTION   CREATE FUNCTION LANGUAGE

Associated system table: sys.functions where type in (1,5) and language = 1

CREATE FUNCTION LANGUAGE

   CREATE [ OR REPLACE ] FUNCTION [ schema_name . ] function_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    LANGUAGE { C | CPP | R | PYTHON | PYTHON_MAP | PYTHON3 | PYTHON3_MAP }
    '{' function_body '}'

Define a new user-defined function for which the implementation is specified in a specific script language

Note: This command is MonetDB specific. Supported languages are: C, C++, R and Python.
If your Python code requires Python 3 to work correctly use PYTHON3 instead of PYTHON. If your Python code can be executed in parallel (using multiple threads) without side effects, use PYTHON_MAP instead of PYTHON. Idem for PYTHON3_MAP.
Note: Python 2 and the language keywords PYTHON2 and PYTHON2_MAP are no longer supported from release Jun2020 (11.37.7) onwards.
For languages C and CPP a C/C++ compiler must be available on the deployment server and the MonetDB server started with option: --set embedded_c=true.
For language R the R script interpreter software must be available on the deployment server and the MonetDB server started with option: --set embedded_r=true.
For language PYTHON the Python script interpreter software must be available on the deployment server and the MonetDB server started with option: --set embedded_py=true  or --set embedded_py=3.
Besides returning a scalar value (type = 1), functions can also be defined to return a Table as data type (type = 5).
To allow other users to invoke a user-defined function, you must grant the other users (or PUBLIC) EXECUTE privilege for the function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For details see: JIT C/C++ UDFs and embedded-pythonnumpy-monetdb and embedded-r-monetdb and voter-classification-using-monetdbpython
See also: COMMENT ON FUNCTION   GRANT PRIVILEGES   DROP FUNCTION   CREATE AGGREGATE LANGUAGE   CREATE LOADER

Associated system table: sys.functions where type in (1,5) and language > 2; sys.function_languages
 

CREATE FILTER FUNCTION EXTERNAL

   CREATE [ OR REPLACE ] FILTER [ FUNCTION ] [ schema_name . ] function_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    EXTERNAL NAME  MAL_function_name

Define a new user-defined filter function for which the implementation is specified externally using MAL and C

Example:

CREATE FILTER FUNCTION "re_like"(val string, pat string) external name algebra."rexpr_like";


Note: This command is MonetDB specific. External implies language MAL.
To allow other users to invoke a user-defined filter function, you must grant the other users (or PUBLIC) EXECUTE privilege for the filter function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

See also: COMMENT ON FILTER FUNCTION   GRANT PRIVILEGES   DROP FILTER FUNCTION   DROP ALL FILTER FUNCTION

Associated system table: sys.functions where type = 4 and language = 1
 

CREATE LOADER

   CREATE [ OR REPLACE ] LOADER [ FUNCTION ] [ schema_name . ] function_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    LANGUAGE PYTHON
    '{' python_code_with_emit.emit()_function '}'

Define a new user-defined loader function for which the implementation is done in Python language. A loader function can for instance read data from an external file is a specific format such as XML, json, bson, ods, xlsx, etc.

Example:

CREATE LOADER json_loader(filename STRING) LANGUAGE PYTHON {
    import json
    f = open(filename)
    _emit.emit(json.load(f))
    f.close()
};


Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
For language PYTHON the Python script interpreter software must be available on the deployment server and the MonetDB server started with option: --set embedded_py=true  or --set embedded_py=2  or --set embedded_py=3.
To allow other users to invoke a user-defined loader function, you must grant the other users (or PUBLIC) EXECUTE privilege for the loader function.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For details see: blog/monetdbpython-loader-functions
See also: COMMENT ON LOADER   GRANT PRIVILEGES   DROP LOADER   CREATE TABLE FROM LOADER   COPY LOADER INTO FROM

Associated system table: sys.functions where type = 7 and language > 2
 

CREATE PROCEDURE

   CREATE [ OR REPLACE ] PROCEDURE [ schema_name . ] procedure_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    BEGIN procedure_body END

Define a new user-defined procedure

Note: To allow other users to call and execute a user-defined procedure, you must grant the other users (or PUBLIC) EXECUTE privilege for the procedure.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLreference/ProgrammingSQL/Procedures
See also: COMMENT ON PROCEDURE   DECLARE   CALL   GRANT PRIVILEGES   DROP PROCEDURE   DROP ALL PROCEDURE

Associated system table: sys.functions where type = 2 and language = 2

CREATE PROCEDURE EXTERNAL

   CREATE [ OR REPLACE ] PROCEDURE [ schema_name . ] procedure_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    EXTERNAL NAME  MAL_procedure_name

Define a new user-defined procedure for which the implementation is specified externally using MAL and C

Example:

CREATE PROCEDURE sys.createorderindex(sys string, tab string, col string) external name sql.createorderindex;


Note: This command is MonetDB specific. External implies language MAL.
To allow other users to call and execute a user-defined procedure, you must grant the other users (or PUBLIC) EXECUTE privilege for the procedure.
The "OR REPLACE" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLreference/ProgrammingSQL/Procedures
See also: COMMENT ON PROCEDURE   CALL   GRANT PRIVILEGES   DROP PROCEDURE   DROP ALL PROCEDURE

Associated system table: sys.functions where type = 2 and language = 1

CREATE WINDOW EXTERNAL

   CREATE [ OR REPLACE ] WINDOW [ FUNCTION ] [ schema_name . ] window_name ( [ arg1_nm_type [ , arg2_nm_type ] [, ... ] ] )
    RETURNS datatype
    EXTERNAL NAME  MAL_function_name

Define a new user-defined window function for which the implementation is specified externally using MAL and C

Example:

CREATE OR REPLACE WINDOW stddev(val bigint) RETURNS double EXTERNAL NAME "sql"."stdevp";


Note: This command is MonetDB specific and supported from release Jun2020 (11.37.7) onwards. External implies language MAL.
To allow other users to invoke a user-defined window function, you must grant the other users (or PUBLIC) EXECUTE privilege for the window function.

For built-in window functions see: Documentation/SQLReference/FunctionsAndOperators/WindowFunctions
See also: COMMENT ON WINDOW   GRANT PRIVILEGES   DROP WINDOW   DROP ALL WINDOW

Associated system table: sys.functions where type = 6 and language = 1

CREATE TYPE EXTERNAL

   CREATE TYPE [ schema_name . ] type_name
    EXTERNAL NAME  MAL type_name

Declare a new user-defined data type. The implementation (structure, operators & functions both scalar and bulk) must be specified externally in C code and MAL script. For examples see the C implementations of data types: inet, json, url and uuid.

Note: This command is MonetDB specific. External implies language MAL.

For details see: Documentation/SQLReference/DataTypes/UserDefinedTypes
See also: DROP TYPE   CREATE TABLE

Associated system table: sys.types where eclass = 16

CREATE TRIGGER

   CREATE [ OR REPLACE ] TRIGGER [ schema_name . ] trigger_name
    { BEFORE | AFTER }
    { INSERT | DELETE | TRUNCATE | UPDATE [ OF column_name [, column_name] [, ... ] ] }
    ON [ schema_name . ] table_name
    [ REFERENCING { { OLD | NEW } { [ ROW ] | TABLE } [ AS ] ident } [...] ]
    [ FOR [ EACH ] { ROW | STATEMENT } ]
    [ WHEN ( search_condition ) ]
    { trigger_procedure_statement | BEGIN ATOMIC trigger_procedure_statement_list END }

Define a new trigger on a table update event

Note: FOR EACH STATEMENT is the default if not specified.
The schema name of a full qualified trigger name must be the same as the schema name of the table.
The "OR REPLACE" option and the TRUNCATE trigger event are supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLreference/Triggers
See also: DROP TRIGGER   DECLARE   GRANT PRIVILEGES

Associated system table: sys.triggers
 

COMMENT ON SCHEMA

   COMMENT ON SCHEMA schema_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a schema

Example:

COMMENT ON SCHEMA prj4 IS 'schema of new project 4';
COMMENT ON SCHEMA prj0 IS '';
COMMENT ON SCHEMA prjX IS NULL;


Note: By specifying IS NULL or IS '' you remove the comment for the schema.
If the schema is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE SCHEMA   DROP SCHEMA

Associated system table: sys.comments
 

COMMENT ON TABLE

   COMMENT ON TABLE [ schema_name . ] table_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a table

Example:

COMMENT ON TABLE sys.comments IS 'contains comments on all db objects'


Note: By specifying IS NULL or IS '' you remove the comment for the table object.
If the table is dropped, the associated comment (including the comments for the columns) is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.
Note: it is not allowed or possible to add comments for temporary tables or objects in schema "tmp".

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE TABLE   DROP TABLE

Associated system table: sys.comments
 

COMMENT ON VIEW

   COMMENT ON VIEW [ schema_name . ] view_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a view

Example:

COMMENT ON VIEW mysch.articles_aggr IS 'view lists aggregated info on articles'


Note: By specifying IS NULL or IS '' you remove the comment for the view.
If the view is dropped, the associated comment (including the comments for the columns) is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE VIEW   DROP VIEW

Associated system table: sys.comments
 

COMMENT ON COLUMN

   COMMENT ON COLUMN [ schema_name . ] table_or_view_name . column_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a column of a table or view

Example:

COMMENT ON COLUMN sys.comments.remark IS 'contains description text'


Note: By specifying IS NULL or IS '' you remove the comment for the column.
If the column (or table or view) is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.
Note: it is not allowed or possible to add comments for columns of temporary tables or objects in schema "tmp".

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: ALTER TABLE ADD COLUMN   ALTER TABLE DROP COLUMN

Associated system table: sys.comments
 

COMMENT ON INDEX

   COMMENT ON INDEX [ schema_name . ] index_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for an index

Example:

COMMENT ON INDEX mysch.article_id IS 'unique index of id key column of article table'


Note: By specifying IS NULL or IS '' you remove the comment for the index.
If the index is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE INDEX   DROP INDEX

Associated system table: sys.comments
 

COMMENT ON SEQUENCE

   COMMENT ON SEQUENCE [ schema_name . ] sequence_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a sequence

Example:

COMMENT ON SEQUENCE mysch.article_id_seq IS 'sequence for article id column'


Note: By specifying IS NULL or IS '' you remove the comment for the sequence.
If the sequence is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE SEQUENCE   DROP SEQUENCE

Associated system table: sys.comments
 

COMMENT ON FUNCTION

   COMMENT ON FUNCTION [ schema_name . ] function_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a function

Example:

COMMENT ON FUNCTION sys.upper IS 'converts text into uppercase'


Note: By specifying IS NULL or IS '' you remove the comment for the function.
If the function is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE FUNCTION   DROP FUNCTION

Associated system table: sys.comments
 

COMMENT ON PROCEDURE

   COMMENT ON PROCEDURE [ schema_name . ] procedure_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a procedure

Example:

COMMENT ON PROCEDURE mysch.load_articles IS 'proc which reloads the articles from external file article.csv'


Note: By specifying IS NULL or IS '' you remove the comment for the procedure.
If the procedure is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE PROCEDURE   DROP PROCEDURE

Associated system table: sys.comments
 

COMMENT ON AGGREGATE

   COMMENT ON AGGREGATE [ schema_name . ] aggregate_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for an aggregate function

Example:

COMMENT ON AGGREGATE sys.std_dev IS 'computes the standard deviation of a group of numeric values'


Note: By specifying IS NULL or IS '' you remove the comment for the aggregate function.
If the aggregate function is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE AGGREGATE LANGUAGE   DROP AGGREGATE

Associated system table: sys.comments
 

COMMENT ON FILTER FUNCTION

   COMMENT ON FILTER FUNCTION [ schema_name . ] function_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a filter function

Example:

COMMENT ON FILTER FUNCTION sys."ilike"(clob, clob) IS 'case insensitive pattern matching';
COMMENT ON FILTER FUNCTION sys."ilike"(clob, clob, clob) IS 'case insensitive pattern matching with user specified escape character';


Note: By specifying IS NULL or IS '' you remove the comment for the filter function.
If the filter function is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE FILTER FUNCTION EXTERNAL   DROP FILTER FUNCTION

Associated system table: sys.comments
 

COMMENT ON LOADER

   COMMENT ON LOADER [ schema_name . ] function_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a loader function

Example:

COMMENT ON LOADER mysch.load_xls_data IS 'custom loader to extract data from external xls file'


Note: By specifying IS NULL or IS '' you remove the comment for the loader function.
If the loader function is dropped, the associated comment is also removed.
This command is supported from release Mar2018 (11.29.3) onwards.

For details see: bugzilla/show_bug.cgi?id=6109#c5
See also: CREATE LOADER   DROP LOADER

Associated system table: sys.comments
 

COMMENT ON WINDOW

   COMMENT ON WINDOW [ FUNCTION ] [ schema_name . ] window_name IS  { 'comment text' | NULL | '' }

Add or update or remove a comment for a window function

Example:

COMMENT ON WINDOW FUNCTION sys.stddev IS 'computes the standard deviation of a group of numeric values'


Note: By specifying IS NULL or IS '' you remove the comment for the window function.
If the window function is dropped, the associated comment is also removed.
This command is supported from release Jun2020 (11.37.7) onwards.

See also: CREATE WINDOW EXTERNAL   DROP WINDOW

Associated system table: sys.comments
 

DECLARE

   DECLARE variable_name datatype

Example:

DECLARE ts1 timestamp;
SET ts1 = now();
SELECT ts1;
SELECT * FROM sys.var() WHERE name NOT IN (SELECT var_name FROM sys.var_values);


Note: The declared variable is not persistent. It will be lost after closing the connection or session.

For details see: Documentation/SQLreference/ProgrammingSQL/Variables
See also: SET   SELECT

Associated system table: sys.var()

ALTER SEQUENCE

   ALTER SEQUENCE [ schema_name . ] sequence_name [ AS datatype  ]
    [ RESTART [WITH bigint# ] ]
    [ INCREMENT BY bigint# ]
    [ MINVALUE bigint# | NO MINVALUE ]
    [ MAXVALUE bigint# | NO MAXVALUE ]
    [ CACHE bigint# ]
    [ [ NO ] CYCLE ]

Change definition of a sequence generator

For details see: Documentation/SQLReference/DataTypes/SerialDatatypes
See also: DROP SEQUENCE   CREATE SEQUENCE

Associated system table: sys.sequences

ALTER TABLE ADD COLUMN

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    ADD [ COLUMN ] column_name { data_type [ column_option ... ] | SERIAL | BIGSERIAL }

Add a column to a table

Note: The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE ADD CONSTRAINT   ALTER TABLE ALTER COLUMN   ALTER TABLE DROP COLUMN

Associated system table: sys.columns

ALTER TABLE ALTER COLUMN

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    ALTER [ COLUMN ] column_name { SET NULL | SET NOT NULL | SET DEFAULT value | DROP DEFAULT | SET STORAGE {string | NULL} }

Change column nullability or default value or storage

Note: Change of the data type of a column is not supported. Instead use command sequence:
  ALTER TABLE tbl ADD COLUMN new_column new_data_type;
  UPDATE tbl SET new_column = CONVERT(old_column, new_data_type);
  ALTER TABLE tbl DROP COLUMN old_column RESTRICT;
  ALTER TABLE tbl RENAME COLUMN new_column TO old_column;

The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE RENAME COLUMN   ALTER TABLE ADD COLUMN   ALTER TABLE DROP COLUMN   ALTER TABLE DROP CONSTRAINT

Associated system table: sys.columns

ALTER TABLE DROP COLUMN

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    DROP [ COLUMN ] column_name
    [ RESTRICT | CASCADE ]

Remove a column from a table

Note: You cannot drop a column if it is referenced (e.g. from a view, an index, a merge table, a trigger, a foreign key constraint, a function or procedure or another db object except comments). Use option CASCADE to specify to also drop those referencing objects.
The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE DROP CONSTRAINT   ALTER TABLE ALTER COLUMN   DROP TABLE

Associated system table: sys.columns

ALTER TABLE ADD CONSTRAINT

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    ADD [ CONSTRAINT constraint_name ]
    { PRIMARY KEY ( column_name [ , column_name ] [, ... ] )
    |      UNIQUE ( column_name [ , column_name ] [, ... ] )
    | FOREIGN KEY ( column_name [ , column_name ] [, ... ] ) REFERENCES [ schema_name . ] table_name
        [ ( column_name [ , column_name ] [, ... ] ) ]   [ match_options ]   [ ref_actions ]
    }

Add a table constraint to a table

Examples:

ALTER TABLE "tblnm" ADD PRIMARY KEY ("C1_id");
ALTER TABLE if exists "schnm"."tblnm" ADD CONSTRAINT "tblnm_uc" UNIQUE ("name", "desc");
ALTER TABLE "tblnm" ADD CONSTRAINT "tblnm_fk1" FOREIGN KEY ("f_id", "f_seq") REFERENCES "schnm2"."fun" ("id", "seq");


Note: Only one PRIMARY KEY constraint can be defined per table. When a primary key constraint is added, all the primary key columns will become NOT NULLable implicitly.
If no constraint_name is specified a constraint_name will be composed implicitly from the table name, column name(s) and constraint type.
The CHECK constraint is not (yet) supported.
The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE DROP CONSTRAINT   ALTER TABLE ALTER COLUMN

Associated system table: sys.keys

ALTER TABLE DROP CONSTRAINT

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    DROP CONSTRAINT  constraint_name
    [ RESTRICT | CASCADE ]

Remove a table/column constraint from a table

Note: You cannot drop a constraint if it is referenced (e.g. from a foreign key constraint). Use option CASCADE to specify to also drop those referencing objects.
To remove a NOT NULL column constraint use: ALTER TABLE sch.tbl ALTER COLUMN column_name SET NULL.
The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE ADD CONSTRAINT   ALTER TABLE ALTER COLUMN

Associated system table: sys.keys

ALTER TABLE RENAME TO

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    RENAME TO  new_table_name

Change the name of a table

Note: It is only allowed to change the name of a table if no objects exists which depends on the table name, such as foreign key constraints, views, triggers, indices, functions, procedures, etc.
To move a table to s different schema use command: ALTER TABLE ... SET SCHEMA ...
This command is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: CREATE TABLE AS   ALTER TABLE SET SCHEMA

Associated system table: sys.tables

ALTER TABLE RENAME COLUMN

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    RENAME [ COLUMN ]  column_name TO  new_column_name

Change the name of a column

Note: It is only allowed to change the name of a column if no objects exists which depends on the column name, such as constraints, views, functions, etc.
This command is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE ADD COLUMN   ALTER TABLE DROP COLUMN   ALTER TABLE DROP CONSTRAINT

Associated system table: sys.columns

ALTER TABLE SET SCHEMA

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    SET SCHEMA  new_schema_name

Change the schema name of a table

Note: It is only allowed to change the schema name of a table if no objects exists which depends on the table name, such as foreign key constraints, views, triggers, indices, functions, procedures, etc.
This command is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: CREATE TABLE AS   ALTER TABLE RENAME TO

Associated system table: sys.tables

ALTER TABLE ADD TABLE

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] merge_table_name
    ADD TABLE [ schema_name . ] table_name
    [ AS PARTITION  partition_spec ]

partition_spec:

      IN ( expression [ , expression ] [, ... ] )  [ WITH NULL VALUES ]
    | FROM  { RANGE MINVALUE | expression }  TO  { RANGE MAXVALUE | expression }  [ WITH NULL VALUES ]
    | FOR NULL VALUES

Add a table reference to a merge table set optionally with an partitioning specification

Note: This command is MonetDB specific.
Limitations: The added table must have the same column definitions and layout as the merge table.
Only user defined tables and merge tables can be added to a merge table set.
When the merge table was created with a PARTITION BY clause, the AS PARTITION clause must be specified.
The "AS PARTITION" option is supported from release Apr2019 (11.33.3) onwards.
The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/ServerAdministration/DistributedQueryProcessing/DataPartitioning and updatable-merge-tables
and: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: CREATE MERGE TABLE   ALTER TABLE SET TABLE   ALTER TABLE DROP TABLE

Associated system tables: sys.tables where type = 3;   sys.range_partitions;   sys.value_partitions;

ALTER TABLE SET TABLE

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] merge_table_name
    SET TABLE [ schema_name . ] table_name
    AS PARTITION  partition_spec

partition_spec:

      IN ( expression [ , expression ] [, ... ] )  [ WITH NULL VALUES ]
    | FROM  { RANGE MINVALUE | expression }  TO  { RANGE MAXVALUE | expression }  [ WITH NULL VALUES ]
    | FOR NULL VALUES

Change the partitioning specification of a partition table

Note: This command is MonetDB specific. It is supported from release Apr2019 (11.33.3) onwards.

For details see: updatable-merge-tables and Documentation/SQLreference/TableDefinitions/AlterStatement
See also: CREATE MERGE TABLE   ALTER TABLE ADD TABLE   ALTER TABLE DROP TABLE

Associated system tables: sys.tables where type = 3;   sys.range_partitions;   sys.value_partitions;

ALTER TABLE DROP TABLE

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] merge_table_name
    DROP TABLE [ schema_name . ] table_name
    [ RESTRICT | CASCADE ]

Remove a table reference from a merge table set. The partition table itself will not be dropped.

Note: This command is MonetDB specific.
The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/ServerAdministration/DistributedQueryProcessing/DataPartitioning
and: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: CREATE MERGE TABLE   ALTER TABLE ADD TABLE

Associated system tables: sys.tables where type = 3;   sys.range_partitions;   sys.value_partitions;

ALTER TABLE SET INSERT ONLY

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    SET INSERT ONLY

Change access of a table to allow only inserts

Note: The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE SET READ ONLY   ALTER TABLE SET READ WRITE

Associated system table: sys.tables where type in (0, 3, 4, 5, 6)

ALTER TABLE SET READ ONLY

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    SET READ ONLY

Change access of a table to allow only reads (select queries)

Note: The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE SET READ WRITE   ALTER TABLE SET INSERT ONLY

Associated system table: sys.tables

ALTER TABLE SET READ WRITE

   ALTER TABLE [ IF EXISTS ] [ schema_name . ] table_name
    SET READ WRITE

Restore access of a table to allow inserts, updates, deletes and reads

Note: The "IF EXISTS" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/TableDefinitions/AlterStatement
See also: ALTER TABLE SET READ ONLY   ALTER TABLE SET INSERT ONLY

Associated system table: sys.tables where type in (0, 3, 4, 5, 6)

DROP SCHEMA

   DROP SCHEMA [ IF EXISTS ] schema_name
    [ RESTRICT | CASCADE ]

Remove a database schema, potentially including all its dependent objects

Example:

DROP SCHEMA IF EXISTS "my_project" RESTRICT;


Note: You cannot drop a schema if it contains objects (e.g. tables, views, functions or procedures, except comments). Use option CASCADE to specify to also drop those referencing objects. The default behavior is RESTRICT.
System schemas (sys, tmp, profiler, json) can not be dropped as they are needed by the system.
Warning: in releases before Mar2018 (11.29.3) the default behavior was CASCADE always. The option RESTRICT was recognised but ignored without warning. This has been corrected in release Mar2018.
The "IF EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLreference/Schema
See also: CREATE SCHEMA   CURRENT_SCHEMA   SET SCHEMA

Associated system table: sys.schemas
 

DROP SEQUENCE

   DROP SEQUENCE [ schema_name . ] sequence_name

Remove an existing sequence generator

Note: You cannot drop a sequence if it is referenced from another object e.g. from a column, a function or procedure.

For details see: Documentation/SQLReference/DataTypes/SerialDatatypes
and: Documentation/SQLReference/DataDefinition/DropStatement
See also: ALTER SEQUENCE   CREATE SEQUENCE

Associated system table: sys.sequences

DROP TABLE

   DROP TABLE [ IF EXISTS ] [ schema_name . ] table_name
    [ RESTRICT | CASCADE ]

Remove a table, potentially including all its dependent objects

Example:

DROP TABLE IF EXISTS "my_project"."my_Table" CASCADE;


Note: You cannot drop a table if it is referenced from a view, a merge table, a trigger, a foreign key constraint, a function, a procedure. Use option CASCADE to specify to also drop those referencing objects. Objects which are part of the table such as columns, pkey/unique/fkey constraints, indices, comments, table_partitions, range_partitions and value_partitions are removed also when a table is dropped.
Warning: When dropping a merge table, also all the related table partitioning information (in sys.table_partitions, sys.range_partitions and sys.value_partitions) is removed.
System tables can also not be dropped as they are needed by the system.
The "IF EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/ServerAdministration/DistributedQueryProcessing/DataPartitioning
and: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE TABLE

Associated system tables: sys.tables; sys.columns;   sys.comments;   sys.idxs;   sys.table_partitions;   sys.range_partitions;   sys.value_partitions;   sys.dependencies_vw

DROP INDEX

   DROP INDEX [ schema_name . ] index_name

Remove an existing table index

Example:

DROP TABLE "my_project"."my_Index";


For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE INDEX   CREATE ORDERED INDEX   CREATE IMPRINTS INDEX

Associated system table: sys.idxs

DROP VIEW

   DROP VIEW [ IF EXISTS ] [ schema_name . ] view_name
    [ RESTRICT | CASCADE ]

Remove a view

Example:

DROP VIEW IF EXISTS "my_project"."my_View" CASCADE;


Note: You cannot drop a view if it is referenced (e.g. from another view, a function or procedure or another db object except comments). Use option CASCADE to specify to also drop those referencing objects.
System views can also not be dropped as they are needed by the system.
The "IF EXISTS" option is supported from release Jul2017 (11.27.1) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE VIEW

Associated system table: sys.tables where type = 1

DROP AGGREGATE

   DROP AGGREGATE [ FUNCTION ] [ IF EXISTS ] [ schema_name . ] aggregate_function_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined aggregation function. If multiple aggregate functions exist with the same name, supply the full signature.

Example:

DROP AGGREGATE testaggr(int, double);


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.
System aggregates can not be dropped as they are part by the system.
The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP ALL AGGREGATE   CREATE AGGREGATE LANGUAGE   CREATE AGGREGATE EXTERNAL

Associated system table: sys.functions where type = 3

DROP ALL AGGREGATE

   DROP ALL AGGREGATE [ FUNCTION ] [ schema_name . ] aggregate_function_name
    [ RESTRICT | CASCADE ]

Remove all user-defined aggregation functions which share the same name but have different signatures.

Example:

DROP ALL AGGREGATE testaggr;


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP AGGREGATE   CREATE AGGREGATE LANGUAGE   CREATE AGGREGATE EXTERNAL

Associated system table: sys.functions where type = 3

DROP FUNCTION

   DROP FUNCTION [ IF EXISTS ] [ schema_name . ] function_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined function. If multiple functions exist with the same name, supply the full signature.

Example:

DROP FUNCTION testfun(int, double);


Note: Use option CASCADE to specify to also drop referencing objects.
System functions can not be dropped as they are part by the system.
The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP ALL FUNCTION   CREATE FUNCTION   CREATE FUNCTION LANGUAGE

Associated system table: sys.functions where type in (1,5)

DROP ALL FUNCTION

   DROP ALL FUNCTION [ schema_name . ] function_name
    [ RESTRICT | CASCADE ]

Remove all user-defined functions which share the same name but have different signatures.

Example:

DROP ALL FUNCTION testfun;


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP FUNCTION   CREATE FUNCTION   CREATE FUNCTION LANGUAGE

Associated system table: sys.functions where type in (1,5)

DROP FILTER FUNCTION

   DROP FILTER [ FUNCTION ] [ IF EXISTS ] [ schema_name . ] function_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined filter function. If multiple filter functions exist with the same name, supply the full signature.

Example:

DROP FILTER FUNCTION my_like(string, varchar(100));


Note: This command is MonetDB specific.
System filter functions can not be dropped as they are part by the system.
Use option CASCADE to specify to also drop referencing objects.
The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP ALL FILTER FUNCTION   CREATE FILTER FUNCTION EXTERNAL

Associated system table: sys.functions where type = 4

DROP ALL FILTER FUNCTION

   DROP ALL FILTER [ FUNCTION ] [ schema_name . ] function_name
    [ RESTRICT | CASCADE ]

Remove all user-defined filter functions which share the same name but have different signatures.

Example:

DROP ALL FILTER FUNCTION my_like;


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP FILTER FUNCTION   CREATE FILTER FUNCTION EXTERNAL

Associated system table: sys.functions where type = 4

DROP LOADER

   DROP LOADER [ FUNCTION ] [ IF EXISTS ] [ schema_name . ] function_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined loader function. If multiple loader functions exist with the same name, supply the full signature.

Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: blog/monetdbpython-loader-functions
See also: DROP ALL LOADER   CREATE LOADER   CREATE FUNCTION LANGUAGE

Associated system table: sys.functions where type = 7 and language > 2
 

DROP ALL LOADER

   DROP ALL LOADER [ FUNCTION ] [ schema_name . ] function_name
    [ RESTRICT | CASCADE ]

Remove all user-defined loader functions which share the same name but have different signatures.

Example:

DROP ALL LOADER my_ods_loader;


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP LOADER   CREATE LOADER

Associated system table: sys.functions where type = 7 and language > 2

DROP PROCEDURE

   DROP PROCEDURE [ IF EXISTS ] [ schema_name . ] procedure_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined procedure. If multiple procedures exist with the same name, supply the full signature.

Example:

DROP PROCEDURE testproc(int, double);


Note: Use option CASCADE to specify to also drop referencing objects.
System procedures can not be dropped as they are part by the system.
The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP ALL PROCEDURE   CREATE PROCEDURE   CREATE PROCEDURE EXTERNAL

Associated system table: sys.functions where type = 2

DROP ALL PROCEDURE

   DROP ALL PROCEDURE [ schema_name . ] procedure_name
    [ RESTRICT | CASCADE ]

Remove all user-defined procedures which share the same name but have different signatures.

Example:

DROP ALL PROCEDURE testproc;


Note: This command is MonetDB specific.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP PROCEDURE   CREATE PROCEDURE   CREATE PROCEDURE EXTERNAL

Associated system table: sys.functions where type = 2

DROP WINDOW

   DROP WINDOW [ FUNCTION ] [ IF EXISTS ] [ schema_name . ] window_function_name
    [ ( [ arg1_type [ , arg2_type ] [, ... ] ] ) ]
    [ RESTRICT | CASCADE ]

Remove a specific user-defined window function. If multiple window functions exist with the same name, supply the full signature.

Example:

DROP WINDOW stddev(bigint);


Note: This command is MonetDB specific and supported from release Jun2020 (11.37.7) onwards.
Use option CASCADE to specify to also drop referencing objects.
System window functions can not be dropped as they are part by the system.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP ALL WINDOW   CREATE WINDOW EXTERNAL

Associated system table: sys.functions where type = 6 and language = 1 and not system

DROP ALL WINDOW

   DROP ALL WINDOW [ FUNCTION ] [ schema_name . ] window_function_name
    [ RESTRICT | CASCADE ]

Remove all user-defined window functions which share the same name but have different signatures.

Example:

DROP ALL WINDOW my_window_func;


Note: This command is MonetDB specific and supported from release Jun2020 (11.37.7) onwards.
Use option CASCADE to specify to also drop referencing objects.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: DROP WINDOW   CREATE WINDOW EXTERNAL

Associated system table: sys.functions where type = 6 and language = 1 and not system

DROP TYPE

   DROP TYPE [ schema_name . ] type_name
    [ RESTRICT | CASCADE ]

Remove a user-defined type

For details see: Documentation/SQLReference/DataTypes/UserDefinedTypes
See also: CREATE TYPE EXTERNAL

Associated system table: sys.types

DROP TRIGGER

   DROP TRIGGER [ IF EXISTS ] [ schema_name . ] trigger_name

Remove an existing trigger

Note: The "IF EXISTS" option is supported from release Mar2018 (11.29.3) onwards.

For details see: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE TRIGGER

Associated system table: sys.triggers

SELECT

   SELECT selection_list
    [ FROM table_view_subselect_function_list [ [ AS ] table_alias ] ]
    [ WINDOW window_definition_list ]
    [ WHERE condition_list ]
    [ GROUP BY grouping_list ]
    [ HAVING group conditon_list ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] [ CORRESPONDING [ BY '(' column_ref_commalist ')' ] ] SELECT_query ]
    [ ORDER BY ordering_list [ ASC | DESC ]  ]
    [ LIMIT nr_of_rows ]
    [ OFFSET row_nr ]
    [ SAMPLE sample_size [ SEED integer ] ]

Execute a database query and return the resultset data rows

Example:

-- query to list all non-system tables:
SELECT tbl.id, table_type_name, sch.name AS "Schema", tbl.name as "Table"
    , (select count(*) from sys.columns where table_id = tbl.id) as nr_of_columns
  FROM sys."tables" as tbl
 INNER JOIN sys.table_types ON tbl.type = table_type_id
 INNER JOIN sys."schemas" as sch ON tbl.schema_id = sch.id
 WHERE NOT tbl.system	-- exclude system tables and views
   AND table_type_name <> 'VIEW'	-- exclude user views
 ORDER by "Schema", "Table";

-- example using window functions
SELECT id, emp_name, dep_name
     , ROW_NUMBER()           OVER (PARTITION BY dep_name ORDER BY id) AS row_number_in_frame
     , NTH_VALUE(emp_name, 2) OVER (PARTITION BY dep_name ORDER BY id) AS second_row_in_frame
     , LEAD(emp_name, 2)      OVER (PARTITION BY dep_name ORDER BY id) AS two_rows_ahead
     , SUM(salary)  OVER (PARTITION BY dep_name ORDER BY salary  ROWS BETWEEN 2 PRECEDING AND CURRENT ROW) AS sum_over_1or2or3_rows
     , SUM(salary)  OVER (PARTITION BY dep_name ORDER BY salary  GROUPS BETWEEN 1 PRECEDING AND 1 FOLLOWING) AS sum_over_groups
     , SUM(salary)  OVER (PARTITION BY dep_name ORDER BY salary  RANGE BETWEEN 100.0 PRECEDING AND 50.0 FOLLOWING) AS sum_over_range
  FROM employee
 ORDER BY dep_name, id;

-- example using (values(tuple),(tuple),...)
select *
 from ( values(0,'cero'),(1,'uno'),(2,'dos'),(3,'tres'),(4,'cuatro'),(5,'cinco'),(6,'seis'),(7,'siete'),(8,'ocho'),(9,'nueve'),(10,'diez') ) as nr_es(nr, nm)


Note: It is also possible to select data without a FROM-clause, such as: SELECT CURRENT_DATE, (1+2) * 3, pi();
The "WINDOW window_definition_list" option and "SEED integer" option are supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLReference/DataManipulation/TableExpressions , Documentation/SQLReference/FunctionsAndOperators/WindowFunctions ,
Documentation/ServerAdministration/Sampling and wiki/Structured_Query_Language/Window_functions

Associated system table: sys.queue and sys.querylog_history

SELECT INTO

   SELECT selection_list
    INTO variable_list
    [ FROM table_view_subselect_function_list [ [ AS ] table_alias ] ]
    [ WINDOW window_definition_list ]
    [ WHERE condition_list ]
    [ GROUP BY grouping_list ]
    [ HAVING group conditon_list ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] [ CORRESPONDING [ BY '(' column_ref_commalist ')' ] ] SELECT_query ]
    [ ORDER BY ordering_list [ ASC | DESC ]  ]
    [ LIMIT nr_of_rows ]
    [ OFFSET row_nr ]
    [ SAMPLE sample_size [ SEED integer ] ]

Execute a database query and store the resultset data in the named variables

Note: The "WINDOW window_definition_list" option and "SEED integer" option are supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLReference/DataManipulation/TableExpressions
and: Documentation/ServerAdministration/Monitoring

Associated system table: sys.queue and sys.querylog_history

WITH SELECT

   WITH cte_alias AS SELECT_query
     [, cte_alias AS SELECT_query] [, ... ]
   SELECT selection_list
    [ INTO variable_list ]
    [ FROM cte_alias_table_view_subselect_function_list [ [ AS ] table_alias ] ]
    [ WINDOW window_definition_list ]
    [ WHERE condition_list ]
    [ GROUP BY grouping_list ]
    [ HAVING group conditon_list ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] [ CORRESPONDING [ BY '(' column_ref_commalist ')' ] ] SELECT_query ]
    [ ORDER BY ordering_list [ ASC | DESC ]  ]
    [ LIMIT nr_of_rows ]
    [ OFFSET row_nr ]
    [ SAMPLE sample_size [ SEED integer ] ]

Execute a database query using the results of the queries defined in the WITH clause and return the resultset data rows

Note: Recursive queries are NOT supported yet. This feature request is logged in bugzilla.
The "WINDOW window_definition_list" option and "SEED integer" option are supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLReference/DataManipulation/TableExpressions

Associated system table: sys.queue and sys.querylog_history

INSERT VALUES

   INSERT INTO [ schema_name . ] table_name
     [ ( column_name [, column_name] [, ... ] ) ]
    VALUES ( values_list )   [, ( values_list ) [, ... ] ]

Add data row(s) to an existing table

Example:

INSERT INTO "mySch"."myTab" (id, name) VALUES (1, 'a'), (2, 'b'), (3, 'c');


Note: It is also possible to add multiple rows of values in one insert statement by adding extra ", (values_list)" parts.

For details see: Documentation/SQLReference/DataManipulation/TableUpdates
and: Documentation/ServerAdministration/LoadingBulkData

Associated system table: sys.querylog_history

INSERT SELECT

     [ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query] [, ... ] ]
   INSERT INTO [ schema_name . ] table_name
     [ ( column_name [, column_name] [, ... ] ) ]
     SELECT_query

Execute a database query and add the resultset data rows into the existing table

Note: The "WITH cte_alias AS SELECT_query" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLReference/DataManipulation/TableUpdates

Associated system table: sys.querylog_history

UPDATE

     [ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query] [, ... ] ]
   UPDATE [ schema_name . ] table_name [ [ AS ] table_alias ]
     SET column_name = expression_value
        [ , column_name = expression_value ] [, ... ]
     [ FROM cte_alias_table_view_subselect_function_list [ [ AS ] table_alias ] ]
     [ WHERE condition_expression ]

Change values of specific column(s) and row(s) of an existing table. If the optional WHERE clause is specified only the rows which match the condition(s) are changed. Table alias option is available since Apr2019 release.

Example:

UPDATE employee SET salary = salary * 1.07, bonus = 1200 WHERE id = 12345;


Note: The "WITH cte_alias AS SELECT_query" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLReference/DataManipulation/TableUpdates

Associated system table: sys.querylog_history

MERGE

     [ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query] [, ... ] ]
   MERGE INTO [ schema_name . ] table_name [ [ AS ] target_alias ]
    USING table_or_cte_ref [ [ AS ] source_alias ]
       ON merge_search_condition
     WHEN merge_action
     [ WHEN merge_action ]

  merge_action:

     NOT MATCHED THEN INSERT [ (column1 [, column2 ...] ) ] [ { VALUES (value1 [, value2 ...] ) | DEFAULT VALUES } ]
   | MATCHED THEN UPDATE SET column1 = value1 [, column2 = value2 ] [, ... ]
   | MATCHED THEN DELETE

The MERGE INTO command is used to make changes in one table (target) based on values matched from another (source). It can be used to combine insert and update or insert and delete operations into one command, instead of multiple INSERT and UPDATE/DELETE commands. You must specify a merge search condition which determines whether a record will be inserted or updated/deleted.

Example:

MERGE INTO ProductTarget T
     USING ProductSource S
        ON S.ProductID = T.ProductID
      WHEN MATCHED     THEN UPDATE SET Name = S.Name, ProductNumber = S.ProductNumber, Color = S.Color
      WHEN NOT MATCHED THEN INSERT (ProductID, Name, ProductNumber, Color)
                            VALUES (S.ProductID, S.Name, S.ProductNumber, S.Color);

Note: This SQL:2003 command is supported from release Apr2019 (11.33.3) onwards.
Limitations: Multiple WHEN MATCHED clauses or multiply WHEN NOT MATCHED clauses in a merge command are not allowed.
Also WHEN MATCHED AND condition THEN ... syntax is not supported.

For details see: merge_statements_now_supported   and   en.wikipedia.org/wiki/Merge_(SQL)

Associated system table: sys.querylog_history
 

DELETE

     [ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query] [, ... ] ]
   DELETE FROM [ schema_name . ] table_name [ [ AS ] table_alias ]
     [ WHERE condition_expression ]

Remove data row(s) from an existing table. If the optional WHERE clause is specified only the rows which match the condition(s) are removed. Table alias option is available since Apr2019 release.

Example:

DELETE FROM web.log WHERE "timestamp" <= '2016-12-23 23:59:59';


Note: The "WITH cte_alias AS SELECT_query" option is supported from release Apr2019 (11.33.3) onwards.

For details see: Documentation/SQLreference/Updates
See also: TRUNCATE

Associated system table: sys.querylog_history
 

TRUNCATE

   TRUNCATE [ TABLE ] [ schema_name . ] table_name
    [ CONTINUE IDENTITY | RESTART IDENTITY ]
    [ RESTRICT | CASCADE ]

Remove all data row(s) from an existing table quickly

Example:

TRUNCATE TABLE mysch.imp_article CONTINUE IDENTITY CASCADE;


Note: The option RESTART IDENTITY can be used to reset the sequence start value of an identity column for new data inserts after the truncate. Default behavior is to CONTINUE IDENTITY sequence numbering.
The CASCADE option instructs to truncate referencing table(s) also if the referencing table(s) have foreign key references to this table. The default behavior is RESTRICT.
This command is supported from release Mar2018 (11.29.3) onwards.
Note: it is possible to use TRUNCATE statements in a transaction and thus to rollback the effects of a truncate.

For details see: Documentation/SQLReference/DataManipulation/TableUpdates
See also: DELETE

Associated system table: sys.querylog_history

CALL

   CALL [ schema_name . ] procedure_name ( [ arg1_val [ , arg2_val ] [, ... ] ] )

Execute a stored procedure

Example:

CALL sys."settimeout"(3000);
CALL sys.hot_snapshot(R'D:\MonetDB\Backups\demodb.tar.gz');


Note: The current user must have EXECUTE privilege for the called procedure.

For details see: Documentation/SQLreference/Flowofcontrol
See also: CREATE PROCEDURE   GRANT PRIVILEGES

Associated system table: sys.querylog_calls
 

PREPARE

   PREPARE SQL_DML_statement-with-optional-question_mark-parameter-markers

Compiles a SQL statement into its execution plan. This is useful for statements which need to be executed many times but with different values each time, such as an INSERT or UPDATE or SELECT query.

Example:

PREPARE INSERT INTO towns (name, country, citizens) VALUES (?, ?, ?);

-- to find out which prepared statement id is assigned, run query:
SELECT statementid, statement, created FROM sys.prepared_statements;

EXECUTE 5('Amsterdam', 'NL', 856124);
EXECUTE 5('Berlin', 'DE', 3715930);


PREPARE SELECT id, name, schema_id FROM tables WHERE name like ?;

-- to find out which prepared statement id is assigned, run query:
SELECT statementid, statement, created FROM sys.prepared_statements
 WHERE statement ILIKE 'PREPARE SELECT id, name, schema_id FROM tables WHERE name like ?%';

EXECUTE 7( '%type%' );
EXECUTE 7('%id%');

DEALLOCATE 7;
DEALLOCATE ALL;


Note: You can prepare any DML command, such as SELECT, INSERT, UPDATE, DELETE, MERGE, CALL, etc.
The prepared statement will be given a system identifier number which can be used in the EXECUTE and DEALLOCATE commands.
Instead of keyword PREPARE you may also use PREP.

For details see: Documentation/SQLreference/RuntimeFeatures/PrepareExec
and: Documentation/ServerAdministration/LoadingBulkData
See also: EXECUTE and DEALLOCATE

Associated system tables: sys.prepared_statements and sys.prepared_statements_args

EXECUTE

   EXECUTE prepared-SQL-id ( [ parm1_val [ , parm2_val ] [, ... ] ] )

Execute the prepared statement with specific parameter values

Example:

-- first find out which prepared statement id is assigned, run query:
SELECT statementid, statement, created FROM sys.prepared_statements;

EXECUTE 5('Amsterdam', 'NL', 856124);

EXECUTE 19('c-data');


Note: Instead of keyword EXECUTE you may also use EXEC.
WARNING: when an error occurs in the user session, all the user prepared statement(s) are removed !!

For details see: Documentation/SQLreference/RuntimeFeatures/PrepareExec
See also: PREPARE and DEALLOCATE

Associated system tables: sys.prepared_statements and sys.prepared_statements_args

DEALLOCATE

   DEALLOCATE [ PREPARE ] { prepared-SQL-id | ALL }

Close a specific or all prepared statements created in this user session

Example:

-- first find out which prepared statement id's exist, run query:
SELECT statementid, statement, created FROM sys.prepared_statements;

DEALLOCATE PREPARE 65;
DEALLOCATE ALL;


Note: This command is supported from release Jun2020 (11.37.7) onwards.

For details see: Documentation/SQLreference/RuntimeFeatures/PrepareExec
See also: PREPARE

Associated system table: sys.prepared_statements

SET

   SET variable_name = new_value

Change the value of a declared variable

For details see: Documentation/SQLreference/ProgrammingSQL/Variables
See also: DECLARE   SELECT

Associated system table: sys.var()

SET CURRENT_TIMEZONE

   SET CURRENT_TIMEZONE = minutes

Change the current timezone offset from GMT

Example:

SELECT CURRENT_TIMEZONE;
SET CURRENT_TIMEZONE = 3600;


For details see: Documentation/SQLreference/ProgrammingSQL/Variables
See also: CURRENT_TIMEZONE

Associated system table: sys.var_values

SET TIME ZONE

   SET TIME ZONE { LOCAL | INTERVAL 'hh:mi' HOUR TO MINUTE }

Change the current timezone

Example:

SELECT CURRENT_TIMEZONE;
SET TIME ZONE LOCAL;
SELECT CURRENT_TIMEZONE;
SET TIME ZONE INTERVAL '+02:00' HOUR TO MINUTE;
SET TIME ZONE INTERVAL '3' HOUR;
SET TIME ZONE INTERVAL '240' MINUTE;
SET TIME ZONE INTERVAL '-3600' SECOND;


For details see: Documentation/SQLreference/ProgrammingSQL/Variables    Documentation/SQLReference/DataTypes/TemporalTypes

CREATE ROLE

   CREATE ROLE role_name
    [ WITH ADMIN grantor ]

Define a new role. You can use the role to grant privileges and next grant a role (or multiple roles) to specific users. This eases the maintenance of specifying privileges to new users or changing privileges for a set of users which have the same role.

Example:

CREATE ROLE controller;


For details see: Documentation/SQLReference/DataDefinition/Privileges/Roles
and: Documentation/SQLReference/DataDefinition/Privileges
See also: DROP ROLE   GRANT PRIVILEGES   GRANT ROLE   SET ROLE

Associated system table: sys.roles and sys.auths

CREATE USER

   CREATE USER user_login_name
    WITH [ ENCRYPTED | UNENCRYPTED ] PASSWORD pass_phrase
    NAME full_name
    SCHEMA schema_name

Define a new database user account. Only monetdb administrator may create new database users.

Example:

CREATE USER "Donald" WITH UNENCRYPTED PASSWORD 'Secret' NAME 'Donald Duck' SCHEMA "app1";


For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
and: Documentation/SQLReference/DataDefinition/Privileges
See also: ALTER USER RENAME   ALTER USER SET PASSWORD   GRANT PRIVILEGES   DROP USER

Associated system table: sys.users and sys.auths where name in (select name from sys.users)

ALTER USER RENAME

   ALTER USER user_login_name
    RENAME TO new_user_login_name

Change the user id name of a database user account

For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
See also: ALTER USER SET PASSWORD   ALTER USER SET SCHEMA   GRANT PRIVILEGES

Associated system table: sys.users

ALTER USER SET PASSWORD

   ALTER USER SET [ ENCRYPTED | UNENCRYPTED ] PASSWORD new_pass_phrase
    USING OLD PASSWORD old_pass_phrase

Change the password of the current user account

Example to change the default password of system user monetdb (when connected as monetdb):

SELECT CURRENT_USER;
ALTER USER SET PASSWORD 'make it private' USING OLD PASSWORD 'monetdb';


For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
See also: ALTER USER SET SCHEMA   ALTER USER RENAME   GRANT PRIVILEGES

Associated system table: sys.users

ALTER USER SET SCHEMA

   ALTER USER user_login_name
    [ WITH [ ENCRYPTED | UNENCRYPTED ] PASSWORD pass_phrase ]
    SET SCHEMA schema_name

Change the default schema of a database user account

For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
See also: ALTER USER SET PASSWORD   ALTER USER RENAME   GRANT PRIVILEGES

Associated system table: sys.users and sys.auths

DROP ROLE

   DROP ROLE role_name
    [ WITH ADMIN grantor ]

Remove an existing role

Example:

DROP ROLE controller;


Note: Associated role privileges and granted user_role records will also be removed from sys.privileges and sys.user_role

For details see: Documentation/SQLReference/DataDefinition/Privileges/Roles
and: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE ROLE   GRANT ROLE   SET ROLE

Associated system table: sys.roles and sys.user_role

DROP USER

   DROP USER user_login_name

Remove an existing database login account

Note: Associated user privileges and granted user_role records will also be removed from sys.privileges and sys.user_role

For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
and: Documentation/SQLReference/DataDefinition/DropStatement
See also: CREATE USER   ALTER USER RENAME

Associated system table: sys.users and sys.auths where name in (select name from sys.users)

GRANT PRIVILEGES

   GRANT { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | ALL [ PRIVILEGES ] | EXECUTE | COPY INTO | COPY FROM }
    [, ... ]
    ON [ TABLE | FUNCTION | PROCEDURE | AGGREGATE | WINDOW ] object_name
    TO { user_login_name | role_name | PUBLIC } [, ... ]
    [ WITH GRANT OPTION ]

Add privileges on a table or function (incl. procedure, filter function, loader) or aggregate function for a user or role or all users (PUBLIC).
For tables the privileges can be: SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, ALL, COPY INTO, COPY FROM. ALL implies privileges: SELECT, INSERT, UPDATE, DELETE, TRUNCATE and REFERENCES. Note: privilege REFERENCES is currently implemented as a synonym for SELECT.
For aggregates, functions and procedures the privilege can be: EXECUTE or ALL.
The privileges COPY INTO, COPY FROM enable execution of those COPY INTO, COPY FROM commands to users other than the monetdb system user.

Example:

GRANT ALL ON TABLE web_event TO PUBLIC;
GRANT SELECT, INSERT ON TABLE "web_log" TO jan, piet, controller WITH GRANT OPTION;
GRANT EXECUTE ON FUNCTION refresh_func TO PUBLIC;
GRANT COPY INTO, COPY FROM ON TABLE new_facts TO mrdata;


Note: The current user must have permission to GRANT privileges.
The COPY INTO and COPY FROM privileges are MonetDB specific SQL. They are introduced in release Jun2016 (11.23.3).

For details see: Documentation/SQLReference/DataDefinition/Privileges
See also: REVOKE PRIVILEGES   GRANT ROLE   CREATE USER

Associated system table: sys.privileges

REVOKE PRIVILEGES

   REVOKE [ GRANT OPTION FOR ]
    { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | ALL [ PRIVILEGES ] | EXECUTE | COPY INTO | COPY FROM }
    [, ... ]
    ON [ TABLE | FUNCTION | AGGREGATE | WINDOW ] object_name
    FROM { user_login_name | role_name | PUBLIC } [, ... ]

Remove privileges on a table or function (incl. procedure, filter function, loader) or aggregate function from a user or role or PUBLIC

Example:

REVOKE INSERT, DELETE, TRUNCATE ON TABLE web_event FROM jan;
REVOKE EXECUTE ON FUNCTION refresh_func FROM piet;


Note: The current user must have permission to GRANT privileges.
The COPY INTO and COPY FROM privileges are MonetDB specific SQL. They are introduced in release Jun2016 (11.23.3).

For details see: Documentation/SQLReference/DataDefinition/Privileges
See also: GRANT PRIVILEGES   REVOKE ROLE   DROP USER

Associated system table: sys.privileges

GRANT ROLE

   GRANT role_name [, ... ] TO user_login_name [, ... ]
    [ WITH ADMIN OPTION ]
    [ WITH ADMIN grantor ]

Add one or more role privileges to one or more users

Example:

GRANT controller TO jan WITH ADMIN OPTION;


For details see: Documentation/SQLReference/DataDefinition/Privileges
and: Documentation/SQLReference/DataDefinition/Privileges/Roles
See also: REVOKE ROLE   GRANT PRIVILEGES   CREATE ROLE

Associated system table: sys.user_role

REVOKE ROLE

   REVOKE [ ADMIN OPTION FOR ] role_name [, ... ] FROM user_login_name [, ... ]

Remove one or more role privileges from one or more users

Example:

REVOKE controller FROM jan;


For details see: Documentation/SQLReference/DataDefinition/Privileges
and: Documentation/SQLReference/DataDefinition/Privileges/Roles
See also: GRANT ROLE   DROP ROLE

Associated system table: sys.user_role

SET SCHEMA

   SET SCHEMA schema_name

Change the current schema

Example:

SELECT CURRENT_SCHEMA;
SET SCHEMA profiler;
SELECT CURRENT_SCHEMA;


For details see: Documentation/SQLReference/DataDefinition/SchemaDefinitions
and: Documentation/SQLreference/ProgrammingSQL/Variables
See also: CURRENT_SCHEMA

Associated system table: sys.var_values

SET ROLE

   SET ROLE role_name

Change the current role

Example:

SELECT CURRENT_ROLE;
SET ROLE controller;
SELECT CURRENT_ROLE;


For details see: Documentation/SQLReference/DataDefinition/Privileges/Roles
and: Documentation/SQLreference/ProgrammingSQL/Variables
See also: CURRENT_ROLE   GRANT ROLE

Associated system table: sys.var_values

SET USER

   SET USER = user_login_name

Change the current user to the specified user

Example:

SELECT USER;
SET USER = jan;
SELECT USER;


Note: USER is a synonym for CURRENT_USER

For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
and: Documentation/SQLreference/ProgrammingSQL/Variables
See also: USER   GRANT PRIVILEGES

Associated system table: sys.var_values

SET CURRENT_USER

   SET CURRENT_USER = user_login_name

Change the current user to the specified user

Example:

SELECT CURRENT_USER;
SET CURRENT_USER = piet;
SELECT CURRENT_USER;


For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
and: Documentation/SQLreference/ProgrammingSQL/Variables
See also: CURRENT_USER

Associated system table: sys.var_values

SET SESSION_USER

   SET SESSION_USER = user_login_name

Change the session user to the specified user

Example:

SET SESSION_USER = isabel;
SELECT SESSION_USER;


For details see: Documentation/SQLReference/DataDefinition/Privileges/Users
and: Documentation/SQLreference/ProgrammingSQL/Variables
See also: SESSION_USER

Associated system table: sys.var_values

SET SESSION AUTHORIZATION

   SET SESSION AUTHORIZATION role_name

Change the session authorization to the specified role

For details see: Documentation/SQLReference/DataDefinition/Privileges/Roles
and: Documentation/SQLreference/ProgrammingSQL/Variables

COPY INTO FROM

   COPY [ int_val [ OFFSET int_val ] RECORDS ]
    INTO [ schema_name . ] table_name
         [ '(' column_name [ ',' column_name [ ... ] ] ')' ]
    FROM file_name [ ',' file_name [ ... ] ]
     [ '(' ident [ STRING ] [ ',' ident [ STRING ] [ ... ] ] ')' ]
     [ ON { CLIENT | SERVER } ]
     [ [ USING ] DELIMITERS  field_separator
       [ ',' record_separator [ ',' string_quote ] ] ]
     [ NULL [ AS ] null_string ]
     [ LOCKED ]
     [ BEST EFFORT ]
     [ NO CONSTRAINT ]
     [ FWF '(' pos [ ',' pos [ ... ] ] ')' ]

Read data (in UTF-8 encoding) from an external (compressed) csv/tsv/txt file and bulk insert it into an existing table

Note: This command is MonetDB specific.
By default the file(s) must be accessible from the server where mserver5 process is running. From release Apr2019 (11.33.3) onwards it is possible to read the file(s) from the mclient program by specifying ON CLIENT. Default behavior is ON SERVER. The ON CLIENT option is *not* supported in other programs or APIs (ODBC, JDBC, python DBI, etc.).
It can also read directly from a compressed file if the file name has extension: .bz2 or .gz or .xz or .lz4. On Windows OS extensions .xz and .lz4 are not yet supported. Extension .zip is not recognised, use extension .gz instead.
The default field_separator is the pipe '|' character. To change to tab character specify: '\t'.
The default record_separator is the newline '\n' character.
The default string_quote character is a double quote: ".
IMPORTANT: All character string data in the csv/tsv/txt file must be stored in UTF-8 character encoding. Other character encodings are not supported.

For details see: Documentation/ServerAdministration/LoadingBulkData/CSVBulkLoads
and: Documentation/ServerAdministration/LoadingBulkData

Associated system table: sys.querylog_history

COPY INTO FROM STDIN

   COPY [ int_val [ OFFSET int_val ] RECORDS ]
    INTO [ schema_name . ] table_name
         [ '(' column_name [ ',' column_name [ ... ] ] ')' ]
    FROM STDIN
     [ '(' ident [ STRING ] [ ',' ident [ STRING ] [ ... ] ] ')' ]
     [ [ USING ] DELIMITERS  field_separator
       [ ',' record_separator [ ',' string_quote ] ] ]
     [ NULL [ AS ] null_string ]
     [ LOCKED ]
     [ BEST EFFORT ]
     [ NO CONSTRAINT ]

Read data (in UTF-8 encoding) from console (stdin) and bulk insert it into an existing table

Note: This command is MonetDB specific.
The default field_separator is the pipe '|' character. To change to tab character specify: '\t'.
The default record_separator is the newline '\n' character.
The default string_quote character is a double quote: ".

For details see: Documentation/ServerAdministration/LoadingBulkData/CSVBulkLoads
and: Documentation/ServerAdministration/LoadingBulkData
and: SQLcopyinto.java example program

Associated system table: sys.querylog_history

COPY BINARY INTO FROM

   COPY BINARY
    INTO [ schema_name . ] table_name
         [ '(' column_name [ ',' column_name [ ... ] ] ')' ]
    FROM file_name [ ',' file_name [ ... ] ]
     [ ON { CLIENT | SERVER } ]
     [ NO CONSTRAINT ]

Attach column data from an external binary file(s) to very quickly make it available to MonetDB as storage column(s)

Note: This command is MonetDB specific.
By default the files must be accessible from the server where mserver5 process is running. From release Apr2019 (11.33.3) onwards it is possible to read the file from the mclient program by specifying ON CLIENT. Default behavior is ON SERVER. The ON CLIENT option is *not* supported in other programs or APIs (ODBC, JDBC, python DBI, etc.).
IMPORTANT: not all datatypes are supported. Especially all variable length data types such as varchar are *not* supported. Also a NULL value must be represented as a special value, which is different per datatype.

For details see: Documentation/ServerAdministration/LoadingBulkData/BinaryBulkLoad

Associated system table: sys.querylog_history

COPY LOADER INTO FROM

   COPY LOADER INTO [ schema_name . ] table_name
    FROM function_name ( [ arg1_val [ , arg2_val ] [, ... ] ] )

Read data via a loader function and bulk insert it into an existing table

Example:

COPY LOADER INTO tbl FROM web_log_loader();


Note: This command is MonetDB specific. It is introduced in release Dec2016 (11.25.3).
For a loader function defined in language PYTHON the Python script interpreter software must be available on the deployment server.

For details see: blog/monetdbpython-loader-functions
See also: CREATE LOADER   CREATE TABLE FROM LOADER

Associated system table: sys.querylog_history
 

COPY INTO

   COPY SELECT_query
    INTO file_name
    [ ON { CLIENT | SERVER } ]
    [ [ USING ] DELIMITERS field_separator
      [ ',' record_separator [ ',' string_quote ] ] ]
    [ NULL AS null_string ]

Write query result data in bulk to a (compressed) file on disk in UTF-8 encoding

Note: This command is MonetDB specific.
By default the file path must be accessible from the server where mserver5 process is running. From release Apr2019 (11.33.3) onwards it is now possible to write the file locally by the mclient program by specifying ON CLIENT. Default behavior is ON SERVER. The ON CLIENT option is *not* supported in other programs or APIs (ODBC, JDBC, python DBI, etc.).
The default field_separator is the pipe '|' character. To change to tab character specify: '\t'.
The default record_separator is the newline '\n' character.
The default string_quote character is a double quote: ".
Character data will be exported in UTF-8 encoding. Other encodings are not supported.
The file can also be written directly as compressed file if the file name has extension: .bz2 or .gz or .xz or .lz4. On Windows OS extensions .xz and .lz4 are not yet supported. Extension .zip is not recognised, use extension .gz instead.

For details see: Documentation/ServerAdministration/ExportingBulkData
and: Documentation/SQLReference/DataManipulation/BulkInputOutput

Associated system table: sys.querylog_history

COPY INTO STDOUT

   COPY SELECT_query
    INTO STDOUT
    [ [ USING ] DELIMITERS field_separator
      [ ',' record_separator [ ',' string_quote ] ] ]
    [ NULL AS null_string ]

Write query result data to console (stdout) in UTF-8 encoding

Note: This command is MonetDB specific.
The default field_separator is the pipe '|' character. To change to tab character specify: '\t'.
The default record_separator is the newline '\n' character.
The default string_quote character is a double quote: ".

For details see: Documentation/ServerAdministration/ExportingBulkData
and: Documentation/SQLReference/DataManipulation/BulkInputOutput

Associated system table: sys.querylog_history

SET TRANSACTION

   SET TRANSACTION
    [ READ ONLY | READ WRITE | ISOLATION LEVEL { READ UNCOMMITTED | READ COMMITTED | REPEATABLE READ | SERIALIZABLE } | DIAGNOSTICS sqlSize ]

Start a transaction (turn auto-commit off) with optionally a transaction mode or isolation level

Example:

SET TRANSACTION;
ROLLBACK;
SET TRANSACTION READ ONLY;
ROLLBACK;
SET TRANSACTION READ WRITE;
ROLLBACK;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
ROLLBACK;
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
ROLLBACK;
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
ROLLBACK;
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
ROLLBACK;


 

SET LOCAL TRANSACTION

   SET LOCAL TRANSACTION
    [ READ ONLY | READ WRITE | ISOLATION LEVEL { READ UNCOMMITTED | READ COMMITTED | REPEATABLE READ | SERIALIZABLE } | DIAGNOSTICS sqlSize ]

Start a local transaction (turn auto-commit off) with optionally a transaction mode or isolation level

 

START TRANSACTION

   { START | BEGIN } TRANSACTION
    [ READ ONLY | READ WRITE | ISOLATION LEVEL { READ UNCOMMITTED | READ COMMITTED | REPEATABLE READ | SERIALIZABLE } | DIAGNOSTICS sqlSize ]

Disable auto-commit and start a user controlled transaction

Note: A transaction can also include data definition (DDL) commands such as CREATE, ALTER, DROP.

For details see: Documentation/SQLreference/Transactions
and: blog/monetdb-sql-transaction-management-scheme
See also: COMMIT   ROLLBACK

COMMIT

   COMMIT [ WORK ]
      [ AND [ NO ] CHAIN ]

Make all changes done since the start of the transaction persistent

For details see: Documentation/SQLreference/Transactions
and: blog/monetdb-sql-transaction-management-scheme
See also: ROLLBACK   START TRANSACTION

ROLLBACK

   ROLLBACK [ WORK ]
      [ AND [ NO ] CHAIN ]

Undo all changes done since the start of the transaction

For details see: Documentation/SQLreference/Transactions
and: blog/monetdb-sql-transaction-management-scheme
See also: COMMIT   START TRANSACTION

SAVEPOINT

   SAVEPOINT savepoint_id_name

Add a savepoint within a transaction

Example:

START TRANSACTION;
SAVEPOINT sp1;


Note: You need to start a transaction first before you can use savepoints

See also: START TRANSACTION   RELEASE SAVEPOINT   ROLLBACK TO SAVEPOINT
 

ROLLBACK TO SAVEPOINT

   ROLLBACK [ WORK ]
      [ AND [ NO ] CHAIN ]
      TO SAVEPOINT savepoint_id_name

Undo all changes done since the start of the savepoint

Example:

ROLLBACK TO SAVEPOINT sp1;


See also: SAVEPOINT   RELEASE SAVEPOINT
 

RELEASE SAVEPOINT

   RELEASE SAVEPOINT savepoint_id_name

Add all changes done since the start of the savepoint to the current transaction

Example:

RELEASE SAVEPOINT sp1;


See also: SAVEPOINT   ROLLBACK TO SAVEPOINT
 

SET OPTIMIZER

   SET optimizer = optimizer_pipeline_name

Change the execution optimizer pipeline

Example:

SELECT optimizer;
SELECT * FROM sys.optimizers;
SET optimizer = 'sequential_pipe';
SELECT optimizer;
SET optimizer = 'default_pipe';
SELECT optimizer;
SET optimizer = 'ceci_nest_pas_une_pipe';
SELECT optimizer;


For details see: Documentation/SQLReference/PerformanceOptimization/OptimizerPipelines
and: Documentation/MonetDBInternals/MALOptimizers
See also: PLAN   EXPLAIN

Associated system table: sys.optimizers and sys.environment where name = 'sql_optimizer';

EXPLAIN

   EXPLAIN The SQL command

Show the MAL execution plan for the SQL command.

For details see: Documentation/SQLreference/RuntimeFeatures/Explain    Documentation/MonetDBInternals/MALReference
and: Documentation/SQLReference/PerformanceOptimization/OptimizerPipelines
See also: PLAN

PLAN

   PLAN The SQL command

Show the relational execution plan for the SQL command after it has been optimized by the SQL optimzer.

Note: This command is MonetDB specific.

For details see: Documentation/SQLreference/RuntimeFeatures/PlanSQL
and: Documentation/SQLReference/PerformanceOptimization/OptimizerPipelines
See also: EXPLAIN

TRACE

   TRACE The SQL command

Executes the SQL command and return a table with the execution ticks of the MAL instructions.

For details see: Documentation/SQLreference/RuntimeFeatures/Trace

Associated system table: sys.tracelog()

DEBUG

   DEBUG The SQL command

Executes the SQL command in DEBUG mode

For details see: Documentation/SQLreference/RuntimeFeatures/Debug

ANALYZE

   ANALYZE schema_name [ . table_name [ ( column_name [, column_name] [, ... ] ) ] ]
    [ SAMPLE size ]
    [ MINMAX ]

Gather statistics on column(s) of table(s) in a specific schema and store or update them in the system table sys.statistics for analysis

Example:

-- derive the statistics for table sys.statistics
ANALYZE sys.statistics;
SELECT * FROM sys.statistics;

-- update statistics of specific columns of sys.statistics
ANALYZE sys.statistics ("sample", count, "unique", minval, maxval) SAMPLE 1000;

SELECT * FROM sys.statistics
 WHERE column_id IN (SELECT id FROM sys.columns
 WHERE table_id  IN (SELECT id FROM sys.tables
 WHERE schema_id IN (SELECT id FROM sys.schemas
 WHERE name = 'sys') AND name = 'statistics'));

-- remove all the statistics
DELETE FROM sys.statistics;


Note: The statistics information can be used by the query optimizer to choose the optimal execution plan. Rerun the ANALYZE command after many table manipulations (insert/update/delete).
For large tables this command can take some time. Specify a SAMPLE size to reduce the amount of data values to analyze. Add MINMAX to exclude the expensive unique count operation.

For details see: Documentation/ServerAdministration/TableStatistics

Associated system table: sys.statistics

USER

   USER

Example:

SELECT USER;


Note: USER is a synonym for CURRENT_USER

See also: SET USER

Associated system table: sys.var_values
 

CURRENT_USER

   CURRENT_USER

Example:

SELECT CURRENT_USER;


See also: SET CURRENT_USER

Associated system table: sys.var_values
 

SESSION USER

   SESSION_USER

Example:

SELECT SESSION_USER;


See also: SET SESSION_USER

Associated system table: sys.var_values
 

CURRENT_ROLE

   CURRENT_ROLE

Example:

SELECT CURRENT_ROLE;


See also: SET ROLE

Associated system table: sys.var_values
 

CURRENT_SCHEMA

   CURRENT_SCHEMA

Example:

SELECT CURRENT_SCHEMA;


See also: SET SCHEMA

Associated system table: sys.var_values
 

CURRENT_TIMEZONE

   CURRENT_TIMEZONE

Example:

SELECT CURRENT_TIMEZONE;


For details see: Documentation/ServerAdministration/DateTimeFunctionality
See also: SET CURRENT_TIMEZONE

Associated system table: sys.var_values

NOW

   NOW

Example:

SELECT NOW;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

CURRENT_DATE

   CURRENT_DATE

Example:

SELECT CURRENT_DATE;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

CURRENT_TIME

   CURRENT_TIME

Example:

SELECT CURRENT_TIME;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

CURRENT_TIMESTAMP

   CURRENT_TIMESTAMP

Example:

SELECT CURRENT_TIMESTAMP;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

LOCALTIME

   LOCALTIME

Example:

SELECT LOCALTIME;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

LOCALTIMESTAMP

   LOCALTIMESTAMP

Example:

SELECT LOCALTIMESTAMP;


For details see: Documentation/ServerAdministration/DateTimeFunctionality

NEXT VALUE FOR

   NEXT VALUE FOR sequence_name

Example:

CREATE SEQUENCE "my_test_seq" as integer START WITH 2;
CREATE TABLE test (t int DEFAULT NEXT VALUE FOR "my_test_seq", v varchar);
INSERT INTO test(v) VALUES ('ab');
SELECT * FROM test;


For details see: Documentation/SQLReference/DataTypes/SerialDatatypes

Lexical structure

Lexical structure mk Sat, 03/27/2010 - 22:27

Comments

Comments can be added to query scripts for documentation purposes. MonetDB/SQL supports two forms of comments. Any text beginning with '- -' and up to the end of line is ignored. Furthermore, C-style comments ( /* this is ignored */ ) can be injected in a SQL query where a language token is expected. A language token can be a keyword, identifier, a literal constant or a special character. Tokens should be  separated by 'white space' (tab, space, newlines) unless there juxtaposition does not create an ambiguous interpretation. Comments are considered equivalent to white spaces.

Identifiers and Keywords

SQL comes with a large collection of keywords, i.e. names reserved by the committee to designate language constructs. Keywords in MonetDB/SQL are case in-sensitive and adhere to the general convention for identifier denotation in programming languages.

Users can overrule the interpretation of an identifier as a keyword by encapsulation with double quotes, e.g. select denotes a keyword, while "select" denotes a user defined name. This scheme also permits inclusion of case sensitive names and names with special characters or white space in the names. This may be useful for reporting purposes where you want user friendly column header information. However, it is general advisable to limit the number of the escaped keywords.

Names are used to designate database objects. In that role, they are by default case in-sensitive unless encapsulated by double quotes. The terminal identifier classes distinguished are denoted with the suffix _name.

Literal Constants

Numeric constants follow the convention of most programming languages. A numeric constant that contains neither a decimal point or exponential is considered of type integer. The underlying machine determines whether it will be interpreted as a 32- or 64-bit value, although most likely it will be that latter case these days.

String constants in SQL are embraced with single quotes like: 'string data'. If your data contains single quote's, each single quote need to be doubled, so 'a single '' quote in a string' represents string: a single ' quote in a string.

We support Unicode character string literals (from Apr2019 release 11.33.3) using: U&'...' including UESCAPE. For the string literals, you can have U&'...' '...' '...' UESCAPE '...' where the escape must be as single character and the other '...' strings are also Unicode character string literals. For now, these latter strings also undergo C-style backslash interpretation.

We support PostgreSQL-like E'...' strings (from Apr2019 release 11.33.3). The strings can contain C-style backslash escapes.

We support raw strings (from Jun2020 release 11.37.7) by using R'...' or r'...'. This means that C-style backslash escapes will remain uninterpreted within those strings. For instance SELECT r'\t'; returns a char string of length 2 where SELECT e'\t'; returns a char string of length 1.

Binary data can be represented in hexadecimal string notation using 2 hexadecimal characters per byte, for example x'10FF' to represent 2 byte values: 16 and 255. This notation can be used with the blob (binary large object) data type, see also BinaryStringFunctions

Often strings can be cast to other types using the CAST( expr AS type ) expression, provided the typed coercion routine is available. For example:

SELECT CAST( '129' AS integer );
SELECT CAST( '129.42' AS decimal );

SELECT CAST( '0.3' AS double );

illustrates conversion of a digits string value into an integer, a decimal and a double precision floating point number.

Temporal Constants

The DATE, TIME and TIMESTAMP data types come with a straightforward string literal conversion structure, e.g.:

SELECT DATE '2014-02-03', TIME '15:45:56', TIMESTAMP '2014-02-03 15:45:56';

produces a single properly typed row result. It is equivalent to:

SELECT CAST('2014-02-03' AS DATE), CAST ('15:45:56' AS TIME), CAST ('2014-02-03 15:45:56' AS TIMESTAMP);

Special Characters

String literals (currently both the '...' and E'...' styles) may contain the C-style escape characters: '\n' for new lines, '\t' for tab, '\r' for return, and '\\' for backslash. The conventions '\ddd` where d a digit stands for a number denoted in octal.

Operator Precedences

Most operators in SQL have the same precedence and are left-associative. Parenthesis can be used to disambiguate the precedence order. The operator definitions can not be overloaded, nor can you define new operators.

. left table/column name separator
- right unary minus
* / % left multiplication, division, modulo
+ - left unary addition, subtraction
IS, IS TRUE, IS FALSE, IS UNKNOWN    
IS NULL, IS NOT NULL   test for (not) null
IN   set membership
BETWEEN   range containment
OVERLAPS   time interval overlap
LIKE, ILIKE   string pattern matching
< >   less than, greater than
= right equality, assignment
NOT right logical negation
AND left logical conjunction
OR left logical disjunction
^ left logical exclusive disjunction

Value Expressions

The language is built around value- and table- expressions. Value expressions encompass denotation of literal constants, type casts, column references, operator and function invocation, and scalar returning subqueries.

The column references take the form [correlation_name '.'] column_name. The correlation_name is either a table name or an alias introduced in a from clause. The correlation name may be omitted if the column name uniquely identifies a column within the scope of current query.

The table references take the form [schema_name '.'] table_or_view_name [AS alias_name]. Table expressions produce a relational table. It is internally referenced through a correlation name, which supports attribute selection using the '.' denotation.

Data types

Data types mk Sat, 03/27/2010 - 22:30

SQL prescribes a large collection of built-in types, most of which are directly supported. The MonetDB database kernel can also be extended with user defined types to better support application domains.

Some domain specific data types (e.g. GeoSpatial) are not part of the MonetDB core, but are provided by extensions. For more information check the Spatial data types article.

Base types

Base types mk Thu, 04/01/2010 - 22:20
CHAR | CHARACTER |
CHAR '(' length ')'   |
CHARACTER '(' length ')'
UTF-8 character string with optional length upperbound limit.
CHAR or CHARACTER without the "( length )" specification are treated as CHAR(1).
Note: currently no spaces are padded at the end
VARCHAR '(' length ')'   |
CHARACTER VARYING '(' length ')'
UTF-8 character string with length upperbound limit
CLOB '(' length ')'   |
TEXT '(' length ')'   |
STRING '(' length ')'   |
CHARACTER LARGE OBJECT '(' length ')'
UTF-8 character string with length upperbound limit
CLOB | TEXT | STRING | CHARACTER LARGE OBJECT UTF-8 character string with unbounded length
   
BLOB | BINARY LARGE OBJECT bytes string with unbounded length
BLOB '(' length ')'   |
BINARY LARGE OBJECT '(' length ')'
bytes string with length upperbound limit
   
BOOLEAN | BOOL logic values: true or false
   
TINYINT 8 bit signed integer between -127 and 127
SMALLINT 16 bit signed integer between -32767 and 32767
INT | INTEGER | MEDIUMINT 32 bit signed integer between -2147483647 and 2147483647
BIGINT 64 bit signed integer between -9223372036854775807 and 9223372036854775807
HUGEINT 128 bit signed integer between -2127 +1 and +2127 -1 (±170141183460469231731687303715884105727)
Note: HUGEINT is only available on platforms with a C-compiler that supports the __int128 or __int128_t data type (e.g., recent gcc, clang, & icc on Linux or MacOS X) and from Jul2015 release onwards
   
DECIMAL '(' Prec ',' Scale ')' |
DEC '(' Prec ',' Scale ')' |
NUMERIC '(' Prec ',' Scale ')'
Exact decimal number with precision Prec and scale Scale. Prec must be between 1 and 18 (or 38 when HUGEINT is also supported). Scale must be between 0 and Prec
DECIMAL '(' Prec ')' |
DEC '(' Prec ')' |
NUMERIC '(' Prec ')'
Exact decimal number with precision Prec and scale 0. Prec must be between 1 and 18 (or 38 when HUGEINT is also supported).
DECIMAL | DEC | NUMERIC Exact decimal number with precision 18 and scale 3.
   
REAL 32 bit floating point approximate number
DOUBLE | DOUBLE PRECISION |
FLOAT
64 bit floating point approximate number
FLOAT '(' Prec ')' floating point approximate number with binary precision Prec. Prec must be between 1 and 53. FLOAT(24) is same as REAL, FLOAT(53) is same as DOUBLE

 

All scalar types include a NULL value, which is internally represented as a valid domain value. For numerical types, this is the smallest value in the type's domain (i.e., the one omitted in the ranges given above). Arithmetic expressions that overflow may lead to returning the NULL instead.

The integer types align with the storage of 1, 2, 4, 8 and 16 bytes.

The numeric and decimal types are represented as fixed length integers, whose decimal point is produced during result rendering.

The types REAL, FLOAT and DOUBLE map to the underlying implementation system. No special attention is given to the value NaN.

Temporal types

Temporal types mk Thu, 06/30/2011 - 09:46

MonetDB/SQL supports a rich set of time-related operations within the kernel. The starting point are SQL 92 and the ODBC time-related data types.  There are six basic types and operations on them:

DATE a date in the Gregorian calendar YYYY-MM-DD, e.g. 1999-12-31
TIME  [ '(' posint ')' ] time of day (HH.MI.SS.sss) with precision (default 0)
TIME  [ '(' posint ')' ] WITH TIME ZONE time of day (HH.MI.SS.sss) with precision (default 0) and time zone information
TIMESTAMP [ '(' posint ')' ] date concatenated with unique time, precision
TIMESTAMP [ '(' posint ')' ] WITH TIME ZONE date concatenated with unique time, precision and time zone information
INTERVAL interval_qualifier a temporal interval such as: INTERVAL SECOND or INTERVAL MONTH

interval_qualifier :
    { YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [time_precision] }
   |  start_field  TO  end_field

start_field :
   
{ YEAR | MONTH | DAY | HOUR | MINUTE }

end_field:
   
{ YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [time_precision] }

time_precision :
     '(' posint ')'

A timestamp is a combination of date and time, indicating an exact point in time (GMT). GMT is the time at the Greenwich meridian without a daylight savings time (DST) regime. Absence of DST means that hours are consecutive (no jumps) which makes it easy to perform time difference calculations.

The local time is often different from GMT (even at Greenwich in summer, as the UK also has DST). Therefore, whenever a timestamp is composed from a local date and time a timezone should be specified in order to translate the local time to GMT (and vice versa if a timestamp is to be decomposed in a local date and time). To adjust the local time can issue a command such as SET TIME ZONE INTERVAL '1' HOUR TO MINUTE.

We provide predefined timezone objects for a number of timezones (see below). Also, there is one timezone called the local timezone, which can be set to one global value in a running MonetDB server, that is used if the timezone parameter is omitted from a command that needs it (if not set, the default value of the local timezone is plain GMT).

The value ranges and lexical denotations are defined as follows:

Min and max years. The maximum and minimum dates and timestamps that can be stored are in the years 5,867,411 and -5,867,411, respectively. Interestingly, the year 0 is not a valid year. The year before 1 is called -1.

Dates. Fall in a valid year, and have a month and day that is valid in that year. The first day in the year is January 1, the last December 31. Months with 31 days are January, March, May, July, August, October, and December, while April, June, September and November have 30 days. February has 28 days, expect in a leap year, when it has 29. A leap year is a year that is an exact multiple of 4. Years that are a multiple of 100 but not of 400 are an exception; they are no leap years.

Time. The smallest time is 00:00:00.000 and the largest 23:59:59.999 (the hours in a time range between [0,23], minutes and seconds between [0,59] and milliseconds between [0:999] ). Time identifies a valid time-of-day, not an amount of time (for denoting amounts of time, or time differences, we use here concepts like "number of days" or "number of seconds" denoted by some value of a standard integer type).

Timestamp. A valid timestamp is formed by a combination of a valid date and valid daytime. When creating a timestamp from a date and daytime, a timezone should be specified (if timezone is omitted, the local timezone is assumed). If a timezone is specified, it is used to convert the date and time in that timezone to GMT, which is the internal timestamp representation. One problem here is that the first hour after DST has ended (some Sunday night in autumn, generally), the time is set back one hour, so the same times occur twice. Hence two translations to a timestamp are possible for such date and time combinations. In those case, we act as if it was the first occurrence (still within DST).

For difference calculations between dates (in numbers of days) we use signed integer. Hence, the valid range for difference calculations is between -2147483647 and 2147483647 days (which corresponds to roughly -5,867,411 and 5,867,411 years).

For difference between timestamps (in numbers of milliseconds) we use 64-bit bigint. These are large integers of maximally 19 digits, which therefore impose a limit of about 106,000,000,000 years on the maximum time difference used in computations.

datetime_func:
     EXTRACT '(' datetime_field FROM scalar_exp ')'
   | CURRENT_DATE [ '(' ')' ]
   | CURRENT_TIME [ '(' ')' ]
   | CURRENT_TIMESTAMP [ '(' ')' ]
   | LOCALTIME [ '(' ')' ]
   | LOCALTIMESTAMP [ '(' ')' ]

datetime_field:
     YEAR | MONTH | DAY | HOUR | MINUTE | SECOND | CENTURY | DECADE | QUARTER | WEEK | DOW | DOY

Gregorian dates.
The basics of the Gregorian calendar stem from the time of Julius Caesar, when the concept of a solar year as consisting of 365.25 days (365 days plus once in 4 years one extra day) was introduced. However, this Julian Calendar, made a year 11 minutes long, which subsequently accumulated over the ages, causing a shift in seasons. In medieval times this was noticed, and in 1582 Pope Gregory XIII issued a decree, skipped 11 days. This measure was not adopted in the whole of Europe immediately, however.  For this reason, there were many regions in Europe that upheld different dates.

It was only on September 14, 1752 that some consensus was reached and more countries joined the Gregorian Calendar, which also was last modified at that time. The modifications were twofold: first, 12 more days were skipped. Second, it was determined that the year starts on January 1 (in England, for instance, it had been starting on March 25). Other parts of the world have adopted the Gregorian Calendar even later.

MonetDB implements the Gregorian Calendar in all its regularity. This means that values before the year 1752 probably do not correspond with the dates that people really used in times before that (what they did use, however, was very vague anyway, as explained above). In solar terms, however, this calendar is reasonably accurate (see the "correction seconds" note below).

Timezones
The basic timezone regime was established on November 1, 1884 in the International Meridian Conference held in Greenwich (UK). Before that, a different time held in almost any city. The conference established 24 different time zones defined by regular longitude intervals that all differed by one hour.  Not for long it was that national and political interest started to erode this nicely regular system.  Timezones now often follow country borders, and some regions (like the Guinea areas in Latin America) have times that differ with a 15 minute grain from GMT rather than an hour or even half-an-hour grain.

An extra complication became the introduction of daylight saving time (DST), which causes a time jump in spring, when the clock is skips one hour and in autumn, when the
clock is set back one hour (so in a one hour span, the same times occur twice). The DST regime is a purely political decision made on a country-by-country basis. Countries in the same timezone can have different DST regimes. Even worse, some countries have DST in some years, and not in other years.

To avoid confusion, this temporal type module stores absolute points of time in GMT only (GMT does not have a DST regime). When storing local times in the database, or retrieving local times from absolute timestamps, a correct timezone object should be used for the conversion.

Applications that do not make correct use of timezones, will produce irregular results on e.g. time difference calculations.

Correction seconds
Once every such hundred years, a correction second is added on new year's night. This rule would seriously complicate the temporal type module (as then the duration of a day, which is now the fixed number of 24*60*60*1000 milliseconds, becomes parametrized by the date), it is not implemented. Hence these seconds are lost, so time difference calculations in milliseconds (rather than in days) have a small error if the time difference spans many hundreds of years.

We cannot handle well changes in the timezone rules (e.g., DST only exists since 40 years, and some countries make frequent changes to the DST policy). To accommodate this we should make timezone_local a function with a year parameter. The tool should maintain and access a timezone database. Lookup of the correct timezone would be dynamic in this structure. The timezone_setlocal would just set the string name of the timezone.

Serial datatypes

Serial datatypes mk Thu, 04/01/2010 - 22:21

As of 2003 the SQL standard supports serial types (sequences). They are of particular use in auto-generating key values.A serial type is defined as a primary database object over any of the built-in data types. The NEXT VALUE FOR operation generates the next value and can be used anywhere a value expression is allowed. Its name should be unique within the current schema. A sequence can only be dropped when the references (e.g. in the DEFAULT specification of a column) have previously been removed.

serial_data_types:
     SERIAL
   | BIGSERIAL
   | int_datatype AUTO_INCREMENT
   | int_datatype GENERATED ALWAYS AS IDENTITY [ '(' seq_params ')' ]

int_datatype:
    BIGINT | INTEGER | INT | SMALLINT | TINYINT

seq_params:
    [ AS int_datatype ]
    [ START WITH bigint ]
    [ INCREMENT BY bigint ]
    [ MINVALUE bigint | NO MINVALUE ]
    [ MAXVALUE bigint | NO MAXVALUE ]
    [ CACHE bigint ]
    [ [ NO ] CYCLE ]

sequence_commands:
     CREATE SEQUENCE [ schema_name '.'] seq_name [ seq_params ]
   | DROP SEQUENCE [ schema_name '.'] seq_name
   | ALTER SEQUENCE [ schema_name '.'] seq_name [ alter_seq_params ]

alter_seq_params:
    [ AS int_datatype ]
    [ RESTART [WITH bigint ] ]
    [ INCREMENT BY bigint ]
    [ MINVALUE bigint | NO MINVALUE ]
    [ MAXVALUE bigint | NO MAXVALUE ]
    [ CACHE bigint ]
    [ [ NO ] CYCLE ]

Example. The example shown below introduces the column count, which is incremented with each row being added. It is conceptually identical to the value expression max(count)+1in each insert. The column info is a limited range with wrap around.The serial type as found in PostgreSQL and the auto_increment  flag as found in MySQL are both mapped onto a sequence type in MonetDB/SQL.

CREATE TABLE test_serial (
   d DATE,
   id SERIAL,  -- this will implicitly create a PKey. Use BIGSERIAL if you want the id to be of type bigint instead of int.
   count INT AUTO_INCREMENT,
   info INT GENERATED ALWAYS AS

        IDENTITY (
           START WITH 100 INCREMENT BY 2
           NO MINVALUE MAXVALUE 1000
           CACHE 2 CYCLE
)      );

Much like other primary database objects, the sequence type can be altered at any time as illustrated below.

sql>CREATE SEQUENCE "my_test_seq" as integer START WITH 2;
sql>CREATE TABLE test (t int DEFAULT NEXT VALUE FOR "my_test_seq", v char);
sql>INSERT INTO test(v) VALUES ('a');
Rows affected 1
sql>INSERT INTO test VALUES (10, 'b');
Rows affected 1
sql>ALTER SEQUENCE "my_test_seq" RESTART WITH (SELECT MAX(t) + 1 FROM test);
sql>INSERT INTO test(v) VALUES ('c');
Rows affected 1
sql>SELECT * FROM test;
+----+---+
| t  | v |
+====+===+
| 2  | a |
| 10 | b |
| 11 | c |
+----+---+

The functions sys.get_value_for('<schema name>', '<sequence name>') and sys.next_value_for('<schema name>', '<sequence name>') can be used to query the current value of a sequence. The difference is that next_value_for() also advances the current value of a sequence to the next value.  The SQL statement SELECT NEXT VALUE FOR <schema name>.<sequence name> is an equivalent of sys.next_value_for('<schema name>', '<sequence name>'). The following queries demonstrate how these functions and statement work:

sql>CREATE SEQUENCE "myseq" AS INTEGER;
operation successful
sql>SELECT get_value_for('sys', 'myseq');
+------+
| L2   |
+======+
|    1 |
+------+
1 tuple
sql>SELECT next_value_for('sys', 'myseq');
+------+
| L2   |
+======+
|    1 |
+------+
1 tuple
sql>SELECT NEXT VALUE FOR myseq;
+------+
| L2   |
+======+
|    2 |
+------+
1 tuple
sql>SELECT get_value_for('sys', 'myseq');
+------+
| L2   |
+======+
|    2 |
+------+
1 tuple

JSON datatype

JSON datatype mk Thu, 01/23/2014 - 08:44

JSON has become the de facto light weight data interchange format for many web applications. It has a simple hierarchical structure and supports a limited set of value types. JSON is a natural representation of data for the C family of programming languages.

JSON is supported in MonetDB as a subtype over type VARCHAR, which ensures that only valid JSON strings are added to the database.

Example: CREATE TABLE json_example (c1 JSON, c2 JSON(512) NOT NULL);

MonetDB supports most of the JSON path expressions defined in [ref]. It can be used to decompose the values into regular tables, which then act as an index. A limited set of operators are predefined in the SQL catalogue.

json.filter(J, Pathexpr) Extracts the component from J that satisfied the Pathexpr
json.filter(J, Number) Extracts a indexed component from J
json.text(J, [Sep]) Glue together the values separated by Sep character (default space)
json.number(J) Turn a number, singleton array value, or singleton object tag into a double
json."integer"(J) Turn a number, singleton array value, or singleton object element into an integer
json.isvalid(StringExpr) Checks the string for JSON compliance. Returns boolean.
json.isobject(StringExpr) Checks the string for JSON object compliance. Returns boolean.
json.isarray(StringExpr) Checks the string for JSON array compliance. Returns boolean.
json.length(J) Returns the number of top-level components of J.
json.keyarray(J) Returns a list of key tags for the top-level components of J.
json.valuearray(J) Returns a list of values for the top-level components of J.

JSON path expressions always refer to a single JSON structure. The root of this structure is identified by the identifier '$', which is implicitly assumed in most expressions. Components of the JSON structure are addressed through the dot notation, i.e. representing child steps and array element access. The wild card can be used for child names and undetermined array indices.

JSON path Description Example
"$" The root object json.filter(v, '$') = { "store":...}"
"." childname The child step operator json.filter(v, '$.store.bicycle') = {"color": "red", "price": 19.95}
".." childname Recursive child step json.filter(v, '$..price') = [8.95,12.99,8.99,22.99,19.95]
"*" Child name wildcard json.filter(v, '$.store.bicycle.*') = {"color": "red", "price": 19.95}
"[" nr "]" Array element access json.filter(v, '$.store.book.[1]') = the second book
"[" * "]" Any array element access  
E1 "," E2 Union path expressions json.filter(v, '$.store.bicycle,$..price')

An example JSON object used for these expressions [ref], more examples in the testsuite.

{ "store": {
    "book": [
      { "category": "reference",
        "author": "Nigel Rees",
        "title": "Sayings of the Century",
        "price": 8.95
      },
      { "category": "fiction",
        "author": "Evelyn Waugh",
        "title": "Sword of Honour",
        "price": 12.99
      }
    ],
    "bicycle": {
      "color": "red",
      "price": 19.95
    }
  }
}

URL datatype

URL datatype mk Wed, 02/26/2014 - 15:14

The related URL data type is a subdomain over character strings and represent valid Uniform Resource Locators.

Usage example:

   CREATE TABLE URL_example (c1 URL, c2 URL(512) NOT NULL);

 

You can use cast() or convert() functions to convert a valid url string to a url type.

   select cast('https://www.monetdb.org/Doc/Example.html' as url);
   select convert('https://www.monetdb.org/Doc/Example.html', url);

You can also use the url prefix:

   select url 'https://www.monetdb.org/Doc/Example.html';

 

A collection of URL specific functions are provided to create, validate and extract portions.

 

UUID datatype

UUID datatype mk Sat, 01/14/2012 - 14:40

The data type UUID allowes storage of valid Universally Unique IDentifiers as defined by RFC 4122, ISO/IEC 9834-8:2005, and related standards. It can be used as a global unique 128-bit identifier.

UUIDs are generated by an algorithm that ensures an extreme low probability that two calls to the same create function will ever produce the same value. They are often used in distributed (web-based) systems for this reason.

A UUID is written as a sequence of lower-case hexadecimal digits, in several groups optionally separated by hyphens, specifically a group of 8 digits followed by three groups of 4 digits followed by a group of 12 digits, for a total of 32 digits representing the 128 bits. An example of a UUID in this standard form is:

select sys.uuid() as uuid;
+--------------------------------------+ 
| uuid                                 | 
+======================================+
| 65950c76-a2f6-4543-660a-b849cf5f2453 |
+--------------------------------------+

The system function sys.uuid() generates a new random uuid and returns the uuid value.

The system function sys.isauuid(string) checks whether the string value satisfies the grammatical UUID structure and returns a boolean value true or false, or null when the input is null. A valid string should be 36 or 32 characters long, consists of hexadecimals characters and when 36 characters long have hyphens at locations 9, 14, 19 and 24.

 

You can use cast() or convert() function or uuid prefix to a quoted string literal to convert a valid uuid string to a uuid type.

select cast( '26d7a80b-7538-4682-a49a-9d0f9676b765' as uuid) as uuid_val;
select convert('83886744-d558-4e41-a361-a40b2765455b', uuid) as uuid_val;
select     uuid'AC6E4E8C-81B5-41B5-82DE-9C837C23B40A' as uuid_val;

See also UUID functions.

 

Network Address Type

Network Address Type mk Sat, 01/14/2012 - 14:49

The SQL type inet describes IPv4 network addresses, such as 192.168.1.5/24.

Usage example:

   CREATE TABLE inet_example (address inet NOT NULL);

 

A valid IPv4 Network Address string has a specific syntax, see also IPv4 address.

You can use cast() and convert() functions to convert a valid inet string into an inet value.

   select cast('192.168.1.5/24' as inet);
   select convert('192.168.1.5/24', inet);

You can also use the inet casting prefix:

   select inet '192.168.1.5/24';

 

The inet module contains a collection of functions and operators that operate on IPv4 addresses. The most relevant functions are the 'containment' functions that deal with subnet masks. The functionality of this module is greatly inspired by the PostgreSQL inet data type.

In future it should be extended to also support IPv6.

 

User defined types

User defined types mk Thu, 04/01/2010 - 22:22

The MonetDB kernel supports creation of user defined types, e.g. geometric types. The relationship between SQL and MAL world is expressed using an external name.

CREATE TYPE [schema_name '.'] type_name EXTERNAL NAME type_identification

DROP TYPE [schema_name '.'] type_name [RESTRICT | CASCADE]

The implementation of new atomary types is best postponed until there is no other performance-wise acceptable solution. Addition of an atomary type in the kernel would be beneficial if it is also complemented with bulk-operations and when type specific optimizers could exploit their semantics.

Data definition

Data definition mk Thu, 06/30/2011 - 09:49

The MonetDB/SQL supports the full range of object definitions.

Table definitions

Table definitions mk Sat, 03/27/2010 - 22:34

The CREATE TABLE statement conforms to the full SQL standard. Tables are assigned to the current schema unless the schema name is explicitly given as part of the table name. Table names should be unique amongst those mentioned within the same schema and distinct from view names.

Besides the standard SQL CREATE TABLE, CREATE LOCAL TEMPORARY TABLE and CREATE GLOBAL TEMPORARY TABLE statements, MonetDB introduces new table types: MERGE TABLE, REPLICA TABLE, REMOTE TABLE and STREAM TABLE for specific usages.

table_def:
     CREATE TABLE [ IF NOT EXISTS ] table_name  table_content_source [ STORAGE ident string ]
   | CREATE TABLE [ IF NOT EXISTS ] table_name FROM LOADER function_ref
   | CREATE [ LOCAL | GLOBAL ] TEMPORARY TABLE [ IF NOT EXISTS ] table_name  table_content_source
                     [ ON COMMIT { DELETE ROWS  |  PRESERVE ROWS  |  DROP } ]
   | CREATE MERGE TABLE [ IF NOT EXISTS ] table_name  table_content_source
   | CREATE REPLICA TABLE [ IF NOT EXISTS ] table_name  table_content_source
   | CREATE REMOTE TABLE [ IF NOT EXISTS ] table_name  table_content_source  ON
                     'mapi:monetdb://host:port/dbname' [ WITH [ USER 'username' ] [ [ ENCRYPTED ] PASSWORD 'password'] ]
   | CREATE STREAM TABLE [ IF NOT EXISTS ] table_name  table_content_source

table_content_source:
   '(' table_element_list ')'
  |  [ '(' column_name_list ')' ]   AS select_query   [ WITH DATA | WITH NO DATA ]

table_element_list:
   table_element
  |  table_element_list , table_element

The derived (temporary) tables are either filled upon creation or automatically upon use within queries.

Temporary tables are stored automatically under the schema 'tmp'. Temporary local tables are limited to the client session. The qualifiers denote the actions taken during transaction commit over a temporary table. If the ON COMMIT clause is omitted then all tuples are dropped while retaining the structure. In most cases you would use: ON COMMIT PRESERVE ROWS

For using Loader functions we support the MonetDB specific CREATE table FROM LOADER syntax.

For merging partitioned table data we support the MonetDB specific CREATE MERGE table syntax.

For replicating table data we support the MonetDB specific CREATE REPLICA table syntax.

For distributed query processing we support the MonetDB specific CREATE REMOTE table syntax.

For data stream processing we support the MonetDB specific CREATE STREAM table syntax.

Tip: to find out which user created tables are defined in your database run query:
  SELECT * FROM sys.tables WHERE type IN (SELECT table_type_id FROM sys.table_types
           WHERE table_type_name LIKE '%TABLE' AND table_type_name <> 'SYSTEM TABLE')
   ORDER BY schema_id, name;

Table elements

Table elements mk Sun, 03/28/2010 - 13:46
table_element:
     column_name   data_type   [ column_option ... ]
   | column_name { SERIAL | BIGSERIAL }
   | column_name   WITH OPTIONS '(' column_option [ ',' ... ] ')'
   | LIKE table_name
   | [ CONSTRAINT constraint_name ] table_constraint_type
column_option:
     DEFAULT default_value_expr
   | [ CONSTRAINT constraint_name ] column_constraint_type
   | GENERATED ALWAYS AS IDENTITY [ '(' serial_parameters ')' ]
   | AUTO_INCREMENT

Identity columns take their values from a sequence generator. The MySQL (auto_increment) and PostgreSQL (serial data type) syntax are also supported. The SERIAL type is an identity column which is mapped to an INTEGER NOT NULL PRIMARY KEY. Similarly the BIGSERIAL type is an identity column which is mapped to a BIGINT NOT NULL PRIMARY KEY.

Column and Table constraints are both supported. Besides the not null constraint also unique, primary key and foreign key constraints are supported. A table can have at most one primary key definition. We currently check constraints directly on insert, update and delete, so immediate. This limitation stems from the missing triggers. The null matching on foreign keys is limited to the SIMPLE match type (null values satisfy the constraint). The full and partial match types are not supported. The referential action is currently limited to RESTRICT, i.e. an update fails if other columns have references to it.

column_constraint_type:
     NOT NULL
   | NULL
   | UNIQUE
   | PRIMARY KEY
   | REFERENCES table_name [ '(' column_name [ ',' ... ')' ] ]   [ match_options ]   [ ref_actions ]

match_options:
     MATCH { FULL | PARTIAL | SIMPLE }

ref_actions:
     { ON UPDATE | ON DELETE } { NO ACTION | CASCADE | RESTRICT | SET NULL | SET DEFAULT }

table_constraint_type:
     UNIQUE '(' column_name [ ',' ... ] ')'
   | PRIMARY KEY '(' column_name [ ',' ... ] ')'
   | FOREIGN KEY '(' column_name [ ',' ... ] ')' REFERENCES table_name [ '(' column_name [ ',' ... ] ')' ]   [ match_options ]   [ ref_actions ]

Note: The column CHECK constraint definitions are no longer accepted by the parser as of Nov2019 (11.35.3) release. They used to be accepted (for ease of migration) but were not enforced nor recorded in a data dictionary table.

A table constraint definition is not tied to a particular column, but rather to a column group. A column constraint is a notational convenience when the constraint only affects one column.

A constraint over a referenced value can be either a FULL, PARTIAL or SIMPLE (default) match. A full match requires all column values to be not null unless all are null. The simple match is more relaxed; any of the keys may be null. The partial match is considered noise for the time being.

The serial columns are a slight extension over the serial types defined earlier. In particular, we can designate RESTART option when the sequence is exhausted. This may involve a subquery over the database.

serial_parameters:
     [ START WITH nonzero-bigint ]
   | [ RESTART | RESTART WITH subquery
   | RESTART WITH nonzero-bigint ]
   | [INCREMENT BY nonzero-bigint ]
   | [MINVALUE nonzero-bigint | NOMINVALUE]
   | [MAXVALUE nonzero-bigint | NOMAXVALUE ]
   | [CACHE nonzero-bigint ]
   | [CYCLE | NOCYCLE]

Index definitions

Index definitions mk Sat, 03/27/2010 - 22:46

The index statements in the SQL standard are recognized, but their implementation is different from competitive products. MonetDB/SQL interprets these statements as an advice and often freely neglects it, relying on its own decision to create and maintain indexes for fast access. Also the UNIQUE qualifier is not honored or enforced. To add a uniqueness constraint for a table or column use UNIQUE in the ALTER TABLE ADD CONSTRAINT statement.

index_def:
    CREATE [ UNIQUE ] INDEX ident ON [ schema name . ] table name '(' column name [ ','... ] ')'

See also: CREATE INDEX command

 

MonetDB supports two special kinds of secondary indices: IMPRINTS and ORDERED INDEX, introduced in release Dec2016 (v11.25.3). These index types are experimental and have some limitations: Only 1 column can be indexed per index. Only columns of numeric data type (tinyint, smallint, integer, bigint, hugeint, float, real, double, decimal) can be indexed. As of release Mar2018 (11.29.3) the ORDERED INDEX does not have this retriction anymore. The index is NOT maintained automatically and will become inactive when inserts, deletes or updates are done on the column data. Since creating these indices can be expensive, they are only used when explicitly created. They are useful for large static (or read only) tables.

index_def:
    CREATE IMPRINTS INDEX ident ON [ schema name . ] table name '(' numeric column name ')'

Creates a new imprints index on one numerical column of a specific table. This index stores meta data (min, max, nulls) on segments of column data. It can speed-up queries which have a column selection condition (such as: AGE IS NULL OR AGE >= 18). It is a very compact index.

See also: CREATE IMPRINTS INDEX command and MonetDBInternals/MALModules/Imprints

index_def:
    CREATE ORDERED INDEX ident ON [ schema name . ] table name '(' column name ')'

Creates a new ordered index on one column of a specific table. This index is a special single column index where the values are stored in ascending order. It can speed-up queries which have a column range or point selection condition (such as: AGE BETWEEN 18 AND 30) or need sorting such as when used in a GROUP BY clause.

See also: CREATE ORDERED INDEX command

 

Alter statement

Alter statement mk Sat, 03/27/2010 - 22:39

The ALTER statement can be used to change the TABLE properties, it requires authorization to do so. Addition of a column follows the same syntax and functionality as the CREATE TABLE statement. If the table is used in a foreign key relationship the actions to be take can be further specified as RESTRICT to forbid it if there are external references to the column values. The CASCADE nullifies all references to the values being removed.

alter_statement:

         ALTER TABLE [IF EXISTS] qname ADD [COLUMN] column_name { data_type [ column_option ... ] | SERIAL | BIGSERIAL }
      |  ALTER TABLE [IF EXISTS] qname ALTER [COLUMN] column_name SET [NOT] NULL
      |  ALTER TABLE [IF EXISTS] qname ALTER [COLUMN] column_name SET DEFAULT value
      |  ALTER TABLE [IF EXISTS] qname ALTER [COLUMN] column_name DROP DEFAULT
      |  ALTER TABLE [IF EXISTS] qname ALTER [COLUMN] column_name SET STORAGE {string | NULL}
      |  ALTER TABLE [IF EXISTS] qname DROP [COLUMN] column_name [RESTRICT | CASCADE]
      |  ALTER TABLE [IF EXISTS] qname ADD [ CONSTRAINT ident ]  table_constraint_type
      |  ALTER TABLE [IF EXISTS] qname DROP CONSTRAINT ident [RESTRICT | CASCADE]

As of Apr2019 release (11.33.3) you can also change the name of a column, the name of the table itself or the schema the table is belonging to, provided there are no objects which depend on the table or column name.

alter_rename_statement:

         ALTER TABLE [IF EXISTS] qname RENAME [COLUMN] column_name TO new_column_name
      |  ALTER TABLE [IF EXISTS] qname RENAME TO new_table_name
      |  ALTER TABLE [IF EXISTS] qname SET SCHEMA schema_name

An individual table can be protected using the READ ONLY and INSERT ONLY mode. All attempts to update are flagged as a SQL error. The reverse operation is ALTER TABLE qname READ WRITE, which makes the table accessible for all update operations.

alter_access_statement:

         ALTER TABLE [IF EXISTS] qname SET READ ONLY
      |  ALTER TABLE [IF EXISTS] qname SET INSERT ONLY
      |  ALTER TABLE [IF EXISTS] qname SET READ WRITE

The ALTER statement has been extended for merge tables with ADD TABLE and DROP TABLE options to attach and detach a partition table to/from a MERGE TABLE and with SET TABLE p AS PARTITION to change the partitioning specification of the partition table.

alter_statement_for_merge_tables:

        ALTER TABLE [IF EXISTS] qname ADD TABLE qname [ AS PARTITION partition_spec ]
      | ALTER TABLE [IF EXISTS] qname SET TABLE qname AS PARTITION partition_spec
      | ALTER TABLE [IF EXISTS] qname DROP TABLE qname [ RESTRICT | CASCADE ]

View definitions

View definitions mk Fri, 04/02/2010 - 10:39

Regular SQL view definitions are supported.

view_def:
    CREATE [ OR REPLACE ] VIEW [ schema_name '.' ] view_name
           [ '(' column_name [ ',' column_name ] [ ',' ...] ')' ]
           AS select_query_without_limit
           [ WITH CHECK OPTION ]

A view can be seen as a stored SELECT query with a unique name. It can be used in queries at all the places where you can normally use a table name. Views are useful to reduce user query complexity as they can include joins, computations, derivations, aggregations, selections, conditions, ordering, and more in the view definition, so the user doesn't have to define them in the queries again and again. Simply select from the predefined view. They are also very useful to standardise and simplify reporting.

 

Note: The "WITH CHECK OPTION" is accepted for SQL compliance but has no effect.

Note: Views do not contain or store data, so do not require disk space.

Limitations: Recursive views and reference-able views are not (yet) supported.
Updatable views are not supported, so it's not possible to insert, update, merge, delete or truncate data from a view.

Tip: to find out which user created views are defined in your database run query:
  SELECT schema_id, name, type, substring(query, 0, 80) as query FROM sys.tables
   WHERE type IN (SELECT table_type_id FROM sys.table_types WHERE table_type_name = 'VIEW')
   ORDER BY schema_id, name;

 

Schema definitions

Schema definitions mk Sat, 03/27/2010 - 22:50

A SCHEMA is a logical container for objects such as tables, views, indices, sequences, triggers, functions, aggregates and procedures.  Schema access and modification is strictly controlled using the user role and authorisation scheme.

A database contains multiple schemas. Initially a database already contains several system schemas such as sys, tmp, profiler, etc. which are required by the system. You can view the existing schemas in your database by running query: SELECT * FROM sys.schemas;
One reason for organizing your data in schemas rather than databases is that in this way there will still be just one MonetDB process running serving multiple schemas each with their own tables. You can access the tables (or other object) in different schemas by using the schema name prefix: myschema.myobjectname .

create schema:
   CREATE SCHEMA [ IF NOT EXISTS ] schema_name_clause
      [ DEFAULT CHARACTER SET ident ]
      [ PATH schema_name ','... ]
      [ schema_element ','... ]

schema_name_clause:
   schema_name
   | [ schema_name ] AUTHORIZATION ident

schema_element:
   grant | revoke | create_statement | drop_statement | alter_statement

get current schema:
   SELECT CURRENT_SCHEMA

set schema:
   SET SCHEMA schema_name

alter schema:
   ALTER SCHEMA [ IF EXISTS ] schema_name RENAME TO new_schema_name

drop schema:
   DROP SCHEMA [ IF EXISTS ] schema_name [ drop_action ]

drop_action:
   RESTRICT | CASCADE

One can create a new schema using the CREATE command and change to it, by using the SET command. When creating a table (or other object) without specifying the schema, the table (or other object) will be created in the schema that is currently in usage. You can retrieve the current schema name via query: SELECT CURRENT_SCHEMA; In order to create a table in a different schema, use the schema name as a prefix like: myschema.mytable.

The DEFAULT CHARACTER SET and PATH options are here for compatibility reasons with the the SQL standard, however they are not (yet) implemented. The default character set is UTF-8.

The AUTHORIZATION option allows specifying the name of the user or the role that will own the schema. If omitted, the user who has executed the query will be the owner. The owner of the schema is allowed to create, alter and drop tables. With the AUTHORIZATION option, an explicit name for the schema is optional. If omitted, the schema automatically gets the name of the authorised user/role as its name.

Notes on schema creation:

  1. The ownership of a schema can be assigned to only one user/role, and it can not be modified after its creation. Therefore, to share the ownership of a schema, one must assign the ownership of a schema to a role at the creation of the schema. Subsequently, the role can be granted to multiple users to own the schema. 
  2. Only the 'monetdb' user and the 'sysadmin' role can create a new schema. Therefore, to allow other users to create schemas, the 'monetdb' user should assign the 'sysadmin' role to the intended users.

Drop statement

Drop statement mk Mon, 05/24/2010 - 07:58

The objects created can be removed provided the authorization permissions are set.

drop_statement:
     DROP ALL AGGREGATE qname [ RESTRICT | CASCADE ]
   | DROP ALL [ FILTER ] FUNCTION qname [ RESTRICT | CASCADE ]
   | DROP ALL LOADER qname [ RESTRICT | CASCADE ]
   | DROP ALL PROCEDURE qname [ RESTRICT | CASCADE ]
   | DROP ALL WINDOW [ FUNCTION ] qname [ RESTRICT | CASCADE ]
   | DROP AGGREGATE [ IF EXISTS ] qname [ '(' [ data_type ','... ] ')' ] [ RESTRICT | CASCADE ]
   | DROP [ FILTER ] FUNCTION [ IF EXISTS ] qname [ '(' [ data_type ','... ] ')' ] [ RESTRICT | CASCADE ]
   | DROP INDEX qname
   | DROP LOADER [ IF EXISTS ] qname [ '(' [ data_type ','... ] ')' ] [ RESTRICT | CASCADE ]
   | DROP PROCEDURE [ IF EXISTS ] qname [ '(' [ data_type ','... ] ')' ] [ RESTRICT | CASCADE ]
   | DROP ROLE qname
   | DROP SCHEMA [ IF EXISTS ] name [ RESTRICT | CASCADE ]
   | DROP SEQUENCE qname
   | DROP TABLE [ IF EXISTS ] qname [ RESTRICT | CASCADE ]
   | DROP TRIGGER [ IF EXISTS ] qname
   | DROP TYPE qname [ RESTRICT | CASCADE ]
   | DROP USER ident
   | DROP VIEW [ IF EXISTS ] qname [ RESTRICT | CASCADE ]
   | DROP WINDOW [ FUNCTION ] [ IF EXISTS ] qname [ '(' [ data_type ','... ] ')' ] [ RESTRICT | CASCADE ]

Note: If you do not specify the full signature of the function the DROP statement will successfully execute if there is only one function with this name, if not the query is aborted. The DROP ALL is used to drop all the functions with the name specified in the statement.

 

Privileges

Privileges mk Wed, 02/26/2014 - 15:41

Users

Users mk Sat, 03/27/2010 - 22:54

All interactions with the database server are attributed to a particular user known to the system. Therefore, a user login name should be created upfront, much like you would have to on any computer system, Your user name determines the schemas you have permission to access and your role in managing them. Much like your computers file system, it is essential to restrict access to your valuable database content via grant and revoke privileges and/or roles.

To create, modify/alter or drop a user in the database you can use the following syntax:

user_stmt:
    CREATE USER user_name WITH [ ENCRYPTED | UNENCRYPTED ] PASSWORD 'user_password' NAME 'full name' SCHEMA schema_name
   | ALTER USER user_name RENAME TO new_user_name
   | ALTER USER SET [ENCRYPTED | UNENCRYPTED] PASSWORD 'new_password' USING OLD PASSWORD 'user_password'
   | ALTER USER user_name WITH [ENCRYPTED | UNENCRYPTED] PASSWORD 'user_password'
   | ALTER USER user_name [ WITH [ENCRYPTED | UNENCRYPTED] PASSWORD 'user_password' ] SET SCHEMA schema_name
   | DROP USER user_name

The user name, password and default schema can be changed using the different alter user statements.

Note that for a user (including the administrator user: monetdb) to change its own password, the ALTER USER SET form has to be used where the current password is given. When the ENCRYPTED clause is given for PASSWORD, a hashed form of the password has to be supplied. The type of this hash depends on how the server was configured, but defaults to SHA512.

You may view the list of users in the database via query:

    SELECT * FROM sys.users;

The user name, password and database name are needed to authenticate yourself against tools such as mclient and all APIs, to gain access to the particular database. Once connected the current schema is the one as specified for the user.

Every user plays a certain role. So, when a user is created, a role with the same name is automatically created as well. The difference is that, the user has all corresponding permissions, e.g., the user has all permissions on the table it creates. However, the role with the same name remains empty until permissions have been granted to it explicitly.

Roles

Roles mk Mon, 05/24/2010 - 07:51

Every user takes a role with respect to the privileges on a database scheme. A user can be granted multiple roles and a role can be granted to multiple users.

By the creation of a new user, a role with the same name is automatically created, which is also the default role the user takes. However, only the role can be granted to other users/roles.

Privileges cannot be inherited via another role. For example Alice can only SELECT, Bob can only INSERT, and Alice is granted to Bob. If Bob in turn is granted to Charlie, then Charlie can only INSERT, but not SELECT.

role_statement:
    CREATE ROLE role_name   [ WITH ADMIN grantor ]
  | DROP ROLE role_name   [ WITH ADMIN grantor ]
  | SET ROLE role_name

grantor:
    CURRENT_USER | CURRENT_ROLE

A user can only assume a role after he/she has logged in. The user assumes a role by using the SET ROLE command. Then the user can use all the right given to that role. Two roles cannot be assumed at once.

 

Grant and revoke

Grant and revoke mk Fri, 04/02/2010 - 12:47

Qualified users can grant roles and other users various privileges on tables or execute privilege on functions and procedures or global privileges. The table privileges are any combination of SELECT, INSERT, DELETE, TRUNCATE, UPDATE and REFERENCES. ALTER and INDEX privileges cannot be granted. Only the owner has the right to alter a table definition. Any privilege can be later revoked, which takes any combination of the previously granted privileges.

grant:
     GRANT privileges TO grantees   [ WITH GRANT OPTION ]
   | GRANT authid [, ... ] TO grantees   [ WITH ADMIN OPTION ]   [ WITH ADMIN grantor ]

revoke:
     REVOKE [ GRANT OPTION FOR ] privileges FROM grantees   [ FROM grantor ]
   | REVOKE [ ADMIN OPTION FOR ] authid [, ... ] FROM grantees   [ FROM grantor ]

privileges:
     object_privileges ON  [ TABLE ]  qname
   | EXECUTE ON [ FUNCTION | AGGREGATE ] qname
   | global_privilege [ ',' global_privilege ]

object_privileges:
    ALL [ PRIVILEGES ] | table-operation [, ... ]

table-operation:
     INSERT | DELETE | TRUNCATE
   | UPDATE [ opt_column_list ]
   | SELECT [ opt_column_list ]
   | REFERENCES [ opt_column_list ]

global_privilege:
    COPY INTO | COPY FROM

grantees:
    PUBLIC | authid [, ... ]

grantor:
    CURRENT_USER | CURRENT_ROLE

Bulk I/O permissions

For reasons of security, by default, MonetDB only allows the special user monetdb to execute the bulk I/O statements COPY INTO (copy data from the database into a file) and COPY FROM (copy data from a file into the database). As of the June2016 release MonetDB supports granting a user/role the privilege of using the bulk I/O statements. These privileges are global privileges, i.e., they apply to all tables on which the user/role has the INSERT permission.

Examples

1. Grant permissions per table

It is possible to grant one privilege at a time to a user, per table:

GRANT SELECT ON bookSchema.toOrderTable TO libraryUser;
GRANT INSERT ON bookSchema.tOrderTable TO libraryUser;

However, if you want the user to be able to SELECT, INSERT, UPDATE DELETE and TRUNCATE then it can be done in one go:

GRANT ALL ON bookSchema.orderTable TO libraryWorker;

2. Parallel bulk load in shared schema

The following queries grant both the ownership of a schema and the bulk data loading permission (i.e., COPY FROM) to multiple users. Then, those users can log in and bulk load the data into different tables (of the same schema) in parallel.

-- 'monetdb' user
CREATE ROLE copy_role;
GRANT COPY FROM TO copy_role;
CREATE SCHEMA copy_schema AUTHORIZATION copy_role;

CREATE USER user1 WITH PASSWORD 'user1' NAME 'copy user' SCHEMA copy_schema;
CREATE USER user2 WITH PASSWORD 'user2' NAME 'copy user' SCHEMA copy_schema;

GRANT copy_role TO user1;
GRANT copy_role TO user2;

CREATE TABLE copy_schema.t1 (id INT, val VARCHAR(128));
CREATE TABLE copy_schema.t2 (id INT, num INT);

-- normal user user1
SET ROLE copy_role;
COPY INTO t1 FROM '/[path-to]/input.csv' USING DELIMITERS ',';

-- normal user user2
SET ROLE copy_role;
COPY INTO t2 FROM '/[path-to]/input.csv' USING DELIMITERS ',';

 

Data manipulation

Data manipulation mk Sat, 03/27/2010 - 22:42

Table updates

Table updates mk Thu, 06/30/2011 - 16:01

Data insertions

A table can be populated using an insert statement. It takes a table name and a value expression list. The expression result types should align with the columns in the table definition. Otherwise the column-value association should be explicitly defined using a column name list. Multiple rows can be inserted in a single statement.

The result of a query can be bulk inserted into a table, provided both source and destination are type compatible. Insertion of a table into itself effectively doubles its content, provided non of the table constraints is violated.

[ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query , ...] ]
INSERT INTO [ schema_name '.' ] table_name [ '(' column_name [ ',' ... ] ')' ]
{ VALUES '('value_expression [ ',' ... ' ] )' [ ',' ... ] | select_query }

value_expression : { scalar_exp | DEFAULT | NULL }

You must have INSERT privilege for the table. The creator/owner of the table will have INSERT privilege automatically.
The "WITH cte_alias AS SELECT_query" option is supported from release Apr2019 (11.33.3) onwards.

MonetDB/SQL does not support data insertions on views.

Data updates

The update statement syntax follows the SQL standard, but its semantics for bulk updates on keys may be slightly different than expected from other systems. In particular, the update implementation ensures that you can freely update any column without the danger of run-away values. MonetDB/SQL doest not support updates through views.

[ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query , ...] ]
UPDATE [ schema_name '.' ] table_name  [ [AS] table_alias ]
SET assignment [ ',' assignment ... ]
[ WHERE search_condition ]

assignment : column_name '=' { scalar_exp  | search_condition | NULL | DEFAULT }

You must have UPDATE privilege for the table or column(s). The creator/owner of the table will have UPDATE privilege automatically.
The "WITH cte_alias AS SELECT_query" option as well table alias is supported from release Apr2019 (11.33.3) onwards.

MonetDB/SQL does not support data updates on views.

Data deletions

[ WITH cte_alias AS SELECT_query [, cte_alias AS SELECT_query , ...] ]
DELETE FROM [ schema_name '.' ] table_name  [ [AS] table_alias ]
[ WHERE search_condition ]

You must have DELETE privilege for the table. The creator/owner of the table will have DELETE privilege automatically.
The "WITH cte_alias AS SELECT_query" option as well table alias is supported from release Apr2019 (11.33.3) onwards.

MonetDB/SQL does not support data deletions on views.

 

To quickly delete all rows in a table use TRUNCATE TABLE.

TRUNCATE [ TABLE ] [ schema_name '.' ] table_name
[ CONTINUE IDENTITY | RESTART IDENTITY ]
[ RESTRICT | CASCADE ]

You must have TRUNCATE privilege for the table. The creator/owner of the table will have TRUNCATE privilege automatically.

A 'CONTINUE IDENTITY' or 'RESTART IDENTITY' clause can be passed to restart or not an identity sequence if present in the table. Default is to CONTINUE IDENTITY sequence numbering.
The 'CASCADE' option instructs to truncate referencing table(s) also if the referencing table(s) have foreign key references to this table. The default behavior is 'RESTRICT'.

Note: it is possible to use TRUNCATE statements in a transaction and thus to roll back the effects of a truncate.

MonetDB/SQL does not support truncations of data on views.

Table expressions

Table expressions mk Sat, 03/27/2010 - 22:45

When a query is created a table can be referenced in different ways, sometimes by its name or by a select query or a join result. Here is the syntax to refer to a table.

table_reference:
      simple_table
    | joined_table [ [AS] alias [ '(' column_name [',' ...] ')' ] ]
    | '(' select_query ')' [ [AS] alias [ '(' column_name [',' ...] ')' ] ]
    | '(' VALUES '(' tuple ')' [, '(' tuple ')' [, '('...')' ] ] ')' [ [AS] alias [ '(' column_name [',' ...] ')' ] ]

joined_table:
      '(' joined_table ')'
    | table_reference CROSS JOIN table_reference
    | table_reference NATURAL [ join_type ] JOIN table_reference
    | table_reference [ join_type ] JOIN table_reference join_spec
    | table_reference UNIONJOIN table_reference join_spec

join_type:
      INNER
    | { LEFT | RIGHT | FULL } [ OUTER ]

join_spec:
      ON search_condition
    | USING '(' colunm_name [',' ...] ')'

When no join_type is specified, INNER is assumed.

The SQL framework for table expressions is based on the select-from-where construct.

select_query:
    [ with_clause ]
    SELECT [ ALL | DISTINCT ]   ( '*' | column_expr [',' ...] )
    [ INTO column_expr [',' ...] ]
    [ FROM table_reference [',' ... ] ]
    [ WINDOW window_definition_list ]
    [ WHERE search_condition ]
    [ GROUP BY column_expr [',' ...] ]
    [ HAVING search_condition ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] [ CORRESPONDING [ BY '(' column_ref_commalist ')' ] ] select_query ]
    [ ORDER BY ordering_spec [',' ...] ]
    [ LIMIT posint ]
    [ OFFSET posint ]
    [ SAMPLE posint [ SEED integer ] ]

Since Apr2019 release (11.33.3), expressions are allowed in the GROUP BY clause. The same expressions can be used in the projection clause, if and only if they are literally equal e.g.: SELECT count(*)*(col1+col2) as total FROM t1 GROUP BY col1 + col2.

The WITH clause prefix (aka Common Table Expressions (CTE)) provides the mechanism to introduce temporary in-line view definitions:

with_clause:
    WITH cte_element [',' cte_element [',' ...] ]

cte_element:
    query_alias [ '(' column_name [',' ...] ')' ] AS '(' select_query ')'

 

The pattern matching operations are used over predicates. It is possible to compare them, see the differences between them, if a predicate is a sub-predicate of another, etc. The following syntax description cover all the operations supported by MonetDB.

predicate:
       comparison_predicate
     | between_predicate
     | like_predicate
     | test_for_null
     | in_predicate
     | all_or_any_predicate
     | existence_test
     | '(' predicate ')'

comparison_predicate:
       pred_expr COMPARISON pred_expr
     | pred_expr = pred_expr

between_predicate:
     pred_expr [NOT] BETWEEN [SYMMETRIC | ASYMMETRIC] pred_expr AND pred_expr

like_predicate:
     pred_expr [NOT] { LIKE | ILIKE } atom_expr

test_for_null:
     column_name IS [NOT] NULL

in_predicate:
     pred_expr [NOT] IN '(' element_name ',' ... ')'

all_or_any_predicate :
     pred_expr COMPARISON { ANY | ALL | SOME } subquery

existence_test:
     [NOT] EXISTS subquery

pred_expr:
       scalar_expr
     | predicate

atom_expr:
       atom [ ESCAPE string ]
     | '(' atom ')' [ ESCAPE string ]
     | '(' atom_expr ')'
     | '?'

string_funcs:
      scalar_expr '||' scalar_expr
    | SUBSTRING '(' scalar_expr FROM scalar_expr [ FOR scalar_expr ] ')'
    | SUBSTRING '(' scalar_expr ',' scalar_expr [ ',' scalar_expr ] ')'
    | SUBSTRING '(' scalar_expr int_value scalar_expr ')'
   

 

Window functions

Window functions mk Sun, 10/13/2013 - 13:52

SQL provides a method to aggregate over a series of related tuples. They are called window functions and always come with an OVER() clause which determines how tuples are split up over the window functions.The PARTITION BY clause within OVER divides the rows into groups that share the same values of the PARTITION BY expression(s). For each row, the window function is computed over all rows participating in the group. The order within a partition can be used as well.

window_function_spec:
    window_function OVER   { window_name | '(' window_specification ')' }

window_function:
      RANK '(' ')'
    | DENSE_RANK '(' ')'
    | PERCENT_RANK '(' ')'
    | ROW_NUMBER '(' ')'
    | CUME_DIST '(' ')'
    | FIRST_VALUE '(' query_expression ')'
    | LAST_VALUE '(' query_expression ')'
    | NTH_VALUE '(' query_expression ',' numeric_expression ')'
    | NTILE '(' query_expression ')'
    | LEAD '(' query_expression [ ',' query_expression [ ',' query_expression ] ] ')'
    | LAG '(' query_expression [ ',' query_expression [ ',' query_expression ] ] ')'
    | aggregate_function

aggregate_function:
      COUNT '(' '*' ')'
    | COUNT '(' [ DISTINCT ] query_expression ')'
    | MAX '(' query_expression ')'
    | MIN '(' query_expression ')'
    | SUM '(' [ DISTINCT ] query_expression ')'
    | PROD '(' [ DISTINCT ] query_expression ')'
    | AVG '(' query_expression ')'
    | extra_statistic_aggregate_function

window_specification:
    [ window_name ]   [ PARTITION BY column_ref   [ ',' ... ] ]   [ ORDER BY sort_spec ]   [ window_frame ]

window_frame:
    { ROWS | RANGE | GROUPS }   { window_frame_start | BETWEEN window_bound AND window_bound }
        [ EXCLUDING { CURRENT ROW | GROUP | TIES | NO OTHERS }   ]

window_frame_start:
     UNBOUNDED PRECEDING
   | value PRECEDING
   | CURRENT ROW

window_bound:
    window_frame_start
   | UNBOUNDED FOLLOWING
   | value FOLLOWING

Supported Window Functions:
    RANK() : BIGINT - Returns the rank number within a partition, starting at 1.
    DENSE_RANK() : BIGINT - Returns the rank of the current row without gaps, it counts peer groups.
    PERCENT_RANK() : DOUBLE - Calculates the relative rank of the current row: (rank() - 1) / (rows in partition - 1).
    ROW_NUMBER() : BIGINT - Returns the position of the tuple currently in the result set, starting at 1.
    CUME_DIST() : DOUBLE - Calculates the cumulative distribution: number of rows preceding or peer with current row / rows in partition.
    FIRST_VALUE(input A) : A - Returns input value at first row of the window frame.
    LAST_VALUE(input A) : A - Returns input value at last row of the window frame.
    NTH_VALUE(input A, nth BIGINT) : A - Returns input value at “nth” row of the window frame. If there is no “nth” row in the window frame, then NULL is returned.
    NTILE(nbuckets BIGINT) : BIGINT - Enumerates rows from 1 in each partition, dividing it in the most equal way possible.
    LAG(input A [, offset BIGINT [, default_value A ] ]) : A - Returns input value at row “offset” before the current row in the partition. If the offset row does not exist, then the “default_value” is output. If omitted, “offset” defaults to 1 and “default_value” to NULL.
    LEAD(input A [, offset BIGINT [, default_value A ] ]) : A - Returns input value at row “offset” after the current row in the partition. If the offset row does not exist, then the “default_value” is output. If omitted, “offset” defaults to 1 and “default_value” to NULL.
    MIN(input A) : A
    MAX(input A) : A
    COUNT(*) : BIGINT
    COUNT(input A) : BIGINT
    SUM(input A) : A
    PROD(input A) : A
    AVG(input A) : DOUBLE
    and from release Jun2020 (11.37.7) all the extra_statistic_aggregate_function

The supported frames are:
    ROWS - Frames are calculated on physical offsets of input rows.
    RANGE - Result frames are calculated on value differences from input rows (used with a custom PRECEDING or FOLLOWING bound requires an ORDER BY clause).
    GROUPS - Groups of equal row values are used to calculate result frames (requires an ORDER BY clause).

See also en.wikibooks.org/wiki/Structured_Query_Language/Window_functions

 

Examples:

create table ranktest (id int, k varchar(3));
insert into ranktest values (1, 'a'),(2, 'b'),(3, 'c'),(4, 'd');
insert into ranktest values (1, 'a'),(2, 'b'),(3, 'c'),(4, 'd');

select ROW_NUMBER() over () as foo from ranktest;
select ROW_NUMBER() over (PARTITION BY id) as foo, id from ranktest;
select ROW_NUMBER() over (PARTITION BY id ORDER BY id) as foo, id from ranktest;
select ROW_NUMBER() over (ORDER BY id) as foo, id from ranktest;

select RANK() over () as foo from ranktest;
select RANK() over (PARTITION BY id) as foo, id from ranktest;
select RANK() over (PARTITION BY id ORDER BY id) as foo, id from ranktest;
select RANK() over (ORDER BY id) as foo, id from ranktest;

select RANK() over () as foo, id, k from ranktest;
select RANK() over (PARTITION BY id) as foo, id, k from ranktest;
select RANK() over (PARTITION BY id ORDER BY id, k) as foo, id, k from ranktest;
select RANK() over (ORDER BY id, k) as foo, id, k from ranktest;

select DENSE_RANK() over () as foo, id, k from ranktest order by k;
select DENSE_RANK() over (PARTITION BY id) as foo, id, k from ranktest order by k;
select DENSE_RANK() over (PARTITION BY id ORDER BY id, k) as foo, id, k from ranktest order by k;
select DENSE_RANK() over (ORDER BY id, k) as foo, id, k from ranktest order by k;
drop table ranktest;

For more examples see extended_sql_window_functions

Statistic Functions

Statistic Functions mk Tue, 11/19/2013 - 08:52

The SQL implementation provides the well-known standard SQL aggregate functions COUNT(*|...), COUNT(DISTINCT ...), SUM(...), AVG(...), MIN(...) and MAX(...) over scalar types/expressions and groupings. In addition, a few important statistical aggregate functions: MEDIAN, QUANTILE, STDDEV, VAR and correlation CORR are available. From release Jun2020 (11.37.7) also COVAR_SAMP and COVAR_POP are available.

extra_statistical_aggregate_functions:
      sys.median '(' scalar_expr ')'
    | sys.median_avg '(' scalar_expr ')'
    | sys.quantile '(' scalar_expr ',' scalar_expr ')'
    | sys.quantile_avg '(' scalar_expr ',' scalar_expr ')'
    | sys.stddev_samp '(' scalar_expr ')'
    | sys.stddev_pop '(' scalar_expr ')'
    | sys.var_samp '(' scalar_expr ')'
    | sys.var_pop '(' scalar_expr ')'
    | sys.corr '(' scalar_expr ',' scalar_expr ')'
    | sys.covar_samp '(' scalar_expr ',' scalar_expr ')'
    | sys.covar_pop '(' scalar_expr ',' scalar_expr ')'

For sys.quantile the percentile argument is a float value between 0.0 and 1.0. sys.median(<expr>) is equivalent to sys.quantile(<expr>, 0.5).
sys.stddev_samp computes the cumulative sample standard deviation and returns the square root of the sample variance. sys.stddev_pop computes the population standard deviation and returns the square root of the population variance. Both functions take as an argument any numeric datatype.
Likewise, sys.var_samp and sys.var_pop functions return the sample variance (/n-1) of a set of numbers and the biased variance (/n) of a set of numbers, respectively.

Note: The aggregate functions sys.median_avg and sys.quantile_avg are added in Nov2019 (11.35.3) release. They return the interpolated value if the median/quantile doesn't fall exactly on a particular row. These functions always return a value of type DOUBLE and only work for numeric types (various width integers, decimal and floating point).

Usage example:

   create schema aggr_tst;
   set schema aggr_tst;
   create table tc (c real);
   insert into tc values (1), (2), (3), (4), (5), (9);
   select * from tc;
   select count(*) countstar, COUNT(c) count, COUNT(DISTINCT c) countdistinct
        , SUM(c) sum, AVG(c) average, PROD(c) product
        , MIN(c) minimum, MAX(c) maximum
        , sys.MEDIAN(c) median
        , sys.MEDIAN_AVG(c) median_avg
        , sys.QUANTILE(c, 0.5) quantile
        , sys.QUANTILE_AVG(c, 0.5) quantile_avg
        , sys.STDDEV_SAMP(c) stddev_samp
        , sys.STDDEV_POP(c) stddev_pop
        , sys.VAR_SAMP(c) var_samp
        , sys.VAR_POP(c) var_pop
        , sys.CORR(c, c+1) corr
        , sys.COVAR_SAMP(c, c*2) covar_samp
        , sys.COVAR_POP(c, c*2) covar_pop
    from tc;
   drop table tc;
   set schema sys;
   drop schema aggr_tst;

 

Tip: To view all the available aggregate functions in your MonetDB server use query:

SELECT * FROM sys.functions where type = 3;

 

Bulk input/output

Bulk input/output mk Sun, 03/28/2010 - 00:48

The COPY INTO command enables fast insertion of multiple tuples from an text file or standard input. Each tuple  in the input file is terminated by a record-separator (default '\n') and fields are separated by the field separator (default '|'). The field values should adhere to the  syntax for value literals. Alternative separators should adhere to the SQL lexical syntax for string values. A different NULL value representation can be passed using the NULL as null_string option. Furthermore, the fields are optionally enclosed with a user defined quote character. The text file should use UTF-8 encoding if specified as file_name, and the same encoding as mclient is using if read using FROM STDIN.

It is strongly advised to announce the maximum number of records to be inserted. It avoids guessing by the server and subsequent re-allocation of table space which may involve potentially expensive copying. A portion of the input file can be skipped using the offset feature.  The offset value specifies the record at which loading should commence, the first record having offset 1.

As of the Aug2018-SP2 release, if using FROM STDIN and the number of records is not specified, reading the input stops at an empty line. This means that if a one column table is being read, there may be confusion as to whether an empty line is an empty (string) value or a NULL (if NULL AS '' is specified). The end of input takes precedence here.

As of the Apr2019 release (11.33.3), the option ON CLIENT or ON SERVER can be used. This allows the client to read/write files from/to the client instead of doing it in the server. This has the advantage that COPY INTO is then no longer restricted to only the "super user" monetdb, nor only to absolute file names. The syntax to have the server communicate with the client for file content is COPY INTO table FROM file ON CLIENT ...; and COPY query INTO file ON CLIENT ...;. This also works for COPY BINARY INTO. There is also the possibility to specify that files are to be read/written by the server by using ON SERVER. This is also the default when ON CLIENT or ON SERVER is not specified. In that case the file must be accessible by the server. Therefore, it must reside on or be accessible to the database server machine and they must be identified with an absolute path name.

The STDIN file designator reads data streaming from the client application. An empty record determines the end of sequence.

COPY   {  [ int_val [ OFFSET int_val ] RECORDS ]  |  [ int_val RECORDS ] OFFSET int_val  }
      INTO table_name
      FROM ['('] file_name ',' ... [')']
      [ ON { CLIENT | SERVER } ]
      [ [ USING ] DELIMITERS field_separator [',' record_separator [',' string_quote ] ] ]
      [ NULL AS null_string ] [ LOCKED ] [ BEST EFFORT ] [ NO CONSTRAINT ]
      [ FWF '(' pos [ ',' pos [ ... ] ] ')' ]

COPY   {  [ int_val [ OFFSET int_val ] RECORDS ]  |  [ int_val RECORDS ] OFFSET int_val  }
      INTO table_name
      FROM STDIN
      [ [ USING ] DELIMITERS field_separator [',' record_separator [',' string_quote ] ] ]
      [ NULL AS null_string ] [ LOCKED ] [ BEST EFFORT ] [ NO CONSTRAINT ]

The input syntax should comply to the following grammar: [ [ [quote] [[escape]char] * [quote]] feldspar] * record separator. Quote characters in quoted fields may be escaped with a backslash. Field and record separators can be embedded in quoted fields.

LOCKED mode

In many bulk loading situations, the original file can be saved as a backup or recreated for disaster handling. This reliefs the database system from having to prepare for recovery as well and to safe significant storage space. The LOCKED qualifier can be used in this situation (and in single user mode!) to skip the logging operation normally performed.

WARNING It is advised to add integrity constraints to the table after the file has been loaded. The ALTER statements perform bulk integrity checking and perform these checks often more efficiently.

For more see the CSV bulk load recipe.

Copy into File

The COPY INTO command with a file name argument allows for fast dumping of a result set into an ASCII file. The file must be accessible by the server and a full path name may be required. The file STDOUT can be used to direct the result to the primary output channel.

The delimiters and NULL AS arguments provide control over the layout required.  

COPY data_query
      INTO file_name
      [ ON { CLIENT | SERVER } ]
      [ [ USING ] DELIMITERS field_separator [',' record_separator [',' string_quote ] ] ]
      [ NULL AS null_string ]

COPY data_query
      INTO STDOUT
      [ [ USING ] DELIMITERS field_separator [',' record_separator [',' string_quote ] ] ]
      [ NULL AS null_string ]

For both the input and output versions of the COPY INTO commands one can specify a file name ending with '.gz' or '.bz2' or '.xz' or '.lz4' to use the appropriate compression library (if available).

For more see the Exporting bulk data recipe.

Copying binary files

Migration of tables between MonetDB/SQL instances can be speed up using the COPY BINARY INTO format.

For more see the Binary bulk data load recipe.

Aggregate into a single string

Aggregate into a single string pedro Fri, 10/05/2018 - 11:41

In the Aug2018 release of MonetDB, we added a new aggregation function "sys.group_concat", which aggregates an input column into a single string as output. We provide two versions of this aggregate: sys.group_concat(string) and sys.group_concat(string, string). In both versions, the first parameter corresponds to the input string column to be concatenated. In the former the default delimiter is the ',' character, in the latter the second parameter indicates the separator to be used. If either a group in has a NULL value, or the delimiter is NULL, the output will be NULL.

sql>create table demo (a int, b clob);
operation successful
sql>insert into demo values (1, 'chair'), (1, 'desk'), (2, 'room'), (1, 'decoration'), (2, 'window'), (2, 'sofa');
6 affected rows
sql>select '[' || sys.group_concat(a) || ']' from demo;
+---------------+
| L3            |
+===============+
| [1,1,2,1,2,2] |
+---------------+
1 tuple
sql>select a, sys.group_concat(b) from demo group by a;
+------+-----------------------+
| a    | L4                    |
+======+=======================+
| 1    | chair,desk,decoration |
| 2    | room,window,sofa      |
+------+-----------------------+
2 tuples
sql>select a, sys.group_concat(b, '|') from demo group by a;
+------+-----------------------+
| a    | L5                    |
+======+=======================+
|    1 | chair|desk|decoration |
|    2 | room|window|sofa      |
+------+-----------------------+
2 tuples
sql>insert into demo values (3, 'car'), (3, NULL);
2 affected rows
sql>select '[' || sys.group_concat(b, '-') || ']' from demo group by a;
+-------------------------+
| L6                      |
+=========================+
| [chair-desk-decoration] |
| [room-window-sofa]      |
| null                    |
+-------------------------+
3 tuples

Functions and Operators

Functions and Operators dinther Wed, 01/22/2020 - 14:52

MonetDB provides the following groups of built-in SQL functions and operators.

Logical functions and operators

Logical functions and operators dinther Wed, 01/22/2020 - 15:18

SQL uses a three-valued logic system with true, false, and null which represents “missing”.

Logical operators

The basic logical operators are available: AND, OR, NOT. The operators AND and OR are commutative, that is, you can switch the left and right operand without affecting the result. Observe the following truth tables:

 a  b a AND b a OR b
true true true true
true false false true
false true false true
false false false false
true null null true
null true null true
false null false null
null false false null
null null null null

 

 

 

 

 

 

 

 

 a NOT a a IS NULL a IS NOT NULL
true false false true
false true false true
null null true false

 

 

 

 

Logical functions

Function Return type Description Example Result
"all"(a boolean, b boolean, c boolean) boolean if c is null then true
else if a is false then false
else if (b is true or c is true) then null
else true
"all"(true, false, true) null
"and"(a boolean, b boolean) boolean a AND b "and"(true, false) false
"any"(a boolean, b boolean, c boolean) boolean if c is null then false
else if a is true then true
else if (b is true or c is true) then null
else false
"any"(true, false, true) true
"not"(a boolean) boolean NOT a "not"(true) false
"or"(a boolean, b boolean) boolean a OR b "or"(true, false) true
"xor"(a boolean, b boolean) boolean a OR b, but NOT, a AND b "xor"(true, true) false

 

Comparison functions and operators

Comparison functions and operators dinther Thu, 02/06/2020 - 14:00

Comparison operators, predicates and functions are available for all built-in data types.

Comparison operators

All comparison operators are binary operators that return values of type boolean. The usual comparison operators are available:

Operator Description Example Result
< less than 2 < 5 true
> greater than 2 > 5 false
<= less than or equal to 2 <= 5 true
>= greater than or equal to 2 >= 5 false
= equal 2 = 5 false
<> not equal 2 <> 5 true


 


 


 

 

Comparison predicates

The usual comparison predicates are available:

Predicate Description Example Result
val BETWEEN lb AND ub is val between lb and ub.
equivalent to: val >= lb AND val <= ub
'db' between 'abc' and 'db' true
val NOT BETWEEN lb AND ub is val not between lb and ub.
equivalent to: val < lb OR val > ub
'db' not between 'abc' and 'db' false
val BETWEEN SYMMETRIC lb AND ub is val between lb and ub after sorting lb and ub 'db' between symmetric 'abc' and 'db' true
val NOT BETWEEN SYMMETRIC lb AND ub is val not between lb and ub after sorting lb and ub 'db' not between symmetric 'abc' and 'db' false
val IS NULL is val NULL 'db' is null false
val IS NOT NULL is val not NULL 'db' is not null true


 


 


 


 

 

Comparison functions

Function Return type Description Example Result
"<"(arg1, arg2) boolean is arg1 less than arg2 "<"('aa', 'ab') true
">"(arg1, arg2) boolean is arg1 greater than arg2 ">"('aa', 'ab') false
"<="(arg1, arg2) boolean is arg1 less than or equal to arg2 "<="('aa', 'ab') true
">="(arg1, arg2) boolean is arg1 greater than or equal to arg2 ">="('aa', 'ab') false
"="(arg1, arg2) boolean is arg1 equal to arg2 "="('aa', 'ab') false
"<>"(arg1, arg2) boolean is arg1 not equal to arg2 "<>"('aa', 'ab') true
"between"(arg_1 any, arg_2 any, arg_3 any, boolean, boolean, boolean, boolean, boolean) boolean is arg1 between arg2 and arg3 "between"('ab', 'aa', 'ac', false, false, false, false, false) true
coalesce(arg1, arg2, ...) same as arg1 or arg2 returns the first non-NULL value in the list, or NULL if all args are NULL. At least two parameters must be passed. coalesce(null, 'ac', 'dc') 'ac'
ifthenelse(boolean arg1, arg2, arg3) same as arg2 or arg3 when arg1 expression evaluates to true then return arg2 else arg3 ifthenelse(('a' = 'b'), 1, 2) 2
isnull(arg1) boolean is arg1 null isnull('aa') false
nullif(arg1, arg2) same as arg1 returns NULL if arg1 = arg2 is true, otherwise returns arg1.
equivalent to: CASE WHEN arg1 = arg2 THEN NULL ELSE arg1 END
nullif('ams', 'ams') null
not_ilike(s, pat) boolean match pcre pattern pat on string s case insensitive. when matched return false else true. not_ilike('abc', '_B%') false
not_ilike(s, pat, escp) boolean match pcre pattern pat on string s case insensitive using escape character escp to escape wildcards. when matched return false else true. not_ilike('a_bc', '_#_B_', '#') false
not_like(s, pat) boolean match pcre pattern pat on string s. when matched return false else true. not_like('abc', '_b%') false
not_like(s, pat, escp) boolean match pcre pattern pat on string s using escape character escp to escape wildcards. when matched return false else true. not_like('a_bc', '_#_b_', '#') false

 

Cast / Conversion functions and operators

Cast / Conversion functions and operators dinther Wed, 07/15/2020 - 19:45

Casting and conversion functions are available for all built-in system data types.

Casting functions

Function Return type Description Example Result
CAST(col_expr AS data type) same as requested data type converts the value of the col_expr into the specified data type cast(123 as varchar(10)) '123'
CONVERT(col_expr , data type) same as requested data type converts the value of the col_expr into the specified data type convert(123, decimal(10,3)) 123.000

Some more examples:

select cast(true as smallint);
select cast(42 as int);
select cast(123.45 as real);
select cast('123.45' as double precision);
select cast(23.45 as decimal(5,2));    -- precision of 5 digits of which 2 decimal digits

select cast('2020-07-29' as date);
select cast('17:44:59' as time);
select cast('17:44:59.123456' as time);
select cast('2020-07-29 17:44:59' as timestamp);
select cast('2020-07-29T17:44:59' as timestamp);
select cast('2020-07-29 17:44:59.123456' as timestamp);
select cast('17:44:59.321+01:30' as timetz);
select cast('2020-07-29 17:44:59.321+01:30' as timestamptz);
select cast(1234 as interval month);
select cast(24*60*60 + 0.123 as interval second);	-- 86400.123

select cast('192.168.1.5/24' as inet);
select cast(r'{"a":[1,2,4]}' as json);
select cast('https://www.monetdb.org/Home' as url);
select cast('e31960fb-dc8b-452d-ab30-b342723e756a' as uuid);

-- or using convert instead of cast:
select convert('192.168.1.5/24' , inet);
select convert(r'{"a":[1,2,4]}' , json);
select convert('https://www.monetdb.org/Home' , url);
select convert('e31960fb-dc8b-452d-ab30-b342723e756a' , uuid);

Casting operators for character string literals

Operator Description Example
x 'hexadecimals' convert string value (pairs of hexadecimals) to binary string x 'abcd'
blob 'hexadecimals' convert string value (pairs of hexadecimals) to blob type blob 'abcd'
clob 'large string' convert string value to clob type clob 'abcd'
inet 'valid inet address string' convert string value to inet type inet '192.168.1.5/24'
json 'valid json string' convert string value to json type json '{"a":[1,2,4]}'
url 'valid url string' convert string value to url type url 'https://www.monetdb.org/Home'
uuid 'valid uuid string' convert string value to uuid type uuid 'e31960fb-dc8b-452d-ab30-b342723e756a'
E 'string with backslash escapes' convert backslash escapes (such as: \f \t \n \b \u etc) in string as specific (control) characters e 'A\fB\tC\n\\Z'
R 'any string' NO conversion of backslash escapes is done. Treat string characters as provided, so raw r 'A\fB\tC\n\\Z'

 

Mathematical functions and operators

Mathematical functions and operators dinther Thu, 01/23/2020 - 14:48

These apply to MonetDB numeric SQL types: tinyint, smallint, int, bigint, hugeint, decimal, double, float and real.
Some of these functions and operators also work on SQL types: interval month and interval second.

Mathematical operators

Operator Description Example Result
+ addition 2 + 3 5
- subtraction 2 - 3 -1
* multiplication 2 * 3 6
/ division (integer division truncates the result) 5 / 2 2
/ division (on decimals or floating point) 5.0 / 2 2.5
% modulo (remainder) 5 % 4 1
& bitwise AND 91 & 15 11
| bitwise OR 32 | 3 35
^ bitwise XOR 17 ^ 5 20
~ bitwise NOT ~1 -2
<< bitwise shift left 1 << 4 16
>> bitwise shift right 8 >> 2 2


 


 


 


 


 


 

 

Mathematical functions

Function Return type Description Example Result
abs(x) same as input absolute value of a number abs(-17.4) 17.4
bit_and(x, y) int or decimal bitwise AND bit_and(91, 15) 11
bit_not(x) int or decimal bitwise NOT bit_not(1) -2
bit_or(x, y) int or decimal bitwise OR bit_or(32, 3) 35
bit_xor(x, y) int or decimal bitwise XOR bit_xor(17, 5) 20
ceil(x) double nearest integer greater than or equal to argument
(same as ceiling(x))
ceil(-42.8) -42
ceiling(x) double nearest integer greater than or equal to argument
(same as ceil(x))
ceiling(-95.3) -95
exp(x) double exponential exp(1) 2.718281828459045
floor(x) real or double nearest integer less than or equal to argument floor(-42.8) -43
get_value_for(schema_nm, seq_nm) bigint get current value of a sequence get_value_for('dwh2', 'seq_9201') 1234
greatest(x, y) same as input greatest (highest) value of x and y
(same as sql_max(x,y))
greatest(1.2, 5) 5
least(x, y) same as input least (lowest) value of x and y
(same as sql_min(x,y))
least(1.2, 5) 1.2
left_shift(x, i) same as first arg bitwise shift left i bits left_shift(1, 4) 16
ln(x) double natural logarithm ln(2.0) 0.6931471805599453
log(x) double natural logarithm, same as ln(x) log(2.0) 0.6931471805599453
log(b, x) double logarithm to base b.
Note: before Oct2020 release (11.39.5) the arguments were switched, so log(x, b).
log(2, 64.0) 6.0
log10(x) double base 10 logarithm log10(100.0) 2.0
log2(x) double base 2 logarithm log2(64.0) 6.0
mod(x, y) same as input modulo (remainder) mod(5.0, 2.1) 0.8
next_value_for(schema_nm, seq_nm) bigint get current value of a sequence and increment it next_value_for('dwh2', 'seq_9201') 1234
power(x, y) double x raised to the power of y power(2, 5) 32
rand() int random integer value between 0 and 2147483648 rand() 917632440
rand(seed) int random integer value with seed set rand(-5) 1345532277
right_shift(x, i) same as first arg bitwise shift right i bits right_shift(16, 2) 4
round(x, d) same as first arg round x to d decimal places round(42.4382, 2) 42.44
scale_down(x, y) same as first arg ??? divide x by y and round to integer scale_down(100, 3) 33
scale_up(x, y) same as first arg ??? multiply x by y scale_up(13, 3) 39
sign(x) tinyint sign of the argument: -1 when x is negative, 0 when x is zero, 1 when x is positive sign(-8.4) -1
sql_add(x, y) same as input x plus y sql_add(2, 3.4) 5.4
sql_div(x, y) same as input x divided by y sql_div(3.4, 2) 1.7
sql_max(x, y) same as input greatest (highest) value of x and y
(same as greatest(x,y))
sql_max(1.2, sql_max(3.3, 5)) 5
sql_min(x, y) same as input least (lowest) value of x and y
(same as least(x,y))
sql_min(1.2, sql_min(3.3, 5)) 1.2
sql_mul(x, y) same as input x multplied by y sql_mul(1.2, 5) 6.0
sql_neg(x) same as input x times -1 sql_neg(-2.5) 2.5
sql_sub(x, y) same as input subtract y from x sql_sub(5, 7) -2
sqrt(x) double square root sqrt(2.0) 1.4142135623730951
sys.alpha(pdec double, pradius double) double compute alpha 'expansion' of theta for a given declination (used by SkyServer) sys.alpha(5.0, 1.2) 1.2045844792437546
sys.fuse(smallint, smallint) integer combine the bits of two integers into a larger integer type sys.fuse(2, 6) 518
sys.ms_round(x double, prc int, trunc int) double round to prc decimal places and ?? truncate to trunc decimal places sys.ms_round(1.2359, 2, 0) 1.24
sys.ms_trunc(num double, prc int) double truncate to prc decimal places sys.ms_trunc(1.2359, 2) 1.23

 

Trigonometric and Hyperbolic functions

All these functions (except pi()) take argument(s) of type double.

Function Return type Description Example Result
acos(x) double arc cosine of angle x in radians acos(0.54) 1.0003592173949747
asin(x) double arc sine of angle x in radians asin(1.0) 1.5707963267948966
atan(x) double arc tangent of angle x in radians atan(1.0) 0.7853981633974483
atan(x, y) double arc tangent of angle x/y in radians atan(1.0, 2.0) 0.4636476090008061
cos(x) double cosine of angle x in radians cos(12.2) 0.9336336440746373
cosh(x) double hyperbolic cosine of angle x in radians cosh(3.0) 10.067661995777765
cot(x) double cotangent of angle x in radians cot(16.0) 3.326323195635449
degrees(rad) double convert radians angle value to degrees: r*180/pi()
Note: before Oct2020 release (11.39.5) you need to include the sys schema prefix, so sys.degrees(rad).
degrees(0.5) 28.64788975654116
pi() double π constant pi() 3.141592653589793
radians(degr) double convert degrees angle value to radians: d*pi()/180
Note: before Oct2020 release (11.39.5) you need to include the sys schema prefix, so sys.radians(degr).
radians(45) 0.7853981633974483
sin(x) double sine of angle x in radians sin(1.4) 0.9854497299884601
sinh(x) double hyperbolic sine of angle x in radians sinh(1.4) 1.9043015014515339
tan(x) double tangent of angle x in radians tan(1.4) 5.797883715482887
tanh(x) double hyperbolic tangent of angle x in radians tanh(1.4) 0.8853516482022625


 


 


 


 


 


 


 

 

String functions and operators

String functions and operators dinther Wed, 01/29/2020 - 18:51

These apply to MonetDB SQL character string types: char, varchar, clob and subtypes: json and url
In MonetDB all character strings are UTF-8 encoded.

Character string operators

Operator Description Example Result
|| concatenate two strings. Returns null when one of the strings is null 'Monet' || 'DB' MonetDB
|| concatenation of a string with a non-string input 'Value: ' || 42 Value: 42


 


 

Character string functions

Function Return type Description Example Result
ascii(s) int Unicode code point of the first character of the string s ascii('€') 8364
char_length(s) int number of UTF-8 characters in UTF-8 string s char_length('2€') 2
character_length((s) int number of UTF-8 characters in UTF-8 string s character_length(('2€') 2
charindex(substr, s) int start position of substr in string s or 0 when not found charindex('gh', 'highigh') 3
charindex(substr, s, i) int start position of substr in string s starting at offset i
or 0 when not found
charindex('gh', 'highigh', 4) 6
concat(s1, s2) same as input concatenate strings s1 and s2.
returns null when either s1 or s2 is null
concat('Front ', 242) Front 242
difference(s1, s2) int converts two strings s1 and s2 to their soundex codes and reports the number of matching code positions. Since soundex codes have four characters, the result ranges from zero to four, with zero being no match and four being an exact match. difference('MonetDB', 'DB3') 4
editdistance(s1, s2) int compute the 'distance' between two strings returning an integer between 0 (equal) and n (largest distance) where n is the length of largest string editdistance('MonetDB', 'DB3') 6
editdistance2(s1, s2) int compute the 'distance2' between two strings returning an integer between 0 (equal) and n (largest distance) where n is the length of largest string editdistance2('MonetDB', 'DB3') 6
greatest(s1, s2) same as input alphabetically ordered last string value of strings s1 and s2. (same as sql_max(s1, s2)) greatest('ab', 'ac') ac
"index"(s, boolean) int index values of internal string dictionary table. Note: the function name index needs to be surrounded by double quotes. select name, "index"(name, true) nm_idx from sys.schemas order by name 8 for sys, 24 for tmp, 40 for json, etc
insert(s1, int pos, int nr, s2) same as input arg 4 insert string s2 into string s1 after position pos replacing nr characters in string s1. when pos is negative it counts from the end of the string. nr must be >= 0. insert('abcdef', 2, 1, 'XY') abXYdef
lcase(s) same as input convert string s to lower case lcase('MonetDB') monetdb
least(s1, s2) same as input alphabetically ordered first string value of strings s1 and s2. (same as sql_min(s1, s2)) least('ab', 'ac') ab
left(s, int n) same as input arg 1 return first n characters in the string left('MonetDB', 3) Mon
length(s) int count number of UTF-8 characters in UTF-8 string s length('2€') 2
levenshtein(s1, s2) int compute the 'levenshtein distance' between two strings returning an integer between 0 (equal) and n (largest distance) where n is the length of largest string levenshtein('MonetDB', 'DB3') 6
levenshtein(s1, s2, int ??, int ??, int ??) int compute the 'levenshtein distance' between two strings returning an integer between 0 (equal) and n + ?? (largest distance) where n is the length of largest string levenshtein('MonetDB', 'DB3', 4, 2, 1) 8
locate(s1, s2) int locate string s1 in s2, when found return start position else 0 locate('DB', 'MonetDB') 6
locate(s1, s2, int pos) int locate string s1 in s2 starting from position pos, when found return start position else 0 locate('DB', 'DBMonetDB', 3) 8
lower(s) same as input convert string s to lower case lower('MonetDB') monetdb
lpad(s, int len) same as input arg 1 fill up the string to length len by prepending spaces. If the string is already longer than length then it is truncated (on the right). lpad('abc', 6)    abc
lpad(s1, int len, s2) same as input arg 1 fill up the string s1 to length len by prepending the characters s2. If the string s1 is already longer than length then it is truncated (on the right). lpad('abc', 6, 'DB') DBDabc
ltrim(s) varchar remove leading whitespace characters from string s ltrim(E' \t\fab \tdf ') ab df
ltrim(s1, s2) varchar remove leading s2 strings from string s1 ltrim('aabcdaa', 'a') bcdaa
sys.md5(s) clob(32) calculates the MD5 hash of string, returning the result as 32 character hex number sys.md5('abc') 900150983cd24fb0d6963f7d28e17f72
sys.ms_stuff(varchar(32) s1, int pos, int nr, varchar(32) s2) varchar(32) insert string s2 into string s1 at position pos replacing nr characters in string s1. If pos <= 0 or > length of s1 then an empty string is returned. nr may be negative. sys.ms_stuff('abcdef', 2, 1, 'XY') aXYcdef
octet_length(s) int number of bytes in UTF-8 string s octet_length('2€') 4
patindex(pattern, s) int search for pattern in string s, when found return the position of the last matched character, when not found return 0 patindex('%bc%', 'abcd') 3
qgramnormalize(s) same as input normalisation of a string s. Converts letters to uppercase and removes all characters not in a..zA..Z0..9 or space qgramnormalize('Prize €50!') PRIZE 50
repeat(s, nr) same as input arg 1 repeat string s the specified nr of times repeat('kiss,', 3) kiss,kiss,kiss,
replace(s, srch, repl) same as input arg 1 replace occurrences of string srch in string s by string repl replace('abc', 'b', 'X') aXc
sys.reverse(s) clob return reversed string sys.reverse('MonetDB') BDtenoM
right(s, int n) same as input arg 1 return last n characters in the string right('MonetDB', 4) etDB
rpad(s, int) same as input arg 1 fill up the string to length len by appending spaces. If the string is already longer than length then it is truncated (on the right). rpad('abc', 6) || 'End' abc   End
rpad(s1, int len, s2) same as input arg 1 fill up the string s1 to length len by appending the characters s2. If the string s1 is already longer than length then it is truncated (on the right). rpad('abc', 6, 'DB') abcDBD
rtrim(s) varchar remove trailing whitespace characters from string s rtrim(E'ab df \t\n') ab df
rtrim(s1, s2) varchar remove trailing s2 strings from string s1 rtrim('aabcdaa', 'a') aabcd
similarity(s1, s2) double computes the similarity between string s1 and s2 and returns a number between 0 (no similarity) and 1 (equal). similarity('MonetDB', 'DB3') 0.4
soundex(s) varchar(4) computes the Soundex code from string s using a phonetic algorithm soundex('MonetDB') M533
space(nr) clob(nr) generates a string with nr spaces select 's' || space(4) || 'e' s    e
splitpart(s, sep, n) same as input arg 1 extract substring from string s by spliting on separator string sep the field before nth occurrence. n must be greater than zero splitpart('a|a|bc|cd', '|', 3) bc
sql_max(s1, s2) same as input alphabetically ordered last string value of strings s1 and s2 sql_max('ab', 'ac') ac
sql_min(s1, s2) same as input alphabetically ordered first string value of strings s1 and s2 sql_min('ab', 'ac') ab
strings(s) varchar convert a column of type char(n) or varchar(n) or clob or clob(n) to type varchar(m) where m is the maximum of the string lengths of all values in the column select name, length(name) as name_len, strings(name) as nm_varchar8 from sys.schemas the result column nm_varchar8
will be of type varchar(8)
while name is defined
as varchar(1024)
substr(s, startpos) same as input arg 1 extract substring starting from position startpos substr('abCde', 3) Cde
substr(s, startpos, count) clob(count) extract substring starting from position startpos for count characters substr('abCde', 2, 3) bCd
substring(s, startpos) same as input arg 1 extract substring starting from position startpos substring('abcde', 3) cde
substring(s, startpos, count) clob(count) extract substring starting from position startpos for count characters substring('abcde', 2, 2) bc
trim(s) varchar remove leading and trailing whitespace characters from string s trim(E' \t\fab df \t\n') ab df
trim(s1, s2) varchar remove leading and trailing s2 strings from string s1 trim('aabcdaa', 'a') bcd
"truncate"(s, n_chars) same as input arg 1 truncate the string s to a maximum of n_chars characters. Note: the function name truncate need to be surrounded by double quotes. "truncate"('Truncate', 4) Trun
ucase(s) same as input convert string s to upper case ucase('MonetDB') MONETDB
upper(s) same as input convert string s to upper case upper('MonetDB') MONETDB

 

Date/Time functions and operators

Date/Time functions and operators dinther Thu, 02/06/2020 - 16:30

These apply to MonetDB SQL temporal types: date, time, time with time zone, timestamp and timestamp with time zone .
Some functions apply to MonetDB SQL type: second interval and month interval .

Date/Time operators

Operator Description Example Result
  + add seconds to a date or time or timestamp date '2020-09-28' + (7 * 24 * 60 * 60) date '2020-10-05'
  - subtract seconds from a date or time date '2020-09-28' - (7 * 24 * 60 * 60) date '2020-09-21'
  - subtract months from a date or timestamp date '2020-09-28' - month_interval '7' date '2020-02-28'
  - subtract two dates date '2020-09-28' - date '2020-02-28' interval '7 months'
  - subtract two times time '14:35:45' - time '02:12:24' interval '12 hours 23 minutes 31 seconds'

 

Date/Time functions

NOTE: Some examples and results in below table are UNDER CONSTRUCTION

Function Return type Description Example Result
century(date) int extract century from a date or timestamp or timestamptz century(date '2020-03-22') 21
curdate() date get current date curdate() date '2020-03-22'
current_date() date get current date current_date() date '2020-03-22'
current_time() timetz get current time with time zone current_time() timetz '13:16:57.734639+01:00'
current_timestamp() timestamptz get current timestamp (date and time and fractions) with time zone current_timestamp() timestamptz '2020-03-22 13:16:57.734639+01:00'
curtime() timetz get current time with time zone current_time() timetz '13:16:57.734639+01:00'
sys.date_to_str(date, format_str) clob convert date value to a string using format_str sys.date_to_str(date '2020-03-22', '%D %d.%m.%Y'); 03/22/20 22.03.2020
date_trunc(clob, timestamp) timestamp ??? date_trunc(s, ts)  
"day"(dt_or_ts) int extract month day nr (1..31) of a date or timestamp or timestamptz.
same as: dayofmonth(date)
"day"(date '2020-03-22') 22
"day"(sec_interval) bigint compute nr of days and truncate it to an integer "day"(3.89 * (24 * 60 * 60)) 3
dayofmonth(dt_or_ts) int extract month day nr (1..31) of a date or timestamp or timestamptz.
same as: "day"(date)
dayofmonth(date '2020-03-22') 22
dayofweek(dt_or_ts) int extract week day nr (1..7) of a date or timestamp or timestamptz dayofweek(date '2020-03-22') 7
dayofyear(dt_or_ts) int extract year day nr (1..366) of a date or timestamp or timestamptz dayofyear(date '2020-03-22') 82
decade(dt_or_ts) int extract decade nr of a date or timestamp or timestamptz decade(date '2027-03-22') 202
sys.epoch(bigint nr_secs) timestamp add nr of seconds to timestamp '1970-01-01 00:00:00.0' sys.epoch(1234567890) 2009-02-13 23:31:30.0
sys.epoch(timestamp) int convert timestamp (or timestamptz) to nr of seconds since '1970-01-01 00:00:00.0' sys.epoch(timestamp '2009-02-13 23:31:30.0') 1234567890
extract(field from dt_value) int extract a specific field from a date or time or timestamp.
supported keywords for field are: CENTURY, DECADE, YEAR, QUARTER, MONTH, WEEK, DAY, DOW, DOY, HOUR, MINUTE and SECOND.
extract(doy from date '2027-03-22') 82
"hour"(tm_or_ts) int extract hour nr (0..23) of a time or timetz or timestamp or timestamptz or sec_interval "hour"(timetz '15:35:02.002345+01:00') 15
local_timezone() sec_interval get local time zone as represented in seconds local_timezone() 3600
localtime() time get current local time without time zone localtime() time '13:16:57.734639'
localtimestamp() timestamp get current local timestamp (date and time and fractions) without time zone localtimestamp() timestamp '2020-03-22 13:16:57.734639'
"minute"(tm_or_ts) int extract minutes (0..59) of a time or timetz or timestamp or timestamptz or sec_interval "minute"(timetz '15:35:02.002345+01:00') 35
"month"(dt_or_ts) int extract month nr (1..12) of a date or timestamp or timestamptz or month_interval "month"(date '2020-07-22') 7
now() timestamptz get current timestamp (date and time and fractions) with time zone now() timestamptz '2020-03-22 13:16:57.734639+01:00'
quarter(dt_or_ts) int extract quarter nr (1..4) of a date or timestamp or timestamptz quarter(date '2020-07-22') 3
"second"(sec_interval) int extract seconds (0 .. 59) of a sec_interval "second"(24.603) 24
"second"(tm_or_ts) decimal(9,6) extract seconds (0.000 .. 59.999999) of a time or timetz or timestamp or timestamptz "second"(timetz '15:35:02.002345+01:00') 2.002345
sql_add(dt_or_ts, month_interval) same as arg 1 add an integer month interval value to a date or timestamp or timestamptz sql_add(date '', interval month '')  
sql_add(dt_or_tm, sec_interval) same as arg 1 add a decimal seconds interval value to a date or time or timetz or timestamp or timestamptz sql_add(date '', interval second '')  
sql_sub(date, date) int subtract a date from a date returning nr of seconds between the two dates sql_sub(date '', date '')  
sql_sub(dt_or_ts, month_interval) same as arg 1 subtract an integer month interval value from a date or timestamp or timestamptz sql_sub(date '', interval month '')  
sql_sub(dt_or_tm, sec_interval) same as arg 1 subtract a decimal seconds interval value from a date or time or timetz or timestamp or timestamptz sql_sub(date '', interval second '')  
sql_sub(time, time) sec_interval subtract a time from a time returning nr of seconds interval between the two times sql_sub(time '', time '')  
sql_sub(timestamp, timestamp) sec_interval subtract a timestamp from a timestamp returning nr of seconds interval between the two timestamps sql_sub(timestamp '', timestamp '')  
sql_sub(timestamptz, timestamptz) sec_interval subtract a timestamptz from a timestamptz returning nr of seconds interval between the two timestamptzs sql_sub(timestamptz '', timestamptz '')  
sql_sub(timetz, timetz) sec_interval subtract a timetz from a timetz returning nr of seconds interval between the two timetzs sql_sub(timetz '', timetz '')  
sys.str_to_date(s, format_str) date parse string s using format_str and construct a date value sys.str_to_date('', '')  
sys.str_to_time(s, format_str) time parse string s using format_str and construct a time value sys.str_to_time('', '')  
sys.str_to_timestamp(s, format_str) timestamp parse string s using format_str and construct a timestamp value sys.str_to_timestamp('', '')  
sys.time_to_str(time, format_str) clob convert time value to a string using format_str sys.time_to_str(time '', '')  
sys.timestamp_to_str(timestamp, format_str) clob convert timestamp value to a string using format_str sys.timestamp_to_str(timestamp '', '')  
week(dt_or_ts) int extract week nr (1 .. 53) of a date or timestamp or timestamptz.
same as: weekofyear(date)
week(date '2020-03-22') 12
weekofyear(dt_or_ts) int extract week nr (1 .. 53) of a date or timestamp or timestamptz.
same as: week(date)
weekofyear(date '2020-03-22') 12
"year"(dt_or_ts) int extract year nr of a date or timestamp or timestamptz or month_interval "year"(date '2020-03-22') 2020

 

Date/Time pseudo columns

Pseudo column Description Example Result
CURRENT_DATE get current date select current_date date '2020-02-02'
CURRENT_TIME get current time (with time zone) select current_time timetz '15:35:02.073522+01:00'
CURRENT_TIMESTAMP get current timestamp (with time zone) select current_timestamp timestamptz '2020-02-02 15:35:02.002345+01:00'
CURRENT_TIMEZONE get current time zone as seconds interval select current_timezone 3600.000
NOW same as: CURRENT_TIMESTAMP select now timestamptz '2020-02-02 15:35:02.002345+01:00'
LOCALTIME get current local time without time zone select localtime time '15:35:02.073522'
LOCALTIMESTAMP get current local timestamp without time zone select localtimestamp timestamp '2020-02-02 15:35:02.073522'

See also: Date/Time Pseudo Columns

 

Binary string functions

Binary string functions dinther Thu, 04/23/2020 - 18:37

These apply to MonetDB SQL binary string type: blob
To use binary string data in scripts you can use the hex cast notation: x'0012FF' to represent 3 bytes: 0, 18 (16+2) and 255.
The blob cast notation: blob'0012FF' is also allowed.

Binary string functios

Function Return type Description Example Result
length(blob) int number of bytes in binary string blob length(x'0012FF') 3
octet_length(blob) int number of bytes in binary string blob octet_length(x'0012FF') 3

 

In MonetDB binary string data is stored as hex character strings, using two hex characters per byte. Therefore some of the character string functions can also be applied to binary string data, for example

SELECT x'1a2b3c4d5e';
SELECT blob '1a2b3c4d5e';

CREATE TABLE test_blob(b blob NOT NULL, b52 blob(52));
INSERT INTO test_blob(b,b52) VALUES (x'123456', blob'78901234');
INSERT INTO test_blob(b,b52) VALUES ('123456abcdef', '78901234abcdef'); -- implicit conversion from char to blob is done

SELECT length(b) as byte_length, octet_length(b) as octet_length, b from test_blob where b = x'123456';
-- returns: 3 3 123456
SELECT length(b) as byte_length, char_length(b) as char_length, b from test_blob where b = x'123456';
-- returns: 3 6 123456

-- example of how to extract part of a binary string
SELECT b52, substring(b52, 3, 4) as part_as_Clob from test_blob;
SELECT b52, cast(substring(b52, 3, 4) as blob) as part_as_Blob from test_blob;

-- example of how to concatenate two binary strings
SELECT b||b52 as b_concat_result_Clob from test_blob;
SELECT convert(b||b52 , blob) as b_concat_result_Blob from test_blob;

-- comparisons are allowed, except for LIKE and ILIKE pattern matches on blobs
SELECT * from test_blob where b < b52;
SELECT * from test_blob where b like '1234%'; -- NOT allowed, generates an ERROR
SELECT * from test_blob where substring(b,0,9) like '1234%'; -- This is allowed as substring() returns a Clob

 

Inet functions and operators

Inet functions and operators dinther Thu, 07/02/2020 - 21:50

These apply to MonetDB SQL type: inet (IPv4 Network Address).

An IPv4 Network Address string has a specific syntax, see also IPv4 address.

Inet operators

Operator Description Example Result
< is less than inet '192.168.1.5' < inet '192.168.1.6' true
<= is less than or equal inet '192.168.1.5' <= inet '192.168.1.5' true
= equals inet '192.168.1.5' = inet '192.168.1.5' true
> is greater than inet '192.168.1.5' > inet '192.168.1.4' true
>= is greater than or equal inet '192.168.1.5' >= inet '192.168.1.5' true
<> is not equal inet '192.168.1.5' <> inet '192.168.1.4' true
<< is contained by inet '192.168.1.5' << inet '192.168.1/24' true
<<= is contained by or equals inet '192.168.1/24' <<= inet '192.168.1/24' true
>> contains inet '192.168.1/24' >> inet '192.168.1.5' true
>>= contains or equals inet '192.168.1/24' >>= inet '192.168.1/24' true


 


 


 


 


 

 

Inet functions

Note: You must include the sys. prefix for all these inet functions (see examples) in order to work properly from other schemas than sys.

Function Return type Description Example Result
sys.abbrev(inet) clob abbreviated display format as text sys.abbrev(inet '10.1.0.0/16') 10.1/16
sys.broadcast(inet) inet broadcast address for network sys.broadcast(inet '192.168.1.5/24') 192.168.1.255/24
sys.host(inet) clob extract IP address as text sys.host(inet '192.168.1.5/24') 192.168.1.5
sys.hostmask(inet) inet construct host mask for network sys.hostmask(inet '192.168.23.20/30') 0.0.0.3
sys.left_shift(inet, inet) boolean is contained by sys.left_shift(inet '192.168.1/24', inet '192.168.1.5') true
sys.left_shift_assign(inet, inet) boolean is contained by or equals sys.left_shift_assign(inet '192.168.1/24', inet '192.168.1/24') true
sys.masklen(inet) int extract netmask length sys.masklen(inet '192.168.1.5/24') 24
sys.netmask(inet) inet construct netmask for network sys.netmask(inet '192.168.1.5/24') 255.255.255.0
sys.network(inet) inet extract network part of address sys.network(inet '192.168.1.5/24') 192.168.1.0/24
sys.right_shift(inet, inet) boolean contains sys.right_shift(inet '192.168.1/24', inet '192.168.1.5') true
sys.right_shift_assign(inet, inet) boolean contains or equals sys.right_shift_assign(inet '192.168.1/24', inet '192.168.1/24') true
sys.setmasklen(inet, int) inet set netmask length for inet value sys.setmasklen(inet '192.168.1.5/24', 16) 192.168.1.5/16
sys.text(inet) clob extract IP address and netmask length as text sys.text(inet '192.168.1.5') 192.168.1.5/32

 

JSON functions

JSON functions dinther Wed, 02/19/2020 - 18:35

These apply to MonetDB SQL type: JSON (JavaScript Object Notation).

Note: All JSON functions are located in the json schema. You must include the json. prefix for all these functions in order to work properly.

Function Return type Description Example Result
json.filter(js, indx) json extracts a indexed component from js. The index starts at 0 for the first element. json.filter(json '["a", 4]', 1) [4]
json.filter(js, pathexpr) json extracts the compgonent from js that satisfied the pathexpr string. The supported JSON path expression syntax is documented at JSONPath json.filter(json '{"price":9}', '$..price') [9]
json."integer"(js) bigint or int or smallint or tinyint turn a number or singleton array value or singleton object element of js into an integer. Returns null if it fails. json."integer"(json '{"n":4}') 4
json.isarray(str) boolean checks the string str for JSON array compliance json.isarray('[1,7]') true
json.isarray(js) boolean checks the JSON value js for JSON array compliance json.isarray(json '[1,7]') true
json.isobject(str) boolean checks the string str for JSON object compliance json.isobject('{"n":4}') true
json.isobject(js) boolean checks the JSON value js for JSON object compliance json.isobject(json '{"n":4}') true
json.isvalid(str) boolean checks the string str for JSON syntax compliance json.isvalid('{"a":[1]}') true
json.isvalid(js) boolean checks the JSON value js for JSON validity json.isvalid(json '{"a":[1,2]}') true
json.keyarray(js) json returns an arraylist of key tags for the top-level components of js. Note js must represent a JSON object else an error (Object expected) is reported json.keyarray(json '{"id":2, "nm":"X"}') ["id","nm"]
json.length(js) int returns the number of top-level components of js json.length(json '{"a":[1]}') 1
json.number(js) double turn a number or singleton array value or singleton object tag of js into a double. Returns null if it fails. json.number(json '{"n":4}') 4.0
json.text(js) clob glue together the values in js separated by space character json.text(json '[1,2,3,4]') 1 2 3 4
json.text(js, Separator str) clob glue together the values in js separated by Separator string json.text(json '[1,2,3,4]', 'x') 1x2x3x4
json.valuearray(js) json returns an arraylist of value tags for the top-level components of js. Note js must represent a JSON object else an error (Object expected) is reported json.valuearray(json '{"a":1, "b":2}') [1,2]

 

Aggregate functions returning a concatenated CLOB string which is a valid json arrary

Function Return type Description Example Result
json.tojsonarray(double) clob convert numeric values in the column/group into a json array string json.tojsonarray(i) [ "1", "2", "3", "4" ]
json.tojsonarray(clob) clob convert string values in the column/group into a json array string json.tojsonarray(c) [ "one", "two", "tree", "four" ]

See also: AggregateFunctions

 

URL functions

URL functions dinther Thu, 03/26/2020 - 18:33

These functions apply to MonetDB SQL type: URL (Uniform Resource Locator).

A URL string has a specific syntax, see URL syntax for valid URL string patterns.

For the examples below we use following url_example string:
'https://me@www.monetdb.org:458/Doc/Abc.html?lang=nl&sort=asc#example' to create the shown results.

Note: You must include the sys. prefix for all these URL functions (see examples) in order to work properly from other schemas than sys.

Function Return type Description Example Result
sys.getanchor(url) clob extract the anchor part (after the #) from the url, may return null if no achor exists sys.getanchor(url_example) example
sys.getbasename(url) clob extract the base name part (after the / excluding the extension) from the path of the url, may return null sys.getbasename(url_example) Abc
sys.getcontext(url) clob extract the path context part of the url sys.getcontext(url_example) /Doc/Abc.html
sys.getdomain(url) clob extract the top-level domain part of the host part of the url, may return null sys.getdomain(url_example) org
sys.getextension(url) clob extract the file extension part of the url, may return null sys.getextension(url_example) html
sys.getfile(url) clob extract the last file part of the path of the url, may return null sys.getfile(url_example) Abc.html
sys.gethost(url) clob extract the host part of the url, may return null sys.gethost(url_example) www.monetdb.org
sys.getport(url) clob extract the port number part of the url, may return null sys.getport(url_example) 458
sys.getprotocol(url) clob extract the protocol or scheme part of the url sys.getprotocol(url_example) https
sys.getquery(url) clob extract the query part (after the ?) of the url, may return null sys.getquery(url_example) lang=nl&sort=asc
sys.getroboturl(url) clob extract the location of the robot control file of the url sys.getroboturl(url_example) https://me@www.monetdb.org:458/robots.txt
sys.getuser(url) clob extract the user part of the url, may return null sys.getuser(url_example) me
sys.isaurl(string) boolean checks whether a character string complies to the url syntax format sys.isaurl(url_example) true
sys.newurl(scheme, authority, path) url create a new url from three strings: scheme, authority or host and path sys.newurl('https', 'usr@www.a.com:123', 'docs/index.html') https://usr@www.a.com:123/docs/index.html
sys.newurl(scheme, host, int port, path) url create a new url from three strings and a port number as third argument sys.newurl('https', 'www.a.com', 5567, 'docs/index.html') https://www.a.com:5567/docs/index.html

 

UUID functions

UUID functions dinther Wed, 07/15/2020 - 15:20

These apply to MonetDB SQL type: UUID (Universally Unique IDentifiers).

Note: You must include the sys. prefix for these UUID functions (see examples) in order to work properly from other schemas than sys.

Function Return type Description Example Result
sys.isauuid(string) boolean tests if the given string represents a valid uuid value and returns a boolean value true or false, or null when the input is null sys.isauuid('e31960fb-dc8b-452d-ab30-b342723e7565') true
sys.uuid() uuid generates and returns a new random uuid sys.uuid() 65950c76-a2f6-4543-660a-b849cf5f2453

 

To convert a string column or expression or literal (which represents a valid uuid) to a uuid type you can use a cast() or convert() function. Examples:

select  cast('26d7a80b-7538-4682-a49a-9d0f9676b765' as uuid)  as uuid_val;
select convert('83886744-d558-4e41-a361-a40b2765455b', uuid)  as uuid_val;

To convert a quoted string literal which represents a valid uuid to a uuid type you can also use the uuid prefix. Example:

select uuid'AC6E4E8C-81B5-41B5-82DE-9C837C23B40A'  as uuid_val;

 

Aggregate functions

Aggregate functions dinther Wed, 04/15/2020 - 20:06

Aggregate functions operate on a column or column expression of a table or group (as created via GROUP BY clause).

For the examples below we use a simple table t(i int, c varchar(8)) with contents:
INSERT into t(i,c) VALUES
(1, 'one'),
(2, 'two'),
(3, 'tree'),
(4, 'four'),
(NULL, NULL);

to create the shown Results.

Standard aggregate functions

Function Return type Description Example Result
avg(numeric_expr) double compute the average of the non-NULL integer/float/decimal/month_interval values in the column or group avg(i) 2.5
count(*) bigint count the number of rows in the column or group including those who may have NULL values count(*) 5
count(col_expr) bigint count the number of non-NULL values in the column or group count(i) 4
count(distinct col_expr) bigint count the number of distinct non-NULL values in the column or group count(distinct i%2) 2
max(col_expr) type of col_expr return the maximum non-NULL value in the column or group max(c) two
min(col_expr) type of col_expr return the minimum non-NULL value in the column or group min(c) four
prod(numeric_expr) bigint or hugeint or double compute the product of the non-NULL numeric values in the column or group prod(i) 24
prod(distinct numeric_expr) bigint or hugeint or double compute the product of the distinct non-NULL numeric values in the column or group prod(distinct 1 + i%2) 2
sum(integer_expr) bigint or hugeint compute the sum of all non-NULL integer values in the column or group sum(i) 10
sum(distinct integer_expr) bigint or hugeint compute the sum of all distinct non-NULL integer values in the column or group sum(distinct i/2) 3
sum(decimal_expr) decimal compute the sum of all non-NULL decimal values in the column or group sum(cast(i as decimal)) 10.000
sum(float_expr) real or double compute the sum of all non-NULL floating point values in the column or group sum(cast(i as real)) 10.0
sum(month_interval_expr) month_interval compute the sum of all non-NULL interval month values in the column or group sum(cast(i as interval month)) 10
sum(sec_interval_expr) sec_interval compute the sum of all non-NULL interval second values in the column or group sum(cast(i as interval second)) 10.000

 

Aggregate functions returning a concatenated CLOB string

Note: You must include the sys. or json. prefix for these aggregate functions (see examples) in order to work properly.

Function Return type Description Example Result
listagg(col_expr) varchar concatenate non-NULL values in a column or group into one large varchar string with values separated by a comma (the default separator)
Supported from release Jun2020 (11.37.7)
listagg(c) one,two,tree,four
listagg(col_expr, separator_str) varchar concatenate non-NULL values in a column or group into one large varchar string with values separated by separator_str
Supported from release Jun2020 (11.37.7)
listagg(i, ' | ') 1 | 2 | 3 | 4
sys.group_concat(col_expr) clob concatenate non-NULL values in a column or group into one large string with values separated by a comma (the default separator) sys.group_concat(c) one,two,tree,four
sys.group_concat(col_expr, separator_str) clob concatenate non-NULL values in a column or group into one large string with values separated by separator_str sys.group_concat(i, ' | ') 1 | 2 | 3 | 4
json.tojsonarray(clob) clob convert string values in the column or group into a json array string json.tojsonarray(c) [ "one", "two", "tree", "four" ]
json.tojsonarray(double) clob convert numeric values in the column or group into a json array string json.tojsonarray(i) [ "1", "2", "3", "4" ]

 

Aggregate functions for statistics

Note: You must include the sys. prefix for below aggregate functions (see examples) in order to work properly.

Statistic Function Return type Description Example Result
sys.corr(numeric_a, numeric_b) double return the correlation coefficient of the non-NULL values in the numeric (integer/decimal/real/double) column or group numeric_a versus numeric_b sys.corr(i, i+2) 0.7500000000000001
sys.covar_pop(numeric_a, numeric_b) double return the population covariance of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group numeric_a versus numeric_b.
Supported from release Jun2020 (11.37.7)
sys.covar_pop(i, i*2) 2.5
sys.covar_samp(numeric_a, numeric_b) double return the sample covariance of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group numeric_a versus numeric_b.
Supported from release Jun2020 (11.37.7)
sys.covar_samp(i, i*2) 3.3333333333333335
sys.median(col_expr) type of col_expr return the statistic median of the non-NULL values in the numeric (integer/decimal/real/double) or temporal (date/time/timestamp/interval) column or group sys.median(i) 2
sys.median_avg(numeric_expr) double return the statistic median average of the non-NULL values in the numeric (integer/decimal/real/double) column or group sys.median_avg(i) 2.5
sys.quantile(col_expr, percentile) type of col_expr return the statistic quantile of the non-NULL values in the numeric (integer/decimal/real/double) or temporal (date/time/timestamp/interval) column or group. The percentile argument must be between 0.0 and 1.0 sys.quantile(i, 0.7) 3
sys.quantile_avg(numeric_expr, percentile) double return the statistic quantile average of the non-NULL values in the numeric (integer/decimal/real/double) column or group. The percentile argument must be between 0.0 and 1.0 sys.quantile_avg(i, 0.6) 2.8
sys.stddev_pop(numeric_expr) double return the population standard deviation of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group. Same as the square root of var_pop(). sys.stddev_pop(i) 1.118033988749895
sys.stddev_samp(numeric_expr) double return the sample standard deviation of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group. Same as the square root of var_samp(). sys.stddev_samp(i) 1.2909944487358056
sys.var_pop(numeric_expr) double return the population standard variance of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group. Same as the square of stddev_pop(). sys.var_pop(i) 1.25
sys.var_samp(numeric_expr) double return the sample standard variance of numeric_expr of the non-NULL values in the numeric (integer/decimal/real/double/interval) column or group. Same as the square of stddev_samp(). sys.var_samp(i) 1.6666666666666667

For more info see: Statistic Functions

 

You can also create your own aggregate functions, see Create Aggregate function command.

To list the available aggregate functions in your MonetDB server run query:
SELECT DISTINCT schema_id, name, func, mod, language, system FROM sys.functions WHERE type = 3 ORDER BY name;

 

Window functions

Window functions dinther Thu, 06/25/2020 - 20:34

Window functions provide the ability to perform calculations across sets of rows that are related to the current query row.
Note that these functions must be invoked using window function syntax, i.e., an OVER clause is required.
The built-in window functions are listed below.

Built-in window functions

Function Return type Description Available since
cume_dist(value any, boolean, boolean) double cumulative distribution: (number of partition rows preceding or peer with current row) / total partition rows Apr2019 (11.33.3)
dense_rank(value any, boolean, boolean) int rank of the current row without gaps
diff(value any) boolean is the current row value different from other partition rows
diff(boolean, value any) boolean is the current row value different from other partition rows
first_value(value any) any returns value evaluated at the row that is the first row of the window frame Apr2019 (11.33.3)
lag(value any, [offset int, [default any,]] boolean, boolean) same type as value returns value evaluated at the row that is offset rows before the current row within the partition; if there is no such row, instead return default (which must be of the same type as value). Both offset and default are evaluated with respect to the current row. If omitted, offset defaults to 1 and default to null Apr2019 (11.33.3)
 
last_value(value any) same type as value returns value evaluated at the row that is the last row of the window frame Apr2019 (11.33.3)
lead(value any, [offset int, [default any,]] boolean, boolean) same type as value returns value evaluated at the row that is offset rows after the current row within the partition; if there is no such row, instead return default (which must be of the same type as value). Both offset and default are evaluated with respect to the current row. If omitted, offset defaults to 1 and default to null Apr2019 (11.33.3)
nth_value(value any, nth int) same type as value returns value evaluated at the row that is the nth row of the window frame (counting from 1); null if no such row Apr2019 (11.33.3)
ntile(value any, num_buckects int, boolean, boolean) int integer ranging from 1 to the argument value, dividing the partition as equally as possible Apr2019 (11.33.3)
percent_rank(value any, boolean, boolean) double relative rank of the current row: (rank - 1) / (total partition rows - 1) Apr2019 (11.33.3)
rank(value any, boolean, boolean) int rank of the current row with gaps
row_number(value any, boolean, boolean) int number of the current row within its partition, counting from 1

In addition to above functions, some aggregate functions can be used as a window function. Aggregate functions act as window functions only when an OVER clause follows the call; otherwise they act as non-window aggregates and return a single row for the entire set.

When an aggregate function is used as a window function, it aggregates over the rows within the current row's window frame. An aggregate used with ORDER BY and the default window frame definition produces a “running sum” type of behavior, which may or may not be what's wanted. To obtain aggregation over the whole partition, omit ORDER BY or use ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING. Other frame specifications can be used to obtain other effects.

Aggregate functions which can be used as window function

Function Return type Available since
avg(numeric_expr) double Apr2019 (11.33.3)
count(col_expr any, distinct boolean) bigint or hugeint Apr2019 (11.33.3)
max(col_expr any) same as type of col_expr Apr2019 (11.33.3)
min(col_expr any) same as type of col_expr Apr2019 (11.33.3)
prod(numeric_expr) bigint or hugeint or double Apr2019 (11.33.3)
sum(numeric_expr) depends on type of numeric_expr Apr2019 (11.33.3)
   
sys.corr(numeric_a, numeric_b) double Jun2020 (11.37.7)
sys.covar_pop(numeric_a, numeric_b) double Jun2020 (11.37.7)
sys.covar_samp(numeric_a, numeric_b) double Jun2020 (11.37.7)
sys.stddev_pop(numeric_expr) double Jun2020 (11.37.7)
sys.stddev_samp(numeric_expr) double Jun2020 (11.37.7)
sys.var_pop(numeric_expr) double Jun2020 (11.37.7)
sys.var_samp(numeric_expr) double Jun2020 (11.37.7)
   
sys.group_concat(col_expr clob) clob Jun2020 (11.37.7)
sys.group_concat(col_expr clob, separator clob) clob Jun2020 (11.37.7)
listagg(col_expr varchar) varchar Jun2020 (11.37.7)
listagg(col_expr varchar, separator varchar) varchar Jun2020 (11.37.7)

See also Window Functions syntax and examples

See also Extended SQL:2011 Window Functions in MonetDB release Apr2019

You can also create your own window functions, see Create Window Function command.

To query the available window functions in your MonetDB server run query:
SELECT DISTINCT schema_id, name, func, mod, language, system FROM sys.functions WHERE type = 6 ORDER BY name;

 

Procedures

Procedures dinther Wed, 07/22/2020 - 17:34

MonetDB provides the following groups of built-in SQL procedures.

System procedures

System procedures dinther Wed, 07/22/2020 - 17:40
Procedure Description Example
sys.analyze(minmax int, samplesize bigint) create or update sys.statistics data for all tables in all schemas. When minmax is 0 the expensive unique count operation is not performed. When samplesize is > 0 only the specified sample size number of rows are analysed.
Warning: Execution could take a long time depending on the size of your database.
call sys.analyze(0, 4000)
sys.analyze(minmax int, samplesize bigint, sch string) create or update sys.statistics data for all tables data in schema sch. When minmax is 0 the expensive unique count operation is not performed. When samplesize is > 0 only the specified sample size number of rows are analysed. call sys.analyze(1, 0, 'sys')
sys.analyze(minmax int, samplesize bigint, sch string, tbl string) create or update sys.statistics data of table tbl in schema sch. When minmax is 0 the expensive unique count operation is not performed. When samplesize is > 0 only the specified sample size number of rows are analysed. call sys.analyze(1, 0, 'sys', 'statistics')
sys.analyze(minmax int, samplesize bigint, sch string, tbl string, col string) create or update sys.statistics data of column col in table tbl in schema sch. When minmax is 0 the expensive unique count operation is not performed. When samplesize is > 0 only the specified sample size number of rows are analysed. call sys.analyze(1, 0, 'tst', 'weblog', 'url')
sys.clearrejects() clear the rejects table from possible errors encoutered from previous COPY INTO tbl FROM 'datafile.csv' ... BEST EFFORT execution call sys.clearrejects()
sys.createorderindex(schm string, tabl string, col string) create an ordered index on a specific column. The index name and location will be determined based on the schema name, table name and column name. call sys.createorderindex('schemaX', 'tableY', 'columnZ')
sys.droporderindex(schm string, tabl string, col string) remove a previously created ordered index call sys.droporderindex('schemaX', 'tableY', 'columnZ')
sys.evalalgebra(ra_stmt string, opt bool) ?? call sys.evalalgebra(a, true)
sys.flush_log() flush the query log to disk call sys.flush_log()
sys.hot_snapshot(tarfile string) write a snapshot (a binary copy of all data files) of the database into a (potentially very big) tar file. Optionally the tar file can be compressed by adding an extra file name suffix .lz4 or .gz or .bz2 or .xz. See HotBackup for details. call sys.hot_snapshot('/tmp/db_x_2020_06_30.tar.gz');

call sys.hot_snapshot(R'D:\Temp\voc_backup_2020_07_27.tar.gz');
sys.pause(tag bigint) pause the execution of a (long) running statement using its tag id.
run query: select * from sys.queue; to list the running statements
call sys.pause(842)
sys.querylog(filename string) use file filename to log queries call sys.querylog('/tmp/queries_log_2020_07_27.txt')
sys.resume(tag bigint) resume execution of a previouly paused statement call sys.resume(842)
sys.resume_log_flushing() resume logging queries of a previouly suspended query log call sys.resume_log_flushing()
sys.reuse(sch string, tab string) ?? reuse table tab in schema sch call sys.reuse('schemaX', 'tableY')
sys.shrink(sys string, tab string) ?? shrink table tab in schema sch call sys.shrink('schemaX', 'tableY')
sys.shutdown(delay tinyint) shutdown server after delay seconds when no more clients are connected call sys.shutdown(20)
sys.shutdown(delay tinyint, force bool) shutdown server after delay seconds with or without force call sys.shutdown(20, true)
sys.stop(tag bigint) stop/abort execution of a running statement call sys.stop(842)
sys.storagemodelinit() initialize the data for the storage model call sys.storagemodelinit()
sys.suspend_log_flushing() suspend logging of queries call sys.suspend_log_flushing()
sys.vacuum(sch string, tab string) vacuum table tab in schema sch call sys.vacuum('schemaX', 'tableY')

 

Session procedures

Session procedures dinther Wed, 07/22/2020 - 19:09
Procedure Description Example
sys.setmemorylimit("limit" int) set memory limit in MB for current session. 0 will disable any memory limit. call sys.setmemorylimit(500)
sys.setoptimizer("optimizer" string) change optimizer pipeline for current session call sys.setoptimizer('oltp_pipe')
sys.setprinttimeout("timeout" integer) set print timeout in milliseconds for current session. 0 will disable timing out. call sys.setprinttimeout(1000)
sys.setquerytimeout("query" int) set query execution timeout in milliseconds for current session. 0 will disable timing out. call sys.setquerytimeout(8000)
sys.setsession("timeout" bigint) set session timeout in milliseconds for current session
Warning: This procedure is Deprecated as of Jun2020 (11.37.7). Use sys.setsessiontimeout("timeout") instead.
call sys.setsession(30000)
sys.setsessiontimeout("timeout" int) set session timeout in milliseconds for current session. 0 will disable timing out. call sys.setsessiontimeout(30000)
sys.settimeout("query" bigint) set query timeout in milliseconds for current session
Warning: This procedure is Deprecated as of Jun2020 (11.37.7). Use sys.setquerytimeout("query") instead.
call sys.settimeout(8000)
sys.settimeout("query" bigint, "session" bigint) set query and session timeout in milliseconds for current session
Warning: This procedure is Deprecated as of Jun2020 (11.37.7). Use sys.setquerytimeout("query") and sys.setsessiontimeout("timeout") instead.
call sys.settimeout(8000, 30000)
sys.setworkerlimit("limit" int) set number of worker threads limit for current session. 0 will disable any limit of worker threads. call sys.setworkerlimit(16)

 

Session procedures for monetdb admin user only

To list all sessions info in your MonetDB server first run query: SELECT * FROM sys.sessions;

Procedure Description Example
sys.setmemorylimit(sessionid int, "limit" int) set memory limit in MB for session with sessionid. 0 will disable any memory limit.
You will need monetdb admin privileges.
call sys.setmemorylimit(2, 500)
sys.setoptimizer(sessionid int, "optimizer" string) change optimizer pipeline for session with sessionid.
You will need monetdb admin privileges.
call sys.setoptimizer(2, 'minimal_pipe')
sys.setquerytimeout(sessionid int, "query" int) set query execution timeout in milliseconds for session with sessionid. 0 will disable timing out.
You will need monetdb admin privileges.
call sys.setquerytimeout(2, 8000)
sys.setsessiontimeout(sessionid int, "timeout" int) set session timeout in milliseconds for session with sessionid. 0 will disable timing out.
You will need monetdb admin privileges.
call sys.setsessiontimeout(2, 30000)
sys.setworkerlimit(sessionid int, "limit" int) set number of worker threads limit for session with sessionid. 0 will disable any limit of worker threads.
You will need monetdb admin privileges.
call sys.setworkerlimit(2, 16)
sys.stopsession(sessionid int) stop session with sessionid.
Caution: This procedure stops the specified session which may be undesired.
You will need monetdb admin privileges.
call sys.stopsession(2)

 

Querylog procedures

Querylog procedures dinther Thu, 07/30/2020 - 22:45
Procedure Description Example
sys.querylog_disable() stop logging queries call sys.querylog_disable();
sys.querylog_empty() empty the query log call sys.querylog_empty();
sys.querylog_enable() start logging queries call sys.querylog_enable();
sys.querylog_enable(threshold_in_ms integer) start logging queries but only the ones which execution time exceeds the threshold_in_ms time. call sys.querylog_enable(123);

 

These procedures are used with: QueryTiming / QueryHistory.

 

Profiler procedures

Profiler procedures dinther Thu, 07/23/2020 - 15:20
Procedure Description Example
profiler.setheartbeat(beat int) Set heart beat performance tracing call profiler.setheartbeat(100)
profiler.setlimit(lim integer) Set profiler limit call profiler.setlimit(500)
profiler.start() Start offline performance profiling call profiler.start()
profiler.stop() Stop offline performance profiling call profiler.stop()

Note: You must include the profiler. prefix for these procedures and functions (see examples) in order to work properly.

Profiler functions

Function Return type Description Example Result
profiler.getlimit() int Get profiler limit select profiler.getlimit() 500

 

Logging procedures

Logging procedures dinther Thu, 07/23/2020 - 15:51
Procedure Description Example
logging.flush() Flush the buffer explicitly call logging.flush()
logging.resetadapter() Resets the adapter back to the default: BASIC call logging.resetadapter()
logging.resetcomplevel(comp_id string) Resets the log level for a specific component back to the default: ERROR call logging.resetcomplevel('SQL_REWRITER')
logging.resetflushlevel() Resets the flush level back to the default: INFO call logging.resetflushlevel()
logging.resetlayerlevel(layer_id string) Resets the log level for a specific layer back to the default: ERROR call logging.resetlayerlevel('GDK_ALL')
logging.setadapter(adapter_id string) Sets the adapter call logging.setadapter('BASIC')
logging.setcomplevel(comp_id string, level_id string) Sets the log level for a specific component call logging.setcomplevel('SQL_PARSER', 'DEBUG')
logging.setflushlevel(level_id string) Sets the flush level call logging.setflushlevel('WARNING')
logging.setlayerlevel(layer_id string, level_id string) Sets the log level for a specific layer call logging.setlayerlevel('MAL_ALL', 'DEBUG')

Note: You must include the logging. prefix for these procedures and functions (see examples) in order to work properly.

For explanation how to use the logging procedures see Tracer Tutorial

Logging functions

Function Return type Description Example Result
logging.compinfo() table("id" int, "component" string, "log_level" string) Returns a table with for each component its id and current logging level select * from logging.compinfo()
id component log_level
0 ACCELERATOR M_ERROR
1 ALGO M_ERROR
2 ALLOC M_ERROR
3 BAT_ M_ERROR
4 CHECK_ M_ERROR
5 DELTA M_ERROR
6 HEAP M_ERROR
7 IO_ M_ERROR
8 PAR M_ERROR
9 PERF M_ERROR
10 TEM M_ERROR
11 THRD M_ERROR
12 GEOM M_ERROR
13 LIDAR M_ERROR
14 FITS M_ERROR
15 SHP M_ERROR
16 SQL_PARSER M_ERROR
17 SQL_TRANS M_ERROR
18 SQL_REWRITER M_ERROR
19 SQL_EXECUTION M_ERROR
20 SQL_STORE M_ERROR
21 MAL_WLC M_ERROR
22 MAL_REMOTE M_ERROR
23 MAL_MAPI M_ERROR
24 MAL_SERVER M_ERROR
25 MAL_OPTIMIZER M_ERROR
26 GDK M_ERROR

For convenience there is also a system view logging.compinfo which selects all from logging.compinfo().
So you can also use query: SELECT * FROM logging.compinfo to get the same result.

 

Capture and Replay procedures

Capture and Replay procedures dinther Thu, 07/23/2020 - 16:56

Workload Capture procedures

Procedure Description Example
wlc.beat(duration int) set beat call wlc.beat(123)
wlc.flush() flush capture data call wlc.flush()
wlc.master(path string) set master with path call wlc.master('dbfarm/dbfree')
wlc.master() set master call wlc.master()
wlc.stop() stop capture call wlc.stop()

Note: You must include the wlc. prefix for these procedures and functions (see examples) in order to work properly.

Workload Capture functions

Function Return type Description Example Result
wlc.clock() clob get clock as string select wlc.clock()  
wlc.tick() bigint get tick select wlc.tick()  

 

 

Workload Replay procedures

Procedure Description Example
wlr.accept() accept the error reported an skip the record call wlr.accept()
wlr.beat(duration integer) control the interval for replication call wlr.beat(123)
wlr.master(dbname string) set database name of master call wlr.master('dbfree')
wlr.replicate(id integer) run replicator until condition is met call wlr.replicate(12)
wlr.replicate(id smallint) run replicator until condition is met call wlr.replicate(12)
wlr.replicate(id tinyint) run replicator until condition is met call wlr.replicate(12)
wlr.replicate(pointintime timestamp) run replicator until condition is met call wlr.replicate(timestamp '2020-07-25 09:00:00')
wlr.replicate(id bigint) run replicator until condition is met call wlr.replicate(12)
wlr.replicate() run it forever call wlr.replicate()
wlr.stop() stop replicator call wlr.stop()

Note: You must include the wlr. prefix for these procedures and functions (see examples) in order to work properly.

Workload Replay functions

Function Return type Description Example Result
wlr.clock() clob get clock as string select wlr.clock()  
wlr.tick() bigint get tick select wlr.tick()  

 

Programming SQL

Programming SQL mk Thu, 06/30/2011 - 16:39

SQL comes with  imperative programming concepts, such as variable declarations, compound statements, while-loops, and conditional-statements. The are grouped into procedures, functions, and triggers, which strongly differ in their execution paradigm and semantics.

Procedure definition

Procedure definition mk Sat, 05/28/2011 - 21:42

func_def:
       CREATE [OR REPLACE] PROCEDURE qname '(' [ paramlist] ')' routine_body
     | CREATE [OR REPLACE] PROCEDURE qname '(' [ paramlist] ')' EXTERNAL NAME external_function_name

routine_body:
      procedure_statement
     | BEGIN procedure_statement_list END
     | BEGIN ATOMIC procedure_statement_list END

procedure_statement:
       update_statement
     | declare_statement
     | set_statement
     | control_statement
     | select_statement_single_row

Note: CREATE ... EXTERNAL NAME ... is a MonetDB language extension.

Function definitions

Function definitions mk Sat, 03/27/2010 - 22:47

The SQL standard allows to create SQL functions. MonetDB supports this feature. The syntax to create a function is:

func_def:
     CREATE [OR REPLACE] FUNCTION qname '(' [ paramlist ] ')' RETURNS func_data_type  routine_body
   | CREATE [OR REPLACE] FUNCTION qname '(' [ paramlist ] ')' RETURNS func_data_type EXTERNAL NAME external_function_name
   | CREATE [OR REPLACE] FUNCTION qname '(' [ paramlist ] ')' RETURNS func_data_type LANGUAGE language_keyword '{' function_impl_code '}'
   | CREATE [OR REPLACE] FILTER FUNCTION qname '(' [ paramlist ] ')' RETURNS func_data_type EXTERNAL NAME external_function_name
   | CREATE [OR REPLACE] AGGREGATE qname '(' [ paramlist ] ')' RETURNS func_data_type EXTERNAL NAME external_function_name
   | CREATE [OR REPLACE] AGGREGATE qname '(' [ paramlist ] ')' RETURNS func_data_type LANGUAGE language_keyword '{' function_impl_code '}'
   | CREATE [OR REPLACE] WINDOW [FUNCTION] qname '(' [ paramlist ] ')' RETURNS func_data_type EXTERNAL NAME external_function_name

func_data_type:
      TABLE '(' column data_type ',' ... ')'
    | data_type

language_keyword:
    C | CPP | R | PYTHON | PYTHON_MAP | PYTHON3 | PYTHON3_MAP

External functions provide a convenient bridge between SQL and MAL. This way also a bridge can be established with dynamically loaded functions written in C. Any SQL function signature can be bound to MAL function or command.

The example below illustrates a binding to the a function that produces a tabular overview of the BAT catalog.

CREATE FUNCTION bbp ()
RETURNS TABLE (id int, name string, htype string,
    string, count BIGINT, refcnt int, lrefcnt int,
    location string, heat int, dirty string, status string,
    kind string)
EXTERNAL NAME sql.bbp;

A table returning function should be implemented as MAL function that returns a series of synchronized BATs.

FUNCTION bbp():bat[:str,:bat];
   b := bat.new(:str,:bat,12);
   ns := bbp.getNames();
   ri := algebra.markT(ns, 0:oid);
   ...
   kind := algebra.markH(ikind, 0:oid);
   bat.insert(b, "kind", kind);
   RETURN b;
END bbp;

Two useful Microsoft functions supported are 'STUFF' and 'ROUND'. 

SQL> SELECT MS_ROUND(10.0, 1, 0);

The SQL definition for MS_ROUND is:

CREATE OR REPLACE FUNCTION MS_ROUND(num float, precision int, truncat int)
RETURNS float
BEGIN
   IF (truncat = 0)
   THEN RETURN ROUND(num, precision);
   ELSE RETURN TRUNCATE(num, precision);
   END IF;
END;

The SQL definition for MS_STUFF is:

CREATE FUNCTION MS_STUFF( s1 varchar(32), st int, len int, s3 varchar(32))
RETURNS varchar(32)
BEGIN
   DECLARE res varchar(32), aux varchar(32);
   DECLARE ofset int;
   SET ofset = 0;
   SET res = SUBSTRING(s1,ofset,st-1);
   SET res = res || s3;
   SET ofset = LENGTH(s1)-len;
   SET aux = SUBSTRING(s1,ofset, len);
   SET res = res || aux;
   RETURN res;
END;

 

Note: CREATE FILTER FUNCTION is a MonetDB language extension. The SQL standard does not provide for user-defined filter functions such as my_like ... .

Note: CREATE AGGREGATE is a MonetDB language extension. The SQL standard does not provide for user-defined aggregate functions.

Note: CREATE WINDOW is a MonetDB language extension. The SQL standard does not provide for user-defined window functions.

Note: CREATE ... EXTERNAL ... and CREATE ... LANGUAGE ... are MonetDB language extensions.

Note: The language keywords PYTHON2 and PYTHON2_MAP are no longer supported from release Jun2020 (11.37.7) onwards.

Trigger definitions

Trigger definitions mk Sun, 03/28/2010 - 23:32

Triggers are a convenient programming abstraction. They are activated at transaction commit based on updates to the base tables.

trigger_def: CREATE [ OR REPLACE ] TRIGGER qname  trigger_action_time  trigger_event  ON  ident  opt_referencing_list  triggered_action

trigger_action_time: BEFORE | AFTER

trigger_event: INSERT | DELETE | TRUNCATE | UPDATE | UPDATE OF ident ','...

opt_referencing_list: [ REFERENCING old_or_new_values_alias ... ]

old_or_new_values_alias:
      OLD [ ROW ] [ AS ] ident
    | NEW [ ROW ] [ AS ] ident
    | OLD TABLE [ AS ] ident
    | NEW TABLE [ AS ] ident

triggered_action:
     opt_for_each [ WHEN search_condition ] triggered_statement

opt_for_each: /* default is for each statement */ | FOR EACH ROW | FOR EACH STATEMENT

triggered_statement:
     trigger_procedure_statement
   | BEGIN ATOMIC trigger_procedure_statement_list END

trigger_procedure_statement:
     update_statement
   | declare_statement
   | set_statement
   | control_statement
   | select_statement_single_row

Example The following example provides a glimpse of their functionality:

create table t1 (id int, name varchar(1024));
--test FOR EACH STATEMENT (default one)
insert into t1 values(10, 'monetdb');
insert into t1 values(20, 'monet');
create trigger test5
after update on t1
for each statement
when id >0 insert into t1 values(4, 'update_when_statement_true');

All trigger definitions are considered together at the transaction commit. There is no a priori defined order in which they run. Each may in turn activate new triggers, but each trigger definition is also executed only once per transaction commit.

Variables

Variables mk Sat, 03/27/2010 - 22:55

MonetDB/SQL supports session variables declared by the user. They are indistinguishable from table and column names and can be used anywhere a literal constant is allowed.

declare_statement:
     DECLARE variable_list
   | DECLARE table_def

variable_list:
     ident [ ',' ... ] data_type
   | variable_list ',' ident [ ',' ... ] data_type

set_statement:
     SET ident '=' simple_atom
   | SET SESSION AUTHORIZATION ident
   | SET SCHEMA ident
   | SET USER '=' ident
   | SET CURRENT_USER '=' ident
   | SET SESSION_USER '=' ident
   | SET ROLE ident
   | SET TIME ZONE LOCAL
   | SET TIME ZONE interval_expression

Examples

sql>DECLARE high integer;
sql>DECLARE n varchar(256);
sql>SET high=4000;
sql>SET n='monetdb'
sql>SET trace = 'ticks,stmt'
sql>SELECT count(*) from tables where id > high;
+--------+
| count_ |
+========+
| 2      |
+--------+

The SQL variables (and environment variables) can be accessed through predefined table returning functions var() and env(). The debug variable settings are defined in the MonetDB config file. The current_* variables are SQL environment settings. The trace variables is defined in the TRACE command.

sql>select * from var();
+------------------+
| name             |
+==================+
| debug            |
| cache            |
| current_schema   |
| current_user     |
| current_role     |
| optimizer        |
| current_timezone |
| last_id          |
| rowcnte            |
+------------------+

Flow of control

Flow of control mk Fri, 04/02/2010 - 12:48

The persistent stored module facility of SQL provides a method to encode complex algorithm using well-known programming features.

control_statement:
     CALL func_ref
   | CALL routine_name '(' argument_list ')'
   | while_statement
   | if_statement
   | case_statement
   | RETURN return_value

case_statement:
    CASE scalar_exp when_statement ... [ ELSE procedure_statement_list ] END CASE
  | CASE when_search_statement ... [ ELSE procedure_statement_list ] END CASE

when_statement: WHEN scalar_exp THEN procedure_statement_list

when_search_statement: WHEN search_condition THEN procedure_statement_list

if_statement: IF search_condition THEN procedure_statement_list if_opt_else END IF

if_opt_else:
      /* empty */
   | ELSE procedure_statement_list
   | ELSEIF search_condition THEN procedure_statement_list if_opt_else

while_statement:
    [ ident ':' ] WHILE search_condition DO procedure_statement_list END WHILE [ ident ]

return_statement: RETURN return_value

return_value:
      select_no_parens_orderby
    | search_condition
    | TABLE '(' select_no_parens_orderby ')'
    | NULL

Transactions

Transactions mk Sat, 03/27/2010 - 22:49

MonetDB/SQL supports a multi-statement transaction scheme marked by START TRANSACTION and closed with either COMMIT or ROLLBACK. The session variable AUTOCOMMIT can be set to true (default) if each SQL statement should be considered an independent transaction.

In the AUTOCOMMIT mode, you can use START TRANSACTION and COMMIT/ROLLBACK to indicate transactions containing multiple SQL statements.  In this case, AUTOCOMMIT is automatically disabled by a START TRANSACTION, and reenabled by a COMMIT or ROLLBACK.

If AUTOCOMMIT mode is OFF, the START TRANSACTION is implicit, and you should only use COMMIT/ROLLBACK.

WARNING. The transaction management scheme is based on optimistic concurrency control. It provides each transaction with a consistent view on the database, but updates are collected in an addendum processed on transaction commit. If at commit time it can be assured that the data prepared for update affects tables has not changed in the mean time, the results are merged. Otherwise the transaction is aborted.
This optimistic concurrency scheme is particularly useful for query dominant environments. It negatively affects long running transactions which concurrently are affected by updates on their underlying tables. The same holds for applications that tries to perform concurrent updates from multiple threads in a single application. They should be internally serialized by the application to avoid unexpected transaction aborts.

WARNING. Optimistic concurrency control may be confusing for those who built online-transaction applications, because the granularity of the concurrency control scheme will show higher then expected transaction failures. There is not a locking schema to avoid this. Applications may have to resort to serial execution.

WARNING. The tuples being deleted are only marked as such. They do not reduce the table size. You will even experience after many updates that your queries will run slower, because each query first has to establish a consistent private view on the database by inspection of the delete/update lists. It calls for a vacuum cleaning algorithm in the background, which is not yet available.

Runtime features

Runtime features mk Sun, 03/28/2010 - 23:51

The SQL statement modifiers provide system specific information over e.g. relational query plan, MAL execution plan, performance, and access to the debugger.

EXPLAIN SQL STMT

EXPLAIN SQL STMT mk Sun, 03/28/2010 - 23:24

The intermediate mal code produced by the SQL compiler can be made visible using the explain statement modifier. It gives a detailed description of the actions taken to produce the answer. The example below illustrates what you can expect when a simple "select count(*) from sys.tables" query starts with the explain modifier. The output strongly depends on the optimizer pipeline. The details of this program are better understood when you have read the MAL reference.

sql>select count(*) from sys.tables;
+-----+
| %6  |
+=====+
|  93 |
+-----+
1 tuple

sql>explain select count(*) from sys.tables;
+--------------------------------------------------------------------------------------------------------------------+
| mal                                                                                                                |
+====================================================================================================================+
| function user.s6_2():void;                                                                                         |
|     X_1:void := querylog.define("explain select count(*) from sys.tables;":str, "default_pipe":str, 33:int);       |
| barrier X_106:bit := language.dataflow();                                                                          |
|     X_38:bat[:lng] := bat.new(nil:lng);                                                                            |
|     X_4:int := sql.mvc();                                                                                          |
|     X_18:bat[:sht] := sql.bind(X_4:int, "sys":str, "_tables":str, "type":str, 0:int);                              |
|     C_5:bat[:oid] := sql.tid(X_4:int, "sys":str, "_tables":str);                                                   |
|     C_91:bat[:oid] := algebra.thetaselect(X_18:bat[:sht], C_5:bat[:oid], 2:sht, "!=":str);                         |
|     (X_21:bat[:oid], X_22:bat[:sht]) := sql.bind(X_4:int, "sys":str, "_tables":str, "type":str, 2:int);            |
|     C_92:bat[:oid] := algebra.thetaselect(X_22:bat[:sht], nil:bat[:oid], 2:sht, "!=":str);                         |
|     X_20:bat[:sht] := sql.bind(X_4:int, "sys":str, "_tables":str, "type":str, 1:int);                              |
|     C_94:bat[:oid] := algebra.thetaselect(X_20:bat[:sht], C_5:bat[:oid], 2:sht, "!=":str);                         |
|     C_27:bat[:oid] := sql.subdelta(C_91:bat[:oid], C_5:bat[:oid], X_21:bat[:oid], C_92:bat[:oid], C_94:bat[:oid]); |
|     X_31:lng := aggr.count(C_27:bat[:oid]);                                                                        |
|     X_37:bat[:lng] := sql.single(X_31:lng);                                                                        |
|     C_32:bat[:oid] := sql.tid(X_4:int, "tmp":str, "_tables":str);                                                  |
|     X_36:lng := aggr.count(C_32:bat[:oid]);                                                                        |
|     X_40:bat[:lng] := bat.append(X_38:bat[:lng], X_37:bat[:lng], true:bit);                                        |
|     X_42:bat[:lng] := bat.append(X_40:bat[:lng], X_36:lng, true:bit);                                              |
|     X_43:lng := aggr.sum(X_42:bat[:lng]);                                                                          |
|     language.pass(C_5:bat[:oid]);                                                                                  |
| exit X_106:bit;                                                                                                    |
|     sql.resultSet(".%6":str, "%6":str, "bigint":str, 64:int, 0:int, 7:int, X_43:lng);                              |
| end user.s6_2;                                                                                                     |
...
+--------------------------------------------------------------------------------------------------------------------+
52 tuples

 

The SQL compiler maintains a cache of compiled (or prepared) queries. Each query is looked up in this cache based on an expression pattern match where the constants may take on different values. If it doesn't exist, the query is converted into a code block and stored in the module user.s0.

The call to the cached function is included in a wrapper function main, which is the only piece of code produced if the query is used more than once. The query cache disappears when the server is brought to a halt.

     +----------------------------+
     | function user.main():void; |
     |     mdb.start();           |
     |     user.s3_2();           |
     |     mdb.stop();            |
     | end main;                  |
     +----------------------------+

TRACE SQL STMT

TRACE SQL STMT mk Sun, 03/28/2010 - 23:27

A performance trace can be obtained using the TRACE statement modifier. It collects  trace information in a table accessed by sys.tracelog(), which can be queried using ordinary SQL statements. This internal temporary table is reset each new query being traced. Its definition is given below:

CREATE FUNCTION sys.tracelog()
    RETURNS table (
        ticks bigint,       -- time in microseconds
        stmt string         -- actual MAL statement executed
    )
   EXTERNAL NAME sql.dump_trace;

CREATE VIEW sys.tracelog AS SELECT * FROM sys.tracelog();

For more detailed performance analysis consider using the Stethoscpe.

DEBUG SQL STMT

DEBUG SQL STMT mk Sun, 03/28/2010 - 23:26

The SQL statements are translated into MAL programs, which are optimized and stored away in an user module. The generated code can be inspected with the MAL debugger.

The example below illustrates the start of such a session:

>debug select count(*) from tables;
#    mdb.start()
mdb>next
#    user.s1_0()
mdb>next
#    _2:bat[:oid,:int]  := sql.bind(_3="sys", _4="ptables", _5="id", _6=0)
mdb>next
#    _8:bat[:oid,:int]  := sql.bind(_3="sys", _4="ptables", _5="id", _9=1)
mdb> ...
mdb>help
next             -- Advance to next statement
continue         -- Continue program being debugged
catch            -- Catch the next exception 
break [<var>]    -- set breakpoint on current instruction or <var>
delete [<var>]   -- remove break/trace point <var>
debug <int>      -- set kernel debugging mask
dot <obj> [<file>]     -- generate the dependency graph for MAL block
step             -- advance to next MAL instruction
module           -- display the module signatures
atom             -- show atom list
finish           -- finish current call
exit             -- terminate execution
quit             -- turn off debugging
list <obj>       -- list a MAL program block
list #  [+#],-#  -- list current program block slice
List <obj> [#]   -- list MAL block with type information[slice]
list '['<step>']'  -- list program block after optimizer step
List #[+#],-#    -- list current program block slice
var  <obj>       -- print symbol table for module
optimizer <obj>  -- display optimizer steps
print <var>      -- display value of a variable
print <var> <cnt>[<first>]   -- display BAT chunk
info <var>       -- display bat variable properties
run              -- restart current procedure
where            -- print stack trace
down             -- go down the stack
up               -- go up the stack
trace <var>      -- trace assignment to variables
help             -- this message

PLAN SQL STMT

PLAN SQL STMT mk Fri, 12/26/2014 - 13:59

The relational plan used in the SQL optimizer can be obtained by prepending the query with the keyword PLAN.

sql>plan select count(*) from tables;
+----------------------------------------------------------------------------+
| rel                                                                        |
+============================================================================+
| project (                                                                  |
| | group by (                                                               |
| | | union (                                                                |
| | | | group by (                                                           |
| | | | | project (                                                          |
| | | | | | select (                                                         |
| | | | | | | table(sys._tables) [ "_tables"."id", "_tables"."type" ] COUNT  |
| | | | | | ) [ "_tables"."type" != smallint "2" ]                           |
| | | | | ) [ "_tables"."id" as "tables"."id" ]                              |
| | | | ) [  ] [ sys.count() NOT NULL as "L41"."L41" ],                      |
| | | | group by (                                                           |
| | | | | project (                                                          |
| | | | | | table(tmp._tables) [ "_tables"."id" ] COUNT                      |
| | | | | ) [ "_tables"."id" as "tables"."id" ]                              |
| | | | ) [  ] [ sys.count() NOT NULL as "L41"."L41" ]                       |
| | | ) [ "L41"."L41" ]                                                      |
| | ) [  ] [ sys.sum no nil ("L41"."L41") as "L41"."L41" ]                   |
| ) [ "L41"."L41" NOT NULL ]                                                 |
+----------------------------------------------------------------------------+
18 tuples
clk: 1.158 ms

PREPARE SQL STMT

PREPARE SQL STMT mk Sun, 10/13/2013 - 16:33

The PREPARE statement compiles an SQL statement into its execution plan on the server. The plan is given a unique id number and stored in the query cache of the user session. A subsequent EXECUTE command retrieves it from the cache, applies the given parameter values and executes it. When done you can close a prepared statement (or ALL) via DEALLOCATE command (available from release Jun2020 (11.37.7) onwards).

PREPARE statement executions can be given positional arguments to replace any literal constant in the query. Each argument is denoted with a '?'.

sql>prepare select * from tables where name = ?;
execute prepared statement using: EXEC 15(...)
+----------+---------+-------+--------+--------+---------------+
| type     | digits  | scale | schema | table  | column        |
+==========+=========+=======+========+========+===============+
| int      |      32 |     0 |        | tables | id            |
| varchar  |    1024 |     0 |        | tables | name          |
| int      |      32 |     0 |        | tables | schema_id     |
| varchar  | 1048576 |     0 |        | tables | query         |
| smallint |      16 |     0 |        | tables | type          |
| boolean  |       1 |     0 |        | tables | system        |
| smallint |      16 |     0 |        | tables | commit_action |
| smallint |      16 |     0 |        | tables | access        |
| tinyint  |       8 |     0 |        | tables | temporary     |
| varchar  |    1024 |     0 | null   | null   | null          |
+----------+---------+-------+--------+--------+---------------+
10 tuples

sql>select * from sys.prepared_statements;
+-----------+----------+-------------+----------------------------------------------+----------------------------+
| sessionid | username | statementid | statement                                    | created                    |
+===========+==========+=============+==============================================+============================+
|         1 | monetdb  |          15 | prepare select * from tables where name = ?; | 2020-06-18 18:25:47.499219 |
+-----------+----------+-------------+----------------------------------------------+----------------------------+
1 tuple

sql>select * from sys.prepared_statements_args;
+-------------+----------+-------------+------------+-------+--------+--------+--------+---------------+
| statementid | type     | type_digits | type_scale | inout | number | schema | table  | column        |
+=============+==========+=============+============+=======+========+========+========+===============+
|          15 | int      |          32 |          0 |     0 |      0 | null   | tables | id            |
|          15 | varchar  |        1024 |          0 |     0 |      1 | null   | tables | name          |
|          15 | int      |          32 |          0 |     0 |      2 | null   | tables | schema_id     |
|          15 | varchar  |     1048576 |          0 |     0 |      3 | null   | tables | query         |
|          15 | smallint |          16 |          0 |     0 |      4 | null   | tables | type          |
|          15 | boolean  |           1 |          0 |     0 |      5 | null   | tables | system        |
|          15 | smallint |          16 |          0 |     0 |      6 | null   | tables | commit_action |
|          15 | smallint |          16 |          0 |     0 |      7 | null   | tables | access        |
|          15 | tinyint  |           8 |          0 |     0 |      8 | null   | tables | temporary     |
|          15 | varchar  |        1024 |          0 |     1 |      9 | null   | null   | null          |
+-------------+----------+-------------+------------+-------+--------+--------+--------+---------------+
10 tuples

sql>execute 15('_tables');
+------+---------+-----------+-------+------+--------+---------------+--------+-----------+
| id   | name    | schema_id | query | type | system | commit_action | access | temporary |
+======+=========+===========+=======+======+========+===============+========+===========+
| 2067 | _tables |      2000 | null  |   10 | true   |             0 |      0 |         0 |
| 2115 | _tables |      2114 | null  |   10 | true   |             2 |      0 |         0 |
+------+---------+-----------+-------+------+--------+---------------+--------+-----------+
2 tuples

sql>exec 15('table_types');
+------+-------------+-----------+-------+------+--------+---------------+--------+-----------+
| id   | name        | schema_id | query | type | system | commit_action | access | temporary |
+======+=============+===========+=======+======+========+===============+========+===========+
| 7322 | table_types |      2000 | null  |   10 | true   |             0 |      1 |         0 |
+------+-------------+-----------+-------+------+--------+---------------+--------+-----------+
1 tuple

sql>deallocate 15;
operation successful
sql>

As shown above you can query prepared statements information from system views sys.prepared_statements and sys.prepared_statements_args (available from release Jun2020 (11.37.7) onwards).

Performance Optimization

Performance Optimization giulia Mon, 06/15/2020 - 19:00

under construction

Optimizer Pipelines

Optimizer Pipelines mk Sat, 06/05/2010 - 08:20

The code produced by MonetDB/SQL is massaged by an optimizer pipeline.  The pipeline to be used is identified by the SQL global session variable optimizer, which can be modified using a SQL assignment, e.g. the minimal optimizer pipeline is set using:

sql> select optimizer;
+--------------+
| single value |
+==============+
| default_pipe |
+--------------+
sql> set optimizer='minimal_pipe';
sql> select optimizer;
+--------------+
| single value |
+==============+
| minimal_pipe |
+--------------+

Each pipeline consists of a sequence of MAL optimizer function calls that inspect and transform the plan for better execution. The preferred optimizer can be changed by either providing its name or the complete MAL function sequence.  For example the minimal pipe can be set also using:

sql> set optimizer='optimizer.inline();optimizer.remap();optimizer.deadcode();optimizer.multiplex();
optimizer.generator();optimizer.profiler();optimizer.candidates();optimizer.garbageCollector();';

The final result of the optimizer steps becomes visible using the SQL EXPLAIN statement modifier. Alternatively, the SQL DEBUG statement modifier in combination with the 'o' command provides access to the intermediate optimizer results.

Several optimizer pipelines are pre-defined in the MonetDB sources. They represent ongoing development activities and experimental code. Their scope of applicability and/or stability has not reached a satisfactory level to include it in the default pipeline. The predefined optimizer pipelines can be inspected as follows:

sql> select * from sys.optimizers;

name description & definition status
minimal_pipe The minimal pipeline necessary by the server to operate correctly. stable
  optimizer.inline();optimizer.remap();optimizer.deadcode();optimizer.multiplex();optimizer.generator();
optimizer.profiler();optimizer.candidates();optimizer.garbageCollector();
default_pipe The default pipeline contains the mitosis-mergetable-reorder optimizers, aimed at large tables and improved access locality. stable
  optimizer.inline();optimizer.remap();optimizer.costModel();optimizer.coercions();optimizer.aliases();
optimizer.evaluate();optimizer.emptybind();optimizer.pushselect();optimizer.aliases();optimizer.mitosis();
optimizer.mergetable();optimizer.deadcode();optimizer.aliases();optimizer.constants();optimizer.commonTerms();
optimizer.projectionpath();optimizer.deadcode();optimizer.reorder();optimizer.matpack();optimizer.dataflow();
optimizer.querylog();optimizer.multiplex();optimizer.generator();optimizer.profiler();optimizer.candidates();
optimizer.deadcode();optimizer.postfix();optimizer.wlc();optimizer.garbageCollector();
oltp_pipe The pipeline optimised for online transaction processing. stable
  optimizer.inline();optimizer.remap();optimizer.costModel();optimizer.coercions();optimizer.evaluate();
optimizer.emptybind();optimizer.pushselect();optimizer.aliases();optimizer.mitosis();optimizer.mergetable();
optimizer.deadcode();optimizer.aliases();optimizer.constants();optimizer.commonTerms();
optimizer.projectionpath();optimizer.deadcode();optimizer.reorder();optimizer.matpack();optimizer.dataflow();
optimizer.querylog();optimizer.multiplex();optimizer.generator();optimizer.profiler();optimizer.candidates();
optimizer.deadcode();optimizer.postfix();optimizer.oltp();optimizer.wlc();optimizer.garbageCollector();
volcano_pipe The pipeline to optimize queries for volcano style processing. stable
  optimizer.inline();optimizer.remap();optimizer.costModel();optimizer.coercions();optimizer.aliases();
optimizer.evaluate();optimizer.emptybind();optimizer.pushselect();optimizer.aliases();optimizer.mitosis();
optimizer.mergetable();optimizer.deadcode();optimizer.aliases();optimizer.constants();optimizer.commonTerms();
optimizer.projectionpath();optimizer.deadcode();optimizer.reorder();optimizer.matpack();optimizer.dataflow();
optimizer.querylog();optimizer.multiplex();optimizer.generator();optimizer.volcano();optimizer.profiler();
optimizer.candidates();optimizer.deadcode();optimizer.postfix();optimizer.wlc();optimizer.garbageCollector();
no_mitosis_pipe The no_mitosis pipeline is identical to the default pipeline, except that optimizer mitosis is omitted. It is used mainly to make some tests work deterministically, and to check/debug whether "unexpected" problems are related to mitosis (and/or mergetable). stable
  optimizer.inline();optimizer.remap();optimizer.costModel();optimizer.coercions();optimizer.aliases();
optimizer.evaluate();optimizer.emptybind();optimizer.pushselect();optimizer.aliases();optimizer.mergetable();
optimizer.deadcode();optimizer.aliases();optimizer.constants();optimizer.commonTerms();
optimizer.projectionpath();optimizer.deadcode();optimizer.reorder();optimizer.matpack();optimizer.dataflow();
optimizer.querylog();optimizer.multiplex();optimizer.generator();optimizer.profiler();optimizer.candidates();
optimizer.deadcode();optimizer.postfix();optimizer.wlc();optimizer.garbageCollector();
sequential_pipe The sequential pipeline is identical to the default pipeline, except that optimizers mitosis & dataflow are omitted. It is used mainly to make some tests work deterministically, i.e., avoid ambigious output, by avoiding parallelism. stable
  optimizer.inline();optimizer.remap();optimizer.costModel();optimizer.coercions();optimizer.aliases();
optimizer.evaluate();optimizer.emptybind();optimizer.pushselect();optimizer.aliases();optimizer.mergetable();
optimizer.deadcode();optimizer.aliases();optimizer.constants();optimizer.commonTerms();
optimizer.projectionpath();optimizer.deadcode();optimizer.reorder();optimizer.matpack();
optimizer.querylog();optimizer.multiplex();optimizer.generator();optimizer.profiler();optimizer.candidates();
optimizer.deadcode();optimizer.postfix();optimizer.wlc();optimizer.garbageCollector();

 

The default SQL optimization pipe line contains the following steps:

inline Inline functions identified as such.
remap Locate hardwired multiplex operations.
costModel Inspects the SQL catalog for size information.
coercions Performs static type coercions.
aliases Remove alias assignments.
evaluate Evaluate constant expressions.
emptybind Removes empty bindings
pushselect Push selections through e.g. joins.
aliases Remove alias assignments.
mitosis Horizontal fragmentation.
mergetable Expand horizontal fragmented plans.
deadcode Remove all code not leading to used results.
aliases Remove alias assignments.
constants Evaluate constant expressions.
commonterms Remove duplicate expressions.
projectionpath Searchs multiple joins and glues them together for better runtime optimization.
deadcode Remove all code not leading to used results.
reorder Reorder the execution order.
matpack Recombine partitions into a single BAT.
dataflow item Prepare code for multi-core execution
querylog Keep track of SQL query definitions and invocations.
multiplex Expand all remaining multiplex operations to iterators.
generator Implement for-loop generator as table producing function.
profiler Highlight the candidate lists in the code.
candidates Highlight the candidate lists in the code.
deadcode Remove all code not leading to used results.
postfix Post fix.
wlc Workload Capture.
garbageCollector Injects calls to the garbage collector to free up space.

 

A user-defined optimizer pipeline is checked against the dependency information maintained in the optimizer library to ensure there are no conflicts and at least the pre-requisite optimizers are used.

 

Performance Tips

Performance Tips giulia Mon, 06/15/2020 - 19:02

DB Design tips:

  • Define a primary key (pk) for each table and foreign keys (fk) in tables referencing pk's.
    These pk definitions will implicitly create an internal hash index and speed up joins between 2 tables when joined on their pk - fk columns.

  • Specify NOT NULL for columns which may not be NULL.

  • When a table is very large and your queries often need only parts of that table consider to partition the table into multiple partition tables (and one merge table to logically combine the partition tables).
    See: Data Partitioning , Updatable Merge Tables and CREATE MERGE TABLE

  • If your queries do some complex/expensive computations multiple times (or in multiple queries), it may be faster to first store the computation result in an added column of a table and next query the added column to eliminate the computation overhead in the queries.
    Use: ALTER TABLE ... ADD COLUMN column_name ... to add an extra column and UPDATE ... SET column_name = computation expression to update it with the computed values.
    You may also add triggers to keep the extra column values updated when new rows are added (INSERT) or updated.

 

Runtime tips:

 

SQL System Catalog

SQL System Catalog mk Thu, 03/28/2013 - 17:08

A relational database system uses a system catalog to store information on database objects, such as tables, columns, functions, procedures, users. The MonetDB SQL system catalog is a collection of regular mostly readonly system tables and system views located in the schemas "sys" and "tmp". The relations are modified indirectly through SQL commands such as CREATE TABLE. Some system views are implemented as wrappers around table producing system functions to present internal bookkeeping information.

Below you find categories of system tables and views currently provided.

Tip: to find out which system tables and views are available in your database run query:
  SELECT schema_id, name, type, substring(query, 0, 50) as query FROM sys.tables WHERE system ORDER BY schema_id, name;

Schema, table and columns

Schema, table and columns mk Thu, 03/28/2013 - 17:19

All objects belong to a SQL schema, which ensures a conflict-free namespace for accessing them and a focus for user authorization. The schema contains tables and views administered. Statistics on columns can be gathered via the ANALYZE command.

sys.schemas
name type references description
"id" INTEGER   The unique internal identifier for the schema.
"name" VARCHAR   The unique SQL schema name. Names are case sensitive.
"authorization" INTEGER sys.auths.id The identifier associated with the authorization.
"owner" INTEGER sys.auths.id The reference to the owner of this schema.
"system" BOOLEAN   Is it a MonetDB system schema.
sys.table_types
name type references description
"table_type_id" SMALLINT   The unique internal identifier for the table type.
"table_type_name" VARCHAR   The unique SQL name of this table type.
sys.tables
name type references description
"id" INTEGER   The unique internal identifier for the table or view.
"name" VARCHAR   The SQL table or view name. Names are case sensitive.
"schema_id" INTEGER sys.schemas.id The schema identifier.
"query" VARCHAR   The query to populate a view.
"type" SMALLINT sys.table_types. table_type_id The table type identifier.
See sys.table_types for meaning of the identifiers.
"system" BOOLEAN   Is it a MonetDB system table or view.
"commit_action" SMALLINT   Action on commit for temp tables: 0=Not a temp table, 1=Delete rows, 2=Preserve rows, 3=Drop temp table.
"access" SMALLINT   Table access code: 0 = READWRITE, 1 = READ ONLY, 2 = INSERT ONLY.
"temporary" TINYINT   Retention period indicator; 0=persistent, 1=session.
sys.columns
name type references description
"id" INTEGER   The unique internal identifier for the column.
"name" VARCHAR   The SQL column name. Names are case sensitive.
"type" VARCHAR sys.types.sqlname The SQL type name.
"type_digits" INTEGER   The number of digits (radix 2) for numeric types or max length for character/binary strings.
"type_scale" INTEGER   The precision after decimal point. Only applicable for decimal/numeric types.
"table_id" INTEGER sys.tables.id The table this column belongs to.
"default" VARCHAR   The default lexical value.
"null" BOOLEAN   Nulls are allowed constraint.
"number" INTEGER   Column position in the underlying table, starting from 0.
"storage" VARCHAR   Internal storage class identifier.
sys.statistics
name type references description
"column_id" INTEGER sys.columns.id The unique internal identifier for the column.
"type" VARCHAR sys.types.sqlname The SQL type name.
"width" INTEGER   The number of bytes for fixed size data types or number of bytes per character for character/binary strings.
"stamp" TIMESTAMP   Timestamp when the statistics for the column was created or last updated.
"sample" BIGINT   The number of sample items/rows on which the statistic is based.
"count" BIGINT   The number of items/rows on which the statistic is based.
"unique" BIGINT   The number of unique value found for this column.
"nils" BIGINT   The number of NULLs found for this column.
"minval" CLOB   The minimum value found for this column.
"maxval" CLOB   The maximum value found for this column.
"sorted" BOOLEAN   Whether the data in this column is sorted in ascending order.
"revsorted" BOOLEAN   Whether the data in this column is sorted in descending order.

Table Data Partitioning

Table Data Partitioning dinther Thu, 06/27/2019 - 15:03

Tables can be merged into one virtual merge table to provide Data Partitioning. Optionally the merge table can have a table partitioning scheme allowing data to be partitioned automatically by column or expression and on distinct values or value ranges upon insert. The partitioning schemes are stored in below system tables:

sys.table_partitions
name type references description
"id" INTEGER   The unique internal identifier for the table partition.
"table_id" INTEGER sys.tables.id The merge table id this partition belongs to.
"column_id" INTEGER sys.columns.id The merge table's column id by which the partitioning data is selected OR null when an expression is used.
"expression" VARCHAR   The merge table's expression by which the partitioning data is selected OR null when a column is used.
"type" INTEGER   The partitioning type: 5=By Column Range, 6=By Expression Range, 9=By Column Value, 10=By Expression Value.
sys.range_partitions
name type references description
"table_id" INTEGER sys.tables.id The partition table id this partition belongs to.
"partition_id" INTEGER sys.table_partitions.id The merge table's partition id this range partition belongs to.
"minimum" VARCHAR   The minimum value of the range. Can be null when WITH NULL VALUES is specified.
"maximum" VARCHAR   The maximum value of the range. Can be null when WITH NULL VALUES is specified.
"with_nulls" BOOLEAN   Whether this range also include the NULLs of the Column/Expression.
sys.value_partitions
name type references description
"table_id" INTEGER sys.tables.id The partition table id this partition belongs to.
"partition_id" INTEGER sys.table_partitions.id The merge table's partition id this value partition belongs to.
"value" VARCHAR   The partitioning value. Can be null when WITH NULL VALUES is specified.

Functions, arguments, types

Functions, arguments, types mk Thu, 03/28/2013 - 20:35

The functions (including procedures, aggregates, filter functions and loader functions) are all collected in the tables below. It provides an roadmap to check availability of operations supported. Functions can be overloaded, so the same function name can exist multiple times in sys.functions but each will have different arguments, so different function signatures.

sys.functions
name type references description
"id" INTEGER   The unique internal identifier for the function/procedure/aggregate.
"name" VARCHAR   The SQL name.
"func" VARCHAR   MAL function identifier or SQL function definition.
"mod" VARCHAR   MAL function module identifier.
"language" INTEGER sys.function_languages.language_id The programming language id code in which the function is defined, see table sys.function_languages.
"type" INTEGER sys.function_types.function_type_id Type of function, see table sys.function_types.
"side_effect" BOOLEAN   It does (not) lead to updates.
"varres" BOOLEAN   Does the function have varres?
"vararg" BOOLEAN   Can the function be called with a variable number of arguments?
"schema_id" INTEGER sys.schemas.id The schema the function belongs to.
"system" BOOLEAN   Is it a preloaded MonetDB system function/procedure/aggregate.
This column is available from release Apr2019 (11.33.3) onwards.
sys.systemfunctions
name type references description
"function_id" INTEGER sys.functions.id

The unique internal identifier of a system function.
Note: this is not a system controlled foreign key reference, and is not automatically removed when the referred function is dropped from sys.functions.

Note: As of release Apr2019 (11.33.3) table sys.systemfunctions has become deprecated and will be removed in a future release. Use new column sys.functions."system" instead to determine whether a function is a system function or not.

sys.function_languages
name type references description
"language_id" SMALLINT   The unique internal identifier of a function programming language.
"language_name" VARCHAR   A description of the programming language.
sys.function_types
name type references description
"function_type_id" SMALLINT   The unique internal identifier of a function type.
"function_type_name" VARCHAR   A description of the function type.
sys.args
name type references description
"id" INTEGER   The unique internal identifier for function argument.
"func_id" INTEGER sys.functions.id The corresponding function.
"name" VARCHAR   The SQL name.
"type" VARCHAR sys.types.sqlname The SQL type name.
"type_digits" INTEGER   The number of digits for number types.
"type_scale" INTEGER   The precision after decimal point.
"inout" TINYINT   Whether the argument is usable for input (=0) or output or both (=1).
"number" INTEGER   The function argument position ranging from 1 to n for functions and from 0 to n-1 for procedures (sys.functions.type = 2). For functions a number 0 represents the return arg type.
sys.types
name type references description
"id" INTEGER   The unique internal identifier for the data type.
"systemname" VARCHAR   MAL data type name.
"sqlname" VARCHAR   SQL data type name.
"digits" INTEGER   The number of digits (in the specified radix) for numerical, floating point, time, timestamp and interval types.
"scale" INTEGER   Type of scale. 0=not applicable, 1=decimal, 2=exponential (floating point).
"radix" INTEGER   Radix for the number of digits value: 2 (= binary) or 10 (= decimal).
"eclass" INTEGER   The internal storage class equivalence identifier.
"schema_id" INTEGER sys.schemas.id The schema identifier.

Objects, keys, indices, sequences

Objects, keys, indices, sequences mk Thu, 03/28/2013 - 20:32
sys.objects
name type references description
"id" INTEGER   The internal object identifier. Primary key of this table is the combination of "id" and "nr".
"name" VARCHAR   The SQL name.
"nr" INTEGER   Position within the object list.
sys.keys
name type references description
"id" INTEGER sys.objects.id The unique internal key identifier.
"table_id" INTEGER sys.tables.id The corresponding table identifier.
"type" INTEGER sys.key_types.key_type_id Key type id: 0=Primary Key, 1=Unique Key, 2=Foreign Key, see table sys.key_types.
"name" VARCHAR   The SQL name given to the key.
"rkey" INTEGER sys.keys.id when rkey > 0 Related key designator. -1 if not applicable.
"action" INTEGER   Cascading properties. -1 if not applicable.
sys.key_types
name type references description
"key_type_id" SMALLINT   The unique internal identifier of a key type.
"key_type_name" VARCHAR   A description of the key type.
sys.idxs
name type references description
"id" INTEGER sys.objects.id The unique internal index identifier.
"table_id" INTEGER sys.tables.id The corresponding table identifier.
"type" INTEGER sys.index_types.index_type_id The corresponding index type identifier, see table sys.index_types.
"name" VARCHAR   The SQL name.
sys.index_types
name type references description
"index_type_id" SMALLINT   The unique internal identifier of an index type.
"index_type_name" VARCHAR   A description of the index type.
sys.sequences
name type references description
"id" INTEGER   The unique internal sequence identifier.
"schema_id" INTEGER sys.schemas.id The corresponding schema identifier.
"name" VARCHAR   The SQL name.
"start" BIGINT   The start value of the sequence.
"minvalue" BIGINT   The minimal value of the sequence.
"maxvalue" BIGINT   The maximal value of the sequence.
"increment" BIGINT   The sequence increment value.
"cacheinc" BIGINT   The increment to ease transaction management.
"cycle" BOOLEAN   The repeat the sequence upon hitting its bounds.

Triggers, ids, dependencies, comments

Triggers, ids, dependencies, comments mk Thu, 03/28/2013 - 20:38
sys.triggers
name type references description
"id" INTEGER   The unique internal trigger identifier.
"name" VARCHAR   Its SQL name.
"table_id" INTEGER sys.tables.id The corresponding triggering table identifier
"time" SMALLINT   BEFORE/AFTER
"orientation" SMALLINT   FOR EACH ROW/FOR EACH STATEMENT
"event" SMALLINT   Update/insert/delete/truncate event.
"old_name" VARCHAR   The correlation SQL name for the previous state.
"new_name" VARCHAR   The correlation SQL name for the new state.
"condition" VARCHAR   The SQL condition.
"statement" VARCHAR   The SQL statement(s) to be executed.

 

sys.ids
name type references description
"id" INTEGER sys.*.id The identifier of the object. The referenced table where this object id is stored is available in column "sys_table".
"name" VARCHAR   The name of the object.
"schema_id" INTEGER sys.schemas.id If applicable: The schema identifier the object belongs to, else NULL.
"table_id" INTEGER sys.tables.id If applicable: The table identifier the object belongs to, else NULL.
"table_name" VARCHAR sys.tables.name If applicable: The table name the object belongs to, else NULL.
"obj_type" VARCHAR   Object type name.
"sys_table" VARCHAR   Corresponding system table name where details on the object can be queried.
sys.dependency_types
name type references description
"dependency_type_id" SMALLINT   The unique identifier for the dependency type.
"dependency_type_name" VARCHAR   The unique name of this dependency type.
sys.dependencies
name type references description
"id" INTEGER sys.ids.id The identifier which has a dependency.
"depend_id" INTEGER sys.ids.id The identifier reference on which it depends. The combination of "id" and "depend_id" is unique key.
"depend_type" SMALLINT sys.dependency_types
.dependency_type_id
To which sys.<obj>.id it depends: a table or view, a column, a function, an auth, an object.
See sys.dependency_types for meaning of the identifiers
sys.dependencies_vw
name type references description
"id" INTEGER sys.ids.id The identifier of the object which has a dependency.
"obj_type" VARCHAR   Object type name.
"name" VARCHAR   The name of the object.
"used_by_id" INTEGER sys.ids.id The identifier reference on which it depends. The combination of "id" and "used_by_id" forms a unique key.
"used_by_obj_type" VARCHAR   Object type name of the used_by_id.
"used_by_name" VARCHAR   The name of the object referenced by the used_by_id.
"depend_type" SMALLINT sys.dependency_types
.dependency_type_id
To which sys.<obj>.id it depends: a table or view, a column, a function, an auth, an object.
"dependency_type_name" VARCHAR sys.dependency_types
.dependency_type_name
The name of the dependency type.

 

sys.comments
name type references description
"id" INTEGER sys.ids.id The identifier of the object which has a comment.
"remark" VARCHAR   The remark comment associated to the object.

 

Following convenience views exist to find specific dependencies more easily:

SELECT * FROM sys.dependency_owners_on_schemas;
SELECT * FROM sys.dependency_schemas_on_users;
SELECT * FROM sys.dependency_tables_on_foreignkeys;
SELECT * FROM sys.dependency_tables_on_functions;
SELECT * FROM sys.dependency_tables_on_indexes;
SELECT * FROM sys.dependency_tables_on_procedures;
SELECT * FROM sys.dependency_tables_on_triggers;
SELECT * FROM sys.dependency_tables_on_views;
SELECT * FROM sys.dependency_views_on_functions;
SELECT * FROM sys.dependency_views_on_procedures;
SELECT * FROM sys.dependency_views_on_views;
SELECT * FROM sys.dependency_columns_on_functions;
SELECT * FROM sys.dependency_columns_on_indexes;
SELECT * FROM sys.dependency_columns_on_keys;
SELECT * FROM sys.dependency_columns_on_procedures;
SELECT * FROM sys.dependency_columns_on_triggers;
SELECT * FROM sys.dependency_columns_on_types;
SELECT * FROM sys.dependency_columns_on_views;
SELECT * FROM sys.dependency_keys_on_foreignkeys;
SELECT * FROM sys.dependency_functions_on_functions;
SELECT * FROM sys.dependency_functions_on_procedures;
SELECT * FROM sys.dependency_functions_on_triggers;
SELECT * FROM sys.dependency_functions_on_types;
SELECT * FROM sys.dependency_functions_on_views;
SELECT * FROM sys.dependency_args_on_types;

Storage of tables and columns

Storage of tables and columns dinther Thu, 08/30/2018 - 18:17

The information on calculated storage of data tables and columns are accessible from the system views below. These views give the database administrator insight in the actual footprint of the persistent tables and the maximum playground used when indices are introduced upon them. The actual storage footprint of an existing database can be obtained by querying the views sys.schemastorage or sys.tablestorage or sys.storage (for most detailed information). It represents the actual state of affairs, i.e. storage of files on disk of columns and foreign key indices, and possible temporary hash indices. For strings we take a sample to determine their average length.

sys.schemastorage
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"storages" BIGINT   The total number of storage files used by all tables in the schema.
"columnsize" BIGINT   The total size in bytes of all the column data of all tables in the schema.
"heapsize" BIGINT   The total size in bytes of all the column heap data of all tables in the schema.
"hashsize" BIGINT   The total size in bytes of all the column hash data of all tables in the schema.
"imprintsize" BIGINT   The total size in bytes of all the column imprints data of all tables in the schema.
"orderidxsize" BIGINT   The total size in bytes of all the ordered column indices data of all tables in the schema.
sys.tablestorage
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"table" VARCHAR sys.tables.name The table name.
"rowcount" BIGINT   The number of rows in the table.
"storages" BIGINT   The number of storage files used by the table. Besides column storage files also indices and dictionary heaps and pkey hashes require a storage file.
"columnsize" BIGINT   The total size in bytes of all the column data of the table.
"heapsize" BIGINT   The total size in bytes of all the column heap data of the table.
"hashsize" BIGINT   The total size in bytes of all the column hash data of the table.
"imprintsize" BIGINT   The total size in bytes of all the column imprints data of the table.
"orderidxsize" BIGINT   The total size in bytes of all the ordered column indices data of the table.
sys.storage
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"table" VARCHAR sys.tables.name The table name.
"column" VARCHAR sys.columns.name The column name or name of the index or heap (for dictionary encoded strings).
"type" VARCHAR sys.types.sqlname The data type name.
"mode" VARCHAR   State of the column, such as writable.
"location" VARCHAR   The location (relative path and file name) of the persistent storage data file.
"count" BIGINT   The number of data values in the column storage.
"typewidth" INTEGER   Maximum width of the data in bytes for the column. Large objects without a maximum specified will have 0.
"columnsize" BIGINT   The total size in bytes of the column data.
"heapsize" BIGINT   The total size in bytes of the heap data of the column if existing such as when the column is CHAR(n) or VARCHAR(n) or CLOB(n) or BLOB(n).
"hashes" BIGINT   The total size in bytes of the hash data of a column data if existing.
"phash" BOOLEAN   Whether it has a primary key hash?
"imprints" BIGINT   The total size in bytes of the imprints data of a column data if existing.
"sorted" BOOLEAN   Whether the column data is sorted?
"revsorted" BOOLEAN   Whether the column data is reverse sorted?
"unique" BOOLEAN   Whether all values in the column data are distinct from each other?
"orderidx" BIGINT   The total size in bytes of the ordered index data of a column data if existing.

 

By changing the storagemodelinput table directly, the footprint for yet to be loaded databases can be assessed. See also Storage Model and Disk Space

sys.storagemodelinput
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"table" VARCHAR sys.tables.name The table name.
"column" VARCHAR sys.columns.name The column name or name of the index or heap (for dictionary encoded strings).
"type" VARCHAR sys.types.sqlname The data type name.
"typewidth" INTEGER   Maximum width of the data in bytes for the column. Large objects without a maximum specified will have 0.
"count" BIGINT   The estimated number of tuples.
"distinct" BIGINT   Indication of distinct number of strings.
"atomwidth" INTEGER   Average width of strings or clob.
"reference" BOOLEAN   Whether the column is used as foreign key reference?
"sorted" BOOLEAN   Whether the column data is sorted? If set there is no need for an index.
"unique" BOOLEAN   Whether all values in the column data are distinct from each other?
"isacolumn" BOOLEAN   Whether the storage is a column
sys.storagemodel
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"table" VARCHAR sys.tables.name The table name.
"column" VARCHAR sys.columns.name The column name or name of the index or heap (for dictionary encoded strings).
"type" VARCHAR sys.types.sqlname The data type name.
"count" BIGINT   The number of data values in the column.
"columnsize" BIGINT   The total size in bytes of the column.
"heapsize" BIGINT   The total size in bytes of the heap of the column if existing such as when the column is CHAR(n) or VARCHAR(n) or CLOB(n) or BLOB(n).
"hashsize" BIGINT   The total size in bytes of the hash of a column data if existing.
"imprintsize" BIGINT   The total size in bytes of the imprint of a column data if existing.
"orderidxsize" BIGINT   The total size in bytes of the ordered indexx of a column data if existing.
"sorted" BOOLEAN   Whether the column data is sorted?
"unique" BOOLEAN   Whether all values in the column data are distinct from each other?
"isacolumn" BOOLEAN   Whether the storage is a column
sys.tablestoragemodel
name type references description
"schema" VARCHAR sys.schemas.name The schema name.
"table" VARCHAR sys.tables.name The table name.
"rowcount" BIGINT   The number of rows in the table.
"storages" BIGINT   The number of storage files used by the table. Besides column storage files also indices and dictionary heaps and pkey hashes require a storage file.
"columnsize" BIGINT   The total size in bytes of all the column data of the table.
"heapsize" BIGINT   The total size in bytes of all the column heap data of the table.
"hashsize" BIGINT   The total size in bytes of all the column hash data of the table.
"imprintsize" BIGINT   The total size in bytes of all the column imprints data of the table.
"orderidxsize" BIGINT   The total size in bytes of all the ordered column indices data of the table.

Users, roles, privileges, sessions

Users, roles, privileges, sessions mk Thu, 03/28/2013 - 20:37

The user access grants are organized by authorization groups.

sys.auths
name type references description
"id" INTEGER   The unique authorization identifier.
"name" VARCHAR   The SQL authorization name of the user or role.
"grantor" INTEGER sys.auths.id when grantor > 0 The corresponding authorization grantor.

 

sys.users   and   sys.db_user_info
name type references description
"name" VARCHAR sys.auths.name The unique user login name.
"fullname" VARCHAR   Full name of user.
"default_schema" INTEGER sys.schemas.id The default schema for this user.

 

sys.roles
name type references description
"id" INTEGER   The unique role identifier.
"name" VARCHAR   The role name.
"grantor" INTEGER sys.auths.id when grantor > 0 The corresponding authorization grantor.

 

sys.user_role
name type references description
"login_id" INTEGER sys.auths.id The corresponding user identifier.
"role_id" INTEGER sys.roles.id The corresponding role identifier.

 

sys.privileges
name type references description
"obj_id" INTEGER sys.ids.id The identifier of the object for which privilege(s) are given to a certain user or role.
"auth_id" INTEGER sys.auths.id The id of the user or role.
"privileges" INTEGER sys.privilege_codes.privilege_code_id Privileges classification code, see table sys.privilege_codes.
"grantor" INTEGER sys.auths.id when grantor > 0 The corresponding grantor authorization identifier.
"grantable" INTEGER   Permission to pass privilege rights to other users or roles.
sys.privilege_codes
name type references description
"privilege_code_id" INTEGER   The unique internal code of a privilege or combination of privileges.
"privilege_code_name" VARCHAR   A description of the privilege(s) associated with this code.

 

sys.sessions
name type references description
"sessionid" INTEGER   The internal session identifier.
"username" VARCHAR sys.users.name The naem of the user who created the session.
"login" TIMESTAMP   The login start timestamp of the session.
"idle" TIMESTAMP   The timestamp of the session.
"optimizer" VARCHAR sys.optimizers.name The optimizer pipeline name.
"sessiontimeout" INTEGER   The session timeout time in milliseconds, 0 means timeout is disabled.
"querytimeout" INTEGER   The query execution timeout time in milliseconds, 0 means timeout is disabled.
"workerlimit" INTEGER   The maximum number of worker threads allowed, 0 means limit is disabled.
"memorylimit" INTEGER   The memory limit in MB for this session, 0 means limit is disabled.

Note: the sys.sessions structure has been enhanced from release Jun2020 (11.37.7) onwards. Older versions will show less and some different columns.

 

QueryLog catalog, calls, history, queue

QueryLog catalog, calls, history, queue mk Fri, 03/29/2013 - 14:12

The tables below provide insight into queries compiled and executed. See also: /Documentation/ServerAdministration/QueryTiming/QueryHistory

sys.querylog_catalog
name type references description
id oid   The internal query identifier.
owner string sys.users.name The user defining it.
defined timestamp   Time when the query was added to the catalog.
query string   The complete SQL query statement.
pipe string sys.optimizers.name The MAL optimizer pipeline.
plan string   The MAL execution plan.
mal int   Size of MAL plan
optimize bigint   Optimization time in micro-seconds.
sys.querylog_calls
name type references description
id oid sys.querylog_catalog.id Reference to the querylog definition.
"start" timestamp   Time the statement was started.
"stop" timestamp   Time the statement was completely finished.
arguments string   The actual call structure.
tuples bigint   The number of tuples in the result set
run bigint   The time spent (in usec) until the result export.
ship bigint   The time spent (in usec) to ship the result set.
cpu int   The average cpu load percentage during execution.
io int   The percentage time waiting for IO to finish.
sys.querylog_history
name type references description
id oid sys.querylog_catalog.id Reference to the querylog definition.
owner string sys.users.name The user defining it.
defined timestamp   Time when the query was added to the catalog.
query string   The complete SQL query statement.
pipe string sys.optimizers.name The MAL optimizer pipeline.
plan string   The MAL execution plan.
mal int   Size of MAL plan
optimize bigint   Optimization time in micro-seconds.
"start" timestamp   Time the statement was started.
"stop" timestamp   Time the statement was completely finished.
arguments string   The actual call structure.
tuples bigint   The number of tuples in the result set
run bigint   The time spent (in usec) until the result export.
ship bigint   The time spent (in usec) to ship the result set.
cpu int   The average cpu load percentage during execution.
io int   The percentage time waiting for IO to finish.

 

sys.queue
name type references description
"tag" BIGINT   Unique internal query call identifier.
"sessionid" INTEGER sys.sessions.sessionid The internal session identifier.
"username" VARCHAR sys.users.name The name of the user responsible for the call.
"started" TIMESTAMP   The date and time the query was started.
"status" VARCHAR   running or paused.
"query" VARCHAR   The SQL query itself.
"progress" INTEGER   Percentage of completion based on history.
"workers" INTEGER   The number of worker threads based on history.
"memory" INTEGER   The amount of memory used in MB based on history.

Note: the sys.queue structure has been enhanced from release Jun2020 (11.37.7) onwards. Older versions will show less and some different columns.

Prepared statements

Prepared statements dinther Thu, 06/11/2020 - 20:03

System views for querying active prepared statements information in the user session.

These views are available from release Jun2020 (11.37.7) onwards.

sys.prepared_statements
name type references description
"sessionid" INTEGER sys.sessions.sessionid The internal session identifier.
"username" VARCHAR sys.users.name The user who created the prepared statement.
"statementid" INTEGER   The internal prepared statement identifier. This value must be used to execute the prepared statement.
"statement" VARCHAR   The original SQL prepare statement.
"created" TIMESTAMP   Creation date and time of the prepared statement.

 

sys.prepared_statements_args
name type references description
"statementid" INTEGER sys.prepared_statements.statementid The internal prepared statement identifier.
"type" VARCHAR sys.types.sqlname The SQL type name.
"type_digits" INTEGER   The number of digits (radix 2) for numeric types or max length for character/binary strings.
"type_scale" INTEGER   The precision after decimal point. Only applicable for decimal/numeric types.
"inout" TINYINT   Whether the argument is an input (=1) argument or an output(=0) result column.
"number" INTEGER   The argument position starting from 0. First the output result columns are listed next the input parameters.
"schema" VARCHAR   The schema name of an output argument.
"table" VARCHAR   The table name of an output argument.
"column" VARCHAR   The column name of an output argument.

 

Optimizer pipelines

Optimizer pipelines mk Fri, 03/29/2013 - 15:30

See also: /Documentation/SQLReference/PerformanceOptimization/OptimizerPipelines

sys.optimizers
name type references description
"name" VARCHAR   The unique optimizer pipeline name.
"def" VARCHAR   The optimizer pipeline definition.
"status" VARCHAR   Status: stable or experimental.

Environment variables

Environment variables mk Fri, 03/29/2013 - 15:30

The system keeps a small table of global variables, initialized upon system restart, session restart, or declared explicitly by the user.

sys.environment
name type references description
"name" VARCHAR   The unique identifying name of the global environment variable, such as monet_version and monet_release.
"value" VARCHAR   The value (as string) for the environment variable of the current instance of MonetDB.
sys.var_values
name type references description
"var_name" VARCHAR   The unique identifying name of the system session variable, such as current_schema, optimizer or last_id.
"value" VARCHAR   The value (as string) for the system variable of the current session.
sys.keywords
name type references description
"keyword" VARCHAR   The reserved SQL keyword.

Feature overview

Feature overview mk Sat, 03/27/2010 - 23:29

The SQL language standard has grown from a modest SQL'92 document of less then a 100 pages to the latest SQL:2008 >4000 page description comprised of the following volumes:

ISO/IEC 9075-1 Framework (SQL/Framework)
ISO/IEC 9075-2 Foundation (SQL/Foundation)
ISO/IEC 9075-3 Call Level Interface (SQL/CLI)
ISO/IEC 9075-4 Persistent Stored Modules (SQL/PSM)
ISO/IEC 9075-9 Management of External Data (SQL/MED)
ISO/IEC 9075-10 Object Language Bindings (SQL/OLB)
ISO/IEC 9075-11 Information and Definition Schemas (SQL/Schemata)
ISO/IEC 9075-13 Routines and Types using the Java Language (SQL/JRT)
ISO/IEC 9075-14 XML-related specifications (SQL/XML)

The MonetDB SQL implementation is based on SQL 2003 and newer standards with a limited extension to features found elsewhere. The tables below illustrates the (un)supported features in the latest stable distribution release. Beware, some of the features are technically impossible to support due to the design of MonetDB or would cause excessive performance consequences.

Migration from your current database system to MonetDB may require adjustment of the schema definition and query formulation. A comparison table for most actively used features is given in the SQL compatibility wikibook.

 

SQL compatibility

SQL compatibility mk Sun, 10/13/2013 - 23:31

Every SQL implementation differs in minor / major areas from the SQL standard. This calls for using middleware to translate queries, or even manually rewrite them according to the DBMS specifics.

A synopsis of the builtin functionality and comparison with related products, such as Postgresql, MySQL, and several commerical systems, can be found in the SQL wikibook.

Supported

Supported mk Thu, 06/02/2011 - 20:14
Feature ID Feature name
B102 Embedded language C
B112 Module language C
B122 Routine language C
B128 Routine language SQL
   
E011 Numeric data types (FULL support)
E011-01 INTEGER and SMALLINT data types (including all spellings)
E011-02 REAL, DOUBLE PRECISON, and FLOAT data types
E011-03 DECIMAL and NUMERIC data types
E011-04 Arithmetic operators
E011-05 Numeric comparison
E011-06 Implicit casting among the numeric data types
E021 Character data types (PARTIAL support)
E021-01 CHARACTER data type (including all its spellings)
E021-02 CHARACTER VARYING data type (including all its spellings)
E021-03 Character literals
E021-04 CHARACTER_LENGTH function
E021-05 OCTET_LENGTH function
E021-06 SUBSTRING function
E021-07 Character concatenation
E021-08 UPPER and LOWER functions
E021-09 TRIM function
E021-10 Implicit casting among the character data types
E021-11 POSITION function
E021-12 Character comparison
E031 Identifiers (FULL support)
E031-01 Delimited identifiers
E031-02 Lower case identifiers
E031-03 Trailing underscore
E051 Basic query specification (FULL support)
E051-01 SELECT DISTINCT
E051-02 GROUP BY clause
E051-04 GROUP BY can contain columns not in select-list
E051-05 Select list items can be renamed
E051-06 HAVING clause
E051-07 Qualified * in select list
E051-08 Correlation names in the FROM clause
E051-09 Rename columns in the FROM clause
E061 Basic predicates and search conditions (FULL support)
E061-01 Comparison predicate
E061-02 BETWEEN predicate
E061-03 IN predicate with list of values
E061-04 LIKE predicate
E061-05 LIKE predicate: ESCAPE clause
E061-06 NULL predicate
E061-07 Quantified comparison predicate
E061-08 EXISTS predicate
E061-09 Subqueries in comparison predicate
E061-11 Subqueries in IN predicate
E061-12 Subqueries in quantified comparison predicate
E061-13 Correlated subqueries
E061-14 Search condition
E071 Basic query expressions (FULL support)
E071-01 UNION DISTINCT table operator
E071-02 UNION ALL table operator
E071-03 EXCEPT DISTINCT table operator
E071-05 Columns combined via table operators need not have exactly the same data type
E071-06 Table operators in subqueries
E081 Basic Privileges
E081-01 SELECT privilege at the table level
E081-02 DELETE privilege
E081-03 INSERT privilege at the table level
E081-04 UPDATE privilege at the table level
E081-05 UPDATE privilege at the column level
E081-06 REFERENCES privilege at the table level  (SELECT privilege is used)
E081-07 REFERENCES privilege at the column level (SELECT privilege is used)
E081-08 WITH GRANT OPTION
E081-10 EXECUTE privilege
E091 Set functions (FULL support)
E091-01 AVG
E091-02 COUNT
E091-03 MAX
E091-04 MIN
E091-05 SUM
E091-06 ALL quantifier
E091-07 DISTINCT quantifier
E101 Basic data manipulation (FULL support)
E101-01 INSERT statement
E101-03 Searched UPDATE statement
E101-04 Searched DELETE statement
E111 Single row SELECT statement
E121-02 ORDER BY columns need not be in select list
E121-03 Value expressions in ORDER BY clause
E131 Null value support (nulls in lieu of values)
E141 Basic integrity constraints
E141-01 NOT NULL constraints
E141-02 UNIQUE constraints of NOT NULL columns
E141-03 PRIMARY KEY constraints
E141-04 Basic FOREIGN KEY constraint with the NO ACTION default
E141-07 Column defaults
E141-08 NOT NULL inferred on PRIMARY KEY
E151 Transaction support
E151-01 COMMIT statement
E151-02 ROLLBACK statement
E152 Basic SET TRANSACTION statement
E152-01 SET TRANSACTION statement: ISOLATION LEVEL SERIALIZABLE clause
E152-02 SET TRANSACTION statement: READ ONLY and READ WRITE clauses
E161 SQL comments using leading double minus
E171 SQLSTATE support
E182 Module language
   
F031 Basic schema manipulation
F031-01 CREATE TABLE statement to create persistent base tables
F031-02 CREATE VIEW statement
F031-03 GRANT statement
F031-04 ALTER TABLE statement: ADD COLUMN clause
F031-13 DROP TABLE statement: RESTRICT clause
F031-16 DROP VIEW statement: RESTRICT clause
F031-19 REVOKE statement: RESTRICT clause
F032 CASCADE drop behavior
F033 ALTER TABLE statement: DROP COLUMN clause
F041 Basic joined table
F041-01 Inner join (but not necessarily the INNER keyword)
F041-02 INNER keyword
F041-03 LEFT OUTER JOIN
F041-04 RIGHT OUTER JOIN
F041-05 Outer joins can be nested
F041-07 The inner table in a left or right outer join can also be used in an inner join
F041-08 All comparison operators are supported (rather than just =)
F051 Basic date and time
F051-01 DATE data type (including DATE literal)
F051-02 TIME data type (including TIME literal) with fractional seconds precision of 0
F051-03 TIMESTAMP data type (including TIMESTAMP literal) with fractional seconds precision of 0 and 6
F051-04 Comparison predicate on DATE, TIME, and TIMESTAMP data types
F051-05 Explicit CAST between datetime types and character types
F051-06 CURRENT_DATE
F051-07 LOCALTIME
F051-08 LOCALTIMESTAMP
F052 Intervals and datetime arithmetic
F081 UNION and EXCEPT in views
F131 Grouped operations
F131-01 WHERE, GROUP BY, and HAVING clauses supported in queries with grouped views
F131-02 Multiple tables supported in queries with grouped views
F131-03 Set functions supported in queries with grouped views
F131-04 Subqueries with GROUP BY and HAVING clauses and grouped views
F131-05 Single row SELECT with GROUP BY and HAVING clauses and grouped views
F171 Multiple schemas per user
F181 Multiple module support (LIMITED support)
F200 TRUNCATE TABLE statement
F201 CAST function
F202 TRUNCATE TABLE: identify column restart option
F221 Explicit defaults
F222 INSERT statement: DEFAULT VALUES clause
F261 CASE expression
F261-01 Simple CASE
F261-02 Searched CASE
F261-03 NULLIF
F261-04 COALESCE
F262 Extended CASE expression
F301 CORRESPONDING in query expressions
F311 Schema definition statement
F311-01 CREATE SCHEMA
F311-02 CREATE TABLE for persistent base tables
F311-03 CREATE VIEW
F311-05 GRANT statement
F312 MERGE statement
F313 Enhanced MERGE statement
F321 User authorization
F391 Long identifiers
F392 Unicode escapes in identifiers (from Apr2019 release 11.33.3)
F393 Unicode escapes in literals (from Apr2019 release 11.33.3)
F401 Extended joined table
F401-01 NATURAL JOIN
F401-02 FULL OUTER JOIN
F401-03 CROSS JOIN
F411 Time zone specification
F471 Scalar subquery values
F481 Expanded NULL predicate
F531 Temporary tables
F761 Session management
F763 CURRENT_SCHEMA
   
T031 BOOLEAN data type
T041 Basic LOB data type support
T041-01 BLOB data type
T041-02 CLOB data type
T041-03 POSITION, LENGTH, LOWER, TRIM, UPPER, and SUBSTRING functions for LOB data types
T041-04 Concatenation of LOB data types
T071 BIGINT data type
T121 WITH (excluding RECURSIVE) in query expression
T151 DISTINCT predicate
T171 LIKE clause in table definition
T172 AS subquery clause in table definition
T174 Identity columns
T176 Sequence generator support
T177 Sequence generator support: simple restart option
T178 Identity columns: simple restart option
T211 Basic trigger capability
T211-01 Triggers activated on UPDATE, INSERT, or DELETE of one base table.
T211-02 BEFORE triggers
T211-03 AFTER triggers
T211-04 FOR EACH ROW triggers
T241 START TRANSACTION statement
T251 SET TRANSACTION statement: LOCAL option
T271 Savepoints
T281 SELECT privilege with column granularity
T321 Basic SQL-invoked routines
T321-01 User-defined functions with no overloading
T321-02 User-defined stored procedures with no overloading
T321-03 Function invocation
T321-04 CALL statement
T321-05 RETURN statement
T324 Explicit security for SQL routines
T326 Table functions
T331 Basic roles
T332 Extended roles
T341 Overloading of SQL-invoked functions and SQL-invoked procedures
T351 Bracketed comments
T441 ABS and MOD functions
T461 Symmetric BETWEEN predicate
T471 Result sets return value
T491 LATERAL derived table
T591 UNIQUE constraints of possibly null columns
T611 Elementary OLAP operations
T612 Advanced OLAP operations
T613 Sampling
T614 NTILE function
T615 LEAD and LAG functions
T616 Null treatment option for LEAD and LAG functions
T617 FIRST_VALUE and LAST_VALUE
T618 NTH_VALUE function (some options missing)
T619 Nested window functions
T621 Enhanced numeric functions
T622 Trigonometric functions
T623 General logarithm functions
T624 Common logarithm functions
T625 LISTAGG
T641 Multiple column assignment

Unsupported

Unsupported mk Thu, 06/02/2011 - 20:12
Feature ID Feature name
B011, B013-B017 Embedded Language ADA, COBOL, Fortran MUMPS, Pascal, PL/I
B111, B113-B117 Module language ADA, COBOL, Fortran MUMPS, Pascal, PL/I
B121, B123-B127 Routine language ADA, COBOL, Fortran MUMPS, Pascal, PL/I
   
E081-09 USAGE privilege
E121 Basic cursor support (CURSORS are not supported)
E121-01 DECLARE CURSOR
E121-04 OPEN statement
E121-06 Positioned UPDATE statement
E121-07 Positioned DELETE statement
E121-08 CLOSE statement
E121-10 FETCH statement: implicit NEXT
E121-17 WITH HOLD cursors
E141-06 CHECK constraints
E141-10 Names in a foreign key can be specified in any order (columns should be in the proper order)
E153 Updatable queries with subqueries
   
F021 Basic information schema
F021-01 COLUMNS view
F021-02 TABLES view
F021-03 VIEWS view
F021-04 TABLE_CONSTRAINTS view
F021-05 REFERENTIAL_CONSTRAINTS view
F021-06 CHECK_CONSTRAINTS view
F121 Basic diagnostic management
F121-01 GET DIAGNOSTICS statement
F121-02 SET TRANSACTION statement: DIAGNOSTICS SIZE clause
F122 Enhanced diagnostics statement
F123 All diagnostics
F181 Multiple module support
F251 Domain support
F263 Comma-separated predicates in simple CASE expression
F291 UNIQUE predicate
F311-04 CREATE VIEW: WITH CHECK OPTION
F341 Usage tables (ROUTINE_*_USAGE)
F394 Optional normal form specification
F403 Partitioned joined tables
F451 Character set definition
F461 Named character sets
F501 Features and conformance views
F501-01 SQL_FEATURES view
F501-02 SQL_SIZING view
F501-03 SQL_LANGUAGES view
F521 Assertions
F651 Catalog name qualifiers
F671 Subqueries in CHECK
F690 Enhanced collation support
F692 Enhanced collation support
F693 SQL-session and client module collations
F695 Translation support
F696 Additional translation documentation
F701 Referential update actions
F711 ALTER domain
F721 Deferrable constraints
F751 View CHECK enhancements
F762 CURRENT_CATALOG
F812 Basic flagging
F831 - 831-02 Cursor update, scroll, and order
F841 LIKE_REGEX
F842 OCCURRENCES_REGEX function
F843 POSITION_REGEX function
F844 SUBSTRING_REGEX function
F845 TRANSLATE_REGEX function
F846 Octet support in regular expression
F847 Nonconstant regular expression
   
S011 Distinct data types
S011-01 USER_DEFINED_TYPES view
S023 Basic structured types
S024 Enhanced structure types
S025 Final structured types
S026 Self-reference structured types
S027 Create method by specific method name
S028 Permutable UDT options list
S051 Create table of type
S081 Subtables
S091 Basic array support
S091-01 Arrays of built-in data types
S091-02 Arrays of distinct types
S091-03 Array expressions
S094 Arrays of reference types
S097 Array element assignment
S151 - S404 Object support features
   
T011 Timestamp in Information Schema
T021 BINARY and VARBINARY data types
T022 Advanced support for BINARY and VARBINARY data types
T023 Compound binary literal
T024 Spaces in binary literals
T041-05 LOB locator: non-holdable
T042 Extended LOB data type support
T043 Multiplier T
T044 Multiplier P
T051 Row types
T052 MAX and MIN for row types
T053 Explicit aliases for all-fields reference
T061 UCS support
T076 DECFLOAT data type
T101 Enhanced nullability determination
T111 Updatable joins, unions, and columns
T131 Recursive query
T132 Recursive query in subquery
T175 Generated columns
T211-06 Support for run-time rules for the interaction of triggers and constraints
T211-08 Multiple triggers for the same event are executed in the order in which they were created in the catalog intentionally omitted
T261 Chained transactions
T272 Enhanced savepoint management
T285 Enhanced derived column names
T301 Functional dependencies partially supported
T321-06 ROUTINES view
T321-07 PARAMETERS view
T325 Qualified SQL parameter references
T431 Extended grouping capabilities
T432 Nested and concatenated GROUPING SETS
T433 Multiargument GROUPING function
T434 GROUP BY DISTINCT
T511 Transaction counts
T541 Updatable table references
T561 Holdable locators
T571 Array-returning external SQL-invoked functions
T572 Multiset-returning external SQL-invoked functions
T601 Local cursor references
T652 SQL-dynamic statements in SQL routines
T653 SQL-schema statements in external routines
T654 SQL-dynamic statements in external routines
   
M001 Datalinks
M002 Datalinks via SQL/CLI
M003 Datalinks via Embedded SQL
M004 Foreign data support partially supported
M005 Foreign schema support
M006 GetSQLString routine
M007 TransmitRequest
M009 GetOpts and GetStatistics routines
M010 Foreign data wrapper support
M011 Datalinks via Ada, C, COBOL, Fortran, MUMPS, Pascal, PL/I
M018 - M024 Foreign data wrapper interface routines in Ada, C, COBOL, Fortran,MUMPS,Pascal,PL/I
M030 SQL-server foreign data support
M031 Foreign data wrapper general routines
   
X012 Multisets of XML type
X013 Distinct types of XML type
X014 Attributes of XML type
X015 Fields of XML type
X025 XMLCast
X030 XMLDocument
X038 XMLText
X065 XMLParse: BLOB input and CONTENT option
X066 XMLParse: BLOB input and DOCUMENT option
X068 XMLSerialize: BOM
X069 XMLSerialize: INDENT
X073 XMLSerialize: BLOB serialization and CONTENT option
X074 XMLSerialize: BLOB serialization and DOCUMENT option
X075 XMLSerialize: BLOB serialization
X076 XMLSerialize: VERSION
X077 XMLSerialize: explicit ENCODING option
X078 XMLSerialize: explicit XML declaration
X080 Namespaces in XML publishing
X081 Query-level XML namespace declarations
X082 XML namespace declarations in DML
X083 XML namespace declarations in DDL
X084 XML namespace declarations in compound statements
X085 Predefined namespace prefixes
X086 XML namespace declarations in XMLTable
X091 XML content predicate
X096 XMLExists
X100 Host language support for XML: CONTENT option
X101 Host language support for XML: DOCUMENT option
X110 Host language support for XML: VARCHAR mapping
X111 Host language support for XML: CLOB mapping
X112 Host language support for XML: BLOB mapping
X113 Host language support for XML: STRIP WHITESPACE option
X114 Host language support for XML: PRESERVE WHITESPACE option
X131 Query-level XMLBINARY clause
X132 XMLBINARY clause in DML
X133 XMLBINARY clause in DDL
X134 XMLBINARY clause in compound statements
X135 XMLBINARY clause in subqueries
X141 IS VALID predicate: data-driven case
X142 IS VALID predicate: ACCORDING TO clause
X143 IS VALID predicate: ELEMENT clause
X144 IS VALID predicate: schema location
X145 IS VALID predicate outside check constraints
X151 IS VALID predicate with DOCUMENT option
X152 IS VALID predicate with CONTENT option
X153 IS VALID predicate with SEQUENCE option
X155 IS VALID predicate: NAMESPACE without ELEMENT clause
X157 IS VALID predicate: NO NAMESPACE with ELEMENT clause
X160 Basic Information Schema for registered XML Schemas
X161 Advanced Information Schema for registered XML Schemas
X170 XML null handling options
X171 NIL ON NO CONTENT option
X181 XML(DOCUMENT(UNTYPED)) type
X182 XML(DOCUMENT(ANY)) type
X190 XML(SEQUENCE) type
X191 XML(DOCUMENT(XMLSCHEMA)) type
X192 XML(CONTENT(XMLSCHEMA)) type
X200 XMLQuery
X201 XMLQuery: RETURNING CONTENT
X202 XMLQuery: RETURNING SEQUENCE
X203 XMLQuery: passing a context item
X204 XMLQuery: initializing an XQuery variable
X205 XMLQuery: EMPTY ON EMPTY option
X206 XMLQuery: NULL ON EMPTY option
X211 XML 1.1 support
X221 XML passing mechanism BY VALUE
X222 XML passing mechanism BY REF
X231 XML(CONTENT(UNTYPED)) type
X232 XML(CONTENT(ANY)) type
X241 RETURNING CONTENT in XML publishing
X242 RETURNING SEQUENCE in XML publishing
X251 Persistent XML values of XML(DOCUMENT(UNTYPED)) type
X252 Persistent XML values of XML(DOCUMENT(ANY)) type
X253 Persistent XML values of XML(CONTENT(UNTYPED)) type
X254 Persistent XML values of XML(CONTENT(ANY)) type
X255 Persistent XML values of XML(SEQUENCE) type
X256 Persistent XML values of XML(DOCUMENT(XMLSCHEMA)) type
X257 Persistent XML values of XML(CONTENT(XMLSCHEMA)) type
X260 XML type: ELEMENT clause
X261 XML type: NAMESPACE without ELEMENT clause
X263 XML type: NO NAMESPACE with ELEMENT clause
X264 XML type: schema location
X271 XMLValidate: data-driven case
X272 XMLValidate: ACCORDING TO clause
X273 XMLValidate: ELEMENT clause
X274 XMLValidate: schema location
X281 XMLValidate: with DOCUMENT option
X282 XMLValidate with CONTENT option
X283 XMLValidate with SEQUENCE option
X284 XMLValidate NAMESPACE without ELEMENT clause
X286 XMLValidate: NO NAMESPACE with ELEMENT clause
X300 XMLTable
X301 XMLTable: derived column list option
X302 XMLTable: ordinality column option
X303 XMLTable: column default option
X304 XMLTable: passing a context item
X305 XMLTable: initializing an XQuery variable

Language bindings

Language bindings mk Sun, 03/28/2010 - 23:53

MonetDB comes with JDBC and ODBC drivers and PHP, Perl, Ruby and Python programming interface libraries. The JDBC, PHP, Perl, Ruby, Python and Node.js interfaces are native implementations and do not require installation of the MonetDB client/server code. The ODBC driver and setup library are available as a separate installer. The Mapi library is the lowest level C-interface to interacting with the server.

We rely on external documentation for the basics of the language bindings provided: PHP, Perl, Python, and the JDBC and ODBC APIs. Examples provided are used to illustrate their behavior in the context of MonetDB only.

JDBC docs.oracle.com/javase/8/docs/technotes/guides/jdbc/
ODBC docs.microsoft.com/en-us/sql/odbc/reference/odbc-programmer-s-reference
Python Database API v2.0 www.python.org/dev/peps/pep-0249
R www.r-project.org
JavaScript Node.js nodejs.org
Ruby/Rails rubyonrails.org
Perl DBI www.perl.org
PHP Data Objects (PDO) www.php.net/manual/en/book.pdo.php

Notes: The programming interface is based on a client-server architecture, where the client program connects to a server using a TCP/IP connection to exchange commands and receives answers. The underlying protocol uses plain UTF-8 data for ease of use and debugging. This leads to publicly visible information exchanged over a network, which may be undesirable. Therefore, a private and secure channel can be set up with the Secure Socket Layer functionality.

In addition, a deeper integration of MonetDB with R is available on the website of the MonetDB.R connector. If you are looking for information about the embedded R support in MonetDB, follow check this blog post.

More information about using MonetDB on Node.js you can find here.

Mapi Library

Mapi Library mk Sun, 03/28/2010 - 23:55

The Mapi Library

The easiest way to extend the functionality of MonetDB is to construct an independent application, which communicates with a running server using a database driver with a simple API and a textual protocol. The effectiveness of such an approach has been demonstrated by the wide use of database API implementations, such as Perl DBI, PHP, ODBC,...

Sample MAPI Application

The database driver implementation given in this document focuses on developing applications in C. The command collection has been chosen to align with common practice, i.e. queries follow a prepare, execute, and fetch_row paradigm. The output is considered a regular table. An example of a mini application below illustrates the main operations.

#include <mapi.h>
#include <stdio.h>
#include <stdlib.h>

void die(Mapi dbh, MapiHdl hdl) {
  if (hdl != NULL) {
    mapi_explain_query(hdl, stderr);
    do {
      if (mapi_result_error(hdl) != NULL)
        mapi_explain_result(hdl, stderr);
    } while (mapi_next_result(hdl) == 1);
    mapi_close_handle(hdl);
  }
  if (dbh != NULL) {
    mapi_explain(dbh, stderr);
    mapi_destroy(dbh);
  } else {
    fprintf(stderr, "command failed\n");
  }
  exit(-1);
}

MapiHdl query(Mapi dbh, char *q) {
  MapiHdl ret = NULL;

  if ((ret = mapi_query(dbh, q)) == NULL || mapi_error(dbh) != MOK)
    die(dbh, ret);

  return(ret);
}

void update(Mapi dbh, char *q) {
  MapiHdl ret = query(dbh, q);

  if (mapi_close_handle(ret) != MOK)
    die(dbh, ret);
}

int main(int argc, char *argv[]) {
  Mapi dbh;
  MapiHdl hdl = NULL;
  char *name;
  char *age;
  dbh = mapi_connect("localhost", 50000, "monetdb", "monetdb", "sql", "demo");

  if (mapi_error(dbh))
    die(dbh, hdl);

  update(dbh, "CREATE TABLE emp (name VARCHAR(20), age INT)");
  update(dbh, "INSERT INTO emp VALUES ('John', 23)");
  update(dbh, "INSERT INTO emp VALUES ('Mary', 22)");

  hdl = query(dbh, "SELECT * FROM emp");

  while (mapi_fetch_row(hdl)) {
    name = mapi_fetch_field(hdl, 0);
    age = mapi_fetch_field(hdl, 1);
    printf("%s is %s\n", name, age);
  }

  mapi_close_handle(hdl);
  mapi_destroy(dbh);
  return(0);
} 

The mapi_connect() operation establishes a communication channel with a running server. The query language interface is either "sql" or "mal".

Errors on the interaction can be captured using mapi_error(), possibly followed by a request to dump a short error message explanation on a standard file location. It has been abstracted away in a function.

Provided we can establish a connection, the interaction proceeds as in many similar application development packages. Queries are shipped for execution using mapi_query() and an answer table can be consumed one row at a time. In many cases these functions suffice.

The Mapi interface provides caching of rows at the client side. mapi_query() will load tuples into the cache, after which they can be read repeatedly using mapi_fetch_row() or directly accessed (mapi_seek_row()). This facility is particularly handy when small, but stable query results are repeatedly used in the client program.

To ease communication between application code and the cache entries, the user can bind the C-variables both for input and output to the query parameters, and output columns, respectively. The query parameters are indicated by '?' and may appear anywhere in the query template.

The Mapi library expects complete lines from the server as answers to query actions. Incomplete lines leads to Mapi waiting forever on the server. Thus formatted printing is discouraged in favor of tabular printing as offered by the table.print() commands.

The following action is needed to get a working program. Compilation of the application relies on libtool and the pkg-config programs that should be shipped with your installation.  The application above can be compiled and linked as follows:

% libtool --mode=compile --tag=CC gcc -c `env PKG_CONFIG_PATH=$INSTALL_DIR/lib/pkgconfig pkg-config --cflags monetdb-mapi` test.c % libtool --mode=link --tag=CC gcc -o test `env PKG_CONFIG_PATH=$INSTALL_DIR/lib/pkgconfig pkg-config --libs monetdb-mapi` test.o % ./test 

The example assumes you have set the variable INSTALL_DIR to the prefix location given during configure of MonetDB.  If you use a system installation, you can omit the 'env PKGCONFIG_PATH=.....' part, or set INSTALL_DIR to '/usr'.

The compilation on Windows is slightly more complicated. It requires more attention towards the location of the include files and libraries.

Command Summary

The quick reference guide to the Mapi library is given below. More details on their constraints and defaults are given in the next section.

mapi_bind() Bind string C-variable to a field
mapi_bind_numeric() Bind numeric C-variable to field
mapi_bind_var() Bind typed C-variable to a field
mapi_cache_freeup() Forcefully shuffle fraction for cache refreshment
mapi_cache_limit() Set the tuple cache limit
mapi_clear_bindings() Clear all field bindings
mapi_clear_params() Clear all parameter bindings
mapi_close_handle() Close query handle and free resources
mapi_connect() Connect to a Mserver
mapi_destroy() Free handle resources
mapi_disconnect() Disconnect from server
mapi_error() Test for error occurrence
mapi_error_str() Return error string
mapi_execute() Execute a query
mapi_execute_array() Execute a query using string arguments
mapi_explain() Display error message and context on stream
mapi_explain_query() Display error message and context on stream
mapi_explain_result() Display error message and context on stream
mapi_fetch_all_rows() Fetch all answers from server into cache
mapi_fetch_field() Fetch a field from the current row
mapi_fetch_field_array() Fetch all fields from the current row
mapi_fetch_field_len() Fetch the length of a field from the current row
mapi_fetch_line() Retrieve the next line
mapi_fetch_reset() Set the cache reader to the beginning
mapi_fetch_row() Fetch row of values
mapi_finish() Terminate the current query
mapi_get_dbname() Database being served
mapi_get_field_count() Number of fields in current row
mapi_get_from() Get the stream 'from'
mapi_get_host() Host name of server
mapi_get_language() Query language name
mapi_get_last_id() last inserted id of an auto_increment (or alike) column
mapi_get_mapi_version() Mapi version name
mapi_get_monet_versionId() MonetDB version identifier
mapi_get_monet_version() MonetDB version name
mapi_get_motd() Get server welcome message
mapi_get_query() Query being executed
mapi_get_row_count() Number of rows in cache or -1
mapi_get_to() Get the stream 'to'
mapi_get_trace() Get trace flag
mapi_get_user() Current user name
mapi_log() Keep log of client/server interaction
mapi_needmore() Return whether more data is needed
mapi_next_result() Go to next result set
mapi_output() Set output format
mapi_ping() Test server for accessibility
mapi_prepare() Prepare a query for execution
mapi_prepare_array() Prepare a query for execution using arguments
mapi_profile() Set profile flag
mapi_query() Send a query for execution
mapi_query_array() Send a query for execution with arguments
mapi_query_handle() Send a query for execution
mapi_quick_query_array() Send a query for execution with arguments
mapi_quick_query() Send a query for execution
mapi_quick_response() Quick pass response to stream
mapi_quote() Escape characters
mapi_reconnect() Reconnect with a clean session context
mapi_result_error() Return error string
mapi_result_errorcode() Return error SQLSTATE code string
mapi_rows_affected() Obtain number of rows changed
mapi_seek_row() Move row reader to specific location in cache
mapi_setAlgebra() Use algebra backend
mapi_setAutocommit() Set auto-commit flag
mapi_stream_into() Stream document into server
mapi_table() Get current table name
mapi_timeout() Set timeout in milliseconds for long-running queries
mapi_trace() Set trace flag
mapi_unquote() remove escaped characters
mapi_virtual_result() Submit a virtual result set

Library Synopsis

The routines to build a MonetDB application are grouped in the library MonetDB Programming Interface, or shorthand Mapi.

The protocol information is stored in a Mapi interface descriptor (mid). This descriptor can be used to ship queries, which return a MapiHdl to represent the query answer. The application can set up several channels with the same or a different mserver. It is the programmer's responsibility not to mix the descriptors in retrieving the results.

The application may be multi-threaded as long as the user respects the individual connections represented by the database handlers.

The interface assumes a cautious user, who understands and has experience with the query or programming language model. It should also be clear that references returned by the API point directly into the administrative structures of Mapi. This means that they are valid only for a short period, mostly between successive mapi_fetch_row() commands. It also means that it the values are to retained, they have to be copied. A defensive programming style is advised.

Upon an error, the routines mapi_explain() and mapi_explain_query() give information about the context of the failed call, including the expression shipped and any response received. The side-effect is clearing the error status.

Error Message

Almost every call can fail since the connection with the database server can fail at any time. Functions that return a handle (either Mapi or MapiHdl) may return NULL on failure, or they may return the handle with the error flag set. If the function returns a non-NULL handle, always check for errors with mapi_error.

Functions that return MapiMsg indicate success and failure with the following codes.

 

MOK No error
MERROR Mapi internal error.
MTIMEOUT Error communicating with the server.

 

When these functions return MERROR or MTIMEOUT, an explanation of the error can be had by calling one of the functions mapi_error_str(), mapi_explain(), or mapi_explain_query().

To check for error messages from the server, call mapi_result_error(). This function returns NULL if there was no error, or the error message if there was. A user-friendly message can be printed using map_explain_result(). Typical usage is:

do {
    if ((error = mapi_result_error(hdl)) != NULL)
        mapi_explain_result(hdl, stderr);
    while ((line = mapi_fetch_line(hdl)) != NULL)
        /* use output */;
} while (mapi_next_result(hdl) == 1);

Mapi Function Reference

Connecting and Disconnecting

  • Mapi mapi_connect(const char *host, int port, const char *username, const char *password, const char *lang, const char *dbname)

    Setup a connection with a Mserver at a host:port and login with username and password. If host == NULL, the local host is accessed. If host starts with a '/' and the system supports it, host is actually the name of a UNIX domain socket, and port is ignored. If port == 0, a default port is used. If username == NULL, the username of the owner of the client application containing the Mapi code is used. If password == NULL, the password is omitted. The preferred query language is any of {sql,mil,mal,xquery }. On success, the function returns a pointer to a structure with administration about the connection.

  • MapiMsg mapi_disconnect(Mapi mid)

    Terminate the session described by mid. The only possible uses of the handle after this call is mapi_destroy() and mapi_reconnect(). Other uses lead to failure.

  • MapiMsg mapi_destroy(Mapi mid)

    Terminate the session described by mid if not already done so, and free all resources. The handle cannot be used anymore.

  • MapiMsg mapi_reconnect(Mapi mid)

    Close the current channel (if still open) and re-establish a fresh connection. This will remove all global session variables.

  • MapiMsg mapi_ping(Mapi mid)

    Test availability of the server. Returns zero upon success.

Sending Queries

  • MapiHdl mapi_query(Mapi mid, const char *Command)

    Send the Command to the database server represented by mid. This function returns a query handle with which the results of the query can be retrieved. The handle should be closed with mapi_close_handle(). The command response is buffered for consumption, c.f. mapi_fetch_row().

  • MapiMsg mapi_query_handle(MapiHdl hdl, const char *Command)

    Send the Command to the database server represented by hdl, reusing the handle from a previous query. If Command is zero it takes the last query string kept around. The command response is buffered for consumption, e.g. mapi_fetch_row().

  • MapiHdl mapi_query_array(Mapi mid, const char *Command, char **argv)

    Send the Command to the database server replacing the placeholders (?) by the string arguments presented.

  • MapiHdl mapi_quick_query(Mapi mid, const char *Command, FILE *fd)

    Similar to mapi_query(), except that the response of the server is copied immediately to the file indicated.

  • MapiHdl mapi_quick_query_array(Mapi mid, const char *Command, char **argv, FILE *fd)

    Similar to mapi_query_array(), except that the response of the server is not analyzed, but shipped immediately to the file indicated.

  • MapiHdl mapi_prepare(Mapi mid, const char *Command)

    Move the query to a newly allocated query handle (which is returned). Possibly interact with the back-end to prepare the query for execution.

  • MapiMsg mapi_execute(MapiHdl hdl)

    Ship a previously prepared command to the backend for execution. A single answer is pre-fetched to detect any runtime error. MOK is returned upon success.

  • MapiMsg mapi_execute_array(MapiHdl hdl, char **argv)

    Similar to mapi_execute but replacing the placeholders for the string values provided.

  • MapiMsg mapi_finish(MapiHdl hdl)

    Terminate a query. This routine is used in the rare cases that consumption of the tuple stream produced should be prematurely terminated. It is automatically called when a new query using the same query handle is shipped to the database and when the query handle is closed with mapi_close_handle().

  • MapiMsg mapi_virtual_result(MapiHdl hdl, int columns, const char **columnnames, const char **columntypes, const int *columnlengths, int tuplecount, const char ***tuples)

    Submit a table of results to the library that can then subsequently be accessed as if it came from the server. columns is the number of columns of the result set and must be greater than zero. columnnames is a list of pointers to strings giving the names of the individual columns. Each pointer may be NULL and columnnames may be NULL if there are no names. tuplecount is the length (number of rows) of the result set. If tuplecount is less than zero, the number of rows is determined by a NULL pointer in the list of tuples pointers. tuples is a list of pointers to row values. Each row value is a list of pointers to strings giving the individual results. If one of these pointers is NULL it indicates a NULL/nil value.

Getting Results

  • int mapi_get_field_count(MapiHdl mid)

    Return the number of fields in the current row.

  • mapi_int64 mapi_get_row_count(MapiHdl mid)

    If possible, return the number of rows in the last select call. A -1 is returned if this information is not available.

  • mapi_int64 mapi_get_last_id(MapiHdl mid)

    If possible, return the last inserted id of auto_increment (or alike) column. A -1 is returned if this information is not available. We restrict this to single row inserts and one auto_increment column per table. If the restrictions do not hold, the result is unspecified.

  • mapi_int64 mapi_rows_affected(MapiHdl hdl)

    Return the number of rows affected by a database update command such as SQL's INSERT/DELETE/UPDATE statements.

  • int mapi_fetch_row(MapiHdl hdl)

    Retrieve a row from the server. The text retrieved is kept around in a buffer linked with the query handle from which selective fields can be extracted. It returns the number of fields recognized. A zero is returned upon encountering end of sequence or error. This can be analyzed in using mapi_error().

  • mapi_int64 mapi_fetch_all_rows(MapiHdl hdl)

    All rows are cached at the client side first. Subsequent calls to mapi_fetch_row() will take the row from the cache. The number or rows cached is returned.

  • int mapi_quick_response(MapiHdl hdl, FILE *fd)

    Read the answer to a query and pass the results verbatim to a stream. The result is not analyzed or cached.

  • MapiMsg mapi_seek_row(MapiHdl hdl, mapi_int64 rownr, int whence)

    Reset the row pointer to the requested row number. If whence is MAPI_SEEK_SET, rownr is the absolute row number (0 being the first row); if whence is MAPI_SEEK_CUR, rownr is relative to the current row; if whence is MAPI_SEEK_END, rownr is relative to the last row.

  • MapiMsg mapi_fetch_reset(MapiHdl hdl)

    Reset the row pointer to the first line in the cache. This need not be a tuple. This is mostly used in combination with fetching all tuples at once.

  • char **mapi_fetch_field_array(MapiHdl hdl)

    Return an array of string pointers to the individual fields. A zero is returned upon encountering end of sequence or error. This can be analyzed in using mapi_error().

  • char *mapi_fetch_field(MapiHdl hdl, int fnr)

    Return a pointer a C-string representation of the value returned. A zero is returned upon encountering an error or when the database value is NULL; this can be analyzed in using mapi_error().

  • size_t mapi_fetch_fiels_len(MapiHdl hdl, int fnr)

    Return the length of the C-string representation excluding trailing NULL byte of the value. Zero is returned upon encountering an error, when the database value is NULL, of when the string is the empty string. This can be analyzed by using mapi_error() and mapi_fetch_field().

  • MapiMsg mapi_next_result(MapiHdl hdl)

    Go to the next result set, discarding the rest of the output of the current result set.

Errors handling

  • MapiMsg mapi_error(Mapi mid)

    Return the last error code or 0 if there is no error.

  • const char *mapi_error_str(Mapi mid)

    Return a pointer to the last error message.

  • const char *mapi_result_error(MapiHdl hdl)

    Return a pointer to the last error message from the server.

  • const char *mapi_result_errorcode(MapiHdl hdl)

    Return a pointer to the SQLSTATE code of the last error from the server.

  • void mapi_explain(Mapi mid, FILE *fd)

    Write the error message obtained from mserver to a file.

  • void mapi_explain_query(MapiHdl hdl, FILE *fd)

    Write the error message obtained from mserver to a file.

  • void mapi_explain_result(MapiHdl hdl, FILE *fd)

    Write the error message obtained from mserver to a file.

Parameters

  • MapiMsg mapi_bind(MapiHdl hdl, int fldnr, char **val)

    Bind a string variable with a field in the return table. Upon a successful subsequent mapi_fetch_row() the indicated field is stored in the space pointed to by val. Returns an error if the field identified does not exist.

  • MapiMsg mapi_bind_var(MapiHdl hdl, int fldnr, int type, void *val)

    Bind a variable to a field in the return table. Upon a successful subsequent mapi_fetch_row(), the indicated field is converted to the given type and stored in the space pointed to by val. The types recognized are { MAPI_TINY, MAPI_UTINY, MAPI_SHORT, MAPI_USHORT, MAPI_INT, MAPI_UINT, MAPI_LONG, MAPI_ULONG, MAPI_LONGLONG, MAPI_ULONGLONG, MAPI_CHAR, MAPI_VARCHAR, MAPI_FLOAT, MAPI_DOUBLE, MAPI_DATE, MAPI_TIME, MAPI_DATETIME }. The binding operations should be performed after the mapi_execute command. Subsequently all rows being fetched also involve delivery of the field values in the C-variables using proper conversion. For variable length strings a pointer is set into the cache.

  • MapiMsg mapi_bind_numeric(MapiHdl hdl, int fldnr, int scale, int precision, void *val)

    Bind to a numeric variable, internally represented by MAPI_INT Describe the location of a numeric parameter in a query template.

  • MapiMsg mapi_clear_bindings(MapiHdl hdl)

    Clear all field bindings.

  • MapiMsg mapi_param(MapiHdl hdl, int fldnr, char **val)

    Bind a string variable with the n-th placeholder in the query template. No conversion takes place.

  • MapiMsg mapi_param_type(MapiHdl hdl, int fldnr, int ctype, int sqltype, void *val)

    Bind a variable whose type is described by ctype to a parameter whose type is described by sqltype.

  • MapiMsg mapi_param_numeric(MapiHdl hdl, int fldnr, int scale, int precision, void *val)

    Bind to a numeric variable, internally represented by MAPI_INT.

  • MapiMsg mapi_param_string(MapiHdl hdl, int fldnr, int sqltype, char *val, int *sizeptr)

    Bind a string variable, internally represented by MAPI_VARCHAR, to a parameter. The sizeptr parameter points to the length of the string pointed to by val. If sizeptr == NULL or *sizeptr == -1, the string is NULL-terminated.

  • MapiMsg mapi_clear_params(MapiHdl hdl)

    Clear all parameter bindings.

Miscellaneous

  • MapiMsg mapi_setAutocommit(Mapi mid, int autocommit)

    Set the autocommit flag (default is on). This only has effect when the language is SQL. In that case, the server commits after each statement sent to the server.  More information about autocommit and multi-statements transactions can be found here.

  • MapiMsg mapi_setAlgebra(Mapi mid, int algebra)

    Tell the backend to use or stop using the algebra-based compiler.

  • MapiMsg mapi_cache_limit(Mapi mid, int maxrows)

    A limited number of tuples are pre-fetched after each execute(). If maxrows is negative, all rows will be fetched before the application is permitted to continue. Once the cache is filled, a number of tuples are shuffled to make room for new ones, but taking into account non-read elements. Filling the cache quicker than reading leads to an error.

  • MapiMsg mapi_cache_freeup(MapiHdl hdl, int percentage)

    Forcefully shuffle the cache making room for new rows. It ignores the read counter, so rows may be lost.

  • char * mapi_quote(const char *str, int size)

    Escape special characters such as \n, \t in str with backslashes. The returned value is a newly allocated string which should be freed by the caller.

  • char * mapi_unquote(const char *name)

    The reverse action of mapi_quote(), turning the database representation into a C-representation. The storage space is dynamically created and should be freed after use.

  • MapiMsg mapi_output(Mapi mid, char *output)

    Set the output format for results send by the server.

  • MapiMsg mapi_stream_into(Mapi mid, char *docname, char *colname, FILE *fp)

    Stream a document into the server. The name of the document is specified in docname, the collection is optionally specified in colname (if NULL, it defaults to docname), and the content of the document comes from fp.

  • MapiMsg mapi_profile(Mapi mid, int flag)

    Set the profile flag to time commands send to the server.

  • MapiMsg mapi_timeout(Mapi mid, unsigned int time)

    Set timeout in milliseconds for long-running queries.

  • void mapi_trace(Mapi mid, int flag)

    Set the trace flag to monitor interaction of the client with the library. It is primarilly used for debugging Mapi applications.

  • int mapi_get_trace(Mapi mid)

    Return the current value of the trace flag.

  • MapiMsg mapi_log(Mapi mid, const char *fname)

    Log the interaction between the client and server for offline inspection. Beware that the log file overwrites any previous log. For detailed interaction trace with the Mapi library itself use mapi_trace().

The remaining operations are wrappers around the data structures maintained. Note that column properties are derived from the table output returned from the server.

  • char *mapi_get_name(MapiHdl hdl, int fnr)
  • char *mapi_get_type(MapiHdl hdl, int fnr)
  • char *mapi_get_table(MapiHdl hdl, int fnr)
  • int mapi_get_len(Mapi mid, int fnr)
  • char *mapi_get_dbname(Mapi mid)
  • char *mapi_get_host(Mapi mid)
  • char *mapi_get_user(Mapi mid)
  • char *mapi_get_lang(Mapi mid)
  • char *mapi_get_motd(Mapi mid)

 

The mapi library source code can be found in MonetDB source tree at /clients/mapilib

 

JDBC Driver

JDBC Driver mk Sun, 03/28/2010 - 23:58

MonetDB JDBC Driver

The most obvious way to connect to a data source using the Java programming language is by making use of the JDBC API. MonetDB supplies a 100% pure Java JDBC driver (type 4) which allows to connect and work with a MonetDB database from a Java program without any other libraries needed.

This document gives a short description how to use the MonetDB JDBC driver in Java applications. Familiarity with the Java JDBC API is required to fully understand this document. Please note that you can find the complete JDBC API on Oracle's web site http://docs.oracle.com/javase/7/docs/technotes/guides/jdbc/index.html.

The latest release of the MonetDB JDBC driver has implemented most of the essential JDBC API classes and methods. If you make extensive use of JDBC API and semantics and rely on its features, please report any missing functionality on our bugzilla.

In order to use the MonetDB JDBC driver in Java applications you need (of course) a running MonetDB/SQL server instance (mserver5 process running), preferably via monetdbd.

Getting the JDBC driver Jar

The easiest way to acquire the JDBC driver is to download it from our MonetDB Java Download Area. You will find a jar file called monetdb-jdbc-X.Y.jre7.jar where X and Y are major and minor version numbers. The other two listed jar files (jdbcclient.jre7.jar and monetdb-mcl-*.jre7.jar) are optional utility jars. jdbcclient.jre7.jar contains a java command line program similar (but not equal) to mclient, see below.

Compiling the driver (using ant, optional)

If you prefer to build the driver yourself, make sure you acquire the MonetDB Java repository, e.g. as part of the source downloads. The Java sources are built using Apache's Ant tool and a make file. Simply issuing the command ant distjdbc should be sufficient to build the driver jar-archive in the subdirectory jars. See the ant web site for more documentation on the ant build-tool: http://ant.apache.org/. The Java sources currently require at least a Java 8 compatible compiler.

Using the JDBC driver in your Java programs

To use the MonetDB JDBC driver, the monetdb-jdbc-X.Y.jre7.jar jar-archive has to be in the Java classpath. Make sure this is actually the case. Note: as of Jul2015 release (monetdb-jdbc-2.17.jar) the MonetDB JDBC Driver only works with Java 7 (or higher) JVMs.

Using the MonetDB JDBC driver in your Java program:

  import java.sql.*;

  // request a Connection to a MonetDB server running on 'localhost' (with default port 50000) for database demo for user and password monetdb
  Connection con = DriverManager.getConnection("jdbc:monetdb://localhost/demo", "monetdb", "monetdb");

The MonetDB JDBC Connection URL string format passed to the "getConnection()"method is defined as

   jdbc:monetdb://<hostname>[:<portnr>]/<databasename>[?<property>=<value>[&<property>=<value>]]

where elements between "<" and ">" are required and elements between "[" and "]" are optional.

Following optional connection properties are allowed:

	so_timeout=<time in milliseconds>
	language=mal
	language=sql
	treat_blob_as_binary=true
	treat_clob_as_varchar=true
	hash=<sha512, sha384>
	user=<login name>
	password=<secret value>
	debug=true
	logfile=<name logfile>

A sample Java JDBC program

import java.sql.*;

/**
 * This example assumes there exist tables a and b filled with some data.
 * On these tables some queries are executed and the JDBC driver is tested
 * on it's accuracy and robustness against 'users'.
 *
 * @author Fabian Groffen
 */
public class MJDBCTest {
    public static void main(String[] args) throws Exception {
        Connection con = null;
        Statement st = null;
        ResultSet rs = null;

        try {
            String con_url = "jdbc:monetdb://localhost:50000/mydb?so_timeout=10000&treat_clob_as_varchar=true";
            // make a connection to the MonetDB server using JDBC URL starting with: jdbc:monetdb:// 
            con = DriverManager.getConnection(con_url, "monetdb", "monetdb");
            // make a statement object
            st = con.createStatement();
            // execute SQL query which returns a ResultSet object
            String qry = "SELECT a.var1, COUNT(b.id) as total FROM a, b WHERE a.var1 = b.id AND a.var1 = 'andb' GROUP BY a.var1 ORDER BY a.var1, total;"
            rs = st.executeQuery(qry);
            // get meta data and print column names with their type
            ResultSetMetaData md = rs.getMetaData();
            for (int i = 1; i <= md.getColumnCount(); i++) {
                System.out.print(md.getColumnName(i) + ":" + md.getColumnTypeName(i) + "\t");
            }
            System.out.println("");
            // now print the data: only the first 5 rows, while there probably are
            // a lot more. This shouldn't cause any problems afterwards since the
            // result should get properly discarded when we close it
            for (int i = 0; rs.next() && i < 5; i++) {
                for (int j = 1; j <= md.getColumnCount(); j++) {
                    System.out.print(rs.getString(j) + "\t");
                }
                System.out.println("");
            }
            // close (server) resource as soon as we are done processing resultset data
            rs.close();
            rs = null;

            // tell the driver to only return 5 rows for the next execution
            // it can optimize on this value, and will not fetch any more than 5 rows.
            st.setMaxRows(5);
            // we ask the database for 22 rows, while we set the JDBC driver to
            // 5 rows, this shouldn't be a problem at all...
            rs = st.executeQuery("select * from a limit 22");
            int var1_cnr = rs.findColumn("var1");
            int var2_cnr = rs.findColumn("var2");
            int var3_cnr = rs.findColumn("var3");
            int var4_cnr = rs.findColumn("var4");
            // read till the driver says there are no rows left
            for (int i = 0; rs.next(); i++) {
                System.out.println(
                    "[" + rs.getString(var1_cnr) + "]" +
                    "[" + rs.getString(var2_cnr) + "]" +
                    "[" + rs.getInt(var3_cnr) + "]" +
                    "[" + rs.getString(var4_cnr) + "]" );
            }
            // close (server) resource as soon as we are done processing resultset data
            rs.close();
            rs = null;

            // unset the row limit; 0 means as much as the database sends us
            st.setMaxRows(0);
            // we only ask 10 rows
            rs = st.executeQuery("select * from b limit 10;");
            int rowid_cnr = rs.findColumn("rowid");
            int id_cnr = rs.findColumn("id");
            var1_cnr = rs.findColumn("var1");
            var2_cnr = rs.findColumn("var2");
            var3_cnr = rs.findColumn("var3");
            var4_cnr = rs.findColumn("var4");
            // and simply print them
            while (rs.next()) {
                System.out.println(
                    rs.getInt(rowid_cnr) + ", " +
                    rs.getString(id_cnr) + ", " +
                    rs.getInt(var1_cnr) + ", " +
                    rs.getInt(var2_cnr) + ", " +
                    rs.getString(var3_cnr) + ", " +
                    rs.getString(var4_cnr) );
            }
            // close (server) resource as soon as we are done processing resultset data
            rs.close();
            rs = null;

            // perform a ResultSet-less query (with no trailing ; since that should
            // be possible as well and is JDBC standard)
            int updCount = st.executeUpdate("delete from a where var1 = 'zzzz'");
            System.out.println("executeUpdate() returned: " + updCount);
        } catch (SQLException se) {
            System.out.println(se.getMessage());
        } finally {
            // when done, close all (server) resources
            if (rs != null) rs.close();
            if (st != null) st.close();
            if (con != null) con.close();
        }
    }
}

Note: it is no longer required (or recommended) to include code line:

  Class.forName("nl.cwi.monetdb.jdbc.MonetDriver");

as the MonetDriver class registers itself with the JDBC DriverManager automatically when the monetdb-jdbc-X.Y.jre7.jar file is loaded.

 

Note: The JdbcClient program is an example program which uses the JDBC API. See JdbcClient for more information.

ODBC Driver

ODBC Driver mk Sun, 03/28/2010 - 23:59

MonetDB ODBC Driver

Short for Open DataBase Connectivity, a standard database access method developed by the SQL Access group in 1992. The goal of ODBC is to make it possible to access any data from any application, regardless of which database management system (DBMS) is handling the data. ODBC manages this by inserting a middle layer, called a database driver, between an application and the DBMS. The purpose of this layer is to translate the application's data queries into commands that the DBMS understands. For this to work, both the application and the DBMS must be ODBC-compliant – that is, the application must be capable of issuing ODBC commands and the DBMS must be capable of responding to them.

The ODBC driver for MonetDB is included in the Windows installer and Linux RPMs. The source can be found in the SQL CVS tree.

To help you setup your system to use the ODBC driver with MonetDB, two how-tos are available, one for Windows users and one for Linux/UNIX users.

Microsoft Excel demo

A little demo showing how to import data from a MonetDB server into Microsoft Excel.

Using Excel with the MonetDB ODBC Driver

Start up the MonetDB SQL Server and Excel.

In Excel, select from the drop down menu, first Data, then Get External Data, and finally New Database Query...

excel1.png

If MonetDB was installed correctly, there should be an entry MonetDB in the dialog box that opens. Select it and click on OK.

excel2.png

In the wizard that opens, scroll down in the list on the left hand side and select voyages. Then click on the button labeled > and then on Next >.

excel3.png

In the next page of the wizard, click on Next >.

excel4.png

In the next page of the wizard, click on Next >.

excel5.png

In the final page of the wizard, click on Finish.

excel6.png

A new dialog window opens. Click on OK to insert the data into the current Excel worksheet.

excel7.png

That's all.

excel8.png

Installing the MonetDB ODBC Driver for unixODBC

Configuring the MonetDB Driver

As Superuser, start the unixODBC configuration program ODBCConfig and select the Drivers tab.

uodbc1.png

On this tab, click on the button labeled Add... and fill in the fields as follows.

uodbc2.png
Name
MonetDB
Description
ODBC Driver for MonetDB SQL Server
Driver
<path-to-MonetDB>/lib(64)/libMonetODBC.so
Setup
<path-to-MonetDB>/lib(64)/libMonetODBCs.so

Don't change the other fields. When done, click on the check mark in the top left corner of the window. The first window should now contain an entry for MonetDB. Click on OK

Configuring a Data Source

Now as normal user start ODBCConfig again.

uodbc3.png

On the User DSN tab click on the Add... button. A new window pops up in which you have to select the ODBC driver. Click on the entry for MonetDB and click on OK.

uodbc4.png

A new window pops up. Fill in the fields as follows.

uodbc5.png
Name
MonetDB
Description
Default MonetDB Data Source
Host
localhost
Port
50000
User
monetdb
Password
monetdb

Don't change the other fields. When done, click on the check mark in the top left corner of the window. The first window should now contain an entry for MonetDB. Click on OK

Python Library

Python Library mk Sun, 03/28/2010 - 23:58

The MonetDB MAPI and SQL client python API

Introduction

This is the native python client API. This API is cross-platform, and doesn't depend on any monetdb libraries. It has support for python 2.7 and 3.3+ and is Python DBAPI 2.0 compatible.

Installation

To install the MonetDB python API run the following command:

# pip install pymonetdb

That's all, now you are ready to start using the API. We recommend that you use virtual environments to avoid polluting your global python installation.

Documentation

The python code is well documented, so if you need to find documentation you should have a look at the source code. Below is an interactive example on how to use the monetdb SQL API which should get you started quite fast.

Examples

There are some examples in the 'examples' folder, but here are is a line by line example of the SQL API:

> # import the SQL module
> import pymonetdb
>
> # set up a connection. arguments below are the defaults
> connection = pymonetdb.connect(username="monetdb", password="monetdb", hostname="localhost", database="demo")
>
> # create a cursor
> cursor = connection.cursor()
>
> # increase the rows fetched to increase performance (optional)
> cursor.arraysize = 100
>
> # execute a query (return the number of rows to fetch)
> cursor.execute('SELECT * FROM tables')
26
>
> # fetch only one row
> cursor.fetchone()
(1062, 'schemas', 1061, None, 0, True, 0, 0)
>
> # fetch the remaining rows
> cursor.fetchall()
[(1067, 'types', 1061, None, 0, True, 0, 0),
 (1076, 'functions', 1061, None, 0, True, 0, 0),
 (1085, 'args', 1061, None, 0, True, 0, 0),
 (1093, 'sequences', 1061, None, 0, True, 0, 0),
 (1103, 'dependencies', 1061, None, 0, True, 0, 0),
 (1107, 'connections', 1061, None, 0, True, 0, 0),
 (1116, '_tables', 1061, None, 0, True, 0, 0),
 ...
 (4141, 'user_role', 1061, None, 0, True, 0, 0),
 (4144, 'auths', 1061, None, 0, True, 0, 0),
 (4148, 'privileges', 1061, None, 0, True, 0, 0)]
>
> # Show the table meta data
> cursor.description
[('id', 'int', 4, 4, None, None, None),
 ('name', 'varchar', 12, 12, None, None, None),
 ('schema_id', 'int', 4, 4, None, None, None),
 ('query', 'varchar', 168, 168, None, None, None),
 ('type', 'smallint', 1, 1, None, None, None),
 ('system', 'boolean', 5, 5, None, None, None),
 ('commit_action', 'smallint', 1, 1, None, None, None),
 ('temporary', 'tinyint', 1, 1, None, None, None)]

If you would like to communicate with the database at a lower level you can use the MAPI library:

> from pymonetdb import mapi
> mapi_connection = mapi.Connection()
> mapi_connection.connect(hostname="localhost", port=50000, username="monetdb", password="monetdb", database="demo", language="sql", unix_socket=None, connect_timeout=-1)
> mapi_connection.cmd("sSELECT * FROM tables;")
...

Perl Library

Perl Library mk Sun, 03/28/2010 - 23:56

MonetDB Perl Library

Perl is one of the more common scripting languages for which a 'standard' database application programming interface is defined. It is called DBI and it was designed to protect you from the API library details of multiple DBMS vendors. It has a very simple interface to execute SQL queries and for processing the results sent back. DBI doesn't know how to talk to any particular database, but it does know how to locate and load in DBD (`Database Driver') modules. The DBD modules encapsulate the interface library's intricacies and knows how to talk to the real databases.

MonetDB comes with its own DBD module which is included in both the source and binary distribution packages. The module is also available via CPAN.

Two sample Perl applications are included in the source distribution; a MIL session and a simple client to interact with a running server.

For further documentation we refer to the Perl community home page.

A Simple Perl Example

use strict;
use warnings;
use DBI();

print "\nStart a simple Monet MIL interaction\n\n";

# determine the data sources:
my @ds = DBI->data_sources('monetdb');
print "data sources: @ds\n";

# connect to the database:
my $dsn = 'dbi:monetdb:database=test;host=localhost;port=50000;language=mil';
my $dbh = DBI->connect( $dsn,
  undef, undef,  # no authentication in MIL
  { PrintError => 0, RaiseError => 1 }  # turn on exception handling
);
{
  # simple MIL statement:
  my $sth = $dbh->prepare('print(2);');
  $sth->execute;
  my @row = $sth->fetchrow_array;
  print "field[0]: $row[0], last index: $#row\n";
}
{
  my $sth = $dbh->prepare('print(3);');
  $sth->execute;
  my @row = $sth->fetchrow_array;
  print "field[0]: $row[0], last index: $#row\n";
}
{
  # deliberately executing a wrong MIL statement:
  my $sth = $dbh->prepare('( xyz 1);');
  eval { $sth->execute }; print "ERROR REPORTED: $@" if $@;
}
$dbh->do('var b:=new(int,str);');
$dbh->do('insert(b,3,"three");');
{
  # variable binding stuff:
  my $sth = $dbh->prepare('insert(b,?,?);');
  $sth->bind_param( 1,     7 , DBI::SQL_INTEGER() );
  $sth->bind_param( 2,'seven' );
  $sth->execute;
}
{
  my $sth = $dbh->prepare('print(b);');
  # get all rows one at a time:
  $sth->execute;
  while ( my $row = $sth->fetch ) {
    print "bun: $row->[0], $row->[1]\n";
  }
  # get all rows at once:
  $sth->execute;
  my $t = $sth->fetchall_arrayref;
  my $r = @$t;         # row count
  my $f = @{$t->[0]};  # field count
  print "rows: $r, fields: $f\n";
  for my $i ( 0 .. $r-1 ) {
    for my $j ( 0 .. $f-1 ) {
      print "field[$i,$j]: $t->[$i][$j]\n";
    }
  }
}
{
  # get values of the first column from each row:
  my $row = $dbh->selectcol_arrayref('print(b);');
  print "head[$_]: $row->[$_]\n" for 0 .. 1;
}
{
  my @row = $dbh->selectrow_array('print(b);');
  print "field[0]: $row[0]\n";
  print "field[1]: $row[1]\n";
}
{
  my $row = $dbh->selectrow_arrayref('print(b);');
  print "field[0]: $row->[0]\n";
  print "field[1]: $row->[1]\n";
}
$dbh->disconnect;
print "\nFinished\n";