xref: /sqlite-3.40.0/test/date2.test (revision a7d8d4a0)
16e97f8ecSdrh# 2017-07-20
26e97f8ecSdrh#
36e97f8ecSdrh# The author disclaims copyright to this source code.  In place of
46e97f8ecSdrh# a legal notice, here is a blessing:
56e97f8ecSdrh#
66e97f8ecSdrh#    May you do good and not evil.
76e97f8ecSdrh#    May you find forgiveness for yourself and forgive others.
86e97f8ecSdrh#    May you share freely, never taking more than you give.
96e97f8ecSdrh#
106e97f8ecSdrh#***********************************************************************
116e97f8ecSdrh# This file implements regression tests for SQLite library.  The
126e97f8ecSdrh# focus of this file is testing date and time functions used in
136e97f8ecSdrh# check constraints and index expressions.
146e97f8ecSdrh#
156e97f8ecSdrh
166e97f8ecSdrhset testdir [file dirname $argv0]
176e97f8ecSdrhsource $testdir/tester.tcl
186e97f8ecSdrh
196e97f8ecSdrh# Skip this whole file if date and time functions are omitted
206e97f8ecSdrh# at compile-time
216e97f8ecSdrh#
226e97f8ecSdrhifcapable {!datetime} {
236e97f8ecSdrh  finish_test
246e97f8ecSdrh  return
256e97f8ecSdrh}
266e97f8ecSdrh
276e97f8ecSdrhdo_execsql_test date2-100 {
286e97f8ecSdrh  CREATE TABLE t1(x, y, CHECK( date(x) BETWEEN '2017-07-01' AND '2017-07-31' ));
296e97f8ecSdrh  INSERT INTO t1(x,y) VALUES('2017-07-20','one');
306e97f8ecSdrh} {}
316e97f8ecSdrhdo_catchsql_test date2-110 {
326e97f8ecSdrh  INSERT INTO t1(x,y) VALUES('now','two');
3320cee7d0Sdrh} {1 {non-deterministic use of date() in a CHECK constraint}}
346e97f8ecSdrhdo_execsql_test date2-120 {
356e97f8ecSdrh  SELECT * FROM t1;
366e97f8ecSdrh} {2017-07-20 one}
376e97f8ecSdrhdo_catchsql_test date2-130 {
386e97f8ecSdrh  INSERT INTO t1(x,y) VALUES('2017-08-01','two');
3992e21ef0Sdrh} {1 {CHECK constraint failed: date(x) BETWEEN '2017-07-01' AND '2017-07-31'}}
406e97f8ecSdrh
41*a7d8d4a0Sdrh# 2021-03-16 Forum post https://sqlite.org/forum/forumpost/464afd4086
42*a7d8d4a0Sdrhdo_catchsql_test date2-140 {
43*a7d8d4a0Sdrh  DROP TABLE t1;
44*a7d8d4a0Sdrh  CREATE TABLE t1(x, y, z AS (date()));
45*a7d8d4a0Sdrh  INSERT INTO t1(x,y) VALUES(1,2);
46*a7d8d4a0Sdrh} {1 {non-deterministic use of date() in a generated column}}
47*a7d8d4a0Sdrh
486e97f8ecSdrhdo_execsql_test date2-200 {
496e97f8ecSdrh  CREATE TABLE t2(x,y);
506e97f8ecSdrh  INSERT INTO t2(x,y) VALUES(1, '2017-07-20'), (2, 'xyzzy');
516e97f8ecSdrh  CREATE INDEX t2y ON t2(date(y));
526e97f8ecSdrh}
536e97f8ecSdrhdo_catchsql_test date2-210 {
546e97f8ecSdrh  INSERT INTO t2(x,y) VALUES(3, 'now');
5520cee7d0Sdrh} {1 {non-deterministic use of date() in an index}}
566e97f8ecSdrhdo_execsql_test date2-220 {
576e97f8ecSdrh  SELECT x, y FROM t2 ORDER BY x;
586e97f8ecSdrh} {1 2017-07-20 2 xyzzy}
596e97f8ecSdrh
602fbeb7e8Sdrhdo_execsql_test date2-300 {
612fbeb7e8Sdrh  CREATE TABLE t3(a INTEGER PRIMARY KEY,b);
622fbeb7e8Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000)
632fbeb7e8Sdrh    INSERT INTO t3(a,b) SELECT x, julianday('2017-07-01')+x FROM c;
642fbeb7e8Sdrh  UPDATE t3 SET b='now' WHERE a=500;
652fbeb7e8Sdrh}
662fbeb7e8Sdrhdo_catchsql_test date2-310 {
672fbeb7e8Sdrh  CREATE INDEX t3b1 ON t3(datetime(b));
6820cee7d0Sdrh} {1 {non-deterministic use of datetime() in an index}}
692fbeb7e8Sdrhdo_catchsql_test date2-320 {
702fbeb7e8Sdrh  CREATE INDEX t3b1 ON t3(datetime(b)) WHERE typeof(b)='real';
712fbeb7e8Sdrh} {0 {}}
722fbeb7e8Sdrhdo_execsql_test date2-330 {
732fbeb7e8Sdrh  EXPLAIN QUERY PLAN
742fbeb7e8Sdrh  SELECT a FROM t3
752fbeb7e8Sdrh   WHERE typeof(b)='real'
762fbeb7e8Sdrh     AND datetime(b) BETWEEN '2017-07-04' AND '2017-07-08';
772fbeb7e8Sdrh} {/USING INDEX t3b/}
782fbeb7e8Sdrhdo_execsql_test date2-331 {
792fbeb7e8Sdrh  SELECT a FROM t3
802fbeb7e8Sdrh   WHERE typeof(b)='real'
812fbeb7e8Sdrh     AND datetime(b) BETWEEN '2017-07-04' AND '2017-07-08'
822fbeb7e8Sdrh  ORDER BY a;
832fbeb7e8Sdrh} {3 4 5 6}
842fbeb7e8Sdrh
852fbeb7e8Sdrhdo_execsql_test date2-400 {
862fbeb7e8Sdrh  CREATE TABLE t4(a INTEGER PRIMARY KEY,b);
872fbeb7e8Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<1000)
882fbeb7e8Sdrh    INSERT INTO t4(a,b) SELECT x, julianday('2017-07-01')+x FROM c;
892fbeb7e8Sdrh  UPDATE t4 SET b='now' WHERE a=500;
902fbeb7e8Sdrh}
912fbeb7e8Sdrhdo_catchsql_test date2-410 {
922fbeb7e8Sdrh  CREATE INDEX t4b1 ON t4(b)
932fbeb7e8Sdrh    WHERE date(b) BETWEEN '2017-06-01' AND '2017-08-31';
9420cee7d0Sdrh} {1 {non-deterministic use of date() in an index}}
952fbeb7e8Sdrhdo_execsql_test date2-420 {
962fbeb7e8Sdrh  DELETE FROM t4 WHERE a=500;
972fbeb7e8Sdrh  CREATE INDEX t4b1 ON t4(b)
982fbeb7e8Sdrh    WHERE date(b) BETWEEN '2017-06-01' AND '2017-08-31';
992fbeb7e8Sdrh}
1002fbeb7e8Sdrhdo_catchsql_test date2-430 {
1012fbeb7e8Sdrh  INSERT INTO t4(a,b) VALUES(9999,'now');
10220cee7d0Sdrh} {1 {non-deterministic use of date() in an index}}
1032fbeb7e8Sdrh
1042fbeb7e8Sdrhdo_execsql_test date2-500 {
1052fbeb7e8Sdrh  CREATE TABLE mods(x);
1062fbeb7e8Sdrh  INSERT INTO mods(x) VALUES
1072fbeb7e8Sdrh    ('+10 days'),
1082fbeb7e8Sdrh    ('-10 days'),
1092fbeb7e8Sdrh    ('+10 hours'),
1102fbeb7e8Sdrh    ('-10 hours'),
1112fbeb7e8Sdrh    ('+10 minutes'),
1122fbeb7e8Sdrh    ('-10 minutes'),
1132fbeb7e8Sdrh    ('+10 seconds'),
1142fbeb7e8Sdrh    ('-10 seconds'),
1152fbeb7e8Sdrh    ('+10 months'),
1162fbeb7e8Sdrh    ('-10 months'),
1172fbeb7e8Sdrh    ('+10 years'),
1182fbeb7e8Sdrh    ('-10 years'),
1192fbeb7e8Sdrh    ('start of month'),
1202fbeb7e8Sdrh    ('start of year'),
1212fbeb7e8Sdrh    ('start of day'),
1222fbeb7e8Sdrh    ('weekday 1'),
1232fbeb7e8Sdrh    ('unixepoch');
1242fbeb7e8Sdrh  CREATE TABLE t5(y,m);
1252fbeb7e8Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
1262fbeb7e8Sdrh    INSERT INTO t5(y,m) SELECT julianday('2017-07-01')+c.x, mods.x FROM c, mods;
1272fbeb7e8Sdrh  CREATE INDEX t5x1 on t5(y) WHERE datetime(y,m) IS NOT NULL;
1282fbeb7e8Sdrh}
1292fbeb7e8Sdrhdo_catchsql_test date2-510 {
1302fbeb7e8Sdrh  INSERT INTO t5(y,m) VALUES('2017-07-20','localtime');
13120cee7d0Sdrh} {1 {non-deterministic use of datetime() in an index}}
1322fbeb7e8Sdrhdo_catchsql_test date2-520 {
1332fbeb7e8Sdrh  INSERT INTO t5(y,m) VALUES('2017-07-20','utc');
13420cee7d0Sdrh} {1 {non-deterministic use of datetime() in an index}}
13520cee7d0Sdrh
13620cee7d0Sdrh# 2019-10-30 Ticket 830277d9db6c3ba1
13720cee7d0Sdrh#
13820cee7d0Sdrhdo_catchsql_test date2-600 {
13920cee7d0Sdrh  CREATE TABLE t600(a REAL CHECK( a<julianday('now') ));
14020cee7d0Sdrh  INSERT INTO t600(a) VALUES(1.0);
14120cee7d0Sdrh} {1 {non-deterministic use of julianday() in a CHECK constraint}}
14220cee7d0Sdrhdo_catchsql_test date2-601 {
14320cee7d0Sdrh  CREATE TABLE t601(a REAL, b TEXT, CHECK( a<julianday(b) ));
14420cee7d0Sdrh  INSERT INTO t601(a,b) VALUES(1.0, '1970-01-01');
14520cee7d0Sdrh} {0 {}}
14620cee7d0Sdrhdo_catchsql_test date2-602 {
14720cee7d0Sdrh  INSERT INTO t601(a,b) VALUES(1e100, '1970-01-01');
14892e21ef0Sdrh} {1 {CHECK constraint failed: a<julianday(b)}}
14920cee7d0Sdrhdo_catchsql_test date2-603 {
15020cee7d0Sdrh  INSERT INTO t601(a,b) VALUES(10, 'now');
15120cee7d0Sdrh} {1 {non-deterministic use of julianday() in a CHECK constraint}}
15220cee7d0Sdrhdo_catchsql_test date2-604 {
15320cee7d0Sdrh  INSERT INTO t600(a) VALUES(julianday('now')+10);
15420cee7d0Sdrh} {1 {non-deterministic use of julianday() in a CHECK constraint}}
1552fbeb7e8Sdrh
1562fbeb7e8Sdrh
15720cee7d0Sdrhdo_catchsql_test date2-610 {
15820cee7d0Sdrh  CREATE TABLE t610(a,b);
15920cee7d0Sdrh  CREATE INDEX t610x1 ON t610(julianday('now')+b);
16020cee7d0Sdrh  INSERT INTO t610(a,b) VALUES(123,456);
16120cee7d0Sdrh} {1 {non-deterministic use of julianday() in an index}}
16220cee7d0Sdrhdo_catchsql_test date2-611 {
16320cee7d0Sdrh  CREATE TABLE t611(a,b);
16420cee7d0Sdrh  CREATE INDEX t611x1 ON t611(julianday(a)+b);
16520cee7d0Sdrh  INSERT INTO t611(a,b) VALUES('1970-01-01',10.0);
16620cee7d0Sdrh} {0 {}}
16720cee7d0Sdrhdo_catchsql_test date2-612 {
16820cee7d0Sdrh  INSERT INTO t611(a,b) VALUES('now',10.0);
16920cee7d0Sdrh} {1 {non-deterministic use of julianday() in an index}}
1702fbeb7e8Sdrh
17120cee7d0Sdrhdo_catchsql_test date3-620 {
17220cee7d0Sdrh  CREATE TABLE t620(a, b AS (a+julianday('now')));
17320cee7d0Sdrh  INSERT INTO t620 VALUES(10);
17420cee7d0Sdrh} {1 {non-deterministic use of julianday() in a generated column}}
1752fbeb7e8Sdrh
1766e97f8ecSdrhfinish_test
177