xref: /sqlite-3.40.0/test/table.test (revision ef5ecb41)
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.25 2004/06/07 10:00:31 danielk1977 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  sqlite 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  sqlite 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  set v [catch {execsql {CREATE TABLE test2(two text)}} msg]
94  lappend v $msg
95} {1 {table test2 already exists}}
96do_test table-2.1b {
97  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
98  lappend v $msg
99} {1 {table sqlite_master already exists}}
100do_test table-2.1c {
101  db close
102  sqlite db test.db
103  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
104  lappend v $msg
105} {1 {table sqlite_master already exists}}
106do_test table-2.1d {
107  execsql {DROP TABLE test2; SELECT name FROM sqlite_master WHERE type!='meta'}
108} {}
109
110# Verify that we cannot make a table with the same name as an index
111#
112do_test table-2.2a {
113  execsql {CREATE TABLE test2(one text); CREATE INDEX test3 ON test2(one)}
114  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
115  lappend v $msg
116} {1 {there is already an index named test3}}
117do_test table-2.2b {
118  db close
119  sqlite db test.db
120  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
121  lappend v $msg
122} {1 {there is already an index named test3}}
123do_test table-2.2c {
124  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
125} {test2 test3}
126do_test table-2.2d {
127  execsql {DROP INDEX test3}
128  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
129  lappend v $msg
130} {0 {}}
131do_test table-2.2e {
132  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
133} {test2 test3}
134do_test table-2.2f {
135  execsql {DROP TABLE test2; DROP TABLE test3}
136  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
137} {}
138
139# Create a table with many field names
140#
141set big_table \
142{CREATE TABLE big(
143  f1 varchar(20),
144  f2 char(10),
145  f3 varchar(30) primary key,
146  f4 text,
147  f5 text,
148  f6 text,
149  f7 text,
150  f8 text,
151  f9 text,
152  f10 text,
153  f11 text,
154  f12 text,
155  f13 text,
156  f14 text,
157  f15 text,
158  f16 text,
159  f17 text,
160  f18 text,
161  f19 text,
162  f20 text
163)}
164do_test table-3.1 {
165  execsql $big_table
166  execsql {SELECT sql FROM sqlite_master WHERE type=='table'}
167} \{$big_table\}
168do_test table-3.2 {
169  set v [catch {execsql {CREATE TABLE BIG(xyz foo)}} msg]
170  lappend v $msg
171} {1 {table BIG already exists}}
172do_test table-3.3 {
173  set v [catch {execsql {CREATE TABLE biG(xyz foo)}} msg]
174  lappend v $msg
175} {1 {table biG already exists}}
176do_test table-3.4 {
177  set v [catch {execsql {CREATE TABLE bIg(xyz foo)}} msg]
178  lappend v $msg
179} {1 {table bIg already exists}}
180do_test table-3.5 {
181  db close
182  sqlite db test.db
183  set v [catch {execsql {CREATE TABLE Big(xyz foo)}} msg]
184  lappend v $msg
185} {1 {table Big already exists}}
186do_test table-3.6 {
187  execsql {DROP TABLE big}
188  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
189} {}
190
191# Try creating large numbers of tables
192#
193set r {}
194for {set i 1} {$i<=100} {incr i} {
195  lappend r [format test%03d $i]
196}
197do_test table-4.1 {
198  for {set i 1} {$i<=100} {incr i} {
199    set sql "CREATE TABLE [format test%03d $i] ("
200    for {set k 1} {$k<$i} {incr k} {
201      append sql "field$k text,"
202    }
203    append sql "last_field text)"
204    execsql $sql
205  }
206  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
207} $r
208do_test table-4.1b {
209  db close
210  sqlite db test.db
211  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
212} $r
213
214# Drop the even numbered tables
215#
216set r {}
217for {set i 1} {$i<=100} {incr i 2} {
218  lappend r [format test%03d $i]
219}
220do_test table-4.2 {
221  for {set i 2} {$i<=100} {incr i 2} {
222    # if {$i==38} {execsql {pragma vdbe_trace=on}}
223    set sql "DROP TABLE [format TEST%03d $i]"
224    execsql $sql
225  }
226  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
227} $r
228#exit
229
230# Drop the odd number tables
231#
232do_test table-4.3 {
233  for {set i 1} {$i<=100} {incr i 2} {
234    set sql "DROP TABLE [format test%03d $i]"
235    execsql $sql
236  }
237  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
238} {}
239
240# Try to drop a table that does not exist
241#
242do_test table-5.1 {
243  set v [catch {execsql {DROP TABLE test009}} msg]
244  lappend v $msg
245} {1 {no such table: test009}}
246
247# Try to drop sqlite_master
248#
249do_test table-5.2 {
250  set v [catch {execsql {DROP TABLE sqlite_master}} msg]
251  lappend v $msg
252} {1 {table sqlite_master may not be dropped}}
253
254# Make sure an EXPLAIN does not really create a new table
255#
256do_test table-5.3 {
257  execsql {EXPLAIN CREATE TABLE test1(f1 int)}
258  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
259} {}
260
261# Make sure an EXPLAIN does not really drop an existing table
262#
263do_test table-5.4 {
264  execsql {CREATE TABLE test1(f1 int)}
265  execsql {EXPLAIN DROP TABLE test1}
266  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
267} {test1}
268
269# Create a table with a goofy name
270#
271#do_test table-6.1 {
272#  execsql {CREATE TABLE 'Spaces In This Name!'(x int)}
273#  execsql {INSERT INTO 'spaces in this name!' VALUES(1)}
274#  set list [glob -nocomplain testdb/spaces*.tbl]
275#} {testdb/spaces+in+this+name+.tbl}
276
277# Try using keywords as table names or column names.
278#
279do_test table-7.1 {
280  set v [catch {execsql {
281    CREATE TABLE weird(
282      desc text,
283      asc text,
284      explain int,
285      [14_vac] boolean,
286      fuzzy_dog_12 varchar(10),
287      begin blob,
288      end clob
289    )
290  }} msg]
291  lappend v $msg
292} {0 {}}
293do_test table-7.2 {
294  execsql {
295    INSERT INTO weird VALUES('a','b',9,0,'xyz','hi','y''all');
296    SELECT * FROM weird;
297  }
298} {a b 9 0 xyz hi y'all}
299do_test table-7.3 {
300  execsql2 {
301    SELECT * FROM weird;
302  }
303} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
304
305# Try out the CREATE TABLE AS syntax
306#
307do_test table-8.1 {
308breakpoint
309  execsql2 {
310    CREATE TABLE t2 AS SELECT * FROM weird;
311    SELECT * FROM t2;
312  }
313} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
314do_test table-8.1.1 {
315  execsql {
316    SELECT sql FROM sqlite_master WHERE name='t2';
317  }
318} {{CREATE TABLE t2(
319  'desc' text,
320  'asc' text,
321  'explain' int,
322  '14_vac' boolean,
323  fuzzy_dog_12 varchar(10),
324  'begin' blob,
325  'end' clob
326)}}
327do_test table-8.2 {
328  execsql {
329    CREATE TABLE 't3''xyz'(a,b,c);
330    INSERT INTO [t3'xyz] VALUES(1,2,3);
331    SELECT * FROM [t3'xyz];
332  }
333} {1 2 3}
334do_test table-8.3 {
335  execsql2 {
336    CREATE TABLE [t4'abc] AS SELECT count(*) as cnt, max(b+c) FROM [t3'xyz];
337    SELECT * FROM [t4'abc];
338  }
339} {cnt 1 max(b+c) 5}
340do_test table-8.3.1 {
341  execsql {
342    SELECT sql FROM sqlite_master WHERE name='t4''abc'
343  }
344} {{CREATE TABLE 't4''abc'(cnt NUMERIC,'max(b+c)' NUMERIC)}}
345do_test table-8.4 {
346  execsql2 {
347    CREATE TEMPORARY TABLE t5 AS SELECT count(*) AS [y'all] FROM [t3'xyz];
348    SELECT * FROM t5;
349  }
350} {y'all 1}
351do_test table-8.5 {
352  db close
353  sqlite db test.db
354  execsql2 {
355    SELECT * FROM [t4'abc];
356  }
357} {cnt 1 max(b+c) 5}
358do_test table-8.6 {
359  execsql2 {
360    SELECT * FROM t2;
361  }
362} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
363do_test table-8.7 {
364  catchsql {
365    SELECT * FROM t5;
366  }
367} {1 {no such table: t5}}
368do_test table-8.8 {
369  catchsql {
370    CREATE TABLE t5 AS SELECT * FROM no_such_table;
371  }
372} {1 {no such table: no_such_table}}
373
374# Make sure we cannot have duplicate column names within a table.
375#
376do_test table-9.1 {
377  catchsql {
378    CREATE TABLE t6(a,b,a);
379  }
380} {1 {duplicate column name: a}}
381
382# Check the foreign key syntax.
383#
384do_test table-10.1 {
385  catchsql {
386    CREATE TABLE t6(a REFERENCES t4(a) NOT NULL);
387    INSERT INTO t6 VALUES(NULL);
388  }
389} {1 {t6.a may not be NULL}}
390do_test table-10.2 {
391  catchsql {
392    DROP TABLE t6;
393    CREATE TABLE t6(a REFERENCES t4(a) MATCH PARTIAL);
394  }
395} {0 {}}
396do_test table-10.3 {
397  catchsql {
398    DROP TABLE t6;
399    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON DELETE SET NULL NOT NULL);
400  }
401} {0 {}}
402do_test table-10.4 {
403  catchsql {
404    DROP TABLE t6;
405    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON UPDATE SET DEFAULT DEFAULT 1);
406  }
407} {0 {}}
408do_test table-10.5 {
409  catchsql {
410    DROP TABLE t6;
411    CREATE TABLE t6(a NOT NULL NOT DEFERRABLE INITIALLY IMMEDIATE);
412  }
413} {0 {}}
414do_test table-10.6 {
415  catchsql {
416    DROP TABLE t6;
417    CREATE TABLE t6(a NOT NULL DEFERRABLE INITIALLY DEFERRED);
418  }
419} {0 {}}
420do_test table-10.7 {
421  catchsql {
422    DROP TABLE t6;
423    CREATE TABLE t6(a,
424      FOREIGN KEY (a) REFERENCES t4(b) DEFERRABLE INITIALLY DEFERRED
425    );
426  }
427} {0 {}}
428do_test table-10.8 {
429  catchsql {
430    DROP TABLE t6;
431    CREATE TABLE t6(a,b,c,
432      FOREIGN KEY (b,c) REFERENCES t4(x,y) MATCH PARTIAL
433        ON UPDATE SET NULL ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
434    );
435  }
436} {0 {}}
437do_test table-10.9 {
438  catchsql {
439    DROP TABLE t6;
440    CREATE TABLE t6(a,b,c,
441      FOREIGN KEY (b,c) REFERENCES t4(x)
442    );
443  }
444} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
445do_test table-10.10 {
446  catchsql {DROP TABLE t6}
447  catchsql {
448    CREATE TABLE t6(a,b,c,
449      FOREIGN KEY (b,c) REFERENCES t4(x,y,z)
450    );
451  }
452} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
453do_test table-10.11 {
454  catchsql {DROP TABLE t6}
455  catchsql {
456    CREATE TABLE t6(a,b, c REFERENCES t4(x,y));
457  }
458} {1 {foreign key on c should reference only one column of table t4}}
459do_test table-10.12 {
460  catchsql {DROP TABLE t6}
461  catchsql {
462    CREATE TABLE t6(a,b,c,
463      FOREIGN KEY (b,x) REFERENCES t4(x,y)
464    );
465  }
466} {1 {unknown column "x" in foreign key definition}}
467do_test table-10.13 {
468  catchsql {DROP TABLE t6}
469  catchsql {
470    CREATE TABLE t6(a,b,c,
471      FOREIGN KEY (x,b) REFERENCES t4(x,y)
472    );
473  }
474} {1 {unknown column "x" in foreign key definition}}
475
476
477# Test for the "typeof" function. More tests for the
478# typeof() function are found in bind.test and types.test.
479#
480do_test table-11.1 {
481  execsql {
482    CREATE TABLE t7(
483       a integer primary key,
484       b number(5,10),
485       c character varying (8),
486       d VARCHAR(9),
487       e clob,
488       f BLOB,
489       g Text,
490       h
491    );
492    INSERT INTO t7(a) VALUES(1);
493    SELECT typeof(a), typeof(b), typeof(c), typeof(d),
494           typeof(e), typeof(f), typeof(g), typeof(h)
495    FROM t7 LIMIT 1;
496  }
497} {integer null null null null null null null}
498do_test table-11.2 {
499  execsql {
500    SELECT typeof(a+b), typeof(a||b), typeof(c+d), typeof(c||d)
501    FROM t7 LIMIT 1;
502  }
503} {null null null null}
504
505finish_test
506