xref: /sqlite-3.40.0/test/e_createtable.test (revision 6e85b27c)
142825cd2Sdan# 2010 September 25
242825cd2Sdan#
342825cd2Sdan# The author disclaims copyright to this source code.  In place of
442825cd2Sdan# a legal notice, here is a blessing:
542825cd2Sdan#
642825cd2Sdan#    May you do good and not evil.
742825cd2Sdan#    May you find forgiveness for yourself and forgive others.
842825cd2Sdan#    May you share freely, never taking more than you give.
942825cd2Sdan#
1042825cd2Sdan#***********************************************************************
1142825cd2Sdan#
1242825cd2Sdan# This file implements tests to verify that the "testable statements" in
1342825cd2Sdan# the lang_createtable.html document are correct.
1442825cd2Sdan#
1542825cd2Sdan
1642825cd2Sdanset testdir [file dirname $argv0]
1742825cd2Sdansource $testdir/tester.tcl
1842825cd2Sdan
19a3f5108cSdanset ::testprefix e_createtable
20a3f5108cSdan
21a16d1060Sdan# Test organization:
22a16d1060Sdan#
23a16d1060Sdan#   e_createtable-0.*: Test that the syntax diagrams are correct.
24a16d1060Sdan#
25a16d1060Sdan#   e_createtable-1.*: Test statements related to table and database names,
26a16d1060Sdan#       the TEMP and TEMPORARY keywords, and the IF NOT EXISTS clause.
27a16d1060Sdan#
288f1a8afdSdan#   e_createtable-2.*: Test "CREATE TABLE AS" statements.
29a16d1060Sdan#
30a16d1060Sdan
3142825cd2Sdanproc do_createtable_tests {nm args} {
3242825cd2Sdan  uplevel do_select_tests [list e_createtable-$nm] $args
3342825cd2Sdan}
3442825cd2Sdan
358f1a8afdSdan
368f1a8afdSdan#-------------------------------------------------------------------------
378f1a8afdSdan# This command returns a serialized tcl array mapping from the name of
388f1a8afdSdan# each attached database to a list of tables in that database. For example,
398f1a8afdSdan# if the database schema is created with:
408f1a8afdSdan#
418f1a8afdSdan#   CREATE TABLE t1(x);
428f1a8afdSdan#   CREATE TEMP TABLE t2(x);
438f1a8afdSdan#   CREATE TEMP TABLE t3(x);
448f1a8afdSdan#
458f1a8afdSdan# Then this command returns "main t1 temp {t2 t3}".
468f1a8afdSdan#
478f1a8afdSdanproc table_list {} {
488f1a8afdSdan  set res [list]
498f1a8afdSdan  db eval { pragma database_list } a {
508f1a8afdSdan    set dbname $a(name)
518f1a8afdSdan    set master $a(name).sqlite_master
528f1a8afdSdan    if {$dbname == "temp"} { set master sqlite_temp_master }
538f1a8afdSdan    lappend res $dbname [
548f1a8afdSdan      db eval "SELECT DISTINCT tbl_name FROM $master ORDER BY tbl_name"
558f1a8afdSdan    ]
568f1a8afdSdan  }
578f1a8afdSdan  set res
588f1a8afdSdan}
598f1a8afdSdan
608f1a8afdSdan
6142825cd2Sdando_createtable_tests 0.1.1 -repair {
6242825cd2Sdan  drop_all_tables
6342825cd2Sdan} {
6442825cd2Sdan  1   "CREATE TABLE t1(c1 one)"                        {}
6542825cd2Sdan  2   "CREATE TABLE t1(c1 one two)"                    {}
6642825cd2Sdan  3   "CREATE TABLE t1(c1 one two three)"              {}
6742825cd2Sdan  4   "CREATE TABLE t1(c1 one two three four)"         {}
6842825cd2Sdan  5   "CREATE TABLE t1(c1 one two three four(14))"     {}
6942825cd2Sdan  6   "CREATE TABLE t1(c1 one two three four(14, 22))" {}
7042825cd2Sdan  7   "CREATE TABLE t1(c1 var(+14, -22.3))"            {}
7142825cd2Sdan  8   "CREATE TABLE t1(c1 var(1.0e10))"                {}
7242825cd2Sdan}
7342825cd2Sdando_createtable_tests 0.1.2 -error {
7442825cd2Sdan  near "%s": syntax error
7542825cd2Sdan} {
7642825cd2Sdan  1   "CREATE TABLE t1(c1 one(number))"                {number}
7742825cd2Sdan}
7842825cd2Sdan
7942825cd2Sdan
8039759747Sdrh# syntax diagram column-constraint
8142825cd2Sdan#
8242825cd2Sdando_createtable_tests 0.2.1 -repair {
8342825cd2Sdan  drop_all_tables
8442825cd2Sdan  execsql { CREATE TABLE t2(x PRIMARY KEY) }
8542825cd2Sdan} {
8642825cd2Sdan  1.1   "CREATE TABLE t1(c1 text PRIMARY KEY)"                         {}
8742825cd2Sdan  1.2   "CREATE TABLE t1(c1 text PRIMARY KEY ASC)"                     {}
8842825cd2Sdan  1.3   "CREATE TABLE t1(c1 text PRIMARY KEY DESC)"                    {}
8942825cd2Sdan  1.4   "CREATE TABLE t1(c1 text CONSTRAINT cons PRIMARY KEY DESC)"    {}
9042825cd2Sdan
9142825cd2Sdan  2.1   "CREATE TABLE t1(c1 text NOT NULL)"                            {}
9242825cd2Sdan  2.2   "CREATE TABLE t1(c1 text CONSTRAINT nm NOT NULL)"              {}
9342825cd2Sdan  2.3   "CREATE TABLE t1(c1 text NULL)"                                {}
9442825cd2Sdan  2.4   "CREATE TABLE t1(c1 text CONSTRAINT nm NULL)"                  {}
9542825cd2Sdan
9642825cd2Sdan  3.1   "CREATE TABLE t1(c1 text UNIQUE)"                              {}
9742825cd2Sdan  3.2   "CREATE TABLE t1(c1 text CONSTRAINT un UNIQUE)"                {}
9842825cd2Sdan
9942825cd2Sdan  4.1   "CREATE TABLE t1(c1 text CHECK(c1!=0))"                        {}
10042825cd2Sdan  4.2   "CREATE TABLE t1(c1 text CONSTRAINT chk CHECK(c1!=0))"         {}
10142825cd2Sdan
10242825cd2Sdan  5.1   "CREATE TABLE t1(c1 text DEFAULT 1)"                           {}
10342825cd2Sdan  5.2   "CREATE TABLE t1(c1 text DEFAULT -1)"                          {}
10442825cd2Sdan  5.3   "CREATE TABLE t1(c1 text DEFAULT +1)"                          {}
10542825cd2Sdan  5.4   "CREATE TABLE t1(c1 text DEFAULT -45.8e22)"                    {}
10642825cd2Sdan  5.5   "CREATE TABLE t1(c1 text DEFAULT (1+1))"                       {}
10742825cd2Sdan  5.6   "CREATE TABLE t1(c1 text CONSTRAINT \"1 2\" DEFAULT (1+1))"    {}
10842825cd2Sdan
10942825cd2Sdan  6.1   "CREATE TABLE t1(c1 text COLLATE nocase)"        {}
11042825cd2Sdan  6.2   "CREATE TABLE t1(c1 text CONSTRAINT 'a x' COLLATE nocase)"     {}
11142825cd2Sdan
11242825cd2Sdan  7.1   "CREATE TABLE t1(c1 REFERENCES t2)"                            {}
11342825cd2Sdan  7.2   "CREATE TABLE t1(c1 CONSTRAINT abc REFERENCES t2)"             {}
11442825cd2Sdan
11542825cd2Sdan  8.1   {
11642825cd2Sdan    CREATE TABLE t1(c1
11742825cd2Sdan      PRIMARY KEY NOT NULL UNIQUE CHECK(c1 IS 'ten') DEFAULT 123 REFERENCES t1
11842825cd2Sdan    );
11942825cd2Sdan  } {}
12042825cd2Sdan  8.2   {
12142825cd2Sdan    CREATE TABLE t1(c1
12242825cd2Sdan      REFERENCES t1 DEFAULT 123 CHECK(c1 IS 'ten') UNIQUE NOT NULL PRIMARY KEY
12342825cd2Sdan    );
12442825cd2Sdan  } {}
12542825cd2Sdan}
12642825cd2Sdan
12739759747Sdrh# -- syntax diagram table-constraint
12842825cd2Sdan#
12942825cd2Sdando_createtable_tests 0.3.1 -repair {
13042825cd2Sdan  drop_all_tables
13142825cd2Sdan  execsql { CREATE TABLE t2(x PRIMARY KEY) }
13242825cd2Sdan} {
13342825cd2Sdan  1.1   "CREATE TABLE t1(c1, c2, PRIMARY KEY(c1))"                         {}
13442825cd2Sdan  1.2   "CREATE TABLE t1(c1, c2, PRIMARY KEY(c1, c2))"                     {}
13542825cd2Sdan  1.3   "CREATE TABLE t1(c1, c2, PRIMARY KEY(c1, c2) ON CONFLICT IGNORE)"  {}
13642825cd2Sdan
13742825cd2Sdan  2.1   "CREATE TABLE t1(c1, c2, UNIQUE(c1))"                              {}
13842825cd2Sdan  2.2   "CREATE TABLE t1(c1, c2, UNIQUE(c1, c2))"                          {}
13942825cd2Sdan  2.3   "CREATE TABLE t1(c1, c2, UNIQUE(c1, c2) ON CONFLICT IGNORE)"       {}
14042825cd2Sdan
14142825cd2Sdan  3.1   "CREATE TABLE t1(c1, c2, CHECK(c1 IS NOT c2))"                     {}
14242825cd2Sdan
14342825cd2Sdan  4.1   "CREATE TABLE t1(c1, c2, FOREIGN KEY(c1) REFERENCES t2)"           {}
14442825cd2Sdan}
14542825cd2Sdan
14639759747Sdrh# -- syntax diagram column-def
14742825cd2Sdan#
14842825cd2Sdando_createtable_tests 0.4.1 -repair {
14942825cd2Sdan  drop_all_tables
15042825cd2Sdan} {
15142825cd2Sdan  1     {CREATE TABLE t1(
15242825cd2Sdan           col1,
15342825cd2Sdan           col2 TEXT,
15442825cd2Sdan           col3 INTEGER UNIQUE,
15542825cd2Sdan           col4 VARCHAR(10, 10) PRIMARY KEY,
15642825cd2Sdan           "name with spaces" REFERENCES t1
15742825cd2Sdan         );
15842825cd2Sdan        } {}
15942825cd2Sdan}
16042825cd2Sdan
16139759747Sdrh# -- syntax diagram create-table-stmt
16242825cd2Sdan#
16342825cd2Sdando_createtable_tests 0.5.1 -repair {
16442825cd2Sdan  drop_all_tables
16542825cd2Sdan  execsql { CREATE TABLE t2(a, b, c) }
16642825cd2Sdan} {
16742825cd2Sdan  1     "CREATE TABLE t1(a, b, c)"                                    {}
16842825cd2Sdan  2     "CREATE TEMP TABLE t1(a, b, c)"                               {}
16942825cd2Sdan  3     "CREATE TEMPORARY TABLE t1(a, b, c)"                          {}
17042825cd2Sdan  4     "CREATE TABLE IF NOT EXISTS t1(a, b, c)"                      {}
17142825cd2Sdan  5     "CREATE TEMP TABLE IF NOT EXISTS t1(a, b, c)"                 {}
17242825cd2Sdan  6     "CREATE TEMPORARY TABLE IF NOT EXISTS t1(a, b, c)"            {}
17342825cd2Sdan
17442825cd2Sdan  7     "CREATE TABLE main.t1(a, b, c)"                               {}
17542825cd2Sdan  8     "CREATE TEMP TABLE temp.t1(a, b, c)"                          {}
17642825cd2Sdan  9     "CREATE TEMPORARY TABLE temp.t1(a, b, c)"                     {}
17742825cd2Sdan  10    "CREATE TABLE IF NOT EXISTS main.t1(a, b, c)"                 {}
17842825cd2Sdan  11    "CREATE TEMP TABLE IF NOT EXISTS temp.t1(a, b, c)"            {}
17942825cd2Sdan  12    "CREATE TEMPORARY TABLE IF NOT EXISTS temp.t1(a, b, c)"       {}
18042825cd2Sdan
18142825cd2Sdan  13    "CREATE TABLE t1 AS SELECT * FROM t2"                         {}
18242825cd2Sdan  14    "CREATE TEMP TABLE t1 AS SELECT c, b, a FROM t2"              {}
18342825cd2Sdan  15    "CREATE TABLE t1 AS SELECT count(*), max(b), min(a) FROM t2"  {}
18442825cd2Sdan}
18542825cd2Sdan
18642825cd2Sdan#
18742825cd2Sdan#   1:         Explicit parent-key columns.
18842825cd2Sdan#   2:         Implicit child-key columns.
18942825cd2Sdan#
19042825cd2Sdan#   1:         MATCH FULL
19142825cd2Sdan#   2:         MATCH PARTIAL
19242825cd2Sdan#   3:         MATCH SIMPLE
19342825cd2Sdan#   4:         MATCH STICK
19442825cd2Sdan#   5:
19542825cd2Sdan#
19642825cd2Sdan#   1:         ON DELETE SET NULL
19742825cd2Sdan#   2:         ON DELETE SET DEFAULT
19842825cd2Sdan#   3:         ON DELETE CASCADE
19942825cd2Sdan#   4:         ON DELETE RESTRICT
20042825cd2Sdan#   5:         ON DELETE NO ACTION
20142825cd2Sdan#   6:
20242825cd2Sdan#
20342825cd2Sdan#   1:         ON UPDATE SET NULL
20442825cd2Sdan#   2:         ON UPDATE SET DEFAULT
20542825cd2Sdan#   3:         ON UPDATE CASCADE
20642825cd2Sdan#   4:         ON UPDATE RESTRICT
20742825cd2Sdan#   5:         ON UPDATE NO ACTION
20842825cd2Sdan#   6:
20942825cd2Sdan#
21042825cd2Sdan#   1:         NOT DEFERRABLE INITIALLY DEFERRED
21142825cd2Sdan#   2:         NOT DEFERRABLE INITIALLY IMMEDIATE
21242825cd2Sdan#   3:         NOT DEFERRABLE
21342825cd2Sdan#   4:         DEFERRABLE INITIALLY DEFERRED
21442825cd2Sdan#   5:         DEFERRABLE INITIALLY IMMEDIATE
21542825cd2Sdan#   6:         DEFERRABLE
21642825cd2Sdan#   7:
21742825cd2Sdan#
21842825cd2Sdando_createtable_tests 0.6.1 -repair {
21942825cd2Sdan  drop_all_tables
22042825cd2Sdan  execsql { CREATE TABLE t2(x PRIMARY KEY, y) }
22142825cd2Sdan  execsql { CREATE TABLE t3(i, j, UNIQUE(i, j) ) }
22242825cd2Sdan} {
22342825cd2Sdan  11146 { CREATE TABLE t1(a
22442825cd2Sdan    REFERENCES t2(x) MATCH FULL
22542825cd2Sdan    ON DELETE SET NULL ON UPDATE RESTRICT DEFERRABLE
22642825cd2Sdan  )} {}
22742825cd2Sdan  11412 { CREATE TABLE t1(a
22842825cd2Sdan    REFERENCES t2(x)
22942825cd2Sdan    ON DELETE RESTRICT ON UPDATE SET NULL MATCH FULL
23042825cd2Sdan    NOT DEFERRABLE INITIALLY IMMEDIATE
23142825cd2Sdan  )} {}
23242825cd2Sdan  12135 { CREATE TABLE t1(a
23342825cd2Sdan    REFERENCES t2(x) MATCH PARTIAL
23442825cd2Sdan    ON DELETE SET NULL ON UPDATE CASCADE DEFERRABLE INITIALLY IMMEDIATE
23542825cd2Sdan  )} {}
23642825cd2Sdan  12427 { CREATE TABLE t1(a
23742825cd2Sdan    REFERENCES t2(x) MATCH PARTIAL
23842825cd2Sdan    ON DELETE RESTRICT ON UPDATE SET DEFAULT
23942825cd2Sdan  )} {}
24042825cd2Sdan  12446 { CREATE TABLE t1(a
24142825cd2Sdan    REFERENCES t2(x) MATCH PARTIAL
24242825cd2Sdan    ON DELETE RESTRICT ON UPDATE RESTRICT DEFERRABLE
24342825cd2Sdan  )} {}
24442825cd2Sdan  12522 { CREATE TABLE t1(a
24542825cd2Sdan    REFERENCES t2(x) MATCH PARTIAL
24642825cd2Sdan    ON DELETE NO ACTION ON UPDATE SET DEFAULT NOT DEFERRABLE INITIALLY IMMEDIATE
24742825cd2Sdan  )} {}
24842825cd2Sdan  13133 { CREATE TABLE t1(a
24942825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
25042825cd2Sdan    ON DELETE SET NULL ON UPDATE CASCADE NOT DEFERRABLE
25142825cd2Sdan  )} {}
25242825cd2Sdan  13216 { CREATE TABLE t1(a
25342825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
25442825cd2Sdan    ON DELETE SET DEFAULT ON UPDATE SET NULL DEFERRABLE
25542825cd2Sdan  )} {}
25642825cd2Sdan  13263 { CREATE TABLE t1(a
25742825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
25842825cd2Sdan    ON DELETE SET DEFAULT  NOT DEFERRABLE
25942825cd2Sdan  )} {}
26042825cd2Sdan  13421 { CREATE TABLE t1(a
26142825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
26242825cd2Sdan    ON DELETE RESTRICT ON UPDATE SET DEFAULT NOT DEFERRABLE INITIALLY DEFERRED
26342825cd2Sdan  )} {}
26442825cd2Sdan  13432 { CREATE TABLE t1(a
26542825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
26642825cd2Sdan    ON DELETE RESTRICT ON UPDATE CASCADE NOT DEFERRABLE INITIALLY IMMEDIATE
26742825cd2Sdan  )} {}
26842825cd2Sdan  13523 { CREATE TABLE t1(a
26942825cd2Sdan    REFERENCES t2(x) MATCH SIMPLE
27042825cd2Sdan    ON DELETE NO ACTION ON UPDATE SET DEFAULT NOT DEFERRABLE
27142825cd2Sdan  )} {}
27242825cd2Sdan  14336 { CREATE TABLE t1(a
27342825cd2Sdan    REFERENCES t2(x) MATCH STICK
27442825cd2Sdan    ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE
27542825cd2Sdan  )} {}
27642825cd2Sdan  14611 { CREATE TABLE t1(a
27742825cd2Sdan    REFERENCES t2(x) MATCH STICK
27842825cd2Sdan    ON UPDATE SET NULL NOT DEFERRABLE INITIALLY DEFERRED
27942825cd2Sdan  )} {}
28042825cd2Sdan  15155 { CREATE TABLE t1(a
28142825cd2Sdan    REFERENCES t2(x)
28242825cd2Sdan    ON DELETE SET NULL ON UPDATE NO ACTION DEFERRABLE INITIALLY IMMEDIATE
28342825cd2Sdan  )} {}
28442825cd2Sdan  15453 { CREATE TABLE t1(a
28542825cd2Sdan    REFERENCES t2(x) ON DELETE RESTRICT ON UPDATE NO ACTION NOT DEFERRABLE
28642825cd2Sdan  )} {}
28742825cd2Sdan  15661 { CREATE TABLE t1(a
28842825cd2Sdan    REFERENCES t2(x) NOT DEFERRABLE INITIALLY DEFERRED
28942825cd2Sdan  )} {}
29042825cd2Sdan  21115 { CREATE TABLE t1(a
29142825cd2Sdan    REFERENCES t2 MATCH FULL
29242825cd2Sdan    ON DELETE SET NULL ON UPDATE SET NULL DEFERRABLE INITIALLY IMMEDIATE
29342825cd2Sdan  )} {}
29442825cd2Sdan  21123 { CREATE TABLE t1(a
29542825cd2Sdan    REFERENCES t2 MATCH FULL
29642825cd2Sdan    ON DELETE SET NULL ON UPDATE SET DEFAULT NOT DEFERRABLE
29742825cd2Sdan  )} {}
29842825cd2Sdan  21217 { CREATE TABLE t1(a
29942825cd2Sdan    REFERENCES t2 MATCH FULL ON DELETE SET DEFAULT ON UPDATE SET NULL
30042825cd2Sdan  )} {}
30142825cd2Sdan  21362 { CREATE TABLE t1(a
30242825cd2Sdan    REFERENCES t2 MATCH FULL
30342825cd2Sdan    ON DELETE CASCADE NOT DEFERRABLE INITIALLY IMMEDIATE
30442825cd2Sdan  )} {}
30542825cd2Sdan  22143 { CREATE TABLE t1(a
30642825cd2Sdan    REFERENCES t2 MATCH PARTIAL
30742825cd2Sdan    ON DELETE SET NULL ON UPDATE RESTRICT NOT DEFERRABLE
30842825cd2Sdan  )} {}
30942825cd2Sdan  22156 { CREATE TABLE t1(a
31042825cd2Sdan    REFERENCES t2 MATCH PARTIAL
31142825cd2Sdan    ON DELETE SET NULL ON UPDATE NO ACTION DEFERRABLE
31242825cd2Sdan  )} {}
31342825cd2Sdan  22327 { CREATE TABLE t1(a
31442825cd2Sdan    REFERENCES t2 MATCH PARTIAL ON DELETE CASCADE ON UPDATE SET DEFAULT
31542825cd2Sdan  )} {}
31642825cd2Sdan  22663 { CREATE TABLE t1(a
31742825cd2Sdan    REFERENCES t2 MATCH PARTIAL NOT DEFERRABLE
31842825cd2Sdan  )} {}
31942825cd2Sdan  23236 { CREATE TABLE t1(a
32042825cd2Sdan    REFERENCES t2 MATCH SIMPLE
32142825cd2Sdan    ON DELETE SET DEFAULT ON UPDATE CASCADE DEFERRABLE
32242825cd2Sdan  )} {}
32342825cd2Sdan  24155 { CREATE TABLE t1(a
32442825cd2Sdan    REFERENCES t2 MATCH STICK
32542825cd2Sdan    ON DELETE SET NULL ON UPDATE NO ACTION DEFERRABLE INITIALLY IMMEDIATE
32642825cd2Sdan  )} {}
32742825cd2Sdan  24522 { CREATE TABLE t1(a
32842825cd2Sdan    REFERENCES t2 MATCH STICK
32942825cd2Sdan    ON DELETE NO ACTION ON UPDATE SET DEFAULT NOT DEFERRABLE INITIALLY IMMEDIATE
33042825cd2Sdan  )} {}
33142825cd2Sdan  24625 { CREATE TABLE t1(a
33242825cd2Sdan    REFERENCES t2 MATCH STICK
33342825cd2Sdan    ON UPDATE SET DEFAULT DEFERRABLE INITIALLY IMMEDIATE
33442825cd2Sdan  )} {}
33542825cd2Sdan  25454 { CREATE TABLE t1(a
33642825cd2Sdan    REFERENCES t2
33742825cd2Sdan    ON DELETE RESTRICT ON UPDATE NO ACTION DEFERRABLE INITIALLY DEFERRED
33842825cd2Sdan  )} {}
33942825cd2Sdan}
34042825cd2Sdan
341a16d1060Sdan#-------------------------------------------------------------------------
342a16d1060Sdan# Test cases e_createtable-1.* - test statements related to table and
343a16d1060Sdan# database names, the TEMP and TEMPORARY keywords, and the IF NOT EXISTS
344a16d1060Sdan# clause.
345a16d1060Sdan#
346a16d1060Sdandrop_all_tables
347a16d1060Sdanforcedelete test.db2 test.db3
348a16d1060Sdan
349a16d1060Sdando_execsql_test e_createtable-1.0 {
350a16d1060Sdan  ATTACH 'test.db2' AS auxa;
351a16d1060Sdan  ATTACH 'test.db3' AS auxb;
352a16d1060Sdan} {}
353a16d1060Sdan
354a16d1060Sdan# EVIDENCE-OF: R-17899-04554 Table names that begin with "sqlite_" are
355a16d1060Sdan# reserved for internal use. It is an error to attempt to create a table
356a16d1060Sdan# with a name that starts with "sqlite_".
357a16d1060Sdan#
358a16d1060Sdando_createtable_tests 1.1.1 -error {
359a16d1060Sdan  object name reserved for internal use: %s
360a16d1060Sdan} {
361a16d1060Sdan  1    "CREATE TABLE sqlite_abc(a, b, c)"        sqlite_abc
362a16d1060Sdan  2    "CREATE TABLE temp.sqlite_helloworld(x)"  sqlite_helloworld
363a16d1060Sdan  3    {CREATE TABLE auxa."sqlite__"(x, y)}      sqlite__
364a16d1060Sdan  4    {CREATE TABLE auxb."sqlite_"(z)}          sqlite_
365a16d1060Sdan  5    {CREATE TABLE "SQLITE_TBL"(z)}            SQLITE_TBL
366a16d1060Sdan}
367a16d1060Sdando_createtable_tests 1.1.2 {
368a16d1060Sdan  1    "CREATE TABLE sqlit_abc(a, b, c)"         {}
369a16d1060Sdan  2    "CREATE TABLE temp.sqlitehelloworld(x)"   {}
370a16d1060Sdan  3    {CREATE TABLE auxa."sqlite"(x, y)}        {}
371a16d1060Sdan  4    {CREATE TABLE auxb."sqlite-"(z)}          {}
372a16d1060Sdan  5    {CREATE TABLE "SQLITE-TBL"(z)}            {}
373a16d1060Sdan}
374a16d1060Sdan
375a16d1060Sdan
376b3366b99Sdrh# EVIDENCE-OF: R-18448-33677 If a schema-name is specified, it must be
377b3366b99Sdrh# either "main", "temp", or the name of an attached database.
378a16d1060Sdan#
379a16d1060Sdan# EVIDENCE-OF: R-39822-07822 In this case the new table is created in
380a16d1060Sdan# the named database.
381a16d1060Sdan#
382a16d1060Sdan#   Test cases 1.2.* test the first of the two requirements above. The
383a16d1060Sdan#   second is verified by cases 1.3.*.
384a16d1060Sdan#
385a16d1060Sdando_createtable_tests 1.2.1 -error {
386a16d1060Sdan  unknown database %s
387a16d1060Sdan} {
388a16d1060Sdan  1    "CREATE TABLE george.t1(a, b)"            george
389a16d1060Sdan  2    "CREATE TABLE _.t1(a, b)"                 _
390a16d1060Sdan}
391a16d1060Sdando_createtable_tests 1.2.2 {
392a16d1060Sdan  1    "CREATE TABLE main.abc(a, b, c)"          {}
393a16d1060Sdan  2    "CREATE TABLE temp.helloworld(x)"         {}
394a16d1060Sdan  3    {CREATE TABLE auxa."t 1"(x, y)}           {}
395a16d1060Sdan  4    {CREATE TABLE auxb.xyz(z)}                {}
396a16d1060Sdan}
397a16d1060Sdandrop_all_tables
39800bd55e1Sdanif {[permutation]!="maindbname"} {
399a16d1060Sdan  do_createtable_tests 1.3 -tclquery {
400a16d1060Sdan    unset -nocomplain X
401a16d1060Sdan    array set X [table_list]
402a16d1060Sdan    list $X(main) $X(temp) $X(auxa) $X(auxb)
403a16d1060Sdan  } {
404a16d1060Sdan    1    "CREATE TABLE main.abc(a, b, c)"  {abc {} {} {}}
405a16d1060Sdan    2    "CREATE TABLE main.t1(a, b, c)"   {{abc t1} {} {} {}}
406a16d1060Sdan    3    "CREATE TABLE temp.tmp(a, b, c)"  {{abc t1} tmp {} {}}
407a16d1060Sdan    4    "CREATE TABLE auxb.tbl(x, y)"     {{abc t1} tmp {} tbl}
408a16d1060Sdan    5    "CREATE TABLE auxb.t1(k, v)"      {{abc t1} tmp {} {t1 tbl}}
409a16d1060Sdan    6    "CREATE TABLE auxa.next(c, d)"    {{abc t1} tmp next {t1 tbl}}
410a16d1060Sdan  }
41100bd55e1Sdan}
412a16d1060Sdan
413a16d1060Sdan# EVIDENCE-OF: R-18895-27365 If the "TEMP" or "TEMPORARY" keyword occurs
414a16d1060Sdan# between the "CREATE" and "TABLE" then the new table is created in the
415a16d1060Sdan# temp database.
416a16d1060Sdan#
417a16d1060Sdandrop_all_tables
41800bd55e1Sdanif {[permutation]!="maindbname"} {
419a16d1060Sdan  do_createtable_tests 1.4 -tclquery {
420a16d1060Sdan    unset -nocomplain X
421a16d1060Sdan    array set X [table_list]
422a16d1060Sdan    list $X(main) $X(temp) $X(auxa) $X(auxb)
423a16d1060Sdan  } {
424a16d1060Sdan    1    "CREATE TEMP TABLE t1(a, b)"      {{} t1 {} {}}
425a16d1060Sdan    2    "CREATE TEMPORARY TABLE t2(a, b)" {{} {t1 t2} {} {}}
426a16d1060Sdan  }
42700bd55e1Sdan}
428a16d1060Sdan
429b3366b99Sdrh# EVIDENCE-OF: R-23976-43329 It is an error to specify both a
430b3366b99Sdrh# schema-name and the TEMP or TEMPORARY keyword, unless the schema-name
431b3366b99Sdrh# is "temp".
432a16d1060Sdan#
433a16d1060Sdandrop_all_tables
434a16d1060Sdando_createtable_tests 1.5.1 -error {
435a16d1060Sdan  temporary table name must be unqualified
436a16d1060Sdan} {
437a16d1060Sdan  1    "CREATE TEMP TABLE main.t1(a, b)"        {}
438a16d1060Sdan  2    "CREATE TEMPORARY TABLE auxa.t2(a, b)"   {}
439a16d1060Sdan  3    "CREATE TEMP TABLE auxb.t3(a, b)"        {}
440a16d1060Sdan  4    "CREATE TEMPORARY TABLE main.xxx(x)"     {}
441a16d1060Sdan}
442a16d1060Sdandrop_all_tables
44300bd55e1Sdanif {[permutation]!="maindbname"} {
444a16d1060Sdan  do_createtable_tests 1.5.2 -tclquery {
445a16d1060Sdan    unset -nocomplain X
446a16d1060Sdan    array set X [table_list]
447a16d1060Sdan    list $X(main) $X(temp) $X(auxa) $X(auxb)
448a16d1060Sdan  } {
449a16d1060Sdan    1    "CREATE TEMP TABLE temp.t1(a, b)"        {{} t1 {} {}}
450a16d1060Sdan    2    "CREATE TEMPORARY TABLE temp.t2(a, b)"   {{} {t1 t2} {} {}}
451a16d1060Sdan    3    "CREATE TEMP TABLE TEMP.t3(a, b)"        {{} {t1 t2 t3} {} {}}
452a16d1060Sdan    4    "CREATE TEMPORARY TABLE TEMP.xxx(x)"     {{} {t1 t2 t3 xxx} {} {}}
453a16d1060Sdan  }
45400bd55e1Sdan}
455a16d1060Sdan
456b3366b99Sdrh# EVIDENCE-OF: R-31997-24564 If no schema name is specified and the TEMP
457b3366b99Sdrh# keyword is not present then the table is created in the main database.
458a16d1060Sdan#
459a16d1060Sdandrop_all_tables
46000bd55e1Sdanif {[permutation]!="maindbname"} {
461a16d1060Sdan  do_createtable_tests 1.6 -tclquery {
462a16d1060Sdan    unset -nocomplain X
463a16d1060Sdan    array set X [table_list]
464a16d1060Sdan    list $X(main) $X(temp) $X(auxa) $X(auxb)
465a16d1060Sdan  } {
466a16d1060Sdan    1    "CREATE TABLE t1(a, b)"   {t1 {} {} {}}
467a16d1060Sdan    2    "CREATE TABLE t2(a, b)"   {{t1 t2} {} {} {}}
468a16d1060Sdan    3    "CREATE TABLE t3(a, b)"   {{t1 t2 t3} {} {} {}}
469a16d1060Sdan    4    "CREATE TABLE xxx(x)"     {{t1 t2 t3 xxx} {} {} {}}
470a16d1060Sdan  }
47100bd55e1Sdan}
472a16d1060Sdan
473a16d1060Sdandrop_all_tables
474a16d1060Sdando_execsql_test e_createtable-1.7.0 {
475a16d1060Sdan  CREATE TABLE t1(x, y);
476a16d1060Sdan  CREATE INDEX i1 ON t1(x);
477a16d1060Sdan  CREATE VIEW  v1 AS SELECT * FROM t1;
478a16d1060Sdan
479a16d1060Sdan  CREATE TABLE auxa.tbl1(x, y);
480a16d1060Sdan  CREATE INDEX auxa.idx1 ON tbl1(x);
481a16d1060Sdan  CREATE VIEW auxa.view1 AS SELECT * FROM tbl1;
482a16d1060Sdan} {}
483a16d1060Sdan
484a16d1060Sdan# EVIDENCE-OF: R-01232-54838 It is usually an error to attempt to create
485a16d1060Sdan# a new table in a database that already contains a table, index or view
486a16d1060Sdan# of the same name.
487a16d1060Sdan#
488a16d1060Sdan#   Test cases 1.7.1.* verify that creating a table in a database with a
489a16d1060Sdan#   table/index/view of the same name does fail. 1.7.2.* tests that creating
490a16d1060Sdan#   a table with the same name as a table/index/view in a different database
491a16d1060Sdan#   is Ok.
492a16d1060Sdan#
493a16d1060Sdando_createtable_tests 1.7.1 -error { %s } {
494a16d1060Sdan  1    "CREATE TABLE t1(a, b)"   {{table t1 already exists}}
495a16d1060Sdan  2    "CREATE TABLE i1(a, b)"   {{there is already an index named i1}}
496*6e85b27cSlarrybr  3    "CREATE TABLE v1(a, b)"   {{view v1 already exists}}
497a16d1060Sdan  4    "CREATE TABLE auxa.tbl1(a, b)"   {{table tbl1 already exists}}
498a16d1060Sdan  5    "CREATE TABLE auxa.idx1(a, b)"   {{there is already an index named idx1}}
499*6e85b27cSlarrybr  6    "CREATE TABLE auxa.view1(a, b)"  {{view view1 already exists}}
500a16d1060Sdan}
501a16d1060Sdando_createtable_tests 1.7.2 {
502a16d1060Sdan  1    "CREATE TABLE auxa.t1(a, b)"   {}
503a16d1060Sdan  2    "CREATE TABLE auxa.i1(a, b)"   {}
504a16d1060Sdan  3    "CREATE TABLE auxa.v1(a, b)"   {}
505a16d1060Sdan  4    "CREATE TABLE tbl1(a, b)"      {}
506a16d1060Sdan  5    "CREATE TABLE idx1(a, b)"      {}
507a16d1060Sdan  6    "CREATE TABLE view1(a, b)"     {}
508a16d1060Sdan}
509a16d1060Sdan
510a16d1060Sdan# EVIDENCE-OF: R-33917-24086 However, if the "IF NOT EXISTS" clause is
511a16d1060Sdan# specified as part of the CREATE TABLE statement and a table or view of
512a16d1060Sdan# the same name already exists, the CREATE TABLE command simply has no
513a16d1060Sdan# effect (and no error message is returned).
514a16d1060Sdan#
515a16d1060Sdandrop_all_tables
516a16d1060Sdando_execsql_test e_createtable-1.8.0 {
517a16d1060Sdan  CREATE TABLE t1(x, y);
518a16d1060Sdan  CREATE INDEX i1 ON t1(x);
519a16d1060Sdan  CREATE VIEW  v1 AS SELECT * FROM t1;
520a16d1060Sdan  CREATE TABLE auxa.tbl1(x, y);
521a16d1060Sdan  CREATE INDEX auxa.idx1 ON tbl1(x);
522a16d1060Sdan  CREATE VIEW auxa.view1 AS SELECT * FROM tbl1;
523a16d1060Sdan} {}
524a16d1060Sdando_createtable_tests 1.8 {
525a16d1060Sdan  1    "CREATE TABLE IF NOT EXISTS t1(a, b)"          {}
526a16d1060Sdan  2    "CREATE TABLE IF NOT EXISTS auxa.tbl1(a, b)"   {}
527a16d1060Sdan  3    "CREATE TABLE IF NOT EXISTS v1(a, b)"          {}
528a16d1060Sdan  4    "CREATE TABLE IF NOT EXISTS auxa.view1(a, b)"  {}
529a16d1060Sdan}
530a16d1060Sdan
531a16d1060Sdan# EVIDENCE-OF: R-16465-40078 An error is still returned if the table
532a16d1060Sdan# cannot be created because of an existing index, even if the "IF NOT
533a16d1060Sdan# EXISTS" clause is specified.
534a16d1060Sdan#
535a16d1060Sdando_createtable_tests 1.9 -error { %s } {
536a16d1060Sdan  1    "CREATE TABLE IF NOT EXISTS i1(a, b)"
537a16d1060Sdan       {{there is already an index named i1}}
538a16d1060Sdan  2    "CREATE TABLE IF NOT EXISTS auxa.idx1(a, b)"
539a16d1060Sdan       {{there is already an index named idx1}}
540a16d1060Sdan}
541a16d1060Sdan
542a16d1060Sdan# EVIDENCE-OF: R-05513-33819 It is not an error to create a table that
543a16d1060Sdan# has the same name as an existing trigger.
544a16d1060Sdan#
545a16d1060Sdandrop_all_tables
546a16d1060Sdando_execsql_test e_createtable-1.10.0 {
547a16d1060Sdan  CREATE TABLE t1(x, y);
548a16d1060Sdan  CREATE TABLE auxb.t2(x, y);
549a16d1060Sdan
550a16d1060Sdan  CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
551a16d1060Sdan    SELECT 1;
552a16d1060Sdan  END;
553a16d1060Sdan  CREATE TRIGGER auxb.tr2 AFTER INSERT ON t2 BEGIN
554a16d1060Sdan    SELECT 1;
555a16d1060Sdan  END;
556a16d1060Sdan} {}
557a16d1060Sdando_createtable_tests 1.10 {
558a16d1060Sdan  1    "CREATE TABLE tr1(a, b)"          {}
559a16d1060Sdan  2    "CREATE TABLE tr2(a, b)"          {}
560a16d1060Sdan  3    "CREATE TABLE auxb.tr1(a, b)"     {}
561a16d1060Sdan  4    "CREATE TABLE auxb.tr2(a, b)"     {}
562a16d1060Sdan}
563a16d1060Sdan
564a16d1060Sdan# EVIDENCE-OF: R-22283-14179 Tables are removed using the DROP TABLE
565a16d1060Sdan# statement.
566a16d1060Sdan#
567a16d1060Sdandrop_all_tables
568a16d1060Sdando_execsql_test e_createtable-1.11.0 {
569a16d1060Sdan  CREATE TABLE t1(a, b);
570a16d1060Sdan  CREATE TABLE t2(a, b);
571a16d1060Sdan  CREATE TABLE auxa.t3(a, b);
572a16d1060Sdan  CREATE TABLE auxa.t4(a, b);
573a16d1060Sdan} {}
574a16d1060Sdan
575a16d1060Sdando_execsql_test e_createtable-1.11.1.1 {
576a16d1060Sdan  SELECT * FROM t1;
577a16d1060Sdan  SELECT * FROM t2;
578a16d1060Sdan  SELECT * FROM t3;
579a16d1060Sdan  SELECT * FROM t4;
580a16d1060Sdan} {}
581a16d1060Sdando_execsql_test  e_createtable-1.11.1.2 { DROP TABLE t1 } {}
582a16d1060Sdando_catchsql_test e_createtable-1.11.1.3 {
583a16d1060Sdan  SELECT * FROM t1
584a16d1060Sdan} {1 {no such table: t1}}
585a16d1060Sdando_execsql_test  e_createtable-1.11.1.4 { DROP TABLE t3 } {}
586a16d1060Sdando_catchsql_test e_createtable-1.11.1.5 {
587a16d1060Sdan  SELECT * FROM t3
588a16d1060Sdan} {1 {no such table: t3}}
589a16d1060Sdan
590a16d1060Sdando_execsql_test e_createtable-1.11.2.1 {
591a16d1060Sdan  SELECT name FROM sqlite_master;
592a16d1060Sdan  SELECT name FROM auxa.sqlite_master;
593a16d1060Sdan} {t2 t4}
594a16d1060Sdando_execsql_test  e_createtable-1.11.2.2 { DROP TABLE t2 } {}
595a16d1060Sdando_execsql_test  e_createtable-1.11.2.3 { DROP TABLE t4 } {}
596a16d1060Sdando_execsql_test e_createtable-1.11.2.4 {
597a16d1060Sdan  SELECT name FROM sqlite_master;
598a16d1060Sdan  SELECT name FROM auxa.sqlite_master;
599a16d1060Sdan} {}
600a16d1060Sdan
6018f1a8afdSdan#-------------------------------------------------------------------------
6028f1a8afdSdan# Test cases e_createtable-2.* - test statements related to the CREATE
6038f1a8afdSdan# TABLE AS ... SELECT statement.
6048f1a8afdSdan#
6058f1a8afdSdan
6068f1a8afdSdan# Three Tcl commands:
6078f1a8afdSdan#
6088f1a8afdSdan#   select_column_names SQL
6098f1a8afdSdan#     The argument must be a SELECT statement. Return a list of the names
6108f1a8afdSdan#     of the columns of the result-set that would be returned by executing
6118f1a8afdSdan#     the SELECT.
6128f1a8afdSdan#
6138f1a8afdSdan#   table_column_names TBL
6148f1a8afdSdan#     The argument must be a table name. Return a list of column names, from
6158f1a8afdSdan#     left to right, for the table.
6168f1a8afdSdan#
6178f1a8afdSdan#   table_column_decltypes TBL
6188f1a8afdSdan#     The argument must be a table name. Return a list of column declared
6198f1a8afdSdan#     types, from left to right, for the table.
6208f1a8afdSdan#
6218f1a8afdSdanproc sci {select cmd} {
6228f1a8afdSdan  set res [list]
6238f1a8afdSdan  set STMT [sqlite3_prepare_v2 db $select -1 dummy]
6248f1a8afdSdan  for {set i 0} {$i < [sqlite3_column_count $STMT]} {incr i} {
6258f1a8afdSdan    lappend res [$cmd $STMT $i]
6268f1a8afdSdan  }
6278f1a8afdSdan  sqlite3_finalize $STMT
6288f1a8afdSdan  set res
6298f1a8afdSdan}
6308f1a8afdSdanproc tci {tbl cmd} { sci "SELECT * FROM $tbl" $cmd }
6318f1a8afdSdanproc select_column_names    {sql} { sci $sql sqlite3_column_name }
6328f1a8afdSdanproc table_column_names     {tbl} { tci $tbl sqlite3_column_name }
6338f1a8afdSdanproc table_column_decltypes {tbl} { tci $tbl sqlite3_column_decltype }
6348f1a8afdSdan
6358f1a8afdSdan# Create a database schema. This schema is used by tests 2.1.* through 2.3.*.
6368f1a8afdSdan#
6378f1a8afdSdandrop_all_tables
6388f1a8afdSdando_execsql_test e_createtable-2.0 {
6398f1a8afdSdan  CREATE TABLE t1(a, b, c);
6408f1a8afdSdan  CREATE TABLE t2(d, e, f);
6418f1a8afdSdan  CREATE TABLE t3(g BIGINT, h VARCHAR(10));
6428f1a8afdSdan  CREATE TABLE t4(i BLOB, j ANYOLDATA);
6438f1a8afdSdan  CREATE TABLE t5(k FLOAT, l INTEGER);
6448f1a8afdSdan  CREATE TABLE t6(m DEFAULT 10, n DEFAULT 5, PRIMARY KEY(m, n));
6458f1a8afdSdan  CREATE TABLE t7(x INTEGER PRIMARY KEY);
6468f1a8afdSdan  CREATE TABLE t8(o COLLATE nocase DEFAULT 'abc');
6478f1a8afdSdan  CREATE TABLE t9(p NOT NULL, q DOUBLE CHECK (q!=0), r STRING UNIQUE);
6488f1a8afdSdan} {}
6498f1a8afdSdan
6508f1a8afdSdan# EVIDENCE-OF: R-64828-59568 The table has the same number of columns as
6518f1a8afdSdan# the rows returned by the SELECT statement. The name of each column is
6528f1a8afdSdan# the same as the name of the corresponding column in the result set of
6538f1a8afdSdan# the SELECT statement.
6548f1a8afdSdan#
6558f1a8afdSdando_createtable_tests 2.1 -tclquery {
6568f1a8afdSdan  table_column_names x1
6578f1a8afdSdan} -repair {
6588f1a8afdSdan  catchsql { DROP TABLE x1 }
6598f1a8afdSdan} {
6608f1a8afdSdan  1    "CREATE TABLE x1 AS SELECT * FROM t1"                     {a b c}
6618f1a8afdSdan  2    "CREATE TABLE x1 AS SELECT c, b, a FROM t1"               {c b a}
6628f1a8afdSdan  3    "CREATE TABLE x1 AS SELECT * FROM t1, t2"                 {a b c d e f}
6638f1a8afdSdan  4    "CREATE TABLE x1 AS SELECT count(*) FROM t1"              {count(*)}
6648f1a8afdSdan  5    "CREATE TABLE x1 AS SELECT count(a) AS a, max(b) FROM t1" {a max(b)}
6658f1a8afdSdan}
6668f1a8afdSdan
667e3d511c0Sdrh# EVIDENCE-OF: R-55407-45319 The declared type of each column is
6688f1a8afdSdan# determined by the expression affinity of the corresponding expression
6698f1a8afdSdan# in the result set of the SELECT statement, as follows: Expression
6708f1a8afdSdan# Affinity Column Declared Type TEXT "TEXT" NUMERIC "NUM" INTEGER "INT"
671e3d511c0Sdrh# REAL "REAL" BLOB (a.k.a "NONE") "" (empty string)
6728f1a8afdSdan#
6738f1a8afdSdando_createtable_tests 2.2 -tclquery {
6748f1a8afdSdan  table_column_decltypes x1
6758f1a8afdSdan} -repair {
6768f1a8afdSdan  catchsql { DROP TABLE x1 }
6778f1a8afdSdan} {
6788f1a8afdSdan  1    "CREATE TABLE x1 AS SELECT a FROM t1"     {""}
6798f1a8afdSdan  2    "CREATE TABLE x1 AS SELECT * FROM t3"     {INT TEXT}
6808f1a8afdSdan  3    "CREATE TABLE x1 AS SELECT * FROM t4"     {"" NUM}
6818f1a8afdSdan  4    "CREATE TABLE x1 AS SELECT * FROM t5"     {REAL INT}
6828f1a8afdSdan}
6838f1a8afdSdan
6848f1a8afdSdan# EVIDENCE-OF: R-16667-09772 A table created using CREATE TABLE AS has
6858f1a8afdSdan# no PRIMARY KEY and no constraints of any kind. The default value of
6868f1a8afdSdan# each column is NULL. The default collation sequence for each column of
6878f1a8afdSdan# the new table is BINARY.
6888f1a8afdSdan#
6898f1a8afdSdan#   The following tests create tables based on SELECT statements that read
6908f1a8afdSdan#   from tables that have primary keys, constraints and explicit default
6918f1a8afdSdan#   collation sequences. None of this is transfered to the definition of
6928f1a8afdSdan#   the new table as stored in the sqlite_master table.
6938f1a8afdSdan#
6948f1a8afdSdan#   Tests 2.3.2.* show that the default value of each column is NULL.
6958f1a8afdSdan#
6968f1a8afdSdando_createtable_tests 2.3.1 -query {
6978f1a8afdSdan  SELECT sql FROM sqlite_master ORDER BY rowid DESC LIMIT 1
6988f1a8afdSdan} {
6998f1a8afdSdan  1    "CREATE TABLE x1 AS SELECT * FROM t6" {{CREATE TABLE x1(m,n)}}
7008f1a8afdSdan  2    "CREATE TABLE x2 AS SELECT * FROM t7" {{CREATE TABLE x2(x INT)}}
7018f1a8afdSdan  3    "CREATE TABLE x3 AS SELECT * FROM t8" {{CREATE TABLE x3(o)}}
7028f1a8afdSdan  4    "CREATE TABLE x4 AS SELECT * FROM t9" {{CREATE TABLE x4(p,q REAL,r NUM)}}
7038f1a8afdSdan}
7048f1a8afdSdando_execsql_test e_createtable-2.3.2.1 {
7058f1a8afdSdan  INSERT INTO x1 DEFAULT VALUES;
7068f1a8afdSdan  INSERT INTO x2 DEFAULT VALUES;
7078f1a8afdSdan  INSERT INTO x3 DEFAULT VALUES;
7088f1a8afdSdan  INSERT INTO x4 DEFAULT VALUES;
7098f1a8afdSdan} {}
7108f1a8afdSdandb nullvalue null
7118f1a8afdSdando_execsql_test e_createtable-2.3.2.2 { SELECT * FROM x1 } {null null}
7128f1a8afdSdando_execsql_test e_createtable-2.3.2.3 { SELECT * FROM x2 } {null}
7138f1a8afdSdando_execsql_test e_createtable-2.3.2.4 { SELECT * FROM x3 } {null}
7148f1a8afdSdando_execsql_test e_createtable-2.3.2.5 { SELECT * FROM x4 } {null null null}
7158f1a8afdSdandb nullvalue {}
7168f1a8afdSdan
7178f1a8afdSdandrop_all_tables
7188f1a8afdSdando_execsql_test e_createtable-2.4.0 {
7198f1a8afdSdan  CREATE TABLE t1(x, y);
7208f1a8afdSdan  INSERT INTO t1 VALUES('i',   'one');
7218f1a8afdSdan  INSERT INTO t1 VALUES('ii',  'two');
7228f1a8afdSdan  INSERT INTO t1 VALUES('iii', 'three');
7238f1a8afdSdan} {}
7248f1a8afdSdan
7258f1a8afdSdan# EVIDENCE-OF: R-24153-28352 Tables created using CREATE TABLE AS are
7268f1a8afdSdan# initially populated with the rows of data returned by the SELECT
7278f1a8afdSdan# statement.
7288f1a8afdSdan#
7298f1a8afdSdan# EVIDENCE-OF: R-08224-30249 Rows are assigned contiguously ascending
7308f1a8afdSdan# rowid values, starting with 1, in the order that they are returned by
7318f1a8afdSdan# the SELECT statement.
7328f1a8afdSdan#
7338f1a8afdSdan#   Each test case below is specified as the name of a table to create
7348f1a8afdSdan#   using "CREATE TABLE ... AS SELECT ..." and a SELECT statement to use in
7358f1a8afdSdan#   creating it. The table is created.
7368f1a8afdSdan#
7378f1a8afdSdan#   Test cases 2.4.*.1 check that after it has been created, the data in the
7388f1a8afdSdan#   table is the same as the data returned by the SELECT statement executed as
7398f1a8afdSdan#   a standalone command, verifying the first testable statement above.
7408f1a8afdSdan#
7418f1a8afdSdan#   Test cases 2.4.*.2 check that the rowids were allocated contiguously
7428f1a8afdSdan#   as required by the second testable statement above. That the rowids
7438f1a8afdSdan#   from the contiguous block were allocated to rows in the order rows are
7448f1a8afdSdan#   returned by the SELECT statement is verified by 2.4.*.1.
7458f1a8afdSdan#
7468f1a8afdSdan# EVIDENCE-OF: R-32365-09043 A "CREATE TABLE ... AS SELECT" statement
7478f1a8afdSdan# creates and populates a database table based on the results of a
7488f1a8afdSdan# SELECT statement.
7498f1a8afdSdan#
7508f1a8afdSdan#   The above is also considered to be tested by the following. It is
7518f1a8afdSdan#   clear that tables are being created and populated by the command in
7528f1a8afdSdan#   question.
7538f1a8afdSdan#
7548f1a8afdSdanforeach {tn tbl select} {
7558f1a8afdSdan  1   x1   "SELECT * FROM t1"
7568f1a8afdSdan  2   x2   "SELECT * FROM t1 ORDER BY x DESC"
7578f1a8afdSdan  3   x3   "SELECT * FROM t1 ORDER BY x ASC"
7588f1a8afdSdan} {
7598f1a8afdSdan  # Create the table using a "CREATE TABLE ... AS SELECT ..." command.
7608f1a8afdSdan  execsql [subst {CREATE TABLE $tbl AS $select}]
7618f1a8afdSdan
7628f1a8afdSdan  # Check that the rows inserted into the table, sorted in ascending rowid
7638f1a8afdSdan  # order, match those returned by executing the SELECT statement as a
7648f1a8afdSdan  # standalone command.
7658f1a8afdSdan  do_execsql_test e_createtable-2.4.$tn.1 [subst {
7668f1a8afdSdan    SELECT * FROM $tbl ORDER BY rowid;
7678f1a8afdSdan  }] [execsql $select]
7688f1a8afdSdan
7698f1a8afdSdan  # Check that the rowids in the new table are a contiguous block starting
7708f1a8afdSdan  # with rowid 1. Note that this will fail if SELECT statement $select
7718f1a8afdSdan  # returns 0 rows (as max(rowid) will be NULL).
7728f1a8afdSdan  do_execsql_test e_createtable-2.4.$tn.2 [subst {
7738f1a8afdSdan    SELECT min(rowid), count(rowid)==max(rowid) FROM $tbl
7748f1a8afdSdan  }] {1 1}
7758f1a8afdSdan}
776a16d1060Sdan
777fac2bd45Sdan#--------------------------------------------------------------------------
778fac2bd45Sdan# Test cases for column defintions in CREATE TABLE statements that do not
779fac2bd45Sdan# use a SELECT statement. Not including data constraints. In other words,
780fac2bd45Sdan# tests for the specification of:
781fac2bd45Sdan#
782fac2bd45Sdan#   * declared types,
783fac2bd45Sdan#   * default values, and
784fac2bd45Sdan#   * default collation sequences.
785fac2bd45Sdan#
786fac2bd45Sdan
787fac2bd45Sdan# EVIDENCE-OF: R-27219-49057 Unlike most SQL databases, SQLite does not
788fac2bd45Sdan# restrict the type of data that may be inserted into a column based on
789fac2bd45Sdan# the columns declared type.
790fac2bd45Sdan#
791fac2bd45Sdan#   Test this by creating a few tables with varied declared types, then
792fac2bd45Sdan#   inserting various different types of values into them.
793fac2bd45Sdan#
794fac2bd45Sdandrop_all_tables
795fac2bd45Sdando_execsql_test e_createtable-3.1.0 {
796fac2bd45Sdan  CREATE TABLE t1(x VARCHAR(10), y INTEGER, z DOUBLE);
797fac2bd45Sdan  CREATE TABLE t2(a DATETIME, b STRING, c REAL);
798fac2bd45Sdan  CREATE TABLE t3(o, t);
799fac2bd45Sdan} {}
800fac2bd45Sdan
801fac2bd45Sdan# value type -> declared column type
802fac2bd45Sdan# ----------------------------------
803fac2bd45Sdan# integer    -> VARCHAR(10)
804fac2bd45Sdan# string     -> INTEGER
805fac2bd45Sdan# blob       -> DOUBLE
806fac2bd45Sdan#
807fac2bd45Sdando_execsql_test e_createtable-3.1.1 {
808fac2bd45Sdan  INSERT INTO t1 VALUES(14, 'quite a lengthy string', X'555655');
809fac2bd45Sdan  SELECT * FROM t1;
810fac2bd45Sdan} {14 {quite a lengthy string} UVU}
811fac2bd45Sdan
812fac2bd45Sdan# string     -> DATETIME
813fac2bd45Sdan# integer    -> STRING
814fac2bd45Sdan# time       -> REAL
815fac2bd45Sdan#
816fac2bd45Sdando_execsql_test e_createtable-3.1.2 {
817fac2bd45Sdan  INSERT INTO t2 VALUES('not a datetime', 13, '12:41:59');
818fac2bd45Sdan  SELECT * FROM t2;
819fac2bd45Sdan} {{not a datetime} 13 12:41:59}
820fac2bd45Sdan
821fac2bd45Sdan# EVIDENCE-OF: R-10565-09557 The declared type of a column is used to
822fac2bd45Sdan# determine the affinity of the column only.
823fac2bd45Sdan#
824fac2bd45Sdan#     Affinities are tested in more detail elsewhere (see document
825fac2bd45Sdan#     datatype3.html). Here, just test that affinity transformations
826fac2bd45Sdan#     consistent with the expected affinity of each column (based on
827fac2bd45Sdan#     the declared type) appear to take place.
828fac2bd45Sdan#
829fac2bd45Sdan# Affinities of t1 (test cases 3.2.1.*): TEXT, INTEGER, REAL
830fac2bd45Sdan# Affinities of t2 (test cases 3.2.2.*): NUMERIC, NUMERIC, REAL
831fac2bd45Sdan# Affinities of t3 (test cases 3.2.3.*): NONE, NONE
832fac2bd45Sdan#
833fac2bd45Sdando_execsql_test e_createtable-3.2.0 { DELETE FROM t1; DELETE FROM t2; } {}
834fac2bd45Sdan
835fac2bd45Sdando_createtable_tests 3.2.1 -query {
836fac2bd45Sdan  SELECT quote(x), quote(y), quote(z) FROM t1 ORDER BY rowid DESC LIMIT 1;
837fac2bd45Sdan} {
838fac2bd45Sdan  1   "INSERT INTO t1 VALUES(15,   '22.0', '14')"   {'15' 22 14.0}
839fac2bd45Sdan  2   "INSERT INTO t1 VALUES(22.0, 22.0, 22.0)"     {'22.0' 22 22.0}
840fac2bd45Sdan}
841fac2bd45Sdando_createtable_tests 3.2.2 -query {
842fac2bd45Sdan  SELECT quote(a), quote(b), quote(c) FROM t2 ORDER BY rowid DESC LIMIT 1;
843fac2bd45Sdan} {
844fac2bd45Sdan  1   "INSERT INTO t2 VALUES(15,   '22.0', '14')"   {15   22  14.0}
845fac2bd45Sdan  2   "INSERT INTO t2 VALUES(22.0, 22.0, 22.0)"     {22   22  22.0}
846fac2bd45Sdan}
847fac2bd45Sdando_createtable_tests 3.2.3 -query {
848fac2bd45Sdan  SELECT quote(o), quote(t) FROM t3 ORDER BY rowid DESC LIMIT 1;
849fac2bd45Sdan} {
850fac2bd45Sdan  1   "INSERT INTO t3 VALUES('15', '22.0')"         {'15' '22.0'}
851fac2bd45Sdan  2   "INSERT INTO t3 VALUES(15, 22.0)"             {15 22.0}
852fac2bd45Sdan}
853fac2bd45Sdan
854fac2bd45Sdan# EVIDENCE-OF: R-42316-09582 If there is no explicit DEFAULT clause
855fac2bd45Sdan# attached to a column definition, then the default value of the column
856fac2bd45Sdan# is NULL.
857fac2bd45Sdan#
858fac2bd45Sdan#     None of the columns in table t1 have an explicit DEFAULT clause.
859fac2bd45Sdan#     So testing that the default value of all columns in table t1 is
860fac2bd45Sdan#     NULL serves to verify the above.
861fac2bd45Sdan#
862fac2bd45Sdando_createtable_tests 3.2.3 -query {
863fac2bd45Sdan  SELECT quote(x), quote(y), quote(z) FROM t1
864fac2bd45Sdan} -repair {
865fac2bd45Sdan  execsql { DELETE FROM t1 }
866fac2bd45Sdan} {
867fac2bd45Sdan  1   "INSERT INTO t1(x, y) VALUES('abc', 'xyz')"   {'abc' 'xyz' NULL}
868fac2bd45Sdan  2   "INSERT INTO t1(x, z) VALUES('abc', 'xyz')"   {'abc' NULL 'xyz'}
869fac2bd45Sdan  3   "INSERT INTO t1 DEFAULT VALUES"               {NULL NULL NULL}
870fac2bd45Sdan}
871fac2bd45Sdan
8728da47419Sdrh# EVIDENCE-OF: R-07343-35026 An explicit DEFAULT clause may specify that
873fac2bd45Sdan# the default value is NULL, a string constant, a blob constant, a
8748da47419Sdrh# signed-number, or any constant expression enclosed in parentheses. A
8758da47419Sdrh# default value may also be one of the special case-independent keywords
8768da47419Sdrh# CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP.
877fac2bd45Sdan#
878fac2bd45Sdando_execsql_test e_createtable-3.3.1 {
879fac2bd45Sdan  CREATE TABLE t4(
880fac2bd45Sdan    a DEFAULT NULL,
881fac2bd45Sdan    b DEFAULT 'string constant',
882fac2bd45Sdan    c DEFAULT X'424C4F42',
883fac2bd45Sdan    d DEFAULT 1,
884fac2bd45Sdan    e DEFAULT -1,
885fac2bd45Sdan    f DEFAULT 3.14,
886fac2bd45Sdan    g DEFAULT -3.14,
887fac2bd45Sdan    h DEFAULT ( substr('abcd', 0, 2) || 'cd' ),
888fac2bd45Sdan    i DEFAULT CURRENT_TIME,
889fac2bd45Sdan    j DEFAULT CURRENT_DATE,
890fac2bd45Sdan    k DEFAULT CURRENT_TIMESTAMP
891fac2bd45Sdan  );
892fac2bd45Sdan} {}
893fac2bd45Sdan
894396a1036Sdrh# EVIDENCE-OF: R-33440-07331 For the purposes of the DEFAULT clause, an
895396a1036Sdrh# expression is considered constant if it contains no sub-queries,
8968da47419Sdrh# column or table references, bound parameters, or string literals
8971f8bb4b0Sdrh# enclosed in double-quotes instead of single-quotes.
898fac2bd45Sdan#
899fac2bd45Sdando_createtable_tests 3.4.1 -error {
900fac2bd45Sdan  default value of column [x] is not constant
901fac2bd45Sdan} {
902fac2bd45Sdan  1   {CREATE TABLE t5(x DEFAULT ( (SELECT 1) ))}  {}
903fac2bd45Sdan  2   {CREATE TABLE t5(x DEFAULT ( "abc" ))}  {}
904fac2bd45Sdan  3   {CREATE TABLE t5(x DEFAULT ( 1 IN (SELECT 1) ))}  {}
905fac2bd45Sdan  4   {CREATE TABLE t5(x DEFAULT ( EXISTS (SELECT 1) ))}  {}
9068da47419Sdrh  5   {CREATE TABLE t5(x DEFAULT ( x!=?1 ))}  {}
907fac2bd45Sdan}
908fac2bd45Sdando_createtable_tests 3.4.2 -repair {
909fac2bd45Sdan  catchsql { DROP TABLE t5 }
910fac2bd45Sdan} {
911fac2bd45Sdan  1   {CREATE TABLE t5(x DEFAULT ( 'abc' ))}  {}
912fac2bd45Sdan  2   {CREATE TABLE t5(x DEFAULT ( 1 IN (1, 2, 3) ))}  {}
913fac2bd45Sdan}
914fac2bd45Sdan
915fac2bd45Sdan# EVIDENCE-OF: R-18814-23501 Each time a row is inserted into the table
916fac2bd45Sdan# by an INSERT statement that does not provide explicit values for all
917fac2bd45Sdan# table columns the values stored in the new row are determined by their
918fac2bd45Sdan# default values
919fac2bd45Sdan#
920fac2bd45Sdan#     Verify this with some assert statements for which all, some and no
921fac2bd45Sdan#     columns lack explicit values.
922fac2bd45Sdan#
923fac2bd45Sdanset sqlite_current_time 1000000000
924fac2bd45Sdando_createtable_tests 3.5 -query {
925fac2bd45Sdan  SELECT quote(a), quote(b), quote(c), quote(d), quote(e), quote(f),
926fac2bd45Sdan         quote(g), quote(h), quote(i), quote(j), quote(k)
927fac2bd45Sdan  FROM t4 ORDER BY rowid DESC LIMIT 1;
928fac2bd45Sdan} {
929fac2bd45Sdan  1 "INSERT INTO t4 DEFAULT VALUES" {
930fac2bd45Sdan    NULL {'string constant'} X'424C4F42' 1 -1 3.14 -3.14
931fac2bd45Sdan    'acd' '01:46:40' '2001-09-09' {'2001-09-09 01:46:40'}
932fac2bd45Sdan  }
933fac2bd45Sdan
934fac2bd45Sdan  2 "INSERT INTO t4(a, b, c) VALUES(1, 2, 3)" {
935fac2bd45Sdan    1 2 3 1 -1 3.14 -3.14 'acd' '01:46:40' '2001-09-09' {'2001-09-09 01:46:40'}
936fac2bd45Sdan  }
937fac2bd45Sdan
938fac2bd45Sdan  3 "INSERT INTO t4(k, j, i) VALUES(1, 2, 3)" {
939fac2bd45Sdan    NULL {'string constant'} X'424C4F42' 1 -1 3.14 -3.14 'acd' 3 2 1
940fac2bd45Sdan  }
941fac2bd45Sdan
942fac2bd45Sdan  4 "INSERT INTO t4(a,b,c,d,e,f,g,h,i,j,k) VALUES(1,2,3,4,5,6,7,8,9,10,11)" {
943fac2bd45Sdan    1 2 3 4 5 6 7 8 9 10 11
944fac2bd45Sdan  }
945fac2bd45Sdan}
946fac2bd45Sdan
947fac2bd45Sdan# EVIDENCE-OF: R-12572-62501 If the default value of the column is a
948fac2bd45Sdan# constant NULL, text, blob or signed-number value, then that value is
949fac2bd45Sdan# used directly in the new row.
950fac2bd45Sdan#
951fac2bd45Sdando_execsql_test e_createtable-3.6.1 {
952fac2bd45Sdan  CREATE TABLE t5(
953fac2bd45Sdan    a DEFAULT NULL,
954fac2bd45Sdan    b DEFAULT 'text value',
955fac2bd45Sdan    c DEFAULT X'424C4F42',
956fac2bd45Sdan    d DEFAULT -45678.6,
957fac2bd45Sdan    e DEFAULT 394507
958fac2bd45Sdan  );
959fac2bd45Sdan} {}
960fac2bd45Sdando_execsql_test e_createtable-3.6.2 {
961fac2bd45Sdan  INSERT INTO t5 DEFAULT VALUES;
962fac2bd45Sdan  SELECT quote(a), quote(b), quote(c), quote(d), quote(e) FROM t5;
963fac2bd45Sdan} {NULL {'text value'} X'424C4F42' -45678.6 394507}
964fac2bd45Sdan
965fac2bd45Sdan# EVIDENCE-OF: R-60616-50251 If the default value of a column is an
966fac2bd45Sdan# expression in parentheses, then the expression is evaluated once for
967fac2bd45Sdan# each row inserted and the results used in the new row.
968fac2bd45Sdan#
969fac2bd45Sdan#   Test case 3.6.4 demonstrates that the expression is evaluated
970fac2bd45Sdan#   separately for each row if the INSERT is an "INSERT INTO ... SELECT ..."
971fac2bd45Sdan#   command.
972fac2bd45Sdan#
973fac2bd45Sdanset ::nextint 0
974fac2bd45Sdanproc nextint {} { incr ::nextint }
975fac2bd45Sdandb func nextint nextint
976fac2bd45Sdan
977fac2bd45Sdando_execsql_test e_createtable-3.7.1 {
978fac2bd45Sdan  CREATE TABLE t6(a DEFAULT ( nextint() ), b DEFAULT ( nextint() ));
979fac2bd45Sdan} {}
980fac2bd45Sdando_execsql_test e_createtable-3.7.2 {
981fac2bd45Sdan  INSERT INTO t6 DEFAULT VALUES;
982fac2bd45Sdan  SELECT quote(a), quote(b) FROM t6;
983fac2bd45Sdan} {1 2}
984fac2bd45Sdando_execsql_test e_createtable-3.7.3 {
985fac2bd45Sdan  INSERT INTO t6(a) VALUES('X');
986fac2bd45Sdan  SELECT quote(a), quote(b) FROM t6;
987fac2bd45Sdan} {1 2 'X' 3}
988fac2bd45Sdando_execsql_test e_createtable-3.7.4 {
989fac2bd45Sdan  INSERT INTO t6(a) SELECT a FROM t6;
990fac2bd45Sdan  SELECT quote(a), quote(b) FROM t6;
991fac2bd45Sdan} {1 2 'X' 3 1 4 'X' 5}
992fac2bd45Sdan
993fc083ab9Sdan# EVIDENCE-OF: R-15363-55230 If the default value of a column is
994fc083ab9Sdan# CURRENT_TIME, CURRENT_DATE or CURRENT_TIMESTAMP, then the value used
995fc083ab9Sdan# in the new row is a text representation of the current UTC date and/or
996fac2bd45Sdan# time.
997fac2bd45Sdan#
998fac2bd45Sdan#     This is difficult to test literally without knowing what time the
999fac2bd45Sdan#     user will run the tests. Instead, we test that the three cases
1000fac2bd45Sdan#     above set the value to the current date and/or time according to
1001fac2bd45Sdan#     the xCurrentTime() method of the VFS. Which is usually the same
1002fac2bd45Sdan#     as UTC. In this case, however, we instrument it to always return
1003fac2bd45Sdan#     a time equivalent to "2001-09-09 01:46:40 UTC".
1004fac2bd45Sdan#
1005fac2bd45Sdanset sqlite_current_time 1000000000
1006fac2bd45Sdando_execsql_test e_createtable-3.8.1 {
1007fac2bd45Sdan  CREATE TABLE t7(
1008fac2bd45Sdan    a DEFAULT CURRENT_TIME,
1009fac2bd45Sdan    b DEFAULT CURRENT_DATE,
1010fac2bd45Sdan    c DEFAULT CURRENT_TIMESTAMP
1011fac2bd45Sdan  );
1012fac2bd45Sdan} {}
1013fac2bd45Sdando_execsql_test e_createtable-3.8.2 {
1014fac2bd45Sdan  INSERT INTO t7 DEFAULT VALUES;
1015fac2bd45Sdan  SELECT quote(a), quote(b), quote(c) FROM t7;
1016fac2bd45Sdan} {'01:46:40' '2001-09-09' {'2001-09-09 01:46:40'}}
1017fac2bd45Sdan
1018fac2bd45Sdan
1019fac2bd45Sdan# EVIDENCE-OF: R-62327-53843 For CURRENT_TIME, the format of the value
1020fac2bd45Sdan# is "HH:MM:SS".
1021fac2bd45Sdan#
1022fac2bd45Sdan# EVIDENCE-OF: R-03775-43471 For CURRENT_DATE, "YYYY-MM-DD".
1023fac2bd45Sdan#
1024fac2bd45Sdan# EVIDENCE-OF: R-07677-44926 The format for CURRENT_TIMESTAMP is
1025fac2bd45Sdan# "YYYY-MM-DD HH:MM:SS".
1026fac2bd45Sdan#
1027fac2bd45Sdan#     The three above are demonstrated by tests 1, 2 and 3 below.
1028fac2bd45Sdan#     Respectively.
1029fac2bd45Sdan#
1030fac2bd45Sdando_createtable_tests 3.8.3 -query {
1031fac2bd45Sdan  SELECT a, b, c FROM t7 ORDER BY rowid DESC LIMIT 1;
1032fac2bd45Sdan} {
1033fac2bd45Sdan  1 "INSERT INTO t7(b, c) VALUES('x', 'y')" {01:46:40 x y}
1034fac2bd45Sdan  2 "INSERT INTO t7(c, a) VALUES('x', 'y')" {y 2001-09-09 x}
1035fac2bd45Sdan  3 "INSERT INTO t7(a, b) VALUES('x', 'y')" {x y {2001-09-09 01:46:40}}
1036fac2bd45Sdan}
1037fac2bd45Sdan
1038fac2bd45Sdan# EVIDENCE-OF: R-55061-47754 The COLLATE clause specifies the name of a
1039fac2bd45Sdan# collating sequence to use as the default collation sequence for the
1040fac2bd45Sdan# column.
1041fac2bd45Sdan#
1042fac2bd45Sdan# EVIDENCE-OF: R-40275-54363 If no COLLATE clause is specified, the
1043fac2bd45Sdan# default collation sequence is BINARY.
1044fac2bd45Sdan#
1045fac2bd45Sdando_execsql_test e_createtable-3-9.1 {
1046fac2bd45Sdan  CREATE TABLE t8(a COLLATE nocase, b COLLATE rtrim, c COLLATE binary, d);
1047fac2bd45Sdan  INSERT INTO t8 VALUES('abc',   'abc',   'abc',   'abc');
1048fac2bd45Sdan  INSERT INTO t8 VALUES('abc  ', 'abc  ', 'abc  ', 'abc  ');
1049fac2bd45Sdan  INSERT INTO t8 VALUES('ABC  ', 'ABC  ', 'ABC  ', 'ABC  ');
1050fac2bd45Sdan  INSERT INTO t8 VALUES('ABC',   'ABC',   'ABC',   'ABC');
1051fac2bd45Sdan} {}
1052fac2bd45Sdando_createtable_tests 3.9 {
1053fac2bd45Sdan  2    "SELECT a FROM t8 ORDER BY a, rowid"    {abc ABC {abc  } {ABC  }}
1054fac2bd45Sdan  3    "SELECT b FROM t8 ORDER BY b, rowid"    {{ABC  } ABC abc {abc  }}
1055fac2bd45Sdan  4    "SELECT c FROM t8 ORDER BY c, rowid"    {ABC {ABC  } abc {abc  }}
1056fac2bd45Sdan  5    "SELECT d FROM t8 ORDER BY d, rowid"    {ABC {ABC  } abc {abc  }}
1057fac2bd45Sdan}
1058fac2bd45Sdan
1059a3f5108cSdan# EVIDENCE-OF: R-25473-20557 The number of columns in a table is limited
1060a3f5108cSdan# by the SQLITE_MAX_COLUMN compile-time parameter.
1061a3f5108cSdan#
1062a3f5108cSdanproc columns {n} {
1063a3f5108cSdan  set res [list]
1064a3f5108cSdan  for {set i 0} {$i < $n} {incr i} { lappend res "c$i" }
1065a3f5108cSdan  join $res ", "
1066a3f5108cSdan}
1067a3f5108cSdando_execsql_test e_createtable-3.10.1 [subst {
1068a3f5108cSdan  CREATE TABLE t9([columns $::SQLITE_MAX_COLUMN]);
1069a3f5108cSdan}] {}
1070a3f5108cSdando_catchsql_test e_createtable-3.10.2 [subst {
1071a3f5108cSdan  CREATE TABLE t10([columns [expr $::SQLITE_MAX_COLUMN+1]]);
1072a3f5108cSdan}] {1 {too many columns on t10}}
1073a3f5108cSdan
1074a3f5108cSdan# EVIDENCE-OF: R-27775-64721 Both of these limits can be lowered at
1075a3f5108cSdan# runtime using the sqlite3_limit() C/C++ interface.
1076a3f5108cSdan#
1077a3f5108cSdan#   A 30,000 byte blob consumes 30,003 bytes of record space. A record
1078a3f5108cSdan#   that contains 3 such blobs consumes (30,000*3)+1 bytes of space. Tests
1079a3f5108cSdan#   3.11.4 and 3.11.5, which verify that SQLITE_MAX_LENGTH may be lowered
1080a3f5108cSdan#   at runtime, are based on this calculation.
1081a3f5108cSdan#
1082a3f5108cSdansqlite3_limit db SQLITE_LIMIT_COLUMN 500
1083a3f5108cSdando_execsql_test e_createtable-3.11.1 [subst {
1084a3f5108cSdan  CREATE TABLE t10([columns 500]);
1085a3f5108cSdan}] {}
1086a3f5108cSdando_catchsql_test e_createtable-3.11.2 [subst {
1087a3f5108cSdan  CREATE TABLE t11([columns 501]);
1088a3f5108cSdan}] {1 {too many columns on t11}}
1089a3f5108cSdan
1090a3f5108cSdan# Check that it is not possible to raise the column limit above its
1091a3f5108cSdan# default compile time value.
1092a3f5108cSdan#
1093a3f5108cSdansqlite3_limit db SQLITE_LIMIT_COLUMN [expr $::SQLITE_MAX_COLUMN+2]
1094a3f5108cSdando_catchsql_test e_createtable-3.11.3 [subst {
1095a3f5108cSdan  CREATE TABLE t11([columns [expr $::SQLITE_MAX_COLUMN+1]]);
1096a3f5108cSdan}] {1 {too many columns on t11}}
1097a3f5108cSdan
1098a3f5108cSdansqlite3_limit db SQLITE_LIMIT_LENGTH 90010
1099a3f5108cSdando_execsql_test e_createtable-3.11.4 {
1100a3f5108cSdan  CREATE TABLE t12(a, b, c);
1101a3f5108cSdan  INSERT INTO t12 VALUES(randomblob(30000),randomblob(30000),randomblob(30000));
1102a3f5108cSdan} {}
1103a3f5108cSdando_catchsql_test e_createtable-3.11.5 {
1104a3f5108cSdan  INSERT INTO t12 VALUES(randomblob(30001),randomblob(30000),randomblob(30000));
1105a3f5108cSdan} {1 {string or blob too big}}
1106a3f5108cSdan
1107a3f5108cSdan#-------------------------------------------------------------------------
1108a3f5108cSdan# Tests for statements regarding constraints (PRIMARY KEY, UNIQUE, NOT
1109a3f5108cSdan# NULL and CHECK constraints).
1110a3f5108cSdan#
1111a3f5108cSdan
1112a3f5108cSdan# EVIDENCE-OF: R-52382-54248 Each table in SQLite may have at most one
1113a3f5108cSdan# PRIMARY KEY.
1114a3f5108cSdan#
11159338642cSdrh# EVIDENCE-OF: R-31826-01813 An error is raised if more than one PRIMARY
1116eb091cdfSdrh# KEY clause appears in a CREATE TABLE statement.
1117a3f5108cSdan#
1118a3f5108cSdan#     To test the two above, show that zero primary keys is Ok, one primary
1119a3f5108cSdan#     key is Ok, and two or more primary keys is an error.
1120a3f5108cSdan#
1121a3f5108cSdandrop_all_tables
1122a3f5108cSdando_createtable_tests 4.1.1 {
1123a3f5108cSdan  1    "CREATE TABLE t1(a, b, c)"                                        {}
1124a3f5108cSdan  2    "CREATE TABLE t2(a PRIMARY KEY, b, c)"                            {}
1125a3f5108cSdan  3    "CREATE TABLE t3(a, b, c, PRIMARY KEY(a))"                        {}
1126a3f5108cSdan  4    "CREATE TABLE t4(a, b, c, PRIMARY KEY(c,b,a))"                    {}
1127a3f5108cSdan}
1128a3f5108cSdando_createtable_tests 4.1.2 -error {
1129a3f5108cSdan  table "t5" has more than one primary key
1130a3f5108cSdan} {
1131a3f5108cSdan  1    "CREATE TABLE t5(a PRIMARY KEY, b PRIMARY KEY, c)"                {}
1132a3f5108cSdan  2    "CREATE TABLE t5(a, b PRIMARY KEY, c, PRIMARY KEY(a))"            {}
1133a3f5108cSdan  3    "CREATE TABLE t5(a INTEGER PRIMARY KEY, b PRIMARY KEY, c)"        {}
1134a3f5108cSdan  4    "CREATE TABLE t5(a INTEGER PRIMARY KEY, b, c, PRIMARY KEY(b, c))" {}
1135a3f5108cSdan  5    "CREATE TABLE t5(a PRIMARY KEY, b, c, PRIMARY KEY(a))"            {}
1136a3f5108cSdan  6    "CREATE TABLE t5(a INTEGER PRIMARY KEY, b, c, PRIMARY KEY(a))"    {}
1137a3f5108cSdan}
1138a3f5108cSdan
1139eb091cdfSdrh# EVIDENCE-OF: R-54755-39291 The PRIMARY KEY is optional for ordinary
1140eb091cdfSdrh# tables but is required for WITHOUT ROWID tables.
1141eb091cdfSdrh#
1142eb091cdfSdrhdo_catchsql_test 4.1.3 {
1143eb091cdfSdrh  CREATE TABLE t6(a, b); --ok
1144eb091cdfSdrh} {0 {}}
1145eb091cdfSdrhdo_catchsql_test 4.1.4 {
1146eb091cdfSdrh  CREATE TABLE t7(a, b) WITHOUT ROWID; --Error, no PRIMARY KEY
1147eb091cdfSdrh} {1 {PRIMARY KEY missing on table t7}}
1148eb091cdfSdrh
1149eb091cdfSdrh
1150a3f5108cSdanproc table_pk {tbl} {
1151a3f5108cSdan  set pk [list]
1152a3f5108cSdan  db eval "pragma table_info($tbl)" a {
1153a3f5108cSdan    if {$a(pk)} { lappend pk $a(name) }
1154a3f5108cSdan  }
1155a3f5108cSdan  set pk
1156a3f5108cSdan}
1157a3f5108cSdan
1158a3f5108cSdan# EVIDENCE-OF: R-41411-18837 If the keywords PRIMARY KEY are added to a
1159a3f5108cSdan# column definition, then the primary key for the table consists of that
1160a3f5108cSdan# single column.
1161a3f5108cSdan#
1162a3f5108cSdan#     The above is tested by 4.2.1.*
1163a3f5108cSdan#
1164a3f5108cSdan# EVIDENCE-OF: R-31775-48204 Or, if a PRIMARY KEY clause is specified as
1165a3f5108cSdan# a table-constraint, then the primary key of the table consists of the
1166a3f5108cSdan# list of columns specified as part of the PRIMARY KEY clause.
1167a3f5108cSdan#
1168a3f5108cSdan#     The above is tested by 4.2.2.*
1169a3f5108cSdan#
1170a3f5108cSdando_createtable_tests 4.2 -repair {
1171a3f5108cSdan  catchsql { DROP TABLE t5 }
1172a3f5108cSdan} -tclquery {
1173a3f5108cSdan  table_pk t5
1174a3f5108cSdan} {
1175a3f5108cSdan  1.1    "CREATE TABLE t5(a, b INTEGER PRIMARY KEY, c)"       {b}
1176a3f5108cSdan  1.2    "CREATE TABLE t5(a PRIMARY KEY, b, c)"               {a}
1177a3f5108cSdan
1178a3f5108cSdan  2.1    "CREATE TABLE t5(a, b, c, PRIMARY KEY(a))"           {a}
1179a3f5108cSdan  2.2    "CREATE TABLE t5(a, b, c, PRIMARY KEY(c,b,a))"       {a b c}
1180a3f5108cSdan  2.3    "CREATE TABLE t5(a, b INTEGER PRIMARY KEY, c)"       {b}
1181a3f5108cSdan}
1182a3f5108cSdan
1183eb091cdfSdrh# EVIDENCE-OF: R-59124-61339 Each row in a table with a primary key must
1184eb091cdfSdrh# have a unique combination of values in its primary key columns.
1185a3f5108cSdan#
1186e8a537eeSdrh# EVIDENCE-OF: R-06471-16287 If an INSERT or UPDATE statement attempts
1187e8a537eeSdrh# to modify the table content so that two or more rows have identical
1188e8a537eeSdrh# primary key values, that is a constraint violation.
1189a3f5108cSdan#
1190a3f5108cSdandrop_all_tables
1191a3f5108cSdando_execsql_test 4.3.0 {
1192a3f5108cSdan  CREATE TABLE t1(x PRIMARY KEY, y);
1193a3f5108cSdan  INSERT INTO t1 VALUES(0,          'zero');
1194a3f5108cSdan  INSERT INTO t1 VALUES(45.5,       'one');
1195a3f5108cSdan  INSERT INTO t1 VALUES('brambles', 'two');
1196a3f5108cSdan  INSERT INTO t1 VALUES(X'ABCDEF',  'three');
1197a3f5108cSdan
1198a3f5108cSdan  CREATE TABLE t2(x, y, PRIMARY KEY(x, y));
1199a3f5108cSdan  INSERT INTO t2 VALUES(0,          'zero');
1200a3f5108cSdan  INSERT INTO t2 VALUES(45.5,       'one');
1201a3f5108cSdan  INSERT INTO t2 VALUES('brambles', 'two');
1202a3f5108cSdan  INSERT INTO t2 VALUES(X'ABCDEF',  'three');
1203a3f5108cSdan} {}
1204a3f5108cSdan
1205f9c8ce3cSdrhdo_createtable_tests 4.3.1 -error {UNIQUE constraint failed: t1.x} {
1206a3f5108cSdan  1    "INSERT INTO t1 VALUES(0, 0)"                 {"column x is"}
1207a3f5108cSdan  2    "INSERT INTO t1 VALUES(45.5, 'abc')"          {"column x is"}
1208a3f5108cSdan  3    "INSERT INTO t1 VALUES(0.0, 'abc')"           {"column x is"}
1209a3f5108cSdan  4    "INSERT INTO t1 VALUES('brambles', 'abc')"    {"column x is"}
1210a3f5108cSdan  5    "INSERT INTO t1 VALUES(X'ABCDEF', 'abc')"     {"column x is"}
1211f9c8ce3cSdrh}
1212f9c8ce3cSdrhdo_createtable_tests 4.3.1 -error {UNIQUE constraint failed: t2.x, t2.y} {
1213a3f5108cSdan  6    "INSERT INTO t2 VALUES(0, 'zero')"            {"columns x, y are"}
1214a3f5108cSdan  7    "INSERT INTO t2 VALUES(45.5, 'one')"          {"columns x, y are"}
1215a3f5108cSdan  8    "INSERT INTO t2 VALUES(0.0, 'zero')"          {"columns x, y are"}
1216a3f5108cSdan  9    "INSERT INTO t2 VALUES('brambles', 'two')"    {"columns x, y are"}
1217a3f5108cSdan  10   "INSERT INTO t2 VALUES(X'ABCDEF', 'three')"   {"columns x, y are"}
1218a3f5108cSdan}
1219a3f5108cSdando_createtable_tests 4.3.2 {
1220a3f5108cSdan  1    "INSERT INTO t1 VALUES(-1, 0)"                {}
1221a3f5108cSdan  2    "INSERT INTO t1 VALUES(45.2, 'abc')"          {}
1222a3f5108cSdan  3    "INSERT INTO t1 VALUES(0.01, 'abc')"          {}
1223a3f5108cSdan  4    "INSERT INTO t1 VALUES('bramble', 'abc')"     {}
1224a3f5108cSdan  5    "INSERT INTO t1 VALUES(X'ABCDEE', 'abc')"     {}
1225a3f5108cSdan
1226a3f5108cSdan  6    "INSERT INTO t2 VALUES(0, 0)"                 {}
1227a3f5108cSdan  7    "INSERT INTO t2 VALUES(45.5, 'abc')"          {}
1228a3f5108cSdan  8    "INSERT INTO t2 VALUES(0.0, 'abc')"           {}
1229a3f5108cSdan  9    "INSERT INTO t2 VALUES('brambles', 'abc')"    {}
1230a3f5108cSdan  10   "INSERT INTO t2 VALUES(X'ABCDEF', 'abc')"     {}
1231a3f5108cSdan}
1232f9c8ce3cSdrhdo_createtable_tests 4.3.3 -error {UNIQUE constraint failed: t1.x} {
1233a3f5108cSdan  1    "UPDATE t1 SET x=0           WHERE y='two'"    {"column x is"}
1234a3f5108cSdan  2    "UPDATE t1 SET x='brambles'  WHERE y='three'"  {"column x is"}
1235a3f5108cSdan  3    "UPDATE t1 SET x=45.5        WHERE y='zero'"   {"column x is"}
1236a3f5108cSdan  4    "UPDATE t1 SET x=X'ABCDEF'   WHERE y='one'"    {"column x is"}
1237a3f5108cSdan  5    "UPDATE t1 SET x=0.0         WHERE y='three'"  {"column x is"}
1238f9c8ce3cSdrh}
1239f9c8ce3cSdrhdo_createtable_tests 4.3.3 -error {UNIQUE constraint failed: t2.x, t2.y} {
1240a3f5108cSdan  6    "UPDATE t2 SET x=0, y='zero' WHERE y='two'"    {"columns x, y are"}
1241a3f5108cSdan  7    "UPDATE t2 SET x='brambles', y='two' WHERE y='three'"
1242a3f5108cSdan       {"columns x, y are"}
1243a3f5108cSdan  8    "UPDATE t2 SET x=45.5, y='one' WHERE y='zero'" {"columns x, y are"}
1244a3f5108cSdan  9    "UPDATE t2 SET x=X'ABCDEF', y='three' WHERE y='one'"
1245a3f5108cSdan       {"columns x, y are"}
1246a3f5108cSdan  10   "UPDATE t2 SET x=0.0, y='zero'        WHERE y='three'"
1247a3f5108cSdan       {"columns x, y are"}
1248a3f5108cSdan}
1249a3f5108cSdan
1250a3f5108cSdan
1251a3f5108cSdan# EVIDENCE-OF: R-52572-02078 For the purposes of determining the
1252a3f5108cSdan# uniqueness of primary key values, NULL values are considered distinct
1253a3f5108cSdan# from all other values, including other NULLs.
1254a3f5108cSdan#
1255a3f5108cSdando_createtable_tests 4.4 {
1256a3f5108cSdan  1    "INSERT INTO t1 VALUES(NULL, 0)"              {}
1257a3f5108cSdan  2    "INSERT INTO t1 VALUES(NULL, 0)"              {}
1258a3f5108cSdan  3    "INSERT INTO t1 VALUES(NULL, 0)"              {}
1259a3f5108cSdan
1260a3f5108cSdan  4    "INSERT INTO t2 VALUES(NULL, 'zero')"         {}
1261a3f5108cSdan  5    "INSERT INTO t2 VALUES(NULL, 'one')"          {}
1262a3f5108cSdan  6    "INSERT INTO t2 VALUES(NULL, 'two')"          {}
1263a3f5108cSdan  7    "INSERT INTO t2 VALUES(NULL, 'three')"        {}
1264a3f5108cSdan
1265a3f5108cSdan  8    "INSERT INTO t2 VALUES(0, NULL)"              {}
1266a3f5108cSdan  9    "INSERT INTO t2 VALUES(45.5, NULL)"           {}
1267a3f5108cSdan  10   "INSERT INTO t2 VALUES(0.0, NULL)"            {}
1268a3f5108cSdan  11   "INSERT INTO t2 VALUES('brambles', NULL)"     {}
1269a3f5108cSdan  12   "INSERT INTO t2 VALUES(X'ABCDEF', NULL)"      {}
1270a3f5108cSdan
1271a3f5108cSdan  13   "INSERT INTO t2 VALUES(NULL, NULL)"           {}
1272a3f5108cSdan  14   "INSERT INTO t2 VALUES(NULL, NULL)"           {}
1273a3f5108cSdan}
1274a3f5108cSdan
12756f991147Sdrh# EVIDENCE-OF: R-40010-16873 Unless the column is an INTEGER PRIMARY KEY
12766f991147Sdrh# or the table is a WITHOUT ROWID table or a STRICT table or the column
12776f991147Sdrh# is declared NOT NULL, SQLite allows NULL values in a PRIMARY KEY
12786f991147Sdrh# column.
1279a3f5108cSdan#
1280a3f5108cSdan#     If the column is an integer primary key, attempting to insert a NULL
128148864df9Smistachkin#     into the column triggers the auto-increment behavior. Attempting
1282a3f5108cSdan#     to use UPDATE to set an ipk column to a NULL value is an error.
1283a3f5108cSdan#
1284a3f5108cSdando_createtable_tests 4.5.1 {
1285a3f5108cSdan  1    "SELECT count(*) FROM t1 WHERE x IS NULL"                   3
1286a3f5108cSdan  2    "SELECT count(*) FROM t2 WHERE x IS NULL"                   6
1287a3f5108cSdan  3    "SELECT count(*) FROM t2 WHERE y IS NULL"                   7
1288a3f5108cSdan  4    "SELECT count(*) FROM t2 WHERE x IS NULL AND y IS NULL"     2
1289a3f5108cSdan}
1290a3f5108cSdando_execsql_test 4.5.2 {
1291a3f5108cSdan  CREATE TABLE t3(s, u INTEGER PRIMARY KEY, v);
1292a3f5108cSdan  INSERT INTO t3 VALUES(1, NULL, 2);
1293a3f5108cSdan  INSERT INTO t3 VALUES('x', NULL, 'y');
1294a3f5108cSdan  SELECT u FROM t3;
1295a3f5108cSdan} {1 2}
1296a3f5108cSdando_catchsql_test 4.5.3 {
1297a3f5108cSdan  INSERT INTO t3 VALUES(2, 5, 3);
1298a3f5108cSdan  UPDATE t3 SET u = NULL WHERE s = 2;
1299a3f5108cSdan} {1 {datatype mismatch}}
1300eb091cdfSdrhdo_catchsql_test 4.5.4 {
1301eb091cdfSdrh  CREATE TABLE t4(s, u INT PRIMARY KEY, v) WITHOUT ROWID;
1302eb091cdfSdrh  INSERT INTO t4 VALUES(1, NULL, 2);
1303eb091cdfSdrh} {1 {NOT NULL constraint failed: t4.u}}
1304eb091cdfSdrhdo_catchsql_test 4.5.5 {
1305eb091cdfSdrh  CREATE TABLE t5(s, u INT PRIMARY KEY NOT NULL, v);
1306eb091cdfSdrh  INSERT INTO t5 VALUES(1, NULL, 2);
1307eb091cdfSdrh} {1 {NOT NULL constraint failed: t5.u}}
13086f991147Sdrhdo_catchsql_test 4.5.6 {
13096f991147Sdrh  CREATE TABLE t6(s INT, u INT PRIMARY KEY, v INT) STRICT;
13106f991147Sdrh  INSERT INTO t6 VALUES(1, NULL, 2);
13116f991147Sdrh} {1 {NOT NULL constraint failed: t6.u}}
13126f991147Sdrhdo_catchsql_test 4.5.7 {
13136f991147Sdrh  CREATE TABLE t7(s INT, u INT PRIMARY KEY NOT NULL, v INT) STRICT;
13146f991147Sdrh  INSERT INTO t7 VALUES(1, NULL, 2);
13156f991147Sdrh} {1 {NOT NULL constraint failed: t7.u}}
1316a3f5108cSdan
131757f7f4b8Sdan# EVIDENCE-OF: R-00227-21080 A UNIQUE constraint is similar to a PRIMARY
131857f7f4b8Sdan# KEY constraint, except that a single table may have any number of
131957f7f4b8Sdan# UNIQUE constraints.
132057f7f4b8Sdan#
132157f7f4b8Sdandrop_all_tables
132257f7f4b8Sdando_createtable_tests 4.6 {
132357f7f4b8Sdan  1    "CREATE TABLE t1(a UNIQUE, b UNIQUE)"                       {}
132457f7f4b8Sdan  2    "CREATE TABLE t2(a UNIQUE, b, c, UNIQUE(c, b))"             {}
132557f7f4b8Sdan  3    "CREATE TABLE t3(a, b, c, UNIQUE(a), UNIQUE(b), UNIQUE(c))" {}
132657f7f4b8Sdan  4    "CREATE TABLE t4(a, b, c, UNIQUE(a, b, c))"                 {}
132757f7f4b8Sdan}
1328a3f5108cSdan
1329eb091cdfSdrh# EVIDENCE-OF: R-30981-64168 For each UNIQUE constraint on the table,
1330eb091cdfSdrh# each row must contain a unique combination of values in the columns
133157f7f4b8Sdan# identified by the UNIQUE constraint.
133257f7f4b8Sdan#
1333eb091cdfSdrh# EVIDENCE-OF: R-59124-61339 Each row in a table with a primary key must
1334eb091cdfSdrh# have a unique combination of values in its primary key columns.
133557f7f4b8Sdan#
133657f7f4b8Sdando_execsql_test 4.7.0 {
133757f7f4b8Sdan  INSERT INTO t1 VALUES(1, 2);
133857f7f4b8Sdan  INSERT INTO t1 VALUES(4.3, 5.5);
133957f7f4b8Sdan  INSERT INTO t1 VALUES('reveal', 'variableness');
134057f7f4b8Sdan  INSERT INTO t1 VALUES(X'123456', X'654321');
134157f7f4b8Sdan
134257f7f4b8Sdan  INSERT INTO t4 VALUES('xyx', 1, 1);
134357f7f4b8Sdan  INSERT INTO t4 VALUES('xyx', 2, 1);
134457f7f4b8Sdan  INSERT INTO t4 VALUES('uvw', 1, 1);
134557f7f4b8Sdan}
1346f9c8ce3cSdrhdo_createtable_tests 4.7.1 -error {UNIQUE constraint failed: %s} {
1347f9c8ce3cSdrh  1    "INSERT INTO t1 VALUES(1, 'one')"             {{t1.a}}
1348f9c8ce3cSdrh  2    "INSERT INTO t1 VALUES(4.3, 'two')"           {{t1.a}}
1349f9c8ce3cSdrh  3    "INSERT INTO t1 VALUES('reveal', 'three')"    {{t1.a}}
1350f9c8ce3cSdrh  4    "INSERT INTO t1 VALUES(X'123456', 'four')"    {{t1.a}}
135157f7f4b8Sdan
1352f9c8ce3cSdrh  5    "UPDATE t1 SET a = 1 WHERE rowid=2"           {{t1.a}}
1353f9c8ce3cSdrh  6    "UPDATE t1 SET a = 4.3 WHERE rowid=3"         {{t1.a}}
1354f9c8ce3cSdrh  7    "UPDATE t1 SET a = 'reveal' WHERE rowid=4"    {{t1.a}}
1355f9c8ce3cSdrh  8    "UPDATE t1 SET a = X'123456' WHERE rowid=1"   {{t1.a}}
135657f7f4b8Sdan
1357f9c8ce3cSdrh  9    "INSERT INTO t4 VALUES('xyx', 1, 1)"          {{t4.a, t4.b, t4.c}}
1358f9c8ce3cSdrh  10   "INSERT INTO t4 VALUES('xyx', 2, 1)"          {{t4.a, t4.b, t4.c}}
1359f9c8ce3cSdrh  11   "INSERT INTO t4 VALUES('uvw', 1, 1)"          {{t4.a, t4.b, t4.c}}
136057f7f4b8Sdan
1361f9c8ce3cSdrh  12   "UPDATE t4 SET a='xyx' WHERE rowid=3"         {{t4.a, t4.b, t4.c}}
1362f9c8ce3cSdrh  13   "UPDATE t4 SET b=1 WHERE rowid=2"             {{t4.a, t4.b, t4.c}}
1363f9c8ce3cSdrh  14   "UPDATE t4 SET a=0, b=0, c=0"                 {{t4.a, t4.b, t4.c}}
136457f7f4b8Sdan}
136557f7f4b8Sdan
1366eb091cdfSdrh# EVIDENCE-OF: R-00404-17670 For the purposes of UNIQUE constraints,
1367eb091cdfSdrh# NULL values are considered distinct from all other values, including
1368eb091cdfSdrh# other NULLs.
136957f7f4b8Sdan#
137057f7f4b8Sdando_createtable_tests 4.8 {
137157f7f4b8Sdan  1    "INSERT INTO t1 VALUES(NULL, NULL)"           {}
137257f7f4b8Sdan  2    "INSERT INTO t1 VALUES(NULL, NULL)"           {}
137357f7f4b8Sdan  3    "UPDATE t1 SET a = NULL"                      {}
137457f7f4b8Sdan  4    "UPDATE t1 SET b = NULL"                      {}
137557f7f4b8Sdan
137657f7f4b8Sdan  5    "INSERT INTO t4 VALUES(NULL, NULL, NULL)"     {}
137757f7f4b8Sdan  6    "INSERT INTO t4 VALUES(NULL, NULL, NULL)"     {}
137857f7f4b8Sdan  7    "UPDATE t4 SET a = NULL"                      {}
137957f7f4b8Sdan  8    "UPDATE t4 SET b = NULL"                      {}
138057f7f4b8Sdan  9    "UPDATE t4 SET c = NULL"                      {}
138157f7f4b8Sdan}
138257f7f4b8Sdan
1383eb091cdfSdrh# EVIDENCE-OF: R-55820-29984 In most cases, UNIQUE and PRIMARY KEY
1384eb091cdfSdrh# constraints are implemented by creating a unique index in the
1385eb091cdfSdrh# database.
138657f7f4b8Sdando_createtable_tests 4.9 -repair drop_all_tables -query {
138757f7f4b8Sdan  SELECT count(*) FROM sqlite_master WHERE type='index'
138857f7f4b8Sdan} {
138957f7f4b8Sdan  1    "CREATE TABLE t1(a TEXT PRIMARY KEY, b)"              1
139057f7f4b8Sdan  2    "CREATE TABLE t1(a INTEGER PRIMARY KEY, b)"           0
139157f7f4b8Sdan  3    "CREATE TABLE t1(a TEXT UNIQUE, b)"                   1
139257f7f4b8Sdan  4    "CREATE TABLE t1(a PRIMARY KEY, b TEXT UNIQUE)"       2
139357f7f4b8Sdan  5    "CREATE TABLE t1(a PRIMARY KEY, b, c, UNIQUE(c, b))"  2
139457f7f4b8Sdan}
139557f7f4b8Sdan
1396eb091cdfSdrh# Obsolete: R-02252-33116 Such an index is used like any other index
139757f7f4b8Sdan# in the database to optimize queries.
139857f7f4b8Sdan#
139957f7f4b8Sdando_execsql_test 4.10.0 {
140057f7f4b8Sdan  CREATE TABLE t1(a, b PRIMARY KEY);
140157f7f4b8Sdan  CREATE TABLE t2(a, b, c, UNIQUE(b, c));
140257f7f4b8Sdan}
140357f7f4b8Sdando_createtable_tests 4.10 {
140457f7f4b8Sdan  1    "EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 5"
14058210233cSdrh       {/*SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (b=?)*/}
140657f7f4b8Sdan
140757f7f4b8Sdan  2    "EXPLAIN QUERY PLAN SELECT * FROM t2 ORDER BY b, c"
14088210233cSdrh       {/*SCAN t2 USING INDEX sqlite_autoindex_t2_1*/}
140957f7f4b8Sdan
141057f7f4b8Sdan  3    "EXPLAIN QUERY PLAN SELECT * FROM t2 WHERE b=10 AND c>10"
14118210233cSdrh       {/*SEARCH t2 USING INDEX sqlite_autoindex_t2_1 (b=? AND c>?)*/}
141257f7f4b8Sdan}
141357f7f4b8Sdan
141457f7f4b8Sdan# EVIDENCE-OF: R-45493-35653 A CHECK constraint may be attached to a
141557f7f4b8Sdan# column definition or specified as a table constraint. In practice it
141657f7f4b8Sdan# makes no difference.
141757f7f4b8Sdan#
141857f7f4b8Sdan#   All the tests that deal with CHECK constraints below (4.11.* and
141957f7f4b8Sdan#   4.12.*) are run once for a table with the check constraint attached
142057f7f4b8Sdan#   to a column definition, and once with a table where the check
142157f7f4b8Sdan#   condition is specified as a table constraint.
142257f7f4b8Sdan#
142357f7f4b8Sdan# EVIDENCE-OF: R-55435-14303 Each time a new row is inserted into the
142457f7f4b8Sdan# table or an existing row is updated, the expression associated with
142557f7f4b8Sdan# each CHECK constraint is evaluated and cast to a NUMERIC value in the
142657f7f4b8Sdan# same way as a CAST expression. If the result is zero (integer value 0
142757f7f4b8Sdan# or real value 0.0), then a constraint violation has occurred.
142857f7f4b8Sdan#
142957f7f4b8Sdandrop_all_tables
143057f7f4b8Sdando_execsql_test 4.11 {
143157f7f4b8Sdan  CREATE TABLE x1(a TEXT, b INTEGER CHECK( b>0 ));
143257f7f4b8Sdan  CREATE TABLE t1(a TEXT, b INTEGER, CHECK( b>0 ));
143357f7f4b8Sdan  INSERT INTO x1 VALUES('x', 'xx');
143457f7f4b8Sdan  INSERT INTO x1 VALUES('y', 'yy');
143557f7f4b8Sdan  INSERT INTO t1 SELECT * FROM x1;
143657f7f4b8Sdan
143757f7f4b8Sdan  CREATE TABLE x2(a CHECK( a||b ), b);
143857f7f4b8Sdan  CREATE TABLE t2(a, b, CHECK( a||b ));
143957f7f4b8Sdan  INSERT INTO x2 VALUES(1, 'xx');
144057f7f4b8Sdan  INSERT INTO x2 VALUES(1, 'yy');
144157f7f4b8Sdan  INSERT INTO t2 SELECT * FROM x2;
144257f7f4b8Sdan}
144357f7f4b8Sdan
1444f9c8ce3cSdrhdo_createtable_tests 4.11 -error {CHECK constraint failed: %s} {
144592e21ef0Sdrh  1a    "INSERT INTO x1 VALUES('one', 0)"       {b>0}
144692e21ef0Sdrh  1b    "INSERT INTO t1 VALUES('one', -4.0)"    {b>0}
144757f7f4b8Sdan
144892e21ef0Sdrh  2a    "INSERT INTO x2 VALUES('abc', 1)"       {a||b}
144992e21ef0Sdrh  2b    "INSERT INTO t2 VALUES('abc', 1)"       {a||b}
145057f7f4b8Sdan
145192e21ef0Sdrh  3a    "INSERT INTO x2 VALUES(0, 'abc')"       {a||b}
145292e21ef0Sdrh  3b    "INSERT INTO t2 VALUES(0, 'abc')"       {a||b}
145357f7f4b8Sdan
145492e21ef0Sdrh  4a    "UPDATE t1 SET b=-1 WHERE rowid=1"      {b>0}
145592e21ef0Sdrh  4b    "UPDATE x1 SET b=-1 WHERE rowid=1"      {b>0}
145657f7f4b8Sdan
145792e21ef0Sdrh  4a    "UPDATE x2 SET a='' WHERE rowid=1"      {a||b}
145892e21ef0Sdrh  4b    "UPDATE t2 SET a='' WHERE rowid=1"      {a||b}
145957f7f4b8Sdan}
146057f7f4b8Sdan
146157f7f4b8Sdan# EVIDENCE-OF: R-34109-39108 If the CHECK expression evaluates to NULL,
146257f7f4b8Sdan# or any other non-zero value, it is not a constraint violation.
146357f7f4b8Sdan#
146457f7f4b8Sdando_createtable_tests 4.12 {
146557f7f4b8Sdan  1a    "INSERT INTO x1 VALUES('one', NULL)"    {}
146657f7f4b8Sdan  1b    "INSERT INTO t1 VALUES('one', NULL)"    {}
146757f7f4b8Sdan
146857f7f4b8Sdan  2a    "INSERT INTO x1 VALUES('one', 2)"    {}
146957f7f4b8Sdan  2b    "INSERT INTO t1 VALUES('one', 2)"    {}
147057f7f4b8Sdan
147157f7f4b8Sdan  3a    "INSERT INTO x2 VALUES(1, 'abc')"       {}
147257f7f4b8Sdan  3b    "INSERT INTO t2 VALUES(1, 'abc')"       {}
147357f7f4b8Sdan}
147457f7f4b8Sdan
14757b755196Sdan# EVIDENCE-OF: R-02060-64547 A NOT NULL constraint may only be attached
14767b755196Sdan# to a column definition, not specified as a table constraint.
14777b755196Sdan#
14787b755196Sdandrop_all_tables
14797b755196Sdando_createtable_tests 4.13.1 {
14807b755196Sdan  1     "CREATE TABLE t1(a NOT NULL, b)"                               {}
14817b755196Sdan  2     "CREATE TABLE t2(a PRIMARY KEY NOT NULL, b)"                   {}
14827b755196Sdan  3     "CREATE TABLE t3(a NOT NULL, b NOT NULL, c NOT NULL UNIQUE)"   {}
14837b755196Sdan}
14847b755196Sdando_createtable_tests 4.13.2 -error {
14857b755196Sdan  near "NOT": syntax error
14867b755196Sdan} {
14877b755196Sdan  1     "CREATE TABLE t4(a, b, NOT NULL(a))"                   {}
14887b755196Sdan  2     "CREATE TABLE t4(a PRIMARY KEY, b, NOT NULL(a))"       {}
14897b755196Sdan  3     "CREATE TABLE t4(a, b, c UNIQUE, NOT NULL(a, b, c))"   {}
14907b755196Sdan}
14917b755196Sdan
14927b755196Sdan# EVIDENCE-OF: R-31795-57643 a NOT NULL constraint dictates that the
14937b755196Sdan# associated column may not contain a NULL value. Attempting to set the
14947b755196Sdan# column value to NULL when inserting a new row or updating an existing
14957b755196Sdan# one causes a constraint violation.
14967b755196Sdan#
14977b755196Sdan#     These tests use the tables created by 4.13.
14987b755196Sdan#
14997b755196Sdando_execsql_test 4.14.0 {
15007b755196Sdan  INSERT INTO t1 VALUES('x', 'y');
15017b755196Sdan  INSERT INTO t1 VALUES('z', NULL);
15027b755196Sdan
15037b755196Sdan  INSERT INTO t2 VALUES('x', 'y');
15047b755196Sdan  INSERT INTO t2 VALUES('z', NULL);
15057b755196Sdan
15067b755196Sdan  INSERT INTO t3 VALUES('x', 'y', 'z');
15077b755196Sdan  INSERT INTO t3 VALUES(1, 2, 3);
15087b755196Sdan}
1509f9c8ce3cSdrhdo_createtable_tests 4.14 -error {NOT NULL constraint failed: %s} {
15107b755196Sdan  1    "INSERT INTO t1 VALUES(NULL, 'a')"         {t1.a}
15117b755196Sdan  2    "INSERT INTO t2 VALUES(NULL, 'b')"         {t2.a}
15127b755196Sdan  3    "INSERT INTO t3 VALUES('c', 'd', NULL)"    {t3.c}
15137b755196Sdan  4    "INSERT INTO t3 VALUES('e', NULL, 'f')"    {t3.b}
15147b755196Sdan  5    "INSERT INTO t3 VALUES(NULL, 'g', 'h')"    {t3.a}
15157b755196Sdan}
15167b755196Sdan
15177b755196Sdan# EVIDENCE-OF: R-42511-39459 PRIMARY KEY, UNIQUE and NOT NULL
15187b755196Sdan# constraints may be explicitly assigned a default conflict resolution
15197b755196Sdan# algorithm by including a conflict-clause in their definitions.
15207b755196Sdan#
15217b755196Sdan#     Conflict clauses: ABORT, ROLLBACK, IGNORE, FAIL, REPLACE
15227b755196Sdan#
15237b755196Sdan#     Test cases 4.15.*, 4.16.* and 4.17.* focus on PRIMARY KEY, NOT NULL
15247b755196Sdan#     and UNIQUE constraints, respectively.
15257b755196Sdan#
15267b755196Sdandrop_all_tables
15277b755196Sdando_execsql_test 4.15.0 {
15287b755196Sdan  CREATE TABLE t1_ab(a PRIMARY KEY ON CONFLICT ABORT, b);
15297b755196Sdan  CREATE TABLE t1_ro(a PRIMARY KEY ON CONFLICT ROLLBACK, b);
15307b755196Sdan  CREATE TABLE t1_ig(a PRIMARY KEY ON CONFLICT IGNORE, b);
15317b755196Sdan  CREATE TABLE t1_fa(a PRIMARY KEY ON CONFLICT FAIL, b);
15327b755196Sdan  CREATE TABLE t1_re(a PRIMARY KEY ON CONFLICT REPLACE, b);
15337b755196Sdan  CREATE TABLE t1_xx(a PRIMARY KEY, b);
15347b755196Sdan
15357b755196Sdan  INSERT INTO t1_ab VALUES(1, 'one');
15367b755196Sdan  INSERT INTO t1_ab VALUES(2, 'two');
15377b755196Sdan  INSERT INTO t1_ro SELECT * FROM t1_ab;
15387b755196Sdan  INSERT INTO t1_ig SELECT * FROM t1_ab;
15397b755196Sdan  INSERT INTO t1_fa SELECT * FROM t1_ab;
15407b755196Sdan  INSERT INTO t1_re SELECT * FROM t1_ab;
15417b755196Sdan  INSERT INTO t1_xx SELECT * FROM t1_ab;
15427b755196Sdan
15437b755196Sdan  CREATE TABLE t2_ab(a, b NOT NULL ON CONFLICT ABORT);
15447b755196Sdan  CREATE TABLE t2_ro(a, b NOT NULL ON CONFLICT ROLLBACK);
15457b755196Sdan  CREATE TABLE t2_ig(a, b NOT NULL ON CONFLICT IGNORE);
15467b755196Sdan  CREATE TABLE t2_fa(a, b NOT NULL ON CONFLICT FAIL);
15477b755196Sdan  CREATE TABLE t2_re(a, b NOT NULL ON CONFLICT REPLACE);
15487b755196Sdan  CREATE TABLE t2_xx(a, b NOT NULL);
15497b755196Sdan
15507b755196Sdan  INSERT INTO t2_ab VALUES(1, 'one');
15517b755196Sdan  INSERT INTO t2_ab VALUES(2, 'two');
15527b755196Sdan  INSERT INTO t2_ro SELECT * FROM t2_ab;
15537b755196Sdan  INSERT INTO t2_ig SELECT * FROM t2_ab;
15547b755196Sdan  INSERT INTO t2_fa SELECT * FROM t2_ab;
15557b755196Sdan  INSERT INTO t2_re SELECT * FROM t2_ab;
15567b755196Sdan  INSERT INTO t2_xx SELECT * FROM t2_ab;
15577b755196Sdan
15587b755196Sdan  CREATE TABLE t3_ab(a, b, UNIQUE(a, b) ON CONFLICT ABORT);
15597b755196Sdan  CREATE TABLE t3_ro(a, b, UNIQUE(a, b) ON CONFLICT ROLLBACK);
15607b755196Sdan  CREATE TABLE t3_ig(a, b, UNIQUE(a, b) ON CONFLICT IGNORE);
15617b755196Sdan  CREATE TABLE t3_fa(a, b, UNIQUE(a, b) ON CONFLICT FAIL);
15627b755196Sdan  CREATE TABLE t3_re(a, b, UNIQUE(a, b) ON CONFLICT REPLACE);
15637b755196Sdan  CREATE TABLE t3_xx(a, b, UNIQUE(a, b));
15647b755196Sdan
15657b755196Sdan  INSERT INTO t3_ab VALUES(1, 'one');
15667b755196Sdan  INSERT INTO t3_ab VALUES(2, 'two');
15677b755196Sdan  INSERT INTO t3_ro SELECT * FROM t3_ab;
15687b755196Sdan  INSERT INTO t3_ig SELECT * FROM t3_ab;
15697b755196Sdan  INSERT INTO t3_fa SELECT * FROM t3_ab;
15707b755196Sdan  INSERT INTO t3_re SELECT * FROM t3_ab;
15717b755196Sdan  INSERT INTO t3_xx SELECT * FROM t3_ab;
15727b755196Sdan}
15737b755196Sdan
15747b755196Sdanforeach {tn tbl res ac data} {
1575f9c8ce3cSdrh  1   t1_ab    {1 {UNIQUE constraint failed: t1_ab.a}} 0 {1 one 2 two 3 three}
1576f9c8ce3cSdrh  2   t1_ro    {1 {UNIQUE constraint failed: t1_ro.a}} 1 {1 one 2 two}
1577f9c8ce3cSdrh  3   t1_fa    {1 {UNIQUE constraint failed: t1_fa.a}} 0 {1 one 2 two 3 three 4 string}
15787b755196Sdan  4   t1_ig    {0 {}} 0 {1 one 2 two 3 three 4 string 6 string}
15797b755196Sdan  5   t1_re    {0 {}} 0 {1 one 2 two 4 string 3 string 6 string}
1580f9c8ce3cSdrh  6   t1_xx    {1 {UNIQUE constraint failed: t1_xx.a}} 0 {1 one 2 two 3 three}
15817b755196Sdan} {
15827b755196Sdan  catchsql COMMIT
15837b755196Sdan  do_execsql_test  4.15.$tn.1 "BEGIN; INSERT INTO $tbl VALUES(3, 'three')"
15847b755196Sdan
15857b755196Sdan  do_catchsql_test 4.15.$tn.2 "
15867b755196Sdan    INSERT INTO $tbl SELECT ((a%2)*a+3), 'string' FROM $tbl;
15877b755196Sdan  " $res
15887b755196Sdan
15897b755196Sdan  do_test e_createtable-4.15.$tn.3 { sqlite3_get_autocommit db } $ac
15907b755196Sdan  do_execsql_test 4.15.$tn.4 "SELECT * FROM $tbl" $data
15917b755196Sdan}
15927b755196Sdanforeach {tn tbl res ac data} {
1593f9c8ce3cSdrh  1   t2_ab    {1 {NOT NULL constraint failed: t2_ab.b}} 0 {1 one 2 two 3 three}
1594f9c8ce3cSdrh  2   t2_ro    {1 {NOT NULL constraint failed: t2_ro.b}} 1 {1 one 2 two}
1595f9c8ce3cSdrh  3   t2_fa    {1 {NOT NULL constraint failed: t2_fa.b}} 0 {1 one 2 two 3 three 4 xx}
15967b755196Sdan  4   t2_ig    {0 {}} 0 {1 one 2 two 3 three 4 xx 6 xx}
1597f9c8ce3cSdrh  5   t2_re    {1 {NOT NULL constraint failed: t2_re.b}} 0 {1 one 2 two 3 three}
1598f9c8ce3cSdrh  6   t2_xx    {1 {NOT NULL constraint failed: t2_xx.b}} 0 {1 one 2 two 3 three}
15997b755196Sdan} {
16007b755196Sdan  catchsql COMMIT
16017b755196Sdan  do_execsql_test  4.16.$tn.1 "BEGIN; INSERT INTO $tbl VALUES(3, 'three')"
16027b755196Sdan
16037b755196Sdan  do_catchsql_test 4.16.$tn.2 "
16047b755196Sdan    INSERT INTO $tbl SELECT a+3, CASE a WHEN 2 THEN NULL ELSE 'xx' END FROM $tbl
16057b755196Sdan  " $res
16067b755196Sdan
16077b755196Sdan  do_test e_createtable-4.16.$tn.3 { sqlite3_get_autocommit db } $ac
16087b755196Sdan  do_execsql_test 4.16.$tn.4 "SELECT * FROM $tbl" $data
16097b755196Sdan}
16107b755196Sdanforeach {tn tbl res ac data} {
1611f9c8ce3cSdrh  1   t3_ab    {1 {UNIQUE constraint failed: t3_ab.a, t3_ab.b}}
1612f9c8ce3cSdrh               0 {1 one 2 two 3 three}
1613f9c8ce3cSdrh  2   t3_ro    {1 {UNIQUE constraint failed: t3_ro.a, t3_ro.b}}
1614f9c8ce3cSdrh               1 {1 one 2 two}
1615f9c8ce3cSdrh  3   t3_fa    {1 {UNIQUE constraint failed: t3_fa.a, t3_fa.b}}
1616f9c8ce3cSdrh               0 {1 one 2 two 3 three 4 three}
16177b755196Sdan  4   t3_ig    {0 {}} 0 {1 one 2 two 3 three 4 three 6 three}
16187b755196Sdan  5   t3_re    {0 {}} 0 {1 one 2 two 4 three 3 three 6 three}
1619f9c8ce3cSdrh  6   t3_xx    {1 {UNIQUE constraint failed: t3_xx.a, t3_xx.b}}
1620f9c8ce3cSdrh               0 {1 one 2 two 3 three}
16217b755196Sdan} {
16227b755196Sdan  catchsql COMMIT
16237b755196Sdan  do_execsql_test  4.17.$tn.1 "BEGIN; INSERT INTO $tbl VALUES(3, 'three')"
16247b755196Sdan
16257b755196Sdan  do_catchsql_test 4.17.$tn.2 "
16267b755196Sdan    INSERT INTO $tbl SELECT ((a%2)*a+3), 'three' FROM $tbl
16277b755196Sdan  " $res
16287b755196Sdan
16297b755196Sdan  do_test e_createtable-4.17.$tn.3 { sqlite3_get_autocommit db } $ac
16303f4d1d1bSdrh  do_execsql_test 4.17.$tn.4 "SELECT * FROM $tbl ORDER BY rowid" $data
16317b755196Sdan}
16327b755196Sdancatchsql COMMIT
16337b755196Sdan
16347b755196Sdan# EVIDENCE-OF: R-12645-39772 Or, if a constraint definition does not
16357b755196Sdan# include a conflict-clause or it is a CHECK constraint, the default
16367b755196Sdan# conflict resolution algorithm is ABORT.
16377b755196Sdan#
16387b755196Sdan#     The first half of the above is tested along with explicit ON
16397b755196Sdan#     CONFLICT clauses above (specifically, the tests involving t1_xx, t2_xx
16407b755196Sdan#     and t3_xx). The following just tests that the default conflict
16417b755196Sdan#     handling for CHECK constraints is ABORT.
16427b755196Sdan#
16437b755196Sdando_execsql_test 4.18.1 {
16447b755196Sdan  CREATE TABLE t4(a, b CHECK (b!=10));
16457b755196Sdan  INSERT INTO t4 VALUES(1, 2);
16467b755196Sdan  INSERT INTO t4 VALUES(3, 4);
16477b755196Sdan}
16487b755196Sdando_execsql_test  4.18.2 { BEGIN; INSERT INTO t4 VALUES(5, 6) }
16497b755196Sdando_catchsql_test 4.18.3 {
16507b755196Sdan  INSERT INTO t4 SELECT a+4, b+4 FROM t4
165192e21ef0Sdrh} {1 {CHECK constraint failed: b!=10}}
16527b755196Sdando_test e_createtable-4.18.4 { sqlite3_get_autocommit db } 0
16537b755196Sdando_execsql_test 4.18.5 { SELECT * FROM t4 } {1 2 3 4 5 6}
16547b755196Sdan
16557b755196Sdan# EVIDENCE-OF: R-19114-56113 Different constraints within the same table
16567b755196Sdan# may have different default conflict resolution algorithms.
16577b755196Sdan#
16587b755196Sdando_execsql_test 4.19.0 {
16597b755196Sdan  CREATE TABLE t5(a NOT NULL ON CONFLICT IGNORE, b NOT NULL ON CONFLICT ABORT);
16607b755196Sdan}
16617b755196Sdando_catchsql_test 4.19.1 { INSERT INTO t5 VALUES(NULL, 'not null') } {0 {}}
16627b755196Sdando_execsql_test  4.19.2 { SELECT * FROM t5 } {}
16637b755196Sdando_catchsql_test 4.19.3 { INSERT INTO t5 VALUES('not null', NULL) } \
1664f9c8ce3cSdrh  {1 {NOT NULL constraint failed: t5.b}}
16657b755196Sdando_execsql_test  4.19.4 { SELECT * FROM t5 } {}
16667b755196Sdan
1667a975b59fSdan#------------------------------------------------------------------------
1668a975b59fSdan# Tests for INTEGER PRIMARY KEY and rowid related statements.
1669a975b59fSdan#
1670a975b59fSdan
1671a975b59fSdan# EVIDENCE-OF: R-52584-04009 The rowid value can be accessed using one
1672a975b59fSdan# of the special case-independent names "rowid", "oid", or "_rowid_" in
1673a975b59fSdan# place of a column name.
1674a975b59fSdan#
1675bbbb0e80Sdrh# EVIDENCE-OF: R-06726-07466 A column name can be any of the names
1676bbbb0e80Sdrh# defined in the CREATE TABLE statement or one of the following special
1677bbbb0e80Sdrh# identifiers: "ROWID", "OID", or "_ROWID_".
1678bbbb0e80Sdrh#
1679a975b59fSdandrop_all_tables
1680a975b59fSdando_execsql_test 5.1.0 {
1681a975b59fSdan  CREATE TABLE t1(x, y);
1682a975b59fSdan  INSERT INTO t1 VALUES('one', 'first');
1683a975b59fSdan  INSERT INTO t1 VALUES('two', 'second');
1684a975b59fSdan  INSERT INTO t1 VALUES('three', 'third');
1685a975b59fSdan}
1686a975b59fSdando_createtable_tests 5.1 {
1687a975b59fSdan  1   "SELECT rowid FROM t1"        {1 2 3}
1688a975b59fSdan  2   "SELECT oid FROM t1"          {1 2 3}
1689a975b59fSdan  3   "SELECT _rowid_ FROM t1"      {1 2 3}
1690a975b59fSdan  4   "SELECT ROWID FROM t1"        {1 2 3}
1691a975b59fSdan  5   "SELECT OID FROM t1"          {1 2 3}
1692a975b59fSdan  6   "SELECT _ROWID_ FROM t1"      {1 2 3}
1693a975b59fSdan  7   "SELECT RoWiD FROM t1"        {1 2 3}
1694a975b59fSdan  8   "SELECT OiD FROM t1"          {1 2 3}
1695a975b59fSdan  9   "SELECT _RoWiD_ FROM t1"      {1 2 3}
1696a975b59fSdan}
1697a975b59fSdan
1698a975b59fSdan# EVIDENCE-OF: R-26501-17306 If a table contains a user defined column
1699a975b59fSdan# named "rowid", "oid" or "_rowid_", then that name always refers the
1700a975b59fSdan# explicitly declared column and cannot be used to retrieve the integer
1701a975b59fSdan# rowid value.
1702a975b59fSdan#
1703bbbb0e80Sdrh# EVIDENCE-OF: R-44615-33286 The special identifiers only refer to the
1704bbbb0e80Sdrh# row key if the CREATE TABLE statement does not define a real column
1705bbbb0e80Sdrh# with the same name.
1706bbbb0e80Sdrh#
1707a975b59fSdando_execsql_test 5.2.0 {
1708a975b59fSdan  CREATE TABLE t2(oid, b);
1709a975b59fSdan  CREATE TABLE t3(a, _rowid_);
1710a975b59fSdan  CREATE TABLE t4(a, b, rowid);
1711a975b59fSdan
1712a975b59fSdan  INSERT INTO t2 VALUES('one', 'two');
1713a975b59fSdan  INSERT INTO t2 VALUES('three', 'four');
1714a975b59fSdan
1715a975b59fSdan  INSERT INTO t3 VALUES('five', 'six');
1716a975b59fSdan  INSERT INTO t3 VALUES('seven', 'eight');
1717a975b59fSdan
1718a975b59fSdan  INSERT INTO t4 VALUES('nine', 'ten', 'eleven');
1719a975b59fSdan  INSERT INTO t4 VALUES('twelve', 'thirteen', 'fourteen');
1720a975b59fSdan}
1721a975b59fSdando_createtable_tests 5.2 {
1722a975b59fSdan  1   "SELECT oid, rowid, _rowid_ FROM t2"   {one 1 1      three 2 2}
1723a975b59fSdan  2   "SELECT oid, rowid, _rowid_ FROM t3"   {1 1 six      2 2 eight}
1724a975b59fSdan  3   "SELECT oid, rowid, _rowid_ FROM t4"   {1 eleven 1   2 fourteen 2}
1725a975b59fSdan}
1726a975b59fSdan
1727a975b59fSdan
1728a975b59fSdan# Argument $tbl is the name of a table in the database. Argument $col is
1729a975b59fSdan# the name of one of the tables columns. Return 1 if $col is an alias for
1730a975b59fSdan# the rowid, or 0 otherwise.
1731a975b59fSdan#
1732a975b59fSdanproc is_integer_primary_key {tbl col} {
1733a975b59fSdan  lindex [db eval [subst {
1734a975b59fSdan    DELETE FROM $tbl;
1735a975b59fSdan    INSERT INTO $tbl ($col) VALUES(0);
1736a975b59fSdan    SELECT (rowid==$col) FROM $tbl;
1737a975b59fSdan    DELETE FROM $tbl;
1738a975b59fSdan  }]] 0
1739a975b59fSdan}
1740a975b59fSdan
1741eb091cdfSdrh# EVIDENCE-OF: R-47901-33947 With one exception noted below, if a rowid
1742eb091cdfSdrh# table has a primary key that consists of a single column and the
1743eb091cdfSdrh# declared type of that column is "INTEGER" in any mixture of upper and
1744eb091cdfSdrh# lower case, then the column becomes an alias for the rowid.
1745a975b59fSdan#
1746a975b59fSdan# EVIDENCE-OF: R-45951-08347 if the declaration of a column with
1747a975b59fSdan# declared type "INTEGER" includes an "PRIMARY KEY DESC" clause, it does
1748a975b59fSdan# not become an alias for the rowid and is not classified as an integer
1749a975b59fSdan# primary key.
1750a975b59fSdan#
1751a975b59fSdando_createtable_tests 5.3 -tclquery {
1752a975b59fSdan  is_integer_primary_key t5 pk
1753a975b59fSdan} -repair {
1754a975b59fSdan  catchsql { DROP TABLE t5 }
1755a975b59fSdan} {
1756a975b59fSdan  1   "CREATE TABLE t5(pk integer primary key)"                         1
1757a975b59fSdan  2   "CREATE TABLE t5(pk integer, primary key(pk))"                    1
1758a975b59fSdan  3   "CREATE TABLE t5(pk integer, v integer, primary key(pk))"         1
1759a975b59fSdan  4   "CREATE TABLE t5(pk integer, v integer, primary key(pk, v))"      0
1760a975b59fSdan  5   "CREATE TABLE t5(pk int, v integer, primary key(pk, v))"          0
1761a975b59fSdan  6   "CREATE TABLE t5(pk int, v integer, primary key(pk))"             0
1762a975b59fSdan  7   "CREATE TABLE t5(pk int primary key, v integer)"                  0
1763a975b59fSdan  8   "CREATE TABLE t5(pk inTEger primary key)"                         1
1764a975b59fSdan  9   "CREATE TABLE t5(pk inteGEr, primary key(pk))"                    1
1765a975b59fSdan  10  "CREATE TABLE t5(pk INTEGER, v integer, primary key(pk))"         1
1766a975b59fSdan}
1767a975b59fSdan
1768a975b59fSdan# EVIDENCE-OF: R-41444-49665 Other integer type names like "INT" or
1769a975b59fSdan# "BIGINT" or "SHORT INTEGER" or "UNSIGNED INTEGER" causes the primary
1770a975b59fSdan# key column to behave as an ordinary table column with integer affinity
1771a975b59fSdan# and a unique index, not as an alias for the rowid.
1772a975b59fSdan#
1773a975b59fSdando_execsql_test 5.4.1 {
1774a975b59fSdan  CREATE TABLE t6(pk INT primary key);
1775a975b59fSdan  CREATE TABLE t7(pk BIGINT primary key);
1776a975b59fSdan  CREATE TABLE t8(pk SHORT INTEGER primary key);
1777a975b59fSdan  CREATE TABLE t9(pk UNSIGNED INTEGER primary key);
1778a975b59fSdan}
1779a975b59fSdando_test e_createtable-5.4.2.1 { is_integer_primary_key t6 pk } 0
1780a975b59fSdando_test e_createtable-5.4.2.2 { is_integer_primary_key t7 pk } 0
1781a975b59fSdando_test e_createtable-5.4.2.3 { is_integer_primary_key t8 pk } 0
1782a975b59fSdando_test e_createtable-5.4.2.4 { is_integer_primary_key t9 pk } 0
1783a975b59fSdan
1784a975b59fSdando_execsql_test 5.4.3 {
1785a975b59fSdan  INSERT INTO t6 VALUES('2.0');
1786a975b59fSdan  INSERT INTO t7 VALUES('2.0');
1787a975b59fSdan  INSERT INTO t8 VALUES('2.0');
1788a975b59fSdan  INSERT INTO t9 VALUES('2.0');
1789a975b59fSdan  SELECT typeof(pk), pk FROM t6;
1790a975b59fSdan  SELECT typeof(pk), pk FROM t7;
1791a975b59fSdan  SELECT typeof(pk), pk FROM t8;
1792a975b59fSdan  SELECT typeof(pk), pk FROM t9;
1793a975b59fSdan} {integer 2 integer 2 integer 2 integer 2}
1794a975b59fSdan
1795a975b59fSdando_catchsql_test 5.4.4.1 {
1796a975b59fSdan  INSERT INTO t6 VALUES(2)
1797f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t6.pk}}
1798a975b59fSdando_catchsql_test 5.4.4.2 {
1799a975b59fSdan  INSERT INTO t7 VALUES(2)
1800f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t7.pk}}
1801a975b59fSdando_catchsql_test 5.4.4.3 {
1802a975b59fSdan  INSERT INTO t8 VALUES(2)
1803f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t8.pk}}
1804a975b59fSdando_catchsql_test 5.4.4.4 {
1805a975b59fSdan  INSERT INTO t9 VALUES(2)
1806f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t9.pk}}
1807a975b59fSdan
1808a975b59fSdan# EVIDENCE-OF: R-56094-57830 the following three table declarations all
1809a975b59fSdan# cause the column "x" to be an alias for the rowid (an integer primary
1810a975b59fSdan# key): CREATE TABLE t(x INTEGER PRIMARY KEY ASC, y, z); CREATE TABLE
1811a975b59fSdan# t(x INTEGER, y, z, PRIMARY KEY(x ASC)); CREATE TABLE t(x INTEGER, y,
1812a975b59fSdan# z, PRIMARY KEY(x DESC));
1813a975b59fSdan#
1814a975b59fSdan# EVIDENCE-OF: R-20149-25884 the following declaration does not result
1815a975b59fSdan# in "x" being an alias for the rowid: CREATE TABLE t(x INTEGER PRIMARY
1816a975b59fSdan# KEY DESC, y, z);
1817a975b59fSdan#
1818a975b59fSdando_createtable_tests 5 -tclquery {
1819a975b59fSdan  is_integer_primary_key t x
1820a975b59fSdan} -repair {
1821a975b59fSdan  catchsql { DROP TABLE t }
1822a975b59fSdan} {
1823a975b59fSdan  5.1    "CREATE TABLE t(x INTEGER PRIMARY KEY ASC, y, z)"      1
1824a975b59fSdan  5.2    "CREATE TABLE t(x INTEGER, y, z, PRIMARY KEY(x ASC))"  1
1825a975b59fSdan  5.3    "CREATE TABLE t(x INTEGER, y, z, PRIMARY KEY(x DESC))" 1
1826a975b59fSdan  6.1    "CREATE TABLE t(x INTEGER PRIMARY KEY DESC, y, z)"     0
1827a975b59fSdan}
1828a975b59fSdan
1829a975b59fSdan# EVIDENCE-OF: R-03733-29734 Rowid values may be modified using an
1830a975b59fSdan# UPDATE statement in the same way as any other column value can, either
1831a975b59fSdan# using one of the built-in aliases ("rowid", "oid" or "_rowid_") or by
1832a975b59fSdan# using an alias created by an integer primary key.
1833a975b59fSdan#
1834a975b59fSdando_execsql_test 5.7.0 {
1835a975b59fSdan  CREATE TABLE t10(a, b);
1836a975b59fSdan  INSERT INTO t10 VALUES('ten', 10);
1837a975b59fSdan
1838a975b59fSdan  CREATE TABLE t11(a, b INTEGER PRIMARY KEY);
1839a975b59fSdan  INSERT INTO t11 VALUES('ten', 10);
1840a975b59fSdan}
1841a975b59fSdando_createtable_tests 5.7.1 -query {
1842a975b59fSdan  SELECT rowid, _rowid_, oid FROM t10;
1843a975b59fSdan} {
1844a975b59fSdan  1    "UPDATE t10 SET rowid = 5"   {5 5 5}
1845a975b59fSdan  2    "UPDATE t10 SET _rowid_ = 6" {6 6 6}
1846a975b59fSdan  3    "UPDATE t10 SET oid = 7"     {7 7 7}
1847a975b59fSdan}
1848a975b59fSdando_createtable_tests 5.7.2 -query {
1849a975b59fSdan  SELECT rowid, _rowid_, oid, b FROM t11;
1850a975b59fSdan} {
1851a975b59fSdan  1    "UPDATE t11 SET rowid = 5"   {5 5 5 5}
1852a975b59fSdan  2    "UPDATE t11 SET _rowid_ = 6" {6 6 6 6}
1853a975b59fSdan  3    "UPDATE t11 SET oid = 7"     {7 7 7 7}
1854a975b59fSdan  4    "UPDATE t11 SET b = 8"       {8 8 8 8}
1855a975b59fSdan}
1856a975b59fSdan
1857a975b59fSdan# EVIDENCE-OF: R-58706-14229 Similarly, an INSERT statement may provide
1858a975b59fSdan# a value to use as the rowid for each row inserted.
1859a975b59fSdan#
1860a975b59fSdando_createtable_tests 5.8.1 -query {
1861a975b59fSdan  SELECT rowid, _rowid_, oid FROM t10;
1862a975b59fSdan} -repair {
1863a975b59fSdan  execsql { DELETE FROM t10 }
1864a975b59fSdan} {
1865a975b59fSdan  1    "INSERT INTO t10(oid) VALUES(15)"           {15 15 15}
1866a975b59fSdan  2    "INSERT INTO t10(rowid) VALUES(16)"         {16 16 16}
1867a975b59fSdan  3    "INSERT INTO t10(_rowid_) VALUES(17)"       {17 17 17}
1868a975b59fSdan  4    "INSERT INTO t10(a, b, oid) VALUES(1,2,3)"  {3 3 3}
1869a975b59fSdan}
1870a975b59fSdando_createtable_tests 5.8.2 -query {
1871a975b59fSdan  SELECT rowid, _rowid_, oid, b FROM t11;
1872a975b59fSdan} -repair {
1873a975b59fSdan  execsql { DELETE FROM t11 }
1874a975b59fSdan} {
1875a975b59fSdan  1    "INSERT INTO t11(oid) VALUES(15)"           {15 15 15 15}
1876a975b59fSdan  2    "INSERT INTO t11(rowid) VALUES(16)"         {16 16 16 16}
1877a975b59fSdan  3    "INSERT INTO t11(_rowid_) VALUES(17)"       {17 17 17 17}
1878a975b59fSdan  4    "INSERT INTO t11(a, b) VALUES(1,2)"         {2 2 2 2}
1879a975b59fSdan}
1880a975b59fSdan
1881a975b59fSdan# EVIDENCE-OF: R-32326-44592 Unlike normal SQLite columns, an integer
1882a975b59fSdan# primary key or rowid column must contain integer values. Integer
1883a975b59fSdan# primary key or rowid columns are not able to hold floating point
1884a975b59fSdan# values, strings, BLOBs, or NULLs.
1885a975b59fSdan#
1886a975b59fSdan#     This is considered by the tests for the following 3 statements,
1887a975b59fSdan#     which show that:
1888a975b59fSdan#
1889a975b59fSdan#       1. Attempts to UPDATE a rowid column to a non-integer value fail,
1890a975b59fSdan#       2. Attempts to INSERT a real, string or blob value into a rowid
1891a975b59fSdan#          column fail, and
1892a975b59fSdan#       3. Attempting to INSERT a NULL value into a rowid column causes the
1893a975b59fSdan#          system to automatically select an integer value to use.
1894a975b59fSdan#
1895a975b59fSdan
1896a975b59fSdan
1897a975b59fSdan# EVIDENCE-OF: R-64224-62578 If an UPDATE statement attempts to set an
1898a975b59fSdan# integer primary key or rowid column to a NULL or blob value, or to a
1899a975b59fSdan# string or real value that cannot be losslessly converted to an
1900a975b59fSdan# integer, a "datatype mismatch" error occurs and the statement is
1901a975b59fSdan# aborted.
1902a975b59fSdan#
1903a975b59fSdandrop_all_tables
1904a975b59fSdando_execsql_test 5.9.0 {
1905a975b59fSdan  CREATE TABLE t12(x INTEGER PRIMARY KEY, y);
1906a975b59fSdan  INSERT INTO t12 VALUES(5, 'five');
1907a975b59fSdan}
1908a975b59fSdando_createtable_tests 5.9.1 -query { SELECT typeof(x), x FROM t12 } {
1909a975b59fSdan  1   "UPDATE t12 SET x = 4"       {integer 4}
1910a975b59fSdan  2   "UPDATE t12 SET x = 10.0"    {integer 10}
1911a975b59fSdan  3   "UPDATE t12 SET x = '12.0'"  {integer 12}
1912a975b59fSdan  4   "UPDATE t12 SET x = '-15.0'" {integer -15}
1913a975b59fSdan}
1914a975b59fSdando_createtable_tests 5.9.2 -error {
1915a975b59fSdan  datatype mismatch
1916a975b59fSdan} {
1917a975b59fSdan  1   "UPDATE t12 SET x = 4.1"         {}
1918a975b59fSdan  2   "UPDATE t12 SET x = 'hello'"     {}
1919a975b59fSdan  3   "UPDATE t12 SET x = NULL"        {}
1920a975b59fSdan  4   "UPDATE t12 SET x = X'ABCD'"     {}
1921a975b59fSdan  5   "UPDATE t12 SET x = X'3900'"     {}
1922a975b59fSdan  6   "UPDATE t12 SET x = X'39'"       {}
1923a975b59fSdan}
1924a975b59fSdan
1925a975b59fSdan# EVIDENCE-OF: R-05734-13629 If an INSERT statement attempts to insert a
1926a975b59fSdan# blob value, or a string or real value that cannot be losslessly
1927a975b59fSdan# converted to an integer into an integer primary key or rowid column, a
1928a975b59fSdan# "datatype mismatch" error occurs and the statement is aborted.
1929a975b59fSdan#
1930a975b59fSdando_execsql_test 5.10.0 { DELETE FROM t12 }
1931a975b59fSdando_createtable_tests 5.10.1 -error {
1932a975b59fSdan  datatype mismatch
1933a975b59fSdan} {
1934a975b59fSdan  1   "INSERT INTO t12(x) VALUES(4.1)"     {}
1935a975b59fSdan  2   "INSERT INTO t12(x) VALUES('hello')" {}
1936a975b59fSdan  3   "INSERT INTO t12(x) VALUES(X'ABCD')" {}
1937a975b59fSdan  4   "INSERT INTO t12(x) VALUES(X'3900')" {}
1938a975b59fSdan  5   "INSERT INTO t12(x) VALUES(X'39')"   {}
1939a975b59fSdan}
1940a975b59fSdando_createtable_tests 5.10.2 -query {
1941a975b59fSdan  SELECT typeof(x), x FROM t12
1942a975b59fSdan} -repair {
1943a975b59fSdan  execsql { DELETE FROM t12 }
1944a975b59fSdan} {
1945a975b59fSdan  1   "INSERT INTO t12(x) VALUES(4)"       {integer 4}
1946a975b59fSdan  2   "INSERT INTO t12(x) VALUES(10.0)"    {integer 10}
1947a975b59fSdan  3   "INSERT INTO t12(x) VALUES('12.0')"  {integer 12}
1948a975b59fSdan  4   "INSERT INTO t12(x) VALUES('4e3')"   {integer 4000}
1949a975b59fSdan  5   "INSERT INTO t12(x) VALUES('-14.0')" {integer -14}
1950a975b59fSdan}
1951a975b59fSdan
1952a975b59fSdan# EVIDENCE-OF: R-07986-46024 If an INSERT statement attempts to insert a
1953a975b59fSdan# NULL value into a rowid or integer primary key column, the system
1954a975b59fSdan# chooses an integer value to use as the rowid automatically.
1955a975b59fSdan#
1956a975b59fSdando_execsql_test 5.11.0 { DELETE FROM t12 }
1957a975b59fSdando_createtable_tests 5.11 -query {
1958a975b59fSdan  SELECT typeof(x), x FROM t12 WHERE y IS (SELECT max(y) FROM t12)
1959a975b59fSdan} {
1960a975b59fSdan  1   "INSERT INTO t12 DEFAULT VALUES"                {integer 1}
1961a975b59fSdan  2   "INSERT INTO t12(y)   VALUES(5)"                {integer 2}
1962a975b59fSdan  3   "INSERT INTO t12(x,y) VALUES(NULL, 10)"         {integer 3}
1963a975b59fSdan  4   "INSERT INTO t12(x,y) SELECT NULL, 15 FROM t12"
1964a975b59fSdan      {integer 4 integer 5 integer 6}
1965a975b59fSdan  5   "INSERT INTO t12(y) SELECT 20 FROM t12 LIMIT 3"
1966a975b59fSdan      {integer 7 integer 8 integer 9}
1967a975b59fSdan}
1968a975b59fSdan
196957f7f4b8Sdanfinish_test
1970