xref: /sqlite-3.40.0/test/table.test (revision a6370df1)
1# 2001 September 15
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
6#    May you do good and not evil.
7#    May you find forgiveness for yourself and forgive others.
8#    May you share freely, never taking more than you give.
9#
10#***********************************************************************
11# This file implements regression tests for SQLite library.  The
12# focus of this file is testing the CREATE TABLE statement.
13#
14# $Id: table.test,v 1.44 2006/01/04 21:40:07 drh Exp $
15
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
19# Create a basic table and verify it is added to sqlite_master
20#
21do_test table-1.1 {
22  execsql {
23    CREATE TABLE test1 (
24      one varchar(10),
25      two text
26    )
27  }
28  execsql {
29    SELECT sql FROM sqlite_master WHERE type!='meta'
30  }
31} {{CREATE TABLE test1 (
32      one varchar(10),
33      two text
34    )}}
35
36
37# Verify the other fields of the sqlite_master file.
38#
39do_test table-1.3 {
40  execsql {SELECT name, tbl_name, type FROM sqlite_master WHERE type!='meta'}
41} {test1 test1 table}
42
43# Close and reopen the database.  Verify that everything is
44# still the same.
45#
46do_test table-1.4 {
47  db close
48  sqlite3 db test.db
49  execsql {SELECT name, tbl_name, type from sqlite_master WHERE type!='meta'}
50} {test1 test1 table}
51
52# Drop the database and make sure it disappears.
53#
54do_test table-1.5 {
55  execsql {DROP TABLE test1}
56  execsql {SELECT * FROM sqlite_master WHERE type!='meta'}
57} {}
58
59# Close and reopen the database.  Verify that the table is
60# still gone.
61#
62do_test table-1.6 {
63  db close
64  sqlite3 db test.db
65  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
66} {}
67
68# Repeat the above steps, but this time quote the table name.
69#
70do_test table-1.10 {
71  execsql {CREATE TABLE "create" (f1 int)}
72  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
73} {create}
74do_test table-1.11 {
75  execsql {DROP TABLE "create"}
76  execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
77} {}
78do_test table-1.12 {
79  execsql {CREATE TABLE test1("f1 ho" int)}
80  execsql {SELECT name as "X" FROM sqlite_master WHERE type!='meta'}
81} {test1}
82do_test table-1.13 {
83  execsql {DROP TABLE "TEST1"}
84  execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
85} {}
86
87
88
89# Verify that we cannot make two tables with the same name
90#
91do_test table-2.1 {
92  execsql {CREATE TABLE TEST2(one text)}
93  catchsql {CREATE TABLE test2(two text default 'hi')}
94} {1 {table test2 already exists}}
95do_test table-2.1b {
96  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
97  lappend v $msg
98} {1 {object name reserved for internal use: sqlite_master}}
99do_test table-2.1c {
100  db close
101  sqlite3 db test.db
102  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
103  lappend v $msg
104} {1 {object name reserved for internal use: sqlite_master}}
105do_test table-2.1d {
106  catchsql {CREATE TABLE IF NOT EXISTS test2(x,y)}
107} {0 {}}
108do_test table-2.1e {
109  catchsql {CREATE TABLE IF NOT EXISTS test2(x UNIQUE, y TEXT PRIMARY KEY)}
110} {0 {}}
111do_test table-2.1f {
112  execsql {DROP TABLE test2; SELECT name FROM sqlite_master WHERE type!='meta'}
113} {}
114
115# Verify that we cannot make a table with the same name as an index
116#
117do_test table-2.2a {
118  execsql {CREATE TABLE test2(one text); CREATE INDEX test3 ON test2(one)}
119  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
120  lappend v $msg
121} {1 {there is already an index named test3}}
122do_test table-2.2b {
123  db close
124  sqlite3 db test.db
125  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
126  lappend v $msg
127} {1 {there is already an index named test3}}
128do_test table-2.2c {
129  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
130} {test2 test3}
131do_test table-2.2d {
132  execsql {DROP INDEX test3}
133  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
134  lappend v $msg
135} {0 {}}
136do_test table-2.2e {
137  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
138} {test2 test3}
139do_test table-2.2f {
140  execsql {DROP TABLE test2; DROP TABLE test3}
141  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
142} {}
143
144# Create a table with many field names
145#
146set big_table \
147{CREATE TABLE big(
148  f1 varchar(20),
149  f2 char(10),
150  f3 varchar(30) primary key,
151  f4 text,
152  f5 text,
153  f6 text,
154  f7 text,
155  f8 text,
156  f9 text,
157  f10 text,
158  f11 text,
159  f12 text,
160  f13 text,
161  f14 text,
162  f15 text,
163  f16 text,
164  f17 text,
165  f18 text,
166  f19 text,
167  f20 text
168)}
169do_test table-3.1 {
170  execsql $big_table
171  execsql {SELECT sql FROM sqlite_master WHERE type=='table'}
172} \{$big_table\}
173do_test table-3.2 {
174  set v [catch {execsql {CREATE TABLE BIG(xyz foo)}} msg]
175  lappend v $msg
176} {1 {table BIG already exists}}
177do_test table-3.3 {
178  set v [catch {execsql {CREATE TABLE biG(xyz foo)}} msg]
179  lappend v $msg
180} {1 {table biG already exists}}
181do_test table-3.4 {
182  set v [catch {execsql {CREATE TABLE bIg(xyz foo)}} msg]
183  lappend v $msg
184} {1 {table bIg already exists}}
185do_test table-3.5 {
186  db close
187  sqlite3 db test.db
188  set v [catch {execsql {CREATE TABLE Big(xyz foo)}} msg]
189  lappend v $msg
190} {1 {table Big already exists}}
191do_test table-3.6 {
192  execsql {DROP TABLE big}
193  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
194} {}
195
196# Try creating large numbers of tables
197#
198set r {}
199for {set i 1} {$i<=100} {incr i} {
200  lappend r [format test%03d $i]
201}
202do_test table-4.1 {
203  for {set i 1} {$i<=100} {incr i} {
204    set sql "CREATE TABLE [format test%03d $i] ("
205    for {set k 1} {$k<$i} {incr k} {
206      append sql "field$k text,"
207    }
208    append sql "last_field text)"
209    execsql $sql
210  }
211  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
212} $r
213do_test table-4.1b {
214  db close
215  sqlite3 db test.db
216  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
217} $r
218
219# Drop the even numbered tables
220#
221set r {}
222for {set i 1} {$i<=100} {incr i 2} {
223  lappend r [format test%03d $i]
224}
225do_test table-4.2 {
226  for {set i 2} {$i<=100} {incr i 2} {
227    # if {$i==38} {execsql {pragma vdbe_trace=on}}
228    set sql "DROP TABLE [format TEST%03d $i]"
229    execsql $sql
230  }
231  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
232} $r
233#exit
234
235# Drop the odd number tables
236#
237do_test table-4.3 {
238  for {set i 1} {$i<=100} {incr i 2} {
239    set sql "DROP TABLE [format test%03d $i]"
240    execsql $sql
241  }
242  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
243} {}
244
245# Try to drop a table that does not exist
246#
247do_test table-5.1.1 {
248  catchsql {DROP TABLE test009}
249} {1 {no such table: test009}}
250do_test table-5.1.2 {
251  catchsql {DROP TABLE IF EXISTS test009}
252} {0 {}}
253
254# Try to drop sqlite_master
255#
256do_test table-5.2 {
257  catchsql {DROP TABLE IF EXISTS sqlite_master}
258} {1 {table sqlite_master may not be dropped}}
259
260# Make sure an EXPLAIN does not really create a new table
261#
262do_test table-5.3 {
263  ifcapable {explain} {
264    execsql {EXPLAIN CREATE TABLE test1(f1 int)}
265  }
266  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
267} {}
268
269# Make sure an EXPLAIN does not really drop an existing table
270#
271do_test table-5.4 {
272  execsql {CREATE TABLE test1(f1 int)}
273  ifcapable {explain} {
274    execsql {EXPLAIN DROP TABLE test1}
275  }
276  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
277} {test1}
278
279# Create a table with a goofy name
280#
281#do_test table-6.1 {
282#  execsql {CREATE TABLE 'Spaces In This Name!'(x int)}
283#  execsql {INSERT INTO 'spaces in this name!' VALUES(1)}
284#  set list [glob -nocomplain testdb/spaces*.tbl]
285#} {testdb/spaces+in+this+name+.tbl}
286
287# Try using keywords as table names or column names.
288#
289do_test table-7.1 {
290  set v [catch {execsql {
291    CREATE TABLE weird(
292      desc text,
293      asc text,
294      key int,
295      [14_vac] boolean,
296      fuzzy_dog_12 varchar(10),
297      begin blob,
298      end clob
299    )
300  }} msg]
301  lappend v $msg
302} {0 {}}
303do_test table-7.2 {
304  execsql {
305    INSERT INTO weird VALUES('a','b',9,0,'xyz','hi','y''all');
306    SELECT * FROM weird;
307  }
308} {a b 9 0 xyz hi y'all}
309do_test table-7.3 {
310  execsql2 {
311    SELECT * FROM weird;
312  }
313} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
314
315# Try out the CREATE TABLE AS syntax
316#
317do_test table-8.1 {
318  execsql2 {
319    CREATE TABLE t2 AS SELECT * FROM weird;
320    SELECT * FROM t2;
321  }
322} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
323do_test table-8.1.1 {
324  execsql {
325    SELECT sql FROM sqlite_master WHERE name='t2';
326  }
327} {{CREATE TABLE t2(
328  "desc" text,
329  "asc" text,
330  "key" int,
331  "14_vac" boolean,
332  fuzzy_dog_12 varchar(10),
333  "begin" blob,
334  "end" clob
335)}}
336do_test table-8.2 {
337  execsql {
338    CREATE TABLE "t3""xyz"(a,b,c);
339    INSERT INTO [t3"xyz] VALUES(1,2,3);
340    SELECT * FROM [t3"xyz];
341  }
342} {1 2 3}
343do_test table-8.3 {
344  execsql2 {
345    CREATE TABLE [t4"abc] AS SELECT count(*) as cnt, max(b+c) FROM [t3"xyz];
346    SELECT * FROM [t4"abc];
347  }
348} {cnt 1 max(b+c) 5}
349
350# Update for v3: The declaration type of anything except a column is now a
351# NULL pointer, so the created table has no column types. (Changed result
352# from {{CREATE TABLE 't4"abc'(cnt NUMERIC,"max(b+c)" NUMERIC)}}).
353do_test table-8.3.1 {
354  execsql {
355    SELECT sql FROM sqlite_master WHERE name='t4"abc'
356  }
357} {{CREATE TABLE "t4""abc"(cnt,"max(b+c)")}}
358
359ifcapable tempdb {
360  do_test table-8.4 {
361    execsql2 {
362      CREATE TEMPORARY TABLE t5 AS SELECT count(*) AS [y'all] FROM [t3"xyz];
363      SELECT * FROM t5;
364    }
365  } {y'all 1}
366}
367
368do_test table-8.5 {
369  db close
370  sqlite3 db test.db
371  execsql2 {
372    SELECT * FROM [t4"abc];
373  }
374} {cnt 1 max(b+c) 5}
375do_test table-8.6 {
376  execsql2 {
377    SELECT * FROM t2;
378  }
379} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
380do_test table-8.7 {
381  catchsql {
382    SELECT * FROM t5;
383  }
384} {1 {no such table: t5}}
385do_test table-8.8 {
386  catchsql {
387    CREATE TABLE t5 AS SELECT * FROM no_such_table;
388  }
389} {1 {no such table: no_such_table}}
390
391# Make sure we cannot have duplicate column names within a table.
392#
393do_test table-9.1 {
394  catchsql {
395    CREATE TABLE t6(a,b,a);
396  }
397} {1 {duplicate column name: a}}
398do_test table-9.2 {
399  catchsql {
400    CREATE TABLE t6(a varchar(100), b blob, a integer);
401  }
402} {1 {duplicate column name: a}}
403
404# Check the foreign key syntax.
405#
406ifcapable {foreignkey} {
407do_test table-10.1 {
408  catchsql {
409    CREATE TABLE t6(a REFERENCES t4(a) NOT NULL);
410    INSERT INTO t6 VALUES(NULL);
411  }
412} {1 {t6.a may not be NULL}}
413do_test table-10.2 {
414  catchsql {
415    DROP TABLE t6;
416    CREATE TABLE t6(a REFERENCES t4(a) MATCH PARTIAL);
417  }
418} {0 {}}
419do_test table-10.3 {
420  catchsql {
421    DROP TABLE t6;
422    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON DELETE SET NULL NOT NULL);
423  }
424} {0 {}}
425do_test table-10.4 {
426  catchsql {
427    DROP TABLE t6;
428    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON UPDATE SET DEFAULT DEFAULT 1);
429  }
430} {0 {}}
431do_test table-10.5 {
432  catchsql {
433    DROP TABLE t6;
434    CREATE TABLE t6(a NOT NULL NOT DEFERRABLE INITIALLY IMMEDIATE);
435  }
436} {0 {}}
437do_test table-10.6 {
438  catchsql {
439    DROP TABLE t6;
440    CREATE TABLE t6(a NOT NULL DEFERRABLE INITIALLY DEFERRED);
441  }
442} {0 {}}
443do_test table-10.7 {
444  catchsql {
445    DROP TABLE t6;
446    CREATE TABLE t6(a,
447      FOREIGN KEY (a) REFERENCES t4(b) DEFERRABLE INITIALLY DEFERRED
448    );
449  }
450} {0 {}}
451do_test table-10.8 {
452  catchsql {
453    DROP TABLE t6;
454    CREATE TABLE t6(a,b,c,
455      FOREIGN KEY (b,c) REFERENCES t4(x,y) MATCH PARTIAL
456        ON UPDATE SET NULL ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
457    );
458  }
459} {0 {}}
460do_test table-10.9 {
461  catchsql {
462    DROP TABLE t6;
463    CREATE TABLE t6(a,b,c,
464      FOREIGN KEY (b,c) REFERENCES t4(x)
465    );
466  }
467} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
468do_test table-10.10 {
469  catchsql {DROP TABLE t6}
470  catchsql {
471    CREATE TABLE t6(a,b,c,
472      FOREIGN KEY (b,c) REFERENCES t4(x,y,z)
473    );
474  }
475} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
476do_test table-10.11 {
477  catchsql {DROP TABLE t6}
478  catchsql {
479    CREATE TABLE t6(a,b, c REFERENCES t4(x,y));
480  }
481} {1 {foreign key on c should reference only one column of table t4}}
482do_test table-10.12 {
483  catchsql {DROP TABLE t6}
484  catchsql {
485    CREATE TABLE t6(a,b,c,
486      FOREIGN KEY (b,x) REFERENCES t4(x,y)
487    );
488  }
489} {1 {unknown column "x" in foreign key definition}}
490do_test table-10.13 {
491  catchsql {DROP TABLE t6}
492  catchsql {
493    CREATE TABLE t6(a,b,c,
494      FOREIGN KEY (x,b) REFERENCES t4(x,y)
495    );
496  }
497} {1 {unknown column "x" in foreign key definition}}
498} ;# endif foreignkey
499
500# Test for the "typeof" function. More tests for the
501# typeof() function are found in bind.test and types.test.
502#
503do_test table-11.1 {
504  execsql {
505    CREATE TABLE t7(
506       a integer primary key,
507       b number(5,10),
508       c character varying (8),
509       d VARCHAR(9),
510       e clob,
511       f BLOB,
512       g Text,
513       h
514    );
515    INSERT INTO t7(a) VALUES(1);
516    SELECT typeof(a), typeof(b), typeof(c), typeof(d),
517           typeof(e), typeof(f), typeof(g), typeof(h)
518    FROM t7 LIMIT 1;
519  }
520} {integer null null null null null null null}
521do_test table-11.2 {
522  execsql {
523    SELECT typeof(a+b), typeof(a||b), typeof(c+d), typeof(c||d)
524    FROM t7 LIMIT 1;
525  }
526} {null null null null}
527
528# Test that when creating a table using CREATE TABLE AS, column types are
529# assigned correctly for (SELECT ...) and 'x AS y' expressions.
530do_test table-12.1 {
531  ifcapable subquery {
532    execsql {
533      CREATE TABLE t8 AS SELECT b, h, a as i, (SELECT f FROM t7) as j FROM t7;
534    }
535  } else {
536    execsql {
537      CREATE TABLE t8 AS SELECT b, h, a as i, f as j FROM t7;
538    }
539  }
540} {}
541do_test table-12.2 {
542  execsql {
543    SELECT sql FROM sqlite_master WHERE tbl_name = 't8'
544  }
545} {{CREATE TABLE t8(b number(5,10),h,i integer,j BLOB)}}
546
547#--------------------------------------------------------------------
548# Test cases table-13.*
549#
550# Test the ability to have default values of CURRENT_TIME, CURRENT_DATE
551# and CURRENT_TIMESTAMP.
552#
553do_test table-13.1 {
554  execsql {
555    CREATE TABLE tablet8(
556       a integer primary key,
557       tm text DEFAULT CURRENT_TIME,
558       dt text DEFAULT CURRENT_DATE,
559       dttm text DEFAULT CURRENT_TIMESTAMP
560    );
561    SELECT * FROM tablet8;
562  }
563} {}
564set i 0
565foreach {date time} {
566  1976-07-04 12:00:00
567  1994-04-16 14:00:00
568  2000-01-01 00:00:00
569  2003-12-31 12:34:56
570} {
571  incr i
572  set sqlite_current_time [clock scan "$date $time" -gmt 1]
573  # set sqlite_current_time [execsql "SELECT strftime('%s','$date $time')"]
574  do_test table-13.2.$i {
575    execsql "
576      INSERT INTO tablet8(a) VALUES($i);
577      SELECT tm, dt, dttm FROM tablet8 WHERE a=$i;
578    "
579  } [list $time $date [list $date $time]]
580}
581set sqlite_current_time 0
582
583#--------------------------------------------------------------------
584# Test cases table-14.*
585#
586# Test that a table cannot be created or dropped while other virtual
587# machines are active. This is required because otherwise when in
588# auto-vacuum mode the btree-layer may need to move the root-pages of
589# a table for which there is an open cursor.
590#
591
592# db eval {
593#   pragma vdbe_trace = 0;
594# }
595# Try to create a table from within a callback:
596unset -nocomplain result
597do_test table-14.1 {
598  set rc [
599    catch {
600      db eval {SELECT * FROM tablet8 LIMIT 1} {} {
601        db eval {CREATE TABLE t9(a, b, c)}
602      }
603    } msg
604  ]
605  set result [list $rc $msg]
606} {1 {database table is locked}}
607
608do_test table-14.2 {
609  execsql {
610    CREATE TABLE t9(a, b, c)
611  }
612} {}
613
614# Try to drop a table from within a callback:
615do_test table-14.3 {
616  set rc [
617    catch {
618      db eval {SELECT * FROM tablet8 LIMIT 1} {} {
619        db eval {DROP TABLE t9;}
620      }
621    } msg
622  ]
623  set result [list $rc $msg]
624} {1 {database table is locked}}
625
626# Now attach a database and ensure that a table can be created in the
627# attached database whilst in a callback from a query on the main database.
628do_test table-14.4 {
629  file delete -force test2.db
630  file delete -force test2.db-journal
631  execsql {
632    attach 'test2.db' as aux;
633  }
634  db eval {SELECT * FROM tablet8 LIMIT 1} {} {
635    db eval {CREATE TABLE aux.t1(a, b, c)}
636  }
637} {}
638
639# On the other hand, it should be impossible to drop a table when any VMs
640# are active. This is because VerifyCookie instructions may have already
641# been executed, and btree root-pages may not move after this (which a
642# delete table might do).
643do_test table-14.4 {
644  set rc [
645    catch {
646      db eval {SELECT * FROM tablet8 LIMIT 1} {} {
647        db eval {DROP TABLE aux.t1;}
648      }
649    } msg
650  ]
651  set result [list $rc $msg]
652} {1 {database table is locked}}
653
654# Create and drop 2000 tables. This is to check that the balance_shallow()
655# routine works correctly on the sqlite_master table. At one point it
656# contained a bug that would prevent the right-child pointer of the
657# child page from being copied to the root page.
658#
659do_test table-15.1 {
660  execsql {BEGIN}
661  for {set i 0} {$i<2000} {incr i} {
662    execsql "CREATE TABLE tbl$i (a, b, c)"
663  }
664  execsql {COMMIT}
665} {}
666do_test table-15.2 {
667  execsql {BEGIN}
668  for {set i 0} {$i<2000} {incr i} {
669    execsql "DROP TABLE tbl$i"
670  }
671  execsql {COMMIT}
672} {}
673
674finish_test
675