File: table.test

package info (click to toggle)
sqlite 2.8.17-2
  • links: PTS
  • area: main
  • in suites: etch, etch-m68k
  • size: 4,588 kB
  • ctags: 2,670
  • sloc: ansic: 32,402; tcl: 10,821; sh: 8,214; yacc: 677; makefile: 360; awk: 62
file content (503 lines) | stat: -rw-r--r-- 12,441 bytes parent folder | download | duplicates (8)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
# 2001 September 15
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this file is testing the CREATE TABLE statement.
#
# $Id: table.test,v 1.22 2003/01/29 18:46:54 drh Exp $

set testdir [file dirname $argv0]
source $testdir/tester.tcl

# Create a basic table and verify it is added to sqlite_master
#
do_test table-1.1 {
  execsql {
    CREATE TABLE test1 (
      one varchar(10),
      two text
    )
  }
  execsql {
    SELECT sql FROM sqlite_master WHERE type!='meta'
  }
} {{CREATE TABLE test1 (
      one varchar(10),
      two text
    )}}


# Verify the other fields of the sqlite_master file.
#
do_test table-1.3 {
  execsql {SELECT name, tbl_name, type FROM sqlite_master WHERE type!='meta'}
} {test1 test1 table}

# Close and reopen the database.  Verify that everything is
# still the same.
#
do_test table-1.4 {
  db close
  sqlite db test.db
  execsql {SELECT name, tbl_name, type from sqlite_master WHERE type!='meta'}
} {test1 test1 table}

# Drop the database and make sure it disappears.
#
do_test table-1.5 {
  execsql {DROP TABLE test1}
  execsql {SELECT * FROM sqlite_master WHERE type!='meta'}
} {}

# Close and reopen the database.  Verify that the table is
# still gone.
#
do_test table-1.6 {
  db close
  sqlite db test.db
  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
} {}

# Repeat the above steps, but this time quote the table name.
#
do_test table-1.10 {
  execsql {CREATE TABLE "create" (f1 int)}
  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
} {create}
do_test table-1.11 {
  execsql {DROP TABLE "create"}
  execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
} {}
do_test table-1.12 {
  execsql {CREATE TABLE test1("f1 ho" int)}
  execsql {SELECT name as "X" FROM sqlite_master WHERE type!='meta'}
} {test1}
do_test table-1.13 {
  execsql {DROP TABLE "TEST1"}
  execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'}
} {}



# Verify that we cannot make two tables with the same name
#
do_test table-2.1 {
  execsql {CREATE TABLE TEST2(one text)}
  set v [catch {execsql {CREATE TABLE test2(two text)}} msg]
  lappend v $msg
} {1 {table test2 already exists}}
do_test table-2.1b {
  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
  lappend v $msg
} {1 {table sqlite_master already exists}}
do_test table-2.1c {
  db close
  sqlite db test.db
  set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg]
  lappend v $msg
} {1 {table sqlite_master already exists}}
do_test table-2.1d {
  execsql {DROP TABLE test2; SELECT name FROM sqlite_master WHERE type!='meta'}
} {}

# Verify that we cannot make a table with the same name as an index
#
do_test table-2.2a {
  execsql {CREATE TABLE test2(one text); CREATE INDEX test3 ON test2(one)}
  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
  lappend v $msg
} {1 {there is already an index named test3}}
do_test table-2.2b {
  db close
  sqlite db test.db
  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
  lappend v $msg
} {1 {there is already an index named test3}}
do_test table-2.2c {
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} {test2 test3}
do_test table-2.2d {
  execsql {DROP INDEX test3}
  set v [catch {execsql {CREATE TABLE test3(two text)}} msg]
  lappend v $msg
} {0 {}}
do_test table-2.2e {
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} {test2 test3}
do_test table-2.2f {
  execsql {DROP TABLE test2; DROP TABLE test3}
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} {}

# Create a table with many field names
#
set big_table \
{CREATE TABLE big(
  f1 varchar(20),
  f2 char(10),
  f3 varchar(30) primary key,
  f4 text,
  f5 text,
  f6 text,
  f7 text,
  f8 text,
  f9 text,
  f10 text,
  f11 text,
  f12 text,
  f13 text,
  f14 text,
  f15 text,
  f16 text,
  f17 text,
  f18 text,
  f19 text,
  f20 text
)}
do_test table-3.1 {
  execsql $big_table
  execsql {SELECT sql FROM sqlite_master WHERE type=='table'}
} \{$big_table\}
do_test table-3.2 {
  set v [catch {execsql {CREATE TABLE BIG(xyz foo)}} msg]
  lappend v $msg
} {1 {table BIG already exists}}
do_test table-3.3 {
  set v [catch {execsql {CREATE TABLE biG(xyz foo)}} msg]
  lappend v $msg
} {1 {table biG already exists}}
do_test table-3.4 {
  set v [catch {execsql {CREATE TABLE bIg(xyz foo)}} msg]
  lappend v $msg
} {1 {table bIg already exists}}
do_test table-3.5 {
  db close
  sqlite db test.db
  set v [catch {execsql {CREATE TABLE Big(xyz foo)}} msg]
  lappend v $msg
} {1 {table Big already exists}}
do_test table-3.6 {
  execsql {DROP TABLE big}
  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
} {}

# Try creating large numbers of tables
#
set r {}
for {set i 1} {$i<=100} {incr i} {
  lappend r [format test%03d $i]
}
do_test table-4.1 {
  for {set i 1} {$i<=100} {incr i} {
    set sql "CREATE TABLE [format test%03d $i] ("
    for {set k 1} {$k<$i} {incr k} {
      append sql "field$k text,"
    }
    append sql "last_field text)"
    execsql $sql
  }
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} $r
do_test table-4.1b {
  db close
  sqlite db test.db
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} $r

# Drop the even numbered tables
#
set r {}
for {set i 1} {$i<=100} {incr i 2} {
  lappend r [format test%03d $i]
}
do_test table-4.2 {
  for {set i 2} {$i<=100} {incr i 2} {
    # if {$i==38} {execsql {pragma vdbe_trace=on}}
    set sql "DROP TABLE [format TEST%03d $i]"
    execsql $sql
  }
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} $r
#exit

# Drop the odd number tables
#
do_test table-4.3 {
  for {set i 1} {$i<=100} {incr i 2} {
    set sql "DROP TABLE [format test%03d $i]"
    execsql $sql
  }
  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
} {}

# Try to drop a table that does not exist
#
do_test table-5.1 {
  set v [catch {execsql {DROP TABLE test009}} msg]
  lappend v $msg
} {1 {no such table: test009}}

# Try to drop sqlite_master
#
do_test table-5.2 {
  set v [catch {execsql {DROP TABLE sqlite_master}} msg]
  lappend v $msg
} {1 {table sqlite_master may not be dropped}}

# Make sure an EXPLAIN does not really create a new table
#
do_test table-5.3 {
  execsql {EXPLAIN CREATE TABLE test1(f1 int)}
  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
} {}

# Make sure an EXPLAIN does not really drop an existing table
#
do_test table-5.4 {
  execsql {CREATE TABLE test1(f1 int)}
  execsql {EXPLAIN DROP TABLE test1}
  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
} {test1}

# Create a table with a goofy name
#
#do_test table-6.1 {
#  execsql {CREATE TABLE 'Spaces In This Name!'(x int)}
#  execsql {INSERT INTO 'spaces in this name!' VALUES(1)}
#  set list [glob -nocomplain testdb/spaces*.tbl]
#} {testdb/spaces+in+this+name+.tbl}

# Try using keywords as table names or column names.
# 
do_test table-7.1 {
  set v [catch {execsql {
    CREATE TABLE weird(
      desc text,
      asc text,
      explain int,
      [14_vac] boolean,
      fuzzy_dog_12 varchar(10),
      begin blob,
      end clob
    )
  }} msg]
  lappend v $msg
} {0 {}}
do_test table-7.2 {
  execsql {
    INSERT INTO weird VALUES('a','b',9,0,'xyz','hi','y''all');
    SELECT * FROM weird;
  }
} {a b 9 0 xyz hi y'all}
do_test table-7.3 {
  execsql2 {
    SELECT * FROM weird;
  }
} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}

# Try out the CREATE TABLE AS syntax
#
do_test table-8.1 {
  execsql2 {
    CREATE TABLE t2 AS SELECT * FROM weird;
    SELECT * FROM t2;
  }
} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
do_test table-8.1.1 {
  execsql {
    SELECT sql FROM sqlite_master WHERE name='t2';
  }
} {{CREATE TABLE t2(
  'desc',
  'asc',
  'explain',
  '14_vac',
  fuzzy_dog_12,
  'begin',
  'end'
)}}
do_test table-8.2 {
  execsql {
    CREATE TABLE 't3''xyz'(a,b,c);
    INSERT INTO [t3'xyz] VALUES(1,2,3);
    SELECT * FROM [t3'xyz];
  }
} {1 2 3}
do_test table-8.3 {
  execsql2 {
    CREATE TABLE [t4'abc] AS SELECT count(*) as cnt, max(b+c) FROM [t3'xyz];
    SELECT * FROM [t4'abc];
  }
} {cnt 1 max(b+c) 5}
do_test table-8.3.1 {
  execsql {
    SELECT sql FROM sqlite_master WHERE name='t4''abc'
  }
} {{CREATE TABLE 't4''abc'(cnt,'max(b+c)')}}
do_test table-8.4 {
  execsql2 {
    CREATE TEMPORARY TABLE t5 AS SELECT count(*) AS [y'all] FROM [t3'xyz];
    SELECT * FROM t5;
  }
} {y'all 1}
do_test table-8.5 {
  db close
  sqlite db test.db
  execsql2 {
    SELECT * FROM [t4'abc];
  }
} {cnt 1 max(b+c) 5}
do_test table-8.6 {
  execsql2 {
    SELECT * FROM t2;
  }
} {desc a asc b explain 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all}
do_test table-8.7 {
  catchsql {
    SELECT * FROM t5;
  }
} {1 {no such table: t5}}
do_test table-8.8 {
  catchsql {
    CREATE TABLE t5 AS SELECT * FROM no_such_table;
  }
} {1 {no such table: no_such_table}}

# Make sure we cannot have duplicate column names within a table.
#
do_test table-9.1 {
  catchsql {
    CREATE TABLE t6(a,b,a);
  }
} {1 {duplicate column name: a}}

# Check the foreign key syntax.
#
do_test table-10.1 {
  catchsql {
    CREATE TABLE t6(a REFERENCES t4(a) NOT NULL);
    INSERT INTO t6 VALUES(NULL);
  }
} {1 {t6.a may not be NULL}}
do_test table-10.2 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a REFERENCES t4(a) MATCH PARTIAL);
  }
} {0 {}}
do_test table-10.3 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON DELETE SET NULL NOT NULL);
  }
} {0 {}}
do_test table-10.4 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON UPDATE SET DEFAULT DEFAULT 1);
  }
} {0 {}}
do_test table-10.5 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a NOT NULL NOT DEFERRABLE INITIALLY IMMEDIATE);
  }
} {0 {}}
do_test table-10.6 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a NOT NULL DEFERRABLE INITIALLY DEFERRED);
  }
} {0 {}}
do_test table-10.7 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a,
      FOREIGN KEY (a) REFERENCES t4(b) DEFERRABLE INITIALLY DEFERRED
    );
  }
} {0 {}}
do_test table-10.8 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a,b,c,
      FOREIGN KEY (b,c) REFERENCES t4(x,y) MATCH PARTIAL
        ON UPDATE SET NULL ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED
    );
  }
} {0 {}}
do_test table-10.9 {
  catchsql {
    DROP TABLE t6;
    CREATE TABLE t6(a,b,c,
      FOREIGN KEY (b,c) REFERENCES t4(x)
    );
  }
} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
do_test table-10.10 {
  catchsql {DROP TABLE t6}
  catchsql {
    CREATE TABLE t6(a,b,c,
      FOREIGN KEY (b,c) REFERENCES t4(x,y,z)
    );
  }
} {1 {number of columns in foreign key does not match the number of columns in the referenced table}}
do_test table-10.11 {
  catchsql {DROP TABLE t6}
  catchsql {
    CREATE TABLE t6(a,b, c REFERENCES t4(x,y));
  }
} {1 {foreign key on c should reference only one column of table t4}}
do_test table-10.12 {
  catchsql {DROP TABLE t6}
  catchsql {
    CREATE TABLE t6(a,b,c,
      FOREIGN KEY (b,x) REFERENCES t4(x,y)
    );
  }
} {1 {unknown column "x" in foreign key definition}}
do_test table-10.13 {
  catchsql {DROP TABLE t6}
  catchsql {
    CREATE TABLE t6(a,b,c,
      FOREIGN KEY (x,b) REFERENCES t4(x,y)
    );
  }
} {1 {unknown column "x" in foreign key definition}}


# Test for the "typeof" function.
#
do_test table-11.1 {
  execsql {
    CREATE TABLE t7(
       a integer primary key,
       b number(5,10),
       c character varying (8),
       d VARCHAR(9),
       e clob,
       f BLOB,
       g Text,
       h
    );
    INSERT INTO t7(a) VALUES(1);
    SELECT typeof(a), typeof(b), typeof(c), typeof(d),
           typeof(e), typeof(f), typeof(g), typeof(h)
    FROM t7 LIMIT 1;
  }
} {numeric numeric text text text text text numeric}
do_test table-11.2 {
  execsql {
    SELECT typeof(a+b), typeof(a||b), typeof(c+d), typeof(c||d)
    FROM t7 LIMIT 1;
  }
} {numeric text numeric text}

finish_test