xref: /sqlite-3.40.0/test/temptable.test (revision ef4ac8f9)
1# 2001 October 7
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.
12#
13# This file implements tests for temporary tables and indices.
14#
15# $Id: temptable.test,v 1.14 2004/06/19 00:16:31 drh Exp $
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# Create an alternative connection to the database
21#
22do_test temptable-1.0 {
23  sqlite3 db2 ./test.db
24  set dummy {}
25} {}
26
27# Create a permanent table.
28#
29do_test temptable-1.1 {
30  execsql {CREATE TABLE t1(a,b,c);}
31  execsql {INSERT INTO t1 VALUES(1,2,3);}
32  execsql {SELECT * FROM t1}
33} {1 2 3}
34do_test temptable-1.2 {
35  catch {db2 eval {SELECT * FROM sqlite_master}}
36  db2 eval {SELECT * FROM t1}
37} {1 2 3}
38do_test temptable-1.3 {
39  execsql {SELECT name FROM sqlite_master}
40} {t1}
41do_test temptable-1.4 {
42  db2 eval {SELECT name FROM sqlite_master}
43} {t1}
44
45# Create a temporary table.  Verify that only one of the two
46# processes can see it.
47#
48do_test temptable-1.5 {
49  db2 eval {
50    CREATE TEMP TABLE t2(x,y,z);
51    INSERT INTO t2 VALUES(4,5,6);
52  }
53  db2 eval {SELECT * FROM t2}
54} {4 5 6}
55do_test temptable-1.6 {
56  catch {execsql {SELECT * FROM sqlite_master}}
57  catchsql {SELECT * FROM t2}
58} {1 {no such table: t2}}
59do_test temptable-1.7 {
60  catchsql {INSERT INTO t2 VALUES(8,9,0);}
61} {1 {no such table: t2}}
62do_test temptable-1.8 {
63  db2 eval {INSERT INTO t2 VALUES(8,9,0);}
64  db2 eval {SELECT * FROM t2 ORDER BY x}
65} {4 5 6 8 9 0}
66do_test temptable-1.9 {
67  db2 eval {DELETE FROM t2 WHERE x==8}
68  db2 eval {SELECT * FROM t2 ORDER BY x}
69} {4 5 6}
70do_test temptable-1.10 {
71  db2 eval {DELETE FROM t2}
72  db2 eval {SELECT * FROM t2}
73} {}
74do_test temptable-1.11 {
75  db2 eval {
76     INSERT INTO t2 VALUES(7,6,5);
77     INSERT INTO t2 VALUES(4,3,2);
78     SELECT * FROM t2 ORDER BY x;
79  }
80} {4 3 2 7 6 5}
81do_test temptable-1.12 {
82  db2 eval {DROP TABLE t2;}
83  set r [catch {db2 eval {SELECT * FROM t2}} msg]
84  lappend r $msg
85} {1 {no such table: t2}}
86
87# Make sure temporary tables work with transactions
88#
89do_test temptable-2.1 {
90  execsql {
91    BEGIN TRANSACTION;
92    CREATE TEMPORARY TABLE t2(x,y);
93    INSERT INTO t2 VALUES(1,2);
94    SELECT * FROM t2;
95  }
96} {1 2}
97do_test temptable-2.2 {
98  execsql {ROLLBACK}
99  catchsql {SELECT * FROM t2}
100} {1 {no such table: t2}}
101do_test temptable-2.3 {
102  execsql {
103    BEGIN TRANSACTION;
104    CREATE TEMPORARY TABLE t2(x,y);
105    INSERT INTO t2 VALUES(1,2);
106    SELECT * FROM t2;
107  }
108} {1 2}
109do_test temptable-2.4 {
110  execsql {COMMIT}
111  catchsql {SELECT * FROM t2}
112} {0 {1 2}}
113do_test temptable-2.5 {
114  set r [catch {db2 eval {SELECT * FROM t2}} msg]
115  lappend r $msg
116} {1 {no such table: t2}}
117
118# Make sure indices on temporary tables are also temporary.
119#
120do_test temptable-3.1 {
121  execsql {
122    CREATE INDEX i2 ON t2(x);
123    SELECT name FROM sqlite_master WHERE type='index';
124  }
125} {}
126do_test temptable-3.2 {
127  execsql {
128    SELECT y FROM t2 WHERE x=1;
129  }
130} {2}
131do_test temptable-3.3 {
132  execsql {
133    DROP INDEX i2;
134    SELECT y FROM t2 WHERE x=1;
135  }
136} {2}
137do_test temptable-3.4 {
138  execsql {
139    CREATE INDEX i2 ON t2(x);
140    DROP TABLE t2;
141  }
142  catchsql {DROP INDEX i2}
143} {1 {no such index: i2}}
144
145# Check for correct name collision processing. A name collision can
146# occur when process A creates a temporary table T then process B
147# creates a permanent table also named T.  The temp table in process A
148# hides the existance of the permanent table.
149#
150do_test temptable-4.1 {
151  execsql {
152    CREATE TEMP TABLE t2(x,y);
153    INSERT INTO t2 VALUES(10,20);
154    SELECT * FROM t2;
155  } db2
156} {10 20}
157do_test temptable-4.2 {
158  execsql {
159    CREATE TABLE t2(x,y,z);
160    INSERT INTO t2 VALUES(9,8,7);
161    SELECT * FROM t2;
162  }
163} {9 8 7}
164do_test temptable-4.3 {
165  catchsql {
166    SELECT * FROM t2;
167  } db2
168} {0 {10 20}}
169do_test temptable-4.4.1 {
170  catchsql {
171    SELECT * FROM temp.t2;
172  } db2
173} {0 {10 20}}
174do_test temptable-4.4.2 {
175  catchsql {
176    SELECT * FROM main.t2;
177  } db2
178} {1 {no such table: main.t2}}
179#do_test temptable-4.4.3 {
180#  catchsql {
181#    SELECT name FROM main.sqlite_master WHERE type='table';
182#  } db2
183#} {1 {database schema has changed}}
184do_test temptable-4.4.4 {
185  catchsql {
186    SELECT name FROM main.sqlite_master WHERE type='table';
187  } db2
188} {0 {t1 t2}}
189do_test temptable-4.4.5 {
190  catchsql {
191    SELECT * FROM main.t2;
192  } db2
193} {0 {9 8 7}}
194do_test temptable-4.4.6 {
195  # TEMP takes precedence over MAIN
196  catchsql {
197    SELECT * FROM t2;
198  } db2
199} {0 {10 20}}
200do_test temptable-4.5 {
201  catchsql {
202    DROP TABLE t2;     -- should drop TEMP
203    SELECT * FROM t2;  -- data should be from MAIN
204  } db2
205} {0 {9 8 7}}
206do_test temptable-4.6 {
207  db2 close
208  sqlite3 db2 ./test.db
209  catchsql {
210    SELECT * FROM t2;
211  } db2
212} {0 {9 8 7}}
213do_test temptable-4.7 {
214  catchsql {
215    DROP TABLE t2;
216    SELECT * FROM t2;
217  }
218} {1 {no such table: t2}}
219do_test temptable-4.8 {
220  db2 close
221  sqlite3 db2 ./test.db
222  execsql {
223    CREATE TEMP TABLE t2(x unique,y);
224    INSERT INTO t2 VALUES(1,2);
225    SELECT * FROM t2;
226  } db2
227} {1 2}
228do_test temptable-4.9 {
229  execsql {
230    CREATE TABLE t2(x unique, y);
231    INSERT INTO t2 VALUES(3,4);
232    SELECT * FROM t2;
233  }
234} {3 4}
235do_test temptable-4.10.1 {
236  catchsql {
237    SELECT * FROM t2;
238  } db2
239} {0 {1 2}}
240# Update: The schema is reloaded in test temptable-4.10.1. And tclsqlite.c
241#         handles it and retries the query anyway.
242# do_test temptable-4.10.2 {
243#   catchsql {
244#     SELECT name FROM sqlite_master WHERE type='table'
245#   } db2
246# } {1 {database schema has changed}}
247do_test temptable-4.10.3 {
248  catchsql {
249    SELECT name FROM sqlite_master WHERE type='table'
250  } db2
251} {0 {t1 t2}}
252do_test temptable-4.11 {
253  execsql {
254    SELECT * FROM t2;
255  } db2
256} {1 2}
257do_test temptable-4.12 {
258  execsql {
259    SELECT * FROM t2;
260  }
261} {3 4}
262do_test temptable-4.13 {
263  catchsql {
264    DROP TABLE t2;     -- drops TEMP.T2
265    SELECT * FROM t2;  -- uses MAIN.T2
266  } db2
267} {0 {3 4}}
268do_test temptable-4.14 {
269  execsql {
270    SELECT * FROM t2;
271  }
272} {3 4}
273do_test temptable-4.15 {
274  db2 close
275  sqlite3 db2 ./test.db
276  execsql {
277    SELECT * FROM t2;
278  } db2
279} {3 4}
280
281# Now create a temporary table in db2 and a permanent index in db.  The
282# temporary table in db2 should mask the name of the permanent index,
283# but the permanent index should still be accessible and should still
284# be updated when its corresponding table changes.
285#
286do_test temptable-5.1 {
287  execsql {
288    CREATE TEMP TABLE mask(a,b,c)
289  } db2
290  execsql {
291    CREATE INDEX mask ON t2(x);
292    SELECT * FROM t2;
293  }
294} {3 4}
295#do_test temptable-5.2 {
296#  catchsql {
297#    SELECT * FROM t2;
298#  } db2
299#} {1 {database schema has changed}}
300do_test temptable-5.3 {
301  catchsql {
302    SELECT * FROM t2;
303  } db2
304} {0 {3 4}}
305do_test temptable-5.4 {
306  execsql {
307    SELECT y FROM t2 WHERE x=3
308  }
309} {4}
310do_test temptable-5.5 {
311  execsql {
312    SELECT y FROM t2 WHERE x=3
313  } db2
314} {4}
315do_test temptable-5.6 {
316  execsql {
317    INSERT INTO t2 VALUES(1,2);
318    SELECT y FROM t2 WHERE x=1;
319  } db2
320} {2}
321do_test temptable-5.7 {
322  execsql {
323    SELECT y FROM t2 WHERE x=3
324  } db2
325} {4}
326do_test temptable-5.8 {
327  execsql {
328    SELECT y FROM t2 WHERE x=1;
329  }
330} {2}
331do_test temptable-5.9 {
332  execsql {
333    SELECT y FROM t2 WHERE x=3
334  }
335} {4}
336
337db2 close
338
339# Test for correct operation of read-only databases
340#
341do_test temptable-6.1 {
342  execsql {
343    CREATE TABLE t8(x);
344    INSERT INTO t8 VALUES('xyzzy');
345    SELECT * FROM t8;
346  }
347} {xyzzy}
348do_test temptable-6.2 {
349  db close
350  catch {file attributes test.db -permissions 0444}
351  catch {file attributes test.db -readonly 1}
352  sqlite3 db test.db
353  if {[file writable test.db]} {
354    error "Unable to make the database file test.db readonly - rerun this test as an unprivileged user"
355  }
356  execsql {
357    SELECT * FROM t8;
358  }
359} {xyzzy}
360do_test temptable-6.3 {
361  if {[file writable test.db]} {
362    error "Unable to make the database file test.db readonly - rerun this test as an unprivileged user"
363  }
364  catchsql {
365    CREATE TABLE t9(x,y);
366  }
367} {1 {attempt to write a readonly database}}
368do_test temptable-6.4 {
369  catchsql {
370    CREATE TEMP TABLE t9(x,y);
371  }
372} {0 {}}
373do_test temptable-6.5 {
374  catchsql {
375    INSERT INTO t9 VALUES(1,2);
376    SELECT * FROM t9;
377  }
378} {0 {1 2}}
379do_test temptable-6.6 {
380  if {[file writable test.db]} {
381    error "Unable to make the database file test.db readonly - rerun this test as an unprivileged user"
382  }
383  catchsql {
384    INSERT INTO t8 VALUES('hello');
385    SELECT * FROM t8;
386  }
387} {1 {attempt to write a readonly database}}
388do_test temptable-6.7 {
389  catchsql {
390    SELECT * FROM t8,t9;
391  }
392} {0 {xyzzy 1 2}}
393do_test temptable-6.8 {
394  db close
395  sqlite3 db test.db
396  catchsql {
397    SELECT * FROM t8,t9;
398  }
399} {1 {no such table: t9}}
400
401finish_test
402