blob: 4826cb927d519e9cf6debb4cc6fbe74a684d4add [file] [log] [blame]
drhb19a2bc2001-09-16 00:13:26 +00001# 2001 September 15
drh348784e2000-05-29 20:41:49 +00002#
drhb19a2bc2001-09-16 00:13:26 +00003# The author disclaims copyright to this source code. In place of
4# a legal notice, here is a blessing:
drh348784e2000-05-29 20:41:49 +00005#
drhb19a2bc2001-09-16 00:13:26 +00006# 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.
drh348784e2000-05-29 20:41:49 +00009#
10#***********************************************************************
11# This file implements regression tests for SQLite library. The
12# focus of this file is testing the CREATE TABLE statement.
13#
drhdda70fe2009-06-05 17:09:11 +000014# $Id: table.test,v 1.53 2009/06/05 17:09:12 drh Exp $
drh348784e2000-05-29 20:41:49 +000015
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
19# Create a basic table and verify it is added to sqlite_master
20#
drh1b6a71f2000-05-29 23:58:11 +000021do_test table-1.1 {
drh348784e2000-05-29 20:41:49 +000022 execsql {
23 CREATE TABLE test1 (
24 one varchar(10),
25 two text
26 )
27 }
28 execsql {
drh28037572000-08-02 13:47:41 +000029 SELECT sql FROM sqlite_master WHERE type!='meta'
drh348784e2000-05-29 20:41:49 +000030 }
31} {{CREATE TABLE test1 (
32 one varchar(10),
33 two text
34 )}}
35
drh348784e2000-05-29 20:41:49 +000036
37# Verify the other fields of the sqlite_master file.
38#
drh1b6a71f2000-05-29 23:58:11 +000039do_test table-1.3 {
drh28037572000-08-02 13:47:41 +000040 execsql {SELECT name, tbl_name, type FROM sqlite_master WHERE type!='meta'}
drh348784e2000-05-29 20:41:49 +000041} {test1 test1 table}
42
43# Close and reopen the database. Verify that everything is
44# still the same.
45#
drh1b6a71f2000-05-29 23:58:11 +000046do_test table-1.4 {
drh348784e2000-05-29 20:41:49 +000047 db close
drhef4ac8f2004-06-19 00:16:31 +000048 sqlite3 db test.db
drh28037572000-08-02 13:47:41 +000049 execsql {SELECT name, tbl_name, type from sqlite_master WHERE type!='meta'}
drh348784e2000-05-29 20:41:49 +000050} {test1 test1 table}
51
52# Drop the database and make sure it disappears.
53#
drh1b6a71f2000-05-29 23:58:11 +000054do_test table-1.5 {
drh348784e2000-05-29 20:41:49 +000055 execsql {DROP TABLE test1}
drh28037572000-08-02 13:47:41 +000056 execsql {SELECT * FROM sqlite_master WHERE type!='meta'}
drh348784e2000-05-29 20:41:49 +000057} {}
58
drh348784e2000-05-29 20:41:49 +000059# Close and reopen the database. Verify that the table is
60# still gone.
61#
drh1b6a71f2000-05-29 23:58:11 +000062do_test table-1.6 {
drh348784e2000-05-29 20:41:49 +000063 db close
drhef4ac8f2004-06-19 00:16:31 +000064 sqlite3 db test.db
drh28037572000-08-02 13:47:41 +000065 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drh348784e2000-05-29 20:41:49 +000066} {}
67
drh982cef72000-05-30 16:27:03 +000068# Repeat the above steps, but this time quote the table name.
69#
70do_test table-1.10 {
71 execsql {CREATE TABLE "create" (f1 int)}
drh28037572000-08-02 13:47:41 +000072 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drh982cef72000-05-30 16:27:03 +000073} {create}
74do_test table-1.11 {
75 execsql {DROP TABLE "create"}
drh28037572000-08-02 13:47:41 +000076 execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
drh982cef72000-05-30 16:27:03 +000077} {}
78do_test table-1.12 {
79 execsql {CREATE TABLE test1("f1 ho" int)}
drh28037572000-08-02 13:47:41 +000080 execsql {SELECT name as "X" FROM sqlite_master WHERE type!='meta'}
drh982cef72000-05-30 16:27:03 +000081} {test1}
82do_test table-1.13 {
83 execsql {DROP TABLE "TEST1"}
drh28037572000-08-02 13:47:41 +000084 execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
drh982cef72000-05-30 16:27:03 +000085} {}
86
87
drhb24fcbe2000-05-29 23:30:50 +000088
89# Verify that we cannot make two tables with the same name
90#
drh1b6a71f2000-05-29 23:58:11 +000091do_test table-2.1 {
drh4cfa7932000-06-08 15:10:46 +000092 execsql {CREATE TABLE TEST2(one text)}
drh42b9d7c2005-08-13 00:56:27 +000093 catchsql {CREATE TABLE test2(two text default 'hi')}
drh1d37e282000-05-30 03:12:21 +000094} {1 {table test2 already exists}}
drhe4df0e72006-03-29 00:24:06 +000095do_test table-2.1.1 {
96 catchsql {CREATE TABLE "test2" (two)}
97} {1 {table "test2" already exists}}
drh1b6a71f2000-05-29 23:58:11 +000098do_test table-2.1b {
drhb24fcbe2000-05-29 23:30:50 +000099 set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
100 lappend v $msg
danielk1977d8123362004-06-12 09:25:12 +0000101} {1 {object name reserved for internal use: sqlite_master}}
drh1b6a71f2000-05-29 23:58:11 +0000102do_test table-2.1c {
drhb24fcbe2000-05-29 23:30:50 +0000103 db close
drhef4ac8f2004-06-19 00:16:31 +0000104 sqlite3 db test.db
drhb24fcbe2000-05-29 23:30:50 +0000105 set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
106 lappend v $msg
danielk1977d8123362004-06-12 09:25:12 +0000107} {1 {object name reserved for internal use: sqlite_master}}
drh1b6a71f2000-05-29 23:58:11 +0000108do_test table-2.1d {
drhfaa59552005-12-29 23:33:54 +0000109 catchsql {CREATE TABLE IF NOT EXISTS test2(x,y)}
110} {0 {}}
111do_test table-2.1e {
drha6370df2006-01-04 21:40:06 +0000112 catchsql {CREATE TABLE IF NOT EXISTS test2(x UNIQUE, y TEXT PRIMARY KEY)}
113} {0 {}}
114do_test table-2.1f {
drh28037572000-08-02 13:47:41 +0000115 execsql {DROP TABLE test2; SELECT name FROM sqlite_master WHERE type!='meta'}
drhb24fcbe2000-05-29 23:30:50 +0000116} {}
117
118# Verify that we cannot make a table with the same name as an index
119#
drhdcc581c2000-05-30 13:44:19 +0000120do_test table-2.2a {
drh8a1e5942009-04-28 15:43:45 +0000121 execsql {CREATE TABLE test2(one text)}
122 execsql {CREATE INDEX test3 ON test2(one)}
123 catchsql {CREATE TABLE test3(two text)}
drh1d37e282000-05-30 03:12:21 +0000124} {1 {there is already an index named test3}}
drh1b6a71f2000-05-29 23:58:11 +0000125do_test table-2.2b {
drhb24fcbe2000-05-29 23:30:50 +0000126 db close
drhef4ac8f2004-06-19 00:16:31 +0000127 sqlite3 db test.db
drhb24fcbe2000-05-29 23:30:50 +0000128 set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
129 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000130} {1 {there is already an index named test3}}
drh1b6a71f2000-05-29 23:58:11 +0000131do_test table-2.2c {
drh3fc190c2001-09-14 03:24:23 +0000132 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
133} {test2 test3}
134do_test table-2.2d {
drhb24fcbe2000-05-29 23:30:50 +0000135 execsql {DROP INDEX test3}
136 set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
137 lappend v $msg
138} {0 {}}
drh3fc190c2001-09-14 03:24:23 +0000139do_test table-2.2e {
drh28037572000-08-02 13:47:41 +0000140 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000141} {test2 test3}
drh3fc190c2001-09-14 03:24:23 +0000142do_test table-2.2f {
drhb24fcbe2000-05-29 23:30:50 +0000143 execsql {DROP TABLE test2; DROP TABLE test3}
drh28037572000-08-02 13:47:41 +0000144 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000145} {}
146
147# Create a table with many field names
148#
149set big_table \
150{CREATE TABLE big(
151 f1 varchar(20),
152 f2 char(10),
drhdcc581c2000-05-30 13:44:19 +0000153 f3 varchar(30) primary key,
drhb24fcbe2000-05-29 23:30:50 +0000154 f4 text,
155 f5 text,
156 f6 text,
157 f7 text,
158 f8 text,
159 f9 text,
160 f10 text,
161 f11 text,
162 f12 text,
163 f13 text,
164 f14 text,
165 f15 text,
166 f16 text,
167 f17 text,
168 f18 text,
169 f19 text,
170 f20 text
171)}
drh1b6a71f2000-05-29 23:58:11 +0000172do_test table-3.1 {
drhb24fcbe2000-05-29 23:30:50 +0000173 execsql $big_table
drhadbca9c2001-09-27 15:11:53 +0000174 execsql {SELECT sql FROM sqlite_master WHERE type=='table'}
drhb24fcbe2000-05-29 23:30:50 +0000175} \{$big_table\}
drh1b6a71f2000-05-29 23:58:11 +0000176do_test table-3.2 {
drhb24fcbe2000-05-29 23:30:50 +0000177 set v [catch {execsql {CREATE TABLE BIG(xyz foo)}} msg]
178 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000179} {1 {table BIG already exists}}
drh1b6a71f2000-05-29 23:58:11 +0000180do_test table-3.3 {
drhb24fcbe2000-05-29 23:30:50 +0000181 set v [catch {execsql {CREATE TABLE biG(xyz foo)}} msg]
182 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000183} {1 {table biG already exists}}
drh1b6a71f2000-05-29 23:58:11 +0000184do_test table-3.4 {
drhb24fcbe2000-05-29 23:30:50 +0000185 set v [catch {execsql {CREATE TABLE bIg(xyz foo)}} msg]
186 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000187} {1 {table bIg already exists}}
drh1b6a71f2000-05-29 23:58:11 +0000188do_test table-3.5 {
drhb24fcbe2000-05-29 23:30:50 +0000189 db close
drhef4ac8f2004-06-19 00:16:31 +0000190 sqlite3 db test.db
drhb24fcbe2000-05-29 23:30:50 +0000191 set v [catch {execsql {CREATE TABLE Big(xyz foo)}} msg]
192 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000193} {1 {table Big already exists}}
drh1b6a71f2000-05-29 23:58:11 +0000194do_test table-3.6 {
drhb24fcbe2000-05-29 23:30:50 +0000195 execsql {DROP TABLE big}
drh28037572000-08-02 13:47:41 +0000196 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drhb24fcbe2000-05-29 23:30:50 +0000197} {}
198
199# Try creating large numbers of tables
200#
201set r {}
202for {set i 1} {$i<=100} {incr i} {
drha9e99ae2002-08-13 23:02:57 +0000203 lappend r [format test%03d $i]
drhb24fcbe2000-05-29 23:30:50 +0000204}
drh1b6a71f2000-05-29 23:58:11 +0000205do_test table-4.1 {
drhb24fcbe2000-05-29 23:30:50 +0000206 for {set i 1} {$i<=100} {incr i} {
drha9e99ae2002-08-13 23:02:57 +0000207 set sql "CREATE TABLE [format test%03d $i] ("
drhb24fcbe2000-05-29 23:30:50 +0000208 for {set k 1} {$k<$i} {incr k} {
209 append sql "field$k text,"
210 }
211 append sql "last_field text)"
212 execsql $sql
213 }
drh28037572000-08-02 13:47:41 +0000214 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000215} $r
drh1b6a71f2000-05-29 23:58:11 +0000216do_test table-4.1b {
drhb24fcbe2000-05-29 23:30:50 +0000217 db close
drhef4ac8f2004-06-19 00:16:31 +0000218 sqlite3 db test.db
drh28037572000-08-02 13:47:41 +0000219 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000220} $r
221
drhc4a3c772001-04-04 11:48:57 +0000222# Drop the even numbered tables
drhb24fcbe2000-05-29 23:30:50 +0000223#
224set r {}
225for {set i 1} {$i<=100} {incr i 2} {
drha9e99ae2002-08-13 23:02:57 +0000226 lappend r [format test%03d $i]
drhb24fcbe2000-05-29 23:30:50 +0000227}
drh1b6a71f2000-05-29 23:58:11 +0000228do_test table-4.2 {
drhb24fcbe2000-05-29 23:30:50 +0000229 for {set i 2} {$i<=100} {incr i 2} {
drh428ae8c2003-01-04 16:48:09 +0000230 # if {$i==38} {execsql {pragma vdbe_trace=on}}
drha9e99ae2002-08-13 23:02:57 +0000231 set sql "DROP TABLE [format TEST%03d $i]"
drhb24fcbe2000-05-29 23:30:50 +0000232 execsql $sql
233 }
drh28037572000-08-02 13:47:41 +0000234 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000235} $r
drh3fc190c2001-09-14 03:24:23 +0000236#exit
drhb24fcbe2000-05-29 23:30:50 +0000237
238# Drop the odd number tables
239#
drh1b6a71f2000-05-29 23:58:11 +0000240do_test table-4.3 {
drhb24fcbe2000-05-29 23:30:50 +0000241 for {set i 1} {$i<=100} {incr i 2} {
drha9e99ae2002-08-13 23:02:57 +0000242 set sql "DROP TABLE [format test%03d $i]"
drhb24fcbe2000-05-29 23:30:50 +0000243 execsql $sql
244 }
drh28037572000-08-02 13:47:41 +0000245 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000246} {}
247
drh1b6a71f2000-05-29 23:58:11 +0000248# Try to drop a table that does not exist
249#
drha0733842005-12-29 01:11:36 +0000250do_test table-5.1.1 {
251 catchsql {DROP TABLE test009}
drha9e99ae2002-08-13 23:02:57 +0000252} {1 {no such table: test009}}
drha0733842005-12-29 01:11:36 +0000253do_test table-5.1.2 {
254 catchsql {DROP TABLE IF EXISTS test009}
255} {0 {}}
drh1b6a71f2000-05-29 23:58:11 +0000256
257# Try to drop sqlite_master
258#
259do_test table-5.2 {
drha0733842005-12-29 01:11:36 +0000260 catchsql {DROP TABLE IF EXISTS sqlite_master}
drh1d37e282000-05-30 03:12:21 +0000261} {1 {table sqlite_master may not be dropped}}
drh1b6a71f2000-05-29 23:58:11 +0000262
drh08ccfaa2011-10-07 23:52:25 +0000263# Dropping sqlite_statN tables is OK.
264#
265do_test table-5.2.1 {
266 db eval {
267 ANALYZE;
268 DROP TABLE IF EXISTS sqlite_stat1;
269 DROP TABLE IF EXISTS sqlite_stat2;
270 DROP TABLE IF EXISTS sqlite_stat3;
271 SELECT name FROM sqlite_master WHERE name GLOB 'sqlite_stat*';
272 }
273} {}
274
drh1b6a71f2000-05-29 23:58:11 +0000275# Make sure an EXPLAIN does not really create a new table
276#
277do_test table-5.3 {
drh6bf89572004-11-03 16:27:01 +0000278 ifcapable {explain} {
279 execsql {EXPLAIN CREATE TABLE test1(f1 int)}
280 }
drh28037572000-08-02 13:47:41 +0000281 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drh1b6a71f2000-05-29 23:58:11 +0000282} {}
283
284# Make sure an EXPLAIN does not really drop an existing table
285#
286do_test table-5.4 {
287 execsql {CREATE TABLE test1(f1 int)}
drh6bf89572004-11-03 16:27:01 +0000288 ifcapable {explain} {
289 execsql {EXPLAIN DROP TABLE test1}
290 }
drh28037572000-08-02 13:47:41 +0000291 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drh1b6a71f2000-05-29 23:58:11 +0000292} {test1}
293
drh4cfa7932000-06-08 15:10:46 +0000294# Create a table with a goofy name
295#
drh3fc190c2001-09-14 03:24:23 +0000296#do_test table-6.1 {
297# execsql {CREATE TABLE 'Spaces In This Name!'(x int)}
298# execsql {INSERT INTO 'spaces in this name!' VALUES(1)}
299# set list [glob -nocomplain testdb/spaces*.tbl]
300#} {testdb/spaces+in+this+name+.tbl}
drh4cfa7932000-06-08 15:10:46 +0000301
drhc4a3c772001-04-04 11:48:57 +0000302# Try using keywords as table names or column names.
303#
304do_test table-7.1 {
305 set v [catch {execsql {
306 CREATE TABLE weird(
307 desc text,
308 asc text,
drh6bf89572004-11-03 16:27:01 +0000309 key int,
drh17f71932002-02-21 12:01:27 +0000310 [14_vac] boolean,
311 fuzzy_dog_12 varchar(10),
drhd4007282001-04-12 23:21:58 +0000312 begin blob,
313 end clob
drhc4a3c772001-04-04 11:48:57 +0000314 )
315 }} msg]
316 lappend v $msg
317} {0 {}}
318do_test table-7.2 {
319 execsql {
drhd4007282001-04-12 23:21:58 +0000320 INSERT INTO weird VALUES('a','b',9,0,'xyz','hi','y''all');
drhc4a3c772001-04-04 11:48:57 +0000321 SELECT * FROM weird;
322 }
drhd4007282001-04-12 23:21:58 +0000323} {a b 9 0 xyz hi y'all}
drhc4a3c772001-04-04 11:48:57 +0000324do_test table-7.3 {
325 execsql2 {
326 SELECT * FROM weird;
327 }
drh6bf89572004-11-03 16:27:01 +0000328} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
danielk197778c2e6d2009-01-16 11:04:58 +0000329do_test table-7.3 {
330 execsql {
331 CREATE TABLE savepoint(release);
332 INSERT INTO savepoint(release) VALUES(10);
333 UPDATE savepoint SET release = 5;
334 SELECT release FROM savepoint;
335 }
336} {5}
drhc4a3c772001-04-04 11:48:57 +0000337
drh969fa7c2002-02-18 18:30:32 +0000338# Try out the CREATE TABLE AS syntax
339#
340do_test table-8.1 {
341 execsql2 {
342 CREATE TABLE t2 AS SELECT * FROM weird;
343 SELECT * FROM t2;
344 }
drh6bf89572004-11-03 16:27:01 +0000345} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
drh17f71932002-02-21 12:01:27 +0000346do_test table-8.1.1 {
347 execsql {
348 SELECT sql FROM sqlite_master WHERE name='t2';
349 }
350} {{CREATE TABLE t2(
drhc4a64fa2009-05-11 20:53:28 +0000351 "desc" TEXT,
352 "asc" TEXT,
353 "key" INT,
354 "14_vac" NUM,
355 fuzzy_dog_12 TEXT,
356 "begin",
357 "end" TEXT
drh17f71932002-02-21 12:01:27 +0000358)}}
drh969fa7c2002-02-18 18:30:32 +0000359do_test table-8.2 {
360 execsql {
drh234c39d2004-07-24 03:30:47 +0000361 CREATE TABLE "t3""xyz"(a,b,c);
362 INSERT INTO [t3"xyz] VALUES(1,2,3);
363 SELECT * FROM [t3"xyz];
drh969fa7c2002-02-18 18:30:32 +0000364 }
365} {1 2 3}
366do_test table-8.3 {
367 execsql2 {
drh234c39d2004-07-24 03:30:47 +0000368 CREATE TABLE [t4"abc] AS SELECT count(*) as cnt, max(b+c) FROM [t3"xyz];
369 SELECT * FROM [t4"abc];
drh969fa7c2002-02-18 18:30:32 +0000370 }
drh17f71932002-02-21 12:01:27 +0000371} {cnt 1 max(b+c) 5}
danielk197700e279d2004-06-21 07:36:32 +0000372
373# Update for v3: The declaration type of anything except a column is now a
374# NULL pointer, so the created table has no column types. (Changed result
drh234c39d2004-07-24 03:30:47 +0000375# from {{CREATE TABLE 't4"abc'(cnt NUMERIC,"max(b+c)" NUMERIC)}}).
drh17f71932002-02-21 12:01:27 +0000376do_test table-8.3.1 {
377 execsql {
drh234c39d2004-07-24 03:30:47 +0000378 SELECT sql FROM sqlite_master WHERE name='t4"abc'
drh17f71932002-02-21 12:01:27 +0000379 }
drh234c39d2004-07-24 03:30:47 +0000380} {{CREATE TABLE "t4""abc"(cnt,"max(b+c)")}}
danielk197753c0f742005-03-29 03:10:59 +0000381
382ifcapable tempdb {
383 do_test table-8.4 {
384 execsql2 {
385 CREATE TEMPORARY TABLE t5 AS SELECT count(*) AS [y'all] FROM [t3"xyz];
386 SELECT * FROM t5;
387 }
388 } {y'all 1}
389}
390
drh969fa7c2002-02-18 18:30:32 +0000391do_test table-8.5 {
392 db close
drhef4ac8f2004-06-19 00:16:31 +0000393 sqlite3 db test.db
drh969fa7c2002-02-18 18:30:32 +0000394 execsql2 {
drh234c39d2004-07-24 03:30:47 +0000395 SELECT * FROM [t4"abc];
drh969fa7c2002-02-18 18:30:32 +0000396 }
drh17f71932002-02-21 12:01:27 +0000397} {cnt 1 max(b+c) 5}
drh969fa7c2002-02-18 18:30:32 +0000398do_test table-8.6 {
399 execsql2 {
400 SELECT * FROM t2;
401 }
drh6bf89572004-11-03 16:27:01 +0000402} {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
drh969fa7c2002-02-18 18:30:32 +0000403do_test table-8.7 {
404 catchsql {
405 SELECT * FROM t5;
406 }
407} {1 {no such table: t5}}
drh17f71932002-02-21 12:01:27 +0000408do_test table-8.8 {
409 catchsql {
410 CREATE TABLE t5 AS SELECT * FROM no_such_table;
411 }
412} {1 {no such table: no_such_table}}
drh969fa7c2002-02-18 18:30:32 +0000413
danielk19771b870de2009-03-14 08:37:23 +0000414do_test table-8.9 {
415 execsql {
416 CREATE TABLE t10("col.1" [char.3]);
417 CREATE TABLE t11 AS SELECT * FROM t10;
418 SELECT sql FROM sqlite_master WHERE name = 't11';
419 }
drhc4a64fa2009-05-11 20:53:28 +0000420} {{CREATE TABLE t11("col.1" TEXT)}}
danielk19771b870de2009-03-14 08:37:23 +0000421do_test table-8.10 {
422 execsql {
423 CREATE TABLE t12(
424 a INTEGER,
425 b VARCHAR(10),
426 c VARCHAR(1,10),
427 d VARCHAR(+1,-10),
428 e VARCHAR (+1,-10),
429 f "VARCHAR (+1,-10, 5)",
430 g BIG INTEGER
431 );
432 CREATE TABLE t13 AS SELECT * FROM t12;
433 SELECT sql FROM sqlite_master WHERE name = 't13';
434 }
435} {{CREATE TABLE t13(
drhc4a64fa2009-05-11 20:53:28 +0000436 a INT,
437 b TEXT,
438 c TEXT,
439 d TEXT,
440 e TEXT,
441 f TEXT,
442 g INT
danielk19771b870de2009-03-14 08:37:23 +0000443)}}
444
drh97fc3d02002-05-22 21:27:03 +0000445# Make sure we cannot have duplicate column names within a table.
446#
447do_test table-9.1 {
448 catchsql {
449 CREATE TABLE t6(a,b,a);
450 }
451} {1 {duplicate column name: a}}
drhd8919672005-09-10 15:35:06 +0000452do_test table-9.2 {
453 catchsql {
454 CREATE TABLE t6(a varchar(100), b blob, a integer);
455 }
456} {1 {duplicate column name: a}}
drh97fc3d02002-05-22 21:27:03 +0000457
drh04738cb2002-06-02 18:19:00 +0000458# Check the foreign key syntax.
459#
drh6bf89572004-11-03 16:27:01 +0000460ifcapable {foreignkey} {
drh04738cb2002-06-02 18:19:00 +0000461do_test table-10.1 {
462 catchsql {
463 CREATE TABLE t6(a REFERENCES t4(a) NOT NULL);
464 INSERT INTO t6 VALUES(NULL);
465 }
drh483750b2003-01-29 18:46:51 +0000466} {1 {t6.a may not be NULL}}
drh04738cb2002-06-02 18:19:00 +0000467do_test table-10.2 {
468 catchsql {
469 DROP TABLE t6;
470 CREATE TABLE t6(a REFERENCES t4(a) MATCH PARTIAL);
471 }
472} {0 {}}
473do_test table-10.3 {
474 catchsql {
475 DROP TABLE t6;
476 CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON DELETE SET NULL NOT NULL);
477 }
478} {0 {}}
479do_test table-10.4 {
480 catchsql {
481 DROP TABLE t6;
482 CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON UPDATE SET DEFAULT DEFAULT 1);
483 }
484} {0 {}}
485do_test table-10.5 {
486 catchsql {
487 DROP TABLE t6;
488 CREATE TABLE t6(a NOT NULL NOT DEFERRABLE INITIALLY IMMEDIATE);
489 }
490} {0 {}}
491do_test table-10.6 {
492 catchsql {
493 DROP TABLE t6;
494 CREATE TABLE t6(a NOT NULL DEFERRABLE INITIALLY DEFERRED);
495 }
496} {0 {}}
497do_test table-10.7 {
498 catchsql {
499 DROP TABLE t6;
500 CREATE TABLE t6(a,
501 FOREIGN KEY (a) REFERENCES t4(b) DEFERRABLE INITIALLY DEFERRED
502 );
503 }
504} {0 {}}
505do_test table-10.8 {
506 catchsql {
507 DROP TABLE t6;
508 CREATE TABLE t6(a,b,c,
509 FOREIGN KEY (b,c) REFERENCES t4(x,y) MATCH PARTIAL
510 ON UPDATE SET NULL ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
511 );
512 }
513} {0 {}}
drhc2eef3b2002-08-31 18:53:06 +0000514do_test table-10.9 {
515 catchsql {
516 DROP TABLE t6;
517 CREATE TABLE t6(a,b,c,
518 FOREIGN KEY (b,c) REFERENCES t4(x)
519 );
520 }
521} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
522do_test table-10.10 {
523 catchsql {DROP TABLE t6}
524 catchsql {
525 CREATE TABLE t6(a,b,c,
526 FOREIGN KEY (b,c) REFERENCES t4(x,y,z)
527 );
528 }
529} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
530do_test table-10.11 {
531 catchsql {DROP TABLE t6}
532 catchsql {
533 CREATE TABLE t6(a,b, c REFERENCES t4(x,y));
534 }
535} {1 {foreign key on c should reference only one column of table t4}}
536do_test table-10.12 {
537 catchsql {DROP TABLE t6}
538 catchsql {
539 CREATE TABLE t6(a,b,c,
540 FOREIGN KEY (b,x) REFERENCES t4(x,y)
541 );
542 }
543} {1 {unknown column "x" in foreign key definition}}
544do_test table-10.13 {
545 catchsql {DROP TABLE t6}
546 catchsql {
547 CREATE TABLE t6(a,b,c,
548 FOREIGN KEY (x,b) REFERENCES t4(x,y)
549 );
550 }
551} {1 {unknown column "x" in foreign key definition}}
drh6bf89572004-11-03 16:27:01 +0000552} ;# endif foreignkey
drh04738cb2002-06-02 18:19:00 +0000553
danielk197735bb9d02004-05-24 12:55:54 +0000554# Test for the "typeof" function. More tests for the
555# typeof() function are found in bind.test and types.test.
drh38640e12002-07-05 21:42:36 +0000556#
557do_test table-11.1 {
558 execsql {
559 CREATE TABLE t7(
560 a integer primary key,
561 b number(5,10),
562 c character varying (8),
563 d VARCHAR(9),
564 e clob,
565 f BLOB,
566 g Text,
567 h
568 );
569 INSERT INTO t7(a) VALUES(1);
570 SELECT typeof(a), typeof(b), typeof(c), typeof(d),
571 typeof(e), typeof(f), typeof(g), typeof(h)
572 FROM t7 LIMIT 1;
573 }
danielk197735bb9d02004-05-24 12:55:54 +0000574} {integer null null null null null null null}
drh38640e12002-07-05 21:42:36 +0000575do_test table-11.2 {
576 execsql {
577 SELECT typeof(a+b), typeof(a||b), typeof(c+d), typeof(c||d)
578 FROM t7 LIMIT 1;
579 }
danielk197735bb9d02004-05-24 12:55:54 +0000580} {null null null null}
drh97fc3d02002-05-22 21:27:03 +0000581
danielk197700e279d2004-06-21 07:36:32 +0000582# Test that when creating a table using CREATE TABLE AS, column types are
583# assigned correctly for (SELECT ...) and 'x AS y' expressions.
584do_test table-12.1 {
danielk19773e8c37e2005-01-21 03:12:14 +0000585 ifcapable subquery {
586 execsql {
587 CREATE TABLE t8 AS SELECT b, h, a as i, (SELECT f FROM t7) as j FROM t7;
588 }
589 } else {
590 execsql {
591 CREATE TABLE t8 AS SELECT b, h, a as i, f as j FROM t7;
592 }
danielk197700e279d2004-06-21 07:36:32 +0000593 }
594} {}
595do_test table-12.2 {
596 execsql {
597 SELECT sql FROM sqlite_master WHERE tbl_name = 't8'
598 }
drhc4a64fa2009-05-11 20:53:28 +0000599} {{CREATE TABLE t8(b NUM,h,i INT,j)}}
danielk197700e279d2004-06-21 07:36:32 +0000600
danielk1977e6efa742004-11-10 11:55:10 +0000601#--------------------------------------------------------------------
602# Test cases table-13.*
603#
danielk19777977a172004-11-09 12:44:37 +0000604# Test the ability to have default values of CURRENT_TIME, CURRENT_DATE
605# and CURRENT_TIMESTAMP.
606#
607do_test table-13.1 {
608 execsql {
609 CREATE TABLE tablet8(
610 a integer primary key,
611 tm text DEFAULT CURRENT_TIME,
612 dt text DEFAULT CURRENT_DATE,
613 dttm text DEFAULT CURRENT_TIMESTAMP
614 );
615 SELECT * FROM tablet8;
616 }
617} {}
618set i 0
drhd0b26772010-05-03 19:20:46 +0000619unset -nocomplain date time seconds
drh9645d8d2006-09-01 15:49:05 +0000620foreach {date time seconds} {
621 1976-07-04 12:00:00 205329600
622 1994-04-16 14:00:00 766504800
623 2000-01-01 00:00:00 946684800
624 2003-12-31 12:34:56 1072874096
danielk19777977a172004-11-09 12:44:37 +0000625} {
626 incr i
drh9645d8d2006-09-01 15:49:05 +0000627 set sqlite_current_time $seconds
danielk19777977a172004-11-09 12:44:37 +0000628 do_test table-13.2.$i {
629 execsql "
630 INSERT INTO tablet8(a) VALUES($i);
631 SELECT tm, dt, dttm FROM tablet8 WHERE a=$i;
632 "
633 } [list $time $date [list $date $time]]
634}
635set sqlite_current_time 0
636
danielk1977e6efa742004-11-10 11:55:10 +0000637#--------------------------------------------------------------------
638# Test cases table-14.*
639#
640# Test that a table cannot be created or dropped while other virtual
641# machines are active. This is required because otherwise when in
642# auto-vacuum mode the btree-layer may need to move the root-pages of
643# a table for which there is an open cursor.
644#
drhb7af4452007-05-02 17:54:55 +0000645# 2007-05-02: A open btree cursor no longer blocks CREATE TABLE.
646# But DROP TABLE is still prohibited because we do not want to
647# delete a table out from under a running query.
648#
danielk1977e6efa742004-11-10 11:55:10 +0000649
danielk1977a21c6b62005-01-24 10:25:59 +0000650# db eval {
651# pragma vdbe_trace = 0;
652# }
danielk1977e6efa742004-11-10 11:55:10 +0000653# Try to create a table from within a callback:
drh251b0672004-11-23 22:16:39 +0000654unset -nocomplain result
danielk1977e6efa742004-11-10 11:55:10 +0000655do_test table-14.1 {
656 set rc [
657 catch {
658 db eval {SELECT * FROM tablet8 LIMIT 1} {} {
659 db eval {CREATE TABLE t9(a, b, c)}
660 }
661 } msg
662 ]
663 set result [list $rc $msg]
drhb7af4452007-05-02 17:54:55 +0000664} {0 {}}
danielk1977e6efa742004-11-10 11:55:10 +0000665
666# Try to drop a table from within a callback:
danielk19775a8f9372007-10-09 08:29:32 +0000667do_test table-14.2 {
danielk1977e6efa742004-11-10 11:55:10 +0000668 set rc [
669 catch {
670 db eval {SELECT * FROM tablet8 LIMIT 1} {} {
671 db eval {DROP TABLE t9;}
672 }
673 } msg
674 ]
675 set result [list $rc $msg]
676} {1 {database table is locked}}
677
danielk19775a8f9372007-10-09 08:29:32 +0000678ifcapable attach {
679 # Now attach a database and ensure that a table can be created in the
680 # attached database whilst in a callback from a query on the main database.
681 do_test table-14.3 {
mistachkinfda06be2011-08-02 00:57:34 +0000682 forcedelete test2.db
683 forcedelete test2.db-journal
danielk19775a8f9372007-10-09 08:29:32 +0000684 execsql {
685 ATTACH 'test2.db' as aux;
686 }
687 db eval {SELECT * FROM tablet8 LIMIT 1} {} {
688 db eval {CREATE TABLE aux.t1(a, b, c)}
689 }
690 } {}
691
692 # On the other hand, it should be impossible to drop a table when any VMs
693 # are active. This is because VerifyCookie instructions may have already
694 # been executed, and btree root-pages may not move after this (which a
695 # delete table might do).
696 do_test table-14.4 {
697 set rc [
698 catch {
699 db eval {SELECT * FROM tablet8 LIMIT 1} {} {
700 db eval {DROP TABLE aux.t1;}
701 }
702 } msg
703 ]
704 set result [list $rc $msg]
705 } {1 {database table is locked}}
706}
danielk1977e6efa742004-11-10 11:55:10 +0000707
danielk1977ae825582004-11-23 09:06:55 +0000708# Create and drop 2000 tables. This is to check that the balance_shallow()
709# routine works correctly on the sqlite_master table. At one point it
710# contained a bug that would prevent the right-child pointer of the
711# child page from being copied to the root page.
712#
713do_test table-15.1 {
714 execsql {BEGIN}
715 for {set i 0} {$i<2000} {incr i} {
716 execsql "CREATE TABLE tbl$i (a, b, c)"
717 }
718 execsql {COMMIT}
719} {}
720do_test table-15.2 {
721 execsql {BEGIN}
722 for {set i 0} {$i<2000} {incr i} {
723 execsql "DROP TABLE tbl$i"
724 }
725 execsql {COMMIT}
726} {}
727
drh348784e2000-05-29 20:41:49 +0000728finish_test