From 6b21abb5fe4cb241af04e2847a0e5ca325129734 Mon Sep 17 00:00:00 2001 From: Evgeniy Osintsev Date: Mon, 22 Aug 2022 17:55:13 +0400 Subject: [PATCH 1/2] Add description of the now() and date_part() functions Part of #2575 --- doc/reference/reference_sql/sql-features.rst | 589 +++++++++--------- .../sql_statements_and_clauses.rst | 107 +++- .../reference_sql/sql_user_guide.rst | 2 +- 3 files changed, 400 insertions(+), 298 deletions(-) diff --git a/doc/reference/reference_sql/sql-features.rst b/doc/reference/reference_sql/sql-features.rst index 21ea906b30..aa1bb1f161 100644 --- a/doc/reference/reference_sql/sql-features.rst +++ b/doc/reference/reference_sql/sql-features.rst @@ -53,7 +53,7 @@ E011, Numeric data types * - E011-04 - Arithmetic operators - ``SELECT 10+1, 9-2, 8*3, 7/2 FROM t;`` - - :ref:`Okay `. + - :ref:`Okay `. * - E011-05 - Numeric comparisons - ``SELECT * FROM t WHERE 1 < 2;`` @@ -76,7 +76,7 @@ E021, Character string types * - Feature ID - Feature - Example - - Tests + - Tests * - E021-01 - Character data type (including all its spellings) - ``CREATE TABLE t44 (s1 CHAR PRIMARY KEY);`` @@ -85,17 +85,17 @@ E021, Character string types - CHARACTER VARYING data type (including all its spellings) - ``CREATE TABLE t45 (s1 VARCHAR PRIMARY KEY);`` - Fail, Tarantool only allows VARCHAR(n), which is a - synonym for :ref:`STRING `. + synonym for :ref:`STRING `. * - E021-03 - Character literals - ``INSERT INTO t45 VALUES ('');`` - Okay, and the bad practice of accepting ``""`` for - character literals is avoided. + character literals is avoided. * - E021-04 - CHARACTER_LENGTH function - ``SELECT character_length(s1) FROM t;`` - Okay. Tarantool treats this as a synonym of - :ref:`LENGTH() `. + :ref:`LENGTH() `. * - E021-05 - OCTET_LENGTH - ``SELECT octet_length(s1) FROM t;`` @@ -108,7 +108,7 @@ E021, Character string types * - E021-07 - Character concatenation - ``SELECT 'a' || 'b' FROM t;`` - - :ref:`Okay `. + - :ref:`Okay `. * - E021-08 - UPPER and LOWER functions - ``SELECT upper('a'),lower('B') FROM t;`` @@ -134,7 +134,7 @@ E021, Character string types - ``SELECT * FROM t WHERE s1 > 'a';`` - Okay. We should note here that comparisons use a binary collation by default, but it is easy to use a - :ref:`COLLATE clause `. + :ref:`COLLATE clause `. E031, Identifiers @@ -154,8 +154,8 @@ E031, Identifiers - Identifiers - ``CREATE TABLE rank (ceil INT PRIMARY KEY);`` - Fail. Tarantool's list of - :ref:`reserved words ` - differs from the standard's list of reserved words. + :ref:`reserved words ` + differs from the standard's list of reserved words. * - E031-01 - Delimited identifiers - ``CREATE TABLE "t47" (s1 INT PRIMARY KEY);`` @@ -166,11 +166,11 @@ E031, Identifiers * - E031-02 - Lower case identifiers - ``CREATE TABLE t48 (s1 INT PRIMARY KEY);`` - - Okay. + - Okay. * - E031-03 - Trailing underscore - ``CREATE TABLE t49_ (s1 INT PRIMARY KEY);`` - - Okay. + - Okay. E051, Basic query specification @@ -186,7 +186,7 @@ E051, Basic query specification - Feature - Example - Tests - * - E051-01 + * - E051-01 - SELECT DISTINCT - ``SELECT DISTINCT s1 FROM t;`` - Okay. @@ -237,7 +237,7 @@ E061, Basic predicates and search conditions * - E061-01 - Comparison predicate - ``SELECT * FROM t WHERE 0 = 0;`` - - Okay. + - Okay. * - E061-02 - BETWEEN predicate - ``SELECT * FROM t WHERE ' ' BETWEEN '' AND ' ';`` @@ -266,7 +266,7 @@ E061, Basic predicates and search conditions - EXISTS predicate - ``SELECT * FROM t WHERE NOT EXISTS (SELECT * FROM t);`` - :ref:`Okay `. - * - E061-09 + * - E061-09 - Subqueries in comparison predicate - ``SELECT * FROM t WHERE s1 > (SELECT s1 FROM t);`` - :ref:`Okay `. @@ -313,8 +313,8 @@ E071, Basic query expressions * - E071-03 - EXCEPT DISTINCT table operator - ``SELECT * FROM t EXCEPT DISTINCT SELECT * FROM t;`` - - Fail. However, - ``SELECT * FROM t EXCEPT SELECT * FROM t;`` is okay. + - Fail. However, + ``SELECT * FROM t EXCEPT SELECT * FROM t;`` is okay. * - E071-05 - Columns combined via table operators need not have exactly the same data type @@ -344,37 +344,37 @@ E091, Set functions * - Feature ID - Feature - Example - - Tests + - Tests * - E091-01 - AVG - ``SELECT avg(s1) FROM t7;`` - - Fail. Tarantool supports + - Fail. Tarantool supports :ref:`AVG ` but there is no warning - that NULLs are eliminated. - * - E091-02 + that NULLs are eliminated. + * - E091-02 - COUNT - ``SELECT count(*) FROM t7 WHERE s1 > 0;`` - :ref:`Okay `. - * - E091-03 + * - E091-03 - MAX - ``SELECT max(s1) FROM t7 WHERE s1 > 0;`` - :ref:`Okay `. - * - E091-04 + * - E091-04 - MIN - ``SELECT min(s1) FROM t7 WHERE s1 > 0;`` - - :ref:`Okay `. - * - E091-05 + - :ref:`Okay `. + * - E091-05 - SUM - ``SELECT sum(1) FROM t7 WHERE s1 > 0;`` - - :ref:`Okay `. - * - E091-06 + - :ref:`Okay `. + * - E091-06 - ALL quantifier - - ``SELECT sum(ALL s1) FROM t7 WHERE s1 > 0;`` - - Okay. - * - E091-07 + - ``SELECT sum(ALL s1) FROM t7 WHERE s1 > 0;`` + - Okay. + * - E091-07 - DISTINCT quantifier - ``SELECT sum(DISTINCT s1) FROM t7 WHERE s1 > 0;`` - - Okay. + - Okay. E101, Basic data manipulation @@ -390,22 +390,22 @@ E101, Basic data manipulation - Feature - Example - Tests - * - E101-01 + * - E101-01 - INSERT statement - ``INSERT INTO t (s1,s2) VALUES (1,''), (2,NULL), (3,55);`` - - :ref:`Okay `. + - :ref:`Okay `. * - E101-03 - Searched UPDATE statement - ``UPDATE t SET s1 = NULL WHERE s1 IN (SELECT s1 FROM t2);`` - - :ref:`Okay `. - * - E101-04 + - :ref:`Okay `. + * - E101-04 - Searched DELETE statement - ``DELETE FROM t WHERE s1 IN (SELECT s1 FROM t);`` - - :ref:`Okay `. + - :ref:`Okay `. E111, Single row SELECT statement ---------------------------------- +--------------------------------- .. container:: table @@ -417,13 +417,13 @@ E111, Single row SELECT statement - Feature - Example - Tests - * - E111 + * - E111 - Single row SELECT statement - ``SELECT count(*) FROM t;`` - - :ref:`Okay `. - - -E121, Basic cursor support + - :ref:`Okay `. + + +E121, Basic cursor support -------------------------- .. container:: table @@ -436,42 +436,42 @@ E121, Basic cursor support - Feature - Example - Tests - * - E121-01 - - DECLARE CURSOR + * - E121-01 + - DECLARE CURSOR - - - Fail. Tarantool doesn't support cursors. - * - E121-02 + - Fail. Tarantool doesn't support cursors. + * - E121-02 - ORDER BY columns need not be in select list - ``SELECT s1 FROM t ORDER BY s2;`` - - :ref:`Okay `. - * - E121-03 + - :ref:`Okay `. + * - E121-03 - Value expressions in ORDER BY clause - ``SELECT s1 FROM t7 ORDER BY -s1;`` - - Okay. - * - E121-04 - - OPEN statement + - Okay. + * - E121-04 + - OPEN statement - - - Fail. Tarantool doesn't support cursors. - * - E121-06 - - Positioned UPDATE statement + - Fail. Tarantool doesn't support cursors. + * - E121-06 + - Positioned UPDATE statement - - - Fail. Tarantool doesn't support cursors. - * - E121-07 - - Positioned DELETE statement + - Fail. Tarantool doesn't support cursors. + * - E121-07 + - Positioned DELETE statement - - - Fail. Tarantool doesn't support cursors. - * - E121-08 - - CLOSE statement + - Fail. Tarantool doesn't support cursors. + * - E121-08 + - CLOSE statement - - - Fail. Tarantool doesn't support cursors. - * - E121-10 - - FETCH statement implicit next + - Fail. Tarantool doesn't support cursors. + * - E121-10 + - FETCH statement implicit next - - - Fail. Tarantool doesn't support cursors. - * - E121-17 - - WITH HOLD cursors + - Fail. Tarantool doesn't support cursors. + * - E121-17 + - WITH HOLD cursors - - - Fail. Tarantool doesn't support cursors. + - Fail. Tarantool doesn't support cursors. E131, Null value support @@ -487,15 +487,15 @@ E131, Null value support - Feature - Example - Tests - * - E131 + * - E131 - Null value support (nulls in lieu of values) - - ``SELECT s1 FROM t7 WHERE s1 IS NULL;`` - - Okay. - - -E141, Basic integrity constraints ---------------------------------- - + - ``SELECT s1 FROM t7 WHERE s1 IS NULL;`` + - Okay. + + +E141, Basic integrity constraints +--------------------------------- + .. container:: table .. list-table:: @@ -506,45 +506,45 @@ E141, Basic integrity constraints - Feature - Example - Tests - * - E141-01 + * - E141-01 - NOT NULL constraints - ``CREATE TABLE t8 (s1 INT PRIMARY KEY, s2 INT NOT NULL);`` - - :ref:`Okay `. - * - E141-02 + - :ref:`Okay `. + * - E141-02 - UNIQUE constraints of NOT NULL columns - ``CREATE TABLE t9 (s1 INT PRIMARY KEY , s2 INT NOT NULL UNIQUE);`` - - :ref:`Okay `. - * - E141-03 + - :ref:`Okay `. + * - E141-03 - PRIMARY KEY constraints - - ``CREATE TABLE t10 (s1 INT PRIMARY KEY);`` - - Okay, although Tarantool shouldn't always insist on - having a primary key. - * - E141-04 + - ``CREATE TABLE t10 (s1 INT PRIMARY KEY);`` + - Okay, although Tarantool shouldn't always insist on + having a primary key. + * - E141-04 - Basic FOREIGN KEY constraint with the NO ACTION default for both referential delete and referential update actions - ``CREATE TABLE t11 (s0 INT PRIMARY KEY, s1 INT REFERENCES t10);`` - - :ref:`Okay `. - * - E141-06 + - :ref:`Okay `. + * - E141-06 - CHECK constraints - ``CREATE TABLE t12 (s1 INT PRIMARY KEY, s2 INT, CHECK (s1 = s2));`` - - Okay. - * - E141-07 + - Okay. + * - E141-07 - Column defaults - - ``CREATE TABLE t13 (s1 INT PRIMARY KEY, s2 INT DEFAULT -1);`` + - ``CREATE TABLE t13 (s1 INT PRIMARY KEY, s2 INT DEFAULT -1);`` - Okay. - * - E141-08 + * - E141-08 - NOT NULL inferred on primary key - - ``CREATE TABLE t14 (s1 INT PRIMARY KEY);`` + - ``CREATE TABLE t14 (s1 INT PRIMARY KEY);`` - Okay. We are unable to insert NULL although we don't - explicitly say the column is NOT NULL. - * - E141-10 + explicitly say the column is NOT NULL. + * - E141-10 - Names in a foreign key can be specified in any order - ``CREATE TABLE t15 (s1 INT, s2 INT, PRIMARY KEY (s1,s2));`` - ``CREATE TABLE t16 (s1 INT PRIMARY KEY, s2 INT, FOREIGN KEY (s2,s1) REFERENCES t15 (s1,s2));`` - - Okay. - - -E151, Transaction support + ``CREATE TABLE t16 (s1 INT PRIMARY KEY, s2 INT, FOREIGN KEY (s2,s1) REFERENCES t15 (s1,s2));`` + - Okay. + + +E151, Transaction support ------------------------- .. container:: table @@ -557,18 +557,18 @@ E151, Transaction support - Feature - Example - Tests - * - E151-01 + * - E151-01 - COMMIT statement - - ``COMMIT;`` - - Fail. Tarantool supports - :ref:`COMMIT ` but it is necessary to say + - ``COMMIT;`` + - Fail. Tarantool supports + :ref:`COMMIT ` but it is necessary to say :ref:`START TRANSACTION ` first. - * - E151-02 + * - E151-02 - ROLLBACK statement - ``ROLLBACK;`` - - :ref:`Okay `. - - + - :ref:`Okay `. + + E152, Basic SET TRANSACTION statement ------------------------------------- @@ -582,15 +582,15 @@ E152, Basic SET TRANSACTION statement - Feature - Example - Tests - * - E152-01 + * - E152-01 - SET TRANSACTION statement: ISOLATION SERIALIZABLE clause - - ``SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;`` - - Fail. Syntax error. + - ``SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;`` + - Fail. Syntax error. * - E152-02 - SET TRANSACTION statement: READ ONLY and READ WRITE clauses - - ``SET TRANSACTION READ ONLY;`` - - Fail. Syntax error. - + - ``SET TRANSACTION READ ONLY;`` + - Fail. Syntax error. + E*, Other --------- @@ -605,24 +605,24 @@ E*, Other - Feature - Example - Tests - * - E153 + * - E153 - Updatable queries with subqueries - ``UPDATE "view_containing_subquery" SET column1=0;`` - - Fail. - * - E161 + - Fail. + * - E161 - SQL comments using leading double minus - ``--comment;`` - - :ref:`Okay `. - * - E171 + - :ref:`Okay `. + * - E171 - SQLSTATE support - - ``DROP TABLE no_such_table;`` - - Fail. Tarantool returns an error message but not an SQLSTATE string. + - ``DROP TABLE no_such_table;`` + - Fail. Tarantool returns an error message but not an SQLSTATE string. * - E182 - - Host language binding + - Host language binding - - Okay. Any of the Tarantool connectors should be able - to call :ref:`box.execute() `. - + to call :ref:`box.execute() `. + F021, Basic information schema ------------------------------ @@ -637,12 +637,12 @@ F021, Basic information schema - Feature - Example - Tests - * - F021 + * - F021 - Basic information schema - - ``SELECT * from information_schema.tables;`` + - ``SELECT * from information_schema.tables;`` - Fail. Tarantool's metadata is not in a schema with that - name (not counted in the final score). - + name (not counted in the final score). + F031, Basic schema manipulation ------------------------------- @@ -657,40 +657,40 @@ F031, Basic schema manipulation - Feature - Example - Tests - * - F031-01 - - CREATE TABLE statement to create persistent base tables - - ``CREATE TABLE t20 (t20_1 INT NOT NULL);`` - - Fail. We always have to specify PRIMARY KEY (we only count this flaw once). - * - F031-02 + * - F031-01 + - CREATE TABLE statement to create persistent base tables + - ``CREATE TABLE t20 (t20_1 INT NOT NULL);`` + - Fail. We always have to specify PRIMARY KEY (we only count this flaw once). + * - F031-02 - CREATE VIEW statement - ``CREATE VIEW t21 AS SELECT * FROM t20;`` - - :ref:`Okay `. - * - F031-03 - - GRANT statement + - :ref:`Okay `. + * - F031-03 + - GRANT statement - - - Fail. Tarantool doesn't support privileges except via NoSQL. - * - F031-04 + - Fail. Tarantool doesn't support privileges except via NoSQL. + * - F031-04 - ALTER TABLE statement: add column - ``ALTER TABLE t7 ADD COLUMN t7_2 VARCHAR(1) DEFAULT 'q';`` - Okay. Tarantool supports :ref:`ALTER TABLE `, and support for ADD COLUMN was added in Tarantool 2.7. - * - F031-13 + * - F031-13 - DROP TABLE statement: RESTRICT clause - - ``DROP TABLE t20 RESTRICT;`` - - Fail. Tarantool supports :ref:`DROP TABLE ` but not this clause. - * - F031-16 + - ``DROP TABLE t20 RESTRICT;`` + - Fail. Tarantool supports :ref:`DROP TABLE ` but not this clause. + * - F031-16 - DROP VIEW statement: RESTRICT clause - - ``DROP VIEW v2 RESTRICT;`` - - Fail. Tarantool supports :ref:`DROP VIEW ` but not this clause. - * - F031-19 - - REVOKE statement: RESTRICT clause + - ``DROP VIEW v2 RESTRICT;`` + - Fail. Tarantool supports :ref:`DROP VIEW ` but not this clause. + * - F031-19 + - REVOKE statement: RESTRICT clause - - - Fail. Tarantool does not support privileges except via NoSQL. + - Fail. Tarantool does not support privileges except via NoSQL. - -F041, Basic joined table + +F041, Basic joined table ------------------------ - + .. container:: table .. list-table:: @@ -701,39 +701,40 @@ F041, Basic joined table - Feature - Example - Tests - * - F041-01 + * - F041-01 - Inner join but not necessarily the INNER keyword - ``SELECT a.s1 FROM t7 a JOIN t7 b;`` - - :ref:`Okay `. - * - F041-02 + - :ref:`Okay `. + * - F041-02 - INNER keyword - - ``SELECT a.s1 FROM t7 a INNER JOIN t7 b;`` - - Okay. - * - F041-03 + - ``SELECT a.s1 FROM t7 a INNER JOIN t7 b;`` + - Okay. + * - F041-03 - LEFT OUTER JOIN - - ``SELECT t7.*,t22.* FROM t22 LEFT OUTER JOIN t7 ON (t22_1 = s1);`` + - ``SELECT t7.*,t22.* FROM t22 LEFT OUTER JOIN t7 ON (t22_1 = s1);`` - Okay. - * - F041-04 + * - F041-04 - RIGHT OUTER JOIN - - ``SELECT t7.*,t22.* FROM t22 RIGHT OUTER JOIN t7 ON (t22_1 = s1);`` - - Fail. Syntax error. - * - F041-05 + - ``SELECT t7.*,t22.* FROM t22 RIGHT OUTER JOIN t7 ON (t22_1 = s1);`` + - Fail. Syntax error. + * - F041-05 - Outer joins can be nested - ``SELECT t7.*,t22.* FROM t22 LEFT OUTER JOIN t7 ON (t22_1 = s1) LEFT OUTER JOIN t23;`` - Okay. - * - F041-07 + * - F041-07 - The inner table in a left or right outer join can also be used in an inner join - ``SELECT t7.* FROM (t22 LEFT OUTER JOIN t7 ON (t22_1 = s1)) j INNER JOIN t22 ON (j.t22_4 = t7.s1);`` - - Okay. - * - F041-08 + - Okay. + * - F041-08 - All comparison operators are supported - - ``SELECT * FROM t WHERE 0 = 1 OR 0 > 1 OR 0 < 1 OR 0 <> 1;`` - - :ref:`Okay `. + - ``SELECT * FROM t WHERE 0 = 1 OR 0 > 1 OR 0 < 1 OR 0 <> 1;`` + - :ref:`Okay `. + +.. _sql-compare-datetime: - -F051, Basic date and time +F051, Basic date and time ------------------------- - + .. container:: table .. list-table:: @@ -744,43 +745,43 @@ F051, Basic date and time - Feature - Example - Tests - * - F051-01 + * - F051-01 - DATE data type (including support of DATE literal) - - ``CREATE TABLE dates (s1 DATE);`` - - Fail. Tarantool does not support the DATE data type. - * - F051-02 + - ``CREATE TABLE dates (s1 DATE);`` + - Fail. Tarantool does not support the DATE data type. + * - F051-02 - TIME data type (including support of TIME literal) - ``CREATE TABLE times (s1 TIME DEFAULT TIME '1:2:3');`` - Fail. Syntax error. - * - F051-03 - - TIMESTAMP data type (including support of TIMESTAMP literal) - - ``CREATE TABLE timestamps (s1 TIMESTAMP);`` - - Fail. Syntax error. - * - F051-04 - - Comparison predicate on DATE, TIME and TIMESTAMP data types - - ``SELECT * FROM dates WHERE s1 = s1;`` - - Fail. Date and time data types are not supported. - * - F051-05 - - Explicit CAST between date-time types and character string types - - ``SELECT cast(s1 AS VARCHAR(10)) FROM dates;`` - - Fail. Date and time data types are not supported. - * - F051-06 + * - F051-03 + - TIMESTAMP data type (including support of TIMESTAMP literal) + - ``CREATE TABLE timestamps (s1 TIMESTAMP);`` + - Fail. Syntax error. + * - F051-04 + - Comparison predicate on DATE, TIME and TIMESTAMP data types + - ``SELECT * FROM dates WHERE s1 = s1;`` + - Fail. Date and time data types are not supported. + * - F051-05 + - Explicit CAST between date-time types and character string types + - ``SELECT cast(s1 AS VARCHAR(10)) FROM dates;`` + - Fail. Date and time data types are not supported. + * - F051-06 - CURRENT_DATE - - ``SELECT current_date FROM t;`` - - Fail. Syntax error. - * - F051-07 + - ``SELECT current_date FROM t;`` + - Fail. Syntax error. + * - F051-07 - LOCALTIME - - ``SELECT localtime FROM t;`` - - Fail. Syntax error. - * - F051-08 + - ``SELECT localtime FROM t;`` + - Fail. Syntax error. + * - F051-08 - LOCALTIMESTAMP - - ``SELECT localtimestamp FROM t;`` - - Fail. Syntax error. - + - ``SELECT localtimestamp FROM t;`` + - Fail. Syntax error. + F081, UNION and EXCEPT in views ------------------------------- - + .. container:: table .. list-table:: @@ -790,16 +791,16 @@ F081, UNION and EXCEPT in views * - Feature ID - Feature - Example - - Tests - * - F081 + - Tests + * - F081 - UNION and EXCEPT in views - ``CREATE VIEW vv AS SELECT * FROM t7 EXCEPT SELECT * * FROM t15;`` - - Okay. - - + - Okay. + + F131, Grouped operations ------------------------ - + .. container:: table .. list-table:: @@ -809,34 +810,34 @@ F131, Grouped operations * - Feature ID - Feature - Example - - Tests - * - F131-01 + - Tests + * - F131-01 - WHERE, GROUP BY, and HAVING clauses supported in queries with grouped views - - ``CREATE VIEW vv2 AS SELECT * FROM vv GROUP BY s1;`` - - Okay. - * - F131-02 + - ``CREATE VIEW vv2 AS SELECT * FROM vv GROUP BY s1;`` + - Okay. + * - F131-02 - Multiple tables supported in queries with grouped views - - ``CREATE VIEW vv3 AS SELECT * FROM vv2,t30;`` - - Okay. - * - F131-03 + - ``CREATE VIEW vv3 AS SELECT * FROM vv2,t30;`` + - Okay. + * - F131-03 - Set functions supported in queries with grouped views - - ``CREATE VIEW vv4 AS SELECT count(*) FROM vv2;`` - - Okay. - * - F131-04 + - ``CREATE VIEW vv4 AS SELECT count(*) FROM vv2;`` + - Okay. + * - F131-04 - Subqueries with GROUP BY and HAVING clauses and grouped views - - ``CREATE VIEW vv5 AS SELECT count(*) FROM vv2 GROUP BY s1 HAVING count(*) > 0;`` + - ``CREATE VIEW vv5 AS SELECT count(*) FROM vv2 GROUP BY s1 HAVING count(*) > 0;`` - Okay. - * - F131-05 - - Single row SELECT with GROUP BY and HAVING clauses and grouped views - - ``SELECT count(*) FROM vv2 GROUP BY s1 HAVING count(*) > 0;`` + * - F131-05 + - Single row SELECT with GROUP BY and HAVING clauses and grouped views + - ``SELECT count(*) FROM vv2 GROUP BY s1 HAVING count(*) > 0;`` - Okay. - - -F181, Multiple module support + + +F181, Multiple module support ----------------------------- -Fail. Tarantool doesn't have modules. - +Fail. Tarantool doesn't have modules. + F201, CAST function ------------------- @@ -850,11 +851,11 @@ F201, CAST function * - Feature ID - Feature - Example - - Tests + - Tests * - F201 - CAST function - ``SELECT cast(s1 AS INT) FROM t;`` - - :ref:`Okay `. + - :ref:`Okay `. F221, Explicit defaults @@ -869,14 +870,14 @@ F221, Explicit defaults * - Feature ID - Feature - Example - - Tests - * - F221 + - Tests + * - F221 - Explicit defaults - - ``UPDATE t SET s1 = DEFAULT;`` - - Fail. Syntax error. - + - ``UPDATE t SET s1 = DEFAULT;`` + - Fail. Syntax error. + -F261, CASE expression +F261, CASE expression --------------------- .. container:: table @@ -888,28 +889,28 @@ F261, CASE expression * - Feature ID - Feature - Example - - Tests - * - F261-01 + - Tests + * - F261-01 - Simple CASE - - ``SELECT CASE WHEN 1 = 0 THEN 5 ELSE 7 END FROM t;`` - - Okay. - * - F261-02 + - ``SELECT CASE WHEN 1 = 0 THEN 5 ELSE 7 END FROM t;`` + - Okay. + * - F261-02 - Searched CASE - - ``SELECT CASE 1 WHEN 0 THEN 5 ELSE 7 END FROM t;`` - - Okay. - * - F261-03 + - ``SELECT CASE 1 WHEN 0 THEN 5 ELSE 7 END FROM t;`` + - Okay. + * - F261-03 - NULLIF - ``SELECT nullif(s1,7) FROM t;`` - - :ref:`Okay ` - * - F261-04 + - :ref:`Okay ` + * - F261-04 - COALESCE - ``SELECT coalesce(s1,7) FROM t;`` - - :ref:`Okay `. - - + - :ref:`Okay `. + + F311, Schema definition statement --------------------------------- - + .. container:: table .. list-table:: @@ -918,24 +919,24 @@ F311, Schema definition statement * - Feature ID - Feature - - Tests - * - F311-01 - - CREATE SCHEMA - - Fail. Tarantool doesn't have schemas or databases. - * - F311-02 - - CREATE TABLE for persistent base tables - - Fail. Tarantool doesn't have CREATE TABLE inside CREATE SCHEMA. - * - F311-03 - - CREATE VIEW - - Fail. Tarantool doesn't have CREATE VIEW inside CREATE SCHEMA. - * - F311-04 - - CREATE VIEW: WITH CHECK OPTION - - Fail. Tarantool doesn't have CREATE VIEW inside CREATE SCHEMA. - * - F311-05 + - Tests + * - F311-01 + - CREATE SCHEMA + - Fail. Tarantool doesn't have schemas or databases. + * - F311-02 + - CREATE TABLE for persistent base tables + - Fail. Tarantool doesn't have CREATE TABLE inside CREATE SCHEMA. + * - F311-03 + - CREATE VIEW + - Fail. Tarantool doesn't have CREATE VIEW inside CREATE SCHEMA. + * - F311-04 + - CREATE VIEW: WITH CHECK OPTION + - Fail. Tarantool doesn't have CREATE VIEW inside CREATE SCHEMA. + * - F311-05 - GRANT statement - - Fail. Tarantool doesn't have GRANT inside CREATE SCHEMA. - - + - Fail. Tarantool doesn't have GRANT inside CREATE SCHEMA. + + F*, Other --------- @@ -948,21 +949,21 @@ F*, Other * - Feature ID - Feature - Example - - Tests + - Tests * - F471 - Scalar subquery values - - ``SELECT s1 FROM t WHERE s1 = (SELECT count(*) FROM t);`` + - ``SELECT s1 FROM t WHERE s1 = (SELECT count(*) FROM t);`` - Okay. - * - F481 + * - F481 - Expanded NULL predicate - - ``SELECT * FROM t WHERE row(s1,s1) IS NOT NULL;`` - - Fail. Syntax error. - * - F812 - - Basic flagging + - ``SELECT * FROM t WHERE row(s1,s1) IS NOT NULL;`` + - Fail. Syntax error. + * - F812 + - Basic flagging - - - Fail. Tarantool doesn't support any flagging. - - + - Fail. Tarantool doesn't support any flagging. + + S011, Distinct types -------------------- @@ -975,13 +976,13 @@ S011, Distinct types * - Feature ID - Feature - Example - - Tests - * - S011 + - Tests + * - S011 - Distinct types - - ``CREATE TYPE x AS FLOAT;`` - - Fail. Tarantool doesn't support distinct types. - - + - ``CREATE TYPE x AS FLOAT;`` + - Fail. Tarantool doesn't support distinct types. + + T321, Basic SQL-invoked routines -------------------------------- @@ -994,29 +995,29 @@ T321, Basic SQL-invoked routines * - Feature ID - Feature - Example - - Tests - * - T321-01 + - Tests + * - T321-01 - User-defined functions with no overloading - - ``CREATE FUNCTION f() RETURNS INT RETURN 5;`` - - Fail. User-defined functions for SQL are created in - :ref:`Lua ` with a different syntax. - * - T321-02 + - ``CREATE FUNCTION f() RETURNS INT RETURN 5;`` + - Fail. User-defined functions for SQL are created in + :ref:`Lua ` with a different syntax. + * - T321-02 - User-defined procedures with no overloading - - ``CREATE PROCEDURE p() BEGIN END;`` - - Fail. User-defined functions for SQL are created in - :ref:`Lua ` with a different syntax. + - ``CREATE PROCEDURE p() BEGIN END;`` + - Fail. User-defined functions for SQL are created in + :ref:`Lua ` with a different syntax. * - T321-03 - Function invocation - - ``SELECT f(1) FROM t;`` + - ``SELECT f(1) FROM t;`` - Okay. Tarantool can invoke Lua user-defined functions. - * - T321-04 + * - T321-04 - CALL statement - - ``CALL p();`` - - Fail. Tarantool doesn't support CALL statements. - * - T321-05 + - ``CALL p();`` + - Fail. Tarantool doesn't support CALL statements. + * - T321-05 - RETURN statement - - ``CREATE FUNCTION f() RETURNS INT RETURN 5;`` - - Fail. Tarantool doesn't support RETURN statements. + - ``CREATE FUNCTION f() RETURNS INT RETURN 5;`` + - Fail. Tarantool doesn't support RETURN statements. T*, Other @@ -1031,11 +1032,11 @@ T*, Other * - Feature ID - Feature - Example - - Tests - * - T631 + - Tests + * - T631 - IN predicate with one list element - - ``SELECT * FROM t WHERE 1 IN (1);`` - - Okay. + - ``SELECT * FROM t WHERE 1 IN (1);`` + - Okay. Total number of items marked "Fail": 67 diff --git a/doc/reference/reference_sql/sql_statements_and_clauses.rst b/doc/reference/reference_sql/sql_statements_and_clauses.rst index 28ea5c8950..cb3d2d2f7a 100644 --- a/doc/reference/reference_sql/sql_statements_and_clauses.rst +++ b/doc/reference/reference_sql/sql_statements_and_clauses.rst @@ -2751,7 +2751,7 @@ Now that does not happen. Behavior change is done by updating the (STRING) match -- MATCH clause |br| The system table is ``"_fk_constraint"``. * - collation_list - - + - - Return a result set with one row for each supported collation. The first four collations are ``'none'`` and ``'unicode'`` and @@ -2784,7 +2784,7 @@ Now that does not happen. Behavior change is done by updating the unique, 0 is false, 1 is true |br| The system table is ``"_index"``. * - stats - - + - - Return a result set with one row for each index of each table. Each row contains: |br| @@ -3226,6 +3226,72 @@ expression values are NULL, return NULL. Example: ``COALESCE(NULL, 17, 32)`` is 17. +.. _sql_function_datepart: + +DATE_PART ++++++++++ + +Syntax: + +:samp:`DATE_PART(value_requested , datetime)` + +Since :doc:`2.10.0 `. + +The ``DATE_PART()`` function returns the requested information from a DATETIME value. +It takes two arguments: the first one tells us what information is requested, the second is a DATETIME value. + +Below is a list of supported values of the first argument and what information is returned: + +* ``millennium`` -- millennium +* ``century`` -- century +* ``decade`` -- decade +* ``year`` -- year +* ``quarter`` -- quarter of year +* ``month`` -- month of year +* ``week`` -- week of year +* ``day`` -- day of month +* ``dow`` -- day of week +* ``doy`` -- day of year +* ``hour`` -- hour of day +* ``minute`` -- minute of hour +* ``second`` -- second of minute +* ``millisecond`` -- millisecond of second +* ``microsecond`` -- microsecond of second +* ``nanosecond`` -- nanosecond of second +* ``epoch`` -- epoch +* ``timezone_offset`` -- time zone offset from the UTC, in minutes. + +Examples: + +.. code-block:: tarantoolsession + + tarantool> select date_part('millennium', cast({'year': 2000, 'month': 4, 'day': 5, 'hour': 6, 'min': 33, 'sec': 22, 'nsec': 523999111} as datetime)); + --- + - metadata: + - name: COLUMN_1 + type: integer + rows: + - [2] + ... + + tarantool> select date_part('day', cast({'year': 2000, 'month': 4, 'day': 5, 'hour': 6, 'min': 33, 'sec': 22, 'nsec': 523999111} as datetime)); + --- + - metadata: + - name: COLUMN_1 + type: integer + rows: + - [5] + ... + + tarantool> select date_part('nanosecond', cast({'year': 2000, 'month': 4, 'day': 5, 'hour': 6, 'min': 33, 'sec': 22, 'nsec': 523999111} as datetime)); + --- + - metadata: + - name: COLUMN_1 + type: integer + rows: + - [523999111] + ... + .. _sql_function_greatest: ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ @@ -3378,6 +3444,41 @@ The reverse of ``LOWER`` is :ref:`UPPER `. Example: ``LOWER('ДA')`` is 'дa' +.. _sql_function_now: + +NOW ++++ + +Syntax: + +:samp:`NOW()` + +Since :doc:`2.10.0 `. + +The NOW() function returns the current date and time as a DATETIME +value. + +If the function is called more than once in a query, it returns +the same result until the query completes, unless a yield has occurred. +On yield, the value returned by NOW() is changing. + +Examples: + +.. code-block:: tarantoolsession + + tarantool> select now(), now(), now() + --- + - metadata: + - name: COLUMN_1 + type: datetime + - name: COLUMN_2 + type: datetime + - name: COLUMN_3 + type: datetime + rows: + - ['2022-07-20T19:02:02.010812282+0300', '2022-07-20T19:02:02.010812282+0300', '2022-07-20T19:02:02.010812282+0300'] + ... + .. _sql_function_nullif: ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ @@ -3885,7 +3986,7 @@ the three SELECT statements here will return results in three different orders: Default function parameters ******************************************************************************** -Starting in Tarantool 2.10, if a parameter for an :ref:`aggregate function ` +Starting in Tarantool 2.10, if a parameter for an :ref:`aggregate function ` or a :ref:`built-in scalar SQL function ` is one of the ``extra-parameters`` that can appear in :ref:`box.execute(...[,extra-parameters]) ` requests, diff --git a/doc/reference/reference_sql/sql_user_guide.rst b/doc/reference/reference_sql/sql_user_guide.rst index 8d274147eb..bdd01d7f66 100644 --- a/doc/reference/reference_sql/sql_user_guide.rst +++ b/doc/reference/reference_sql/sql_user_guide.rst @@ -640,7 +640,7 @@ type ANY. The difference between SCALAR and ANY is: * SCALAR columns may not contain MAP or ARRAY values, but ANY columns may contain them. -* SCALAR values are comparable, while ANY values are not comparable. +* SCALAR values are comparable, while ANY values are not comparable. Any value of any data type may be NULL. Ordinarily NULL will be cast to the data type of any operand it is being compared to or to the data type of the From 6d9d4130ef66179ed3e71b0e01542ceac5c3dcaf Mon Sep 17 00:00:00 2001 From: Evgeniy Osintsev Date: Mon, 3 Oct 2022 11:28:19 +0400 Subject: [PATCH 2/2] Add description of the DATETIME and INTERVAL types Part of #2575 and #2836 --- .../reference_sql/sql_user_guide.rst | 159 ++++++++++++++++++ 1 file changed, 159 insertions(+) diff --git a/doc/reference/reference_sql/sql_user_guide.rst b/doc/reference/reference_sql/sql_user_guide.rst index bdd01d7f66..c8dc1a263e 100644 --- a/doc/reference/reference_sql/sql_user_guide.rst +++ b/doc/reference/reference_sql/sql_user_guide.rst @@ -504,6 +504,16 @@ and minimum / maximum literal examples. - (none) - 00000000-0000-0000- |br| 0000-000000000000 - ffffffff-ffff-ffff- |br| dfff-ffffffffffff + * - DATETIME + - :ref:`datetime ` + - (none) + - + - + * - INTERVAL + - :ref:`interval ` + - (none) + - + - * - SCALAR - (varies) - (none) @@ -602,6 +612,155 @@ or with the :ref:`UUID() function `, or with the :ref:`CAST() function `. UUID support in SQL was added in Tarantool version 2.9.1. +.. _sql_data_type_datetime: + +DATETIME. Introduced in :tarantool-release:`2.10.0`. +A datetime table field can be created by using this type, which is semantically equivalent to the standard TIMESTAMP WITH TIME ZONE type. + +.. code-block:: tarantoolsession + + tarantool> create table T2(d datetime primary key); + --- + - row_count: 1 + ... + + tarantool> insert into t2 values ('2022-01-01'); + --- + - null + - 'Type mismatch: can not convert string(''2022-01-01'') to datetime' + ... + + tarantool> insert into t2 values (cast('2022-01-01' as datetime)); + --- + - row_count: 1 + ... + + tarantool> select * from t2; + --- + - metadata: + - name: D + type: datetime + rows: + - ['2022-01-01T00:00:00Z'] + ... + +There is no implicit cast available from a string expression to a datetime expression (dislike convention used by majority of SQL vendors). +In such cases, you need to use explicit cast from a string value to a datetime value (see the example above). + +You can subtract datetime and datetime, datetime and interval, or add datetime and interval in any order (see examples of such arithmetics in the description of the :ref:`INTERVAL type `). + +The built-in functions related to the DATETIME type are :ref:`DATE_PART() ` and :ref:`NOW() ` + +.. _sql_data_type_interval: + +INTERVAL. Introduced in :tarantool-release:`2.10.0`. +Similarly to the :ref:`DATETIME ` type, you can define a column of the INTERVAL type. + +.. code-block:: tarantoolsession + + tarantool> create table T(d datetime primary key, i interval); + --- + - row_count: 1 + ... + + tarantool> insert into T values (cast('2022-02-02T01:01' as datetime), cast({'year': 1, 'month': 1} as interval)); + --- + - row_count: 1 + ... + + tarantool> select * from t; + --- + - metadata: + - name: D + type: datetime + - name: I + type: interval + rows: + - ['2022-02-02T01:01:00Z', '+1 years, 1 months'] + ... + +Dislike DATETIME, INTERVAL cannot be a part of an index. + +There is no implicit cast available for conversions to an interval from a string or any other type. +But there is explicit cast allowed from maps (see examples below). + +Intervals can be used in arithmetic operations like ``+`` or ``-`` only with the datetime expression or another interval: + +.. code-block:: tarantoolsession + + tarantool> select * from t + --- + - metadata: + - name: D + type: datetime + - name: I + type: interval + rows: + - ['2022-02-02T01:01:00Z', '+1 years, 1 months'] + ... + + tarantool> select d, d + i, d + cast({'year': 1, 'month': 2} as interval) from t + --- + - metadata: + - name: D + type: datetime + - name: COLUMN_1 + type: datetime + - name: COLUMN_2 + type: datetime + rows: + - ['2022-02-02T01:01:00Z', '2023-03-02T01:01:00Z', '2023-04-02T01:01:00Z'] + ... + + tarantool> select i + cast({'year': 1, 'month': 2} as interval) from t + --- + - metadata: + - name: COLUMN_1 + type: interval + rows: + - ['+2 years, 3 months'] + ... + +There is the predefined list of known attributes for the map if you want to convert one to the INTERVAL expression: + +* ``year`` +* ``month`` +* ``week`` +* ``day`` +* ``hour`` +* ``minute`` +* ``second`` +* ``nsec`` + +.. code-block:: tarantoolsession + + tarantool> select cast({'year': 1, 'month': 1, 'week': 1, 'day': 1, 'hour': 1, 'min': 1, 'sec': 1} as interval) + --- + - metadata: + - name: COLUMN_1 + type: interval + rows: + - ['+1 years, 1 months, 1 weeks, 1 days, 1 hours, 1 minutes, 1 seconds'] + ... + + tarantool> \set language lua + + + tarantool> v = {year = 1, month = 1, week = 1, day = 1, hour = 1, + > min = 1, sec = 1, nsec = 1, adjust = 'none'} + --- + ... + + tarantool> box.execute('select cast(#v as interval);', {{['#v'] = v}}) + + --- + - metadata: + - name: COLUMN_1 + type: interval + rows: + - ['+1 years, 1 months, 1 weeks, 1 days, 1 hours, 1 minutes, 1.000000001 seconds'] + ... + .. _sql_data_type_scalar: SCALAR can be used for