xref: /sqlite-3.40.0/test/insert.test (revision bf57cfeb)
1b19a2bc6Sdrh# 2001 September 15
262c68191Sdrh#
3b19a2bc6Sdrh# The author disclaims copyright to this source code.  In place of
4b19a2bc6Sdrh# a legal notice, here is a blessing:
562c68191Sdrh#
6b19a2bc6Sdrh#    May you do good and not evil.
7b19a2bc6Sdrh#    May you find forgiveness for yourself and forgive others.
8b19a2bc6Sdrh#    May you share freely, never taking more than you give.
962c68191Sdrh#
1062c68191Sdrh#***********************************************************************
1162c68191Sdrh# This file implements regression tests for SQLite library.  The
1262c68191Sdrh# focus of this file is testing the INSERT statement.
1362c68191Sdrh#
14*bf57cfebSdanielk1977# $Id: insert.test,v 1.16 2004/05/11 09:50:02 danielk1977 Exp $
1562c68191Sdrh
1662c68191Sdrhset testdir [file dirname $argv0]
1762c68191Sdrhsource $testdir/tester.tcl
1862c68191Sdrh
1962c68191Sdrh# Try to insert into a non-existant table.
2062c68191Sdrh#
2162c68191Sdrhdo_test insert-1.1 {
2262c68191Sdrh  set v [catch {execsql {INSERT INTO test1 VALUES(1,2,3)}} msg]
2362c68191Sdrh  lappend v $msg
241d37e284Sdrh} {1 {no such table: test1}}
2562c68191Sdrh
2662c68191Sdrh# Try to insert into sqlite_master
2762c68191Sdrh#
2862c68191Sdrhdo_test insert-1.2 {
2962c68191Sdrh  set v [catch {execsql {INSERT INTO sqlite_master VALUES(1,2,3,4)}} msg]
3062c68191Sdrh  lappend v $msg
311d37e284Sdrh} {1 {table sqlite_master may not be modified}}
3262c68191Sdrh
3362c68191Sdrh# Try to insert the wrong number of entries.
3462c68191Sdrh#
3562c68191Sdrhdo_test insert-1.3 {
3662c68191Sdrh  execsql {CREATE TABLE test1(one int, two int, three int)}
3762c68191Sdrh  set v [catch {execsql {INSERT INTO test1 VALUES(1,2)}} msg]
3862c68191Sdrh  lappend v $msg
3962c68191Sdrh} {1 {table test1 has 3 columns but 2 values were supplied}}
4062c68191Sdrhdo_test insert-1.3b {
4162c68191Sdrh  set v [catch {execsql {INSERT INTO test1 VALUES(1,2,3,4)}} msg]
4262c68191Sdrh  lappend v $msg
4362c68191Sdrh} {1 {table test1 has 3 columns but 4 values were supplied}}
4462c68191Sdrhdo_test insert-1.3c {
4562c68191Sdrh  set v [catch {execsql {INSERT INTO test1(one,two) VALUES(1,2,3,4)}} msg]
4662c68191Sdrh  lappend v $msg
4762c68191Sdrh} {1 {4 values for 2 columns}}
4862c68191Sdrhdo_test insert-1.3d {
4962c68191Sdrh  set v [catch {execsql {INSERT INTO test1(one,two) VALUES(1)}} msg]
5062c68191Sdrh  lappend v $msg
5162c68191Sdrh} {1 {1 values for 2 columns}}
5262c68191Sdrh
5362c68191Sdrh# Try to insert into a non-existant column of a table.
5462c68191Sdrh#
5562c68191Sdrhdo_test insert-1.4 {
5662c68191Sdrh  set v [catch {execsql {INSERT INTO test1(one,four) VALUES(1,2)}} msg]
5762c68191Sdrh  lappend v $msg
5862c68191Sdrh} {1 {table test1 has no column named four}}
5962c68191Sdrh
6062c68191Sdrh# Make sure the inserts actually happen
6162c68191Sdrh#
6262c68191Sdrhdo_test insert-1.5 {
6362c68191Sdrh  execsql {INSERT INTO test1 VALUES(1,2,3)}
6462c68191Sdrh  execsql {SELECT * FROM test1}
6562c68191Sdrh} {1 2 3}
6662c68191Sdrhdo_test insert-1.5b {
6762c68191Sdrh  execsql {INSERT INTO test1 VALUES(4,5,6)}
6862c68191Sdrh  execsql {SELECT * FROM test1 ORDER BY one}
6962c68191Sdrh} {1 2 3 4 5 6}
7062c68191Sdrhdo_test insert-1.5c {
7162c68191Sdrh  execsql {INSERT INTO test1 VALUES(7,8,9)}
7262c68191Sdrh  execsql {SELECT * FROM test1 ORDER BY one}
7362c68191Sdrh} {1 2 3 4 5 6 7 8 9}
7462c68191Sdrh
7562c68191Sdrhdo_test insert-1.6 {
7662c68191Sdrh  execsql {DELETE FROM test1}
7762c68191Sdrh  execsql {INSERT INTO test1(one,two) VALUES(1,2)}
7862c68191Sdrh  execsql {SELECT * FROM test1 ORDER BY one}
7962c68191Sdrh} {1 2 {}}
8062c68191Sdrhdo_test insert-1.6b {
8162c68191Sdrh  execsql {INSERT INTO test1(two,three) VALUES(5,6)}
8262c68191Sdrh  execsql {SELECT * FROM test1 ORDER BY one}
8362c68191Sdrh} {{} 5 6 1 2 {}}
8462c68191Sdrhdo_test insert-1.6c {
8562c68191Sdrh  execsql {INSERT INTO test1(three,one) VALUES(7,8)}
8662c68191Sdrh  execsql {SELECT * FROM test1 ORDER BY one}
8762c68191Sdrh} {{} 5 6 1 2 {} 8 {} 7}
8862c68191Sdrh
897020f651Sdrh# A table to use for testing default values
907020f651Sdrh#
91c4a3c779Sdrhdo_test insert-2.1 {
927020f651Sdrh  execsql {
937020f651Sdrh    CREATE TABLE test2(
94c4a3c779Sdrh      f1 int default -111,
95c4a3c779Sdrh      f2 real default +4.32,
96c4a3c779Sdrh      f3 int default +222,
97c4a3c779Sdrh      f4 int default 7.89
98c4a3c779Sdrh    )
99c4a3c779Sdrh  }
100c4a3c779Sdrh  execsql {SELECT * from test2}
101c4a3c779Sdrh} {}
102c4a3c779Sdrhdo_test insert-2.2 {
103c4a3c779Sdrh  execsql {INSERT INTO test2(f1,f3) VALUES(+10,-10)}
104c4a3c779Sdrh  execsql {SELECT * FROM test2}
105c4a3c779Sdrh} {10 4.32 -10 7.89}
106c4a3c779Sdrhdo_test insert-2.3 {
107c4a3c779Sdrh  execsql {INSERT INTO test2(f2,f4) VALUES(1.23,-3.45)}
108c4a3c779Sdrh  execsql {SELECT * FROM test2 WHERE f1==-111}
109c4a3c779Sdrh} {-111 1.23 222 -3.45}
110c4a3c779Sdrhdo_test insert-2.4 {
111c4a3c779Sdrh  execsql {INSERT INTO test2(f1,f2,f4) VALUES(77,+1.23,3.45)}
112c4a3c779Sdrh  execsql {SELECT * FROM test2 WHERE f1==77}
113c4a3c779Sdrh} {77 1.23 222 3.45}
114c4a3c779Sdrhdo_test insert-2.10 {
115c4a3c779Sdrh  execsql {
116c4a3c779Sdrh    DROP TABLE test2;
117c4a3c779Sdrh    CREATE TABLE test2(
1187020f651Sdrh      f1 int default 111,
1197020f651Sdrh      f2 real default -4.32,
1207020f651Sdrh      f3 text default hi,
1217020f651Sdrh      f4 text default 'abc-123',
1227020f651Sdrh      f5 varchar(10)
1237020f651Sdrh    )
1247020f651Sdrh  }
1257020f651Sdrh  execsql {SELECT * from test2}
1267020f651Sdrh} {}
127c4a3c779Sdrhdo_test insert-2.11 {
1287020f651Sdrh  execsql {INSERT INTO test2(f2,f4) VALUES(-2.22,'hi!')}
1297020f651Sdrh  execsql {SELECT * FROM test2}
1307020f651Sdrh} {111 -2.22 hi hi! {}}
131c4a3c779Sdrhdo_test insert-2.12 {
1327020f651Sdrh  execsql {INSERT INTO test2(f1,f5) VALUES(1,'xyzzy')}
1337020f651Sdrh  execsql {SELECT * FROM test2 ORDER BY f1}
1347020f651Sdrh} {1 -4.32 hi abc-123 xyzzy 111 -2.22 hi hi! {}}
1357020f651Sdrh
1367020f651Sdrh# Do additional inserts with default values, but this time
1377020f651Sdrh# on a table that has indices.  In particular we want to verify
1387020f651Sdrh# that the correct default values are inserted into the indices.
1397020f651Sdrh#
1407020f651Sdrhdo_test insert-3.1 {
1415974a30fSdrh  execsql {
1425974a30fSdrh    DELETE FROM test2;
1435974a30fSdrh    CREATE INDEX index9 ON test2(f1,f2);
1445974a30fSdrh    CREATE INDEX indext ON test2(f4,f5);
1455974a30fSdrh    SELECT * from test2;
1465974a30fSdrh  }
1477020f651Sdrh} {}
1487020f651Sdrhdo_test insert-3.2 {
1497020f651Sdrh  execsql {INSERT INTO test2(f2,f4) VALUES(-3.33,'hum')}
1507020f651Sdrh  execsql {SELECT * FROM test2 WHERE f1=111 AND f2=-3.33}
1517020f651Sdrh} {111 -3.33 hi hum {}}
1527020f651Sdrhdo_test insert-3.3 {
1537020f651Sdrh  execsql {INSERT INTO test2(f1,f2,f5) VALUES(22,-4.44,'wham')}
1547020f651Sdrh  execsql {SELECT * FROM test2 WHERE f1=111 AND f2=-3.33}
1557020f651Sdrh} {111 -3.33 hi hum {}}
1567020f651Sdrhdo_test insert-3.4 {
1577020f651Sdrh  execsql {SELECT * FROM test2 WHERE f1=22 AND f2=-4.44}
1587020f651Sdrh} {22 -4.44 hi abc-123 wham}
1592150432eSdrhintegrity_check insert-3.5
16024e97df9Sdrh
161adbe353fSdrh# Test of expressions in the VALUES clause
162adbe353fSdrh#
163e64e7b20Sdrhdo_test insert-4.1 {
164e64e7b20Sdrh  execsql {
165e64e7b20Sdrh    CREATE TABLE t3(a,b,c);
166e64e7b20Sdrh    INSERT INTO t3 VALUES(1+2+3,4,5);
167e64e7b20Sdrh    SELECT * FROM t3;
168e64e7b20Sdrh  }
169e64e7b20Sdrh} {6 4 5}
170e64e7b20Sdrhdo_test insert-4.2 {
171e64e7b20Sdrh  execsql {
172e64e7b20Sdrh    INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1,5,6);
173e64e7b20Sdrh    SELECT * FROM t3 ORDER BY a;
174e64e7b20Sdrh  }
175e64e7b20Sdrh} {6 4 5 7 5 6}
176e64e7b20Sdrhdo_test insert-4.3 {
177e64e7b20Sdrh  catchsql {
178e64e7b20Sdrh    INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1,t3.a,6);
179e64e7b20Sdrh    SELECT * FROM t3 ORDER BY a;
180e64e7b20Sdrh  }
181e64e7b20Sdrh} {1 {no such column: t3.a}}
182e64e7b20Sdrhdo_test insert-4.4 {
183e64e7b20Sdrh  execsql {
184e64e7b20Sdrh    INSERT INTO t3 VALUES((SELECT b FROM t3 WHERE a=0),6,7);
185e64e7b20Sdrh    SELECT * FROM t3 ORDER BY a;
186e64e7b20Sdrh  }
187e64e7b20Sdrh} {{} 6 7 6 4 5 7 5 6}
188e64e7b20Sdrhdo_test insert-4.5 {
189e64e7b20Sdrh  execsql {
190e64e7b20Sdrh    SELECT b,c FROM t3 WHERE a IS NULL;
191e64e7b20Sdrh  }
192e64e7b20Sdrh} {6 7}
193adbe353fSdrhdo_test insert-4.6 {
194adbe353fSdrh  catchsql {
195adbe353fSdrh    INSERT INTO t3 VALUES(notafunc(2,3),2,3);
196adbe353fSdrh  }
197adbe353fSdrh} {1 {no such function: notafunc}}
198adbe353fSdrhdo_test insert-4.7 {
199adbe353fSdrh  execsql {
200adbe353fSdrh    INSERT INTO t3 VALUES(min(1,2,3),max(1,2,3),99);
201adbe353fSdrh    SELECT * FROM t3 WHERE c=99;
202adbe353fSdrh  }
203adbe353fSdrh} {1 3 99}
204adbe353fSdrh
205048c530cSdrh# Test the ability to insert from a temporary table into itself.
206048c530cSdrh# Ticket #275.
207048c530cSdrh#
208048c530cSdrhdo_test insert-5.1 {
209048c530cSdrh  execsql {
210048c530cSdrh    CREATE TEMP TABLE t4(x);
211048c530cSdrh    INSERT INTO t4 VALUES(1);
212048c530cSdrh    SELECT * FROM t4;
213048c530cSdrh  }
214048c530cSdrh} {1}
215048c530cSdrhdo_test insert-5.2 {
216048c530cSdrh  execsql {
217048c530cSdrh    INSERT INTO t4 SELECT x+1 FROM t4;
218048c530cSdrh    SELECT * FROM t4;
219048c530cSdrh  }
220048c530cSdrh} {1 2}
221048c530cSdrhdo_test insert-5.3 {
222048c530cSdrh  # verify that a temporary table is used to copy t4 to t4
223048c530cSdrh  set x [execsql {
224048c530cSdrh    EXPLAIN INSERT INTO t4 SELECT x+2 FROM t4;
225048c530cSdrh  }]
226048c530cSdrh  expr {[lsearch $x OpenTemp]>0}
227048c530cSdrh} {1}
228*bf57cfebSdanielk1977
229048c530cSdrhdo_test insert-5.4 {
230048c530cSdrh  # Verify that table "test1" begins on page 3.  This should be the same
231048c530cSdrh  # page number used by "t4" above.
232*bf57cfebSdanielk1977  #
233*bf57cfebSdanielk1977  # Update for v3 - the first table now begins on page 2 of each file, not 3.
234048c530cSdrh  execsql {
235048c530cSdrh    SELECT rootpage FROM sqlite_master WHERE name='test1';
236048c530cSdrh  }
237*bf57cfebSdanielk1977} {2}
238048c530cSdrhdo_test insert-5.5 {
239048c530cSdrh  # Verify that "t4" begins on page 3.
240*bf57cfebSdanielk1977  #
241*bf57cfebSdanielk1977  # Update for v3 - the first table now begins on page 2 of each file, not 3.
242048c530cSdrh  execsql {
243048c530cSdrh    SELECT rootpage FROM sqlite_temp_master WHERE name='t4';
244048c530cSdrh  }
245*bf57cfebSdanielk1977} {2}
246048c530cSdrhdo_test insert-5.6 {
247048c530cSdrh  # This should not use an intermediate temporary table.
248048c530cSdrh  execsql {
249048c530cSdrh    INSERT INTO t4 SELECT one FROM test1 WHERE three=7;
250048c530cSdrh    SELECT * FROM t4
251048c530cSdrh  }
252048c530cSdrh} {1 2 8}
253048c530cSdrhdo_test insert-5.7 {
254048c530cSdrh  # verify that no temporary table is used to copy test1 to t4
255048c530cSdrh  set x [execsql {
256048c530cSdrh    EXPLAIN INSERT INTO t4 SELECT one FROM test1;
257048c530cSdrh  }]
258048c530cSdrh  expr {[lsearch $x OpenTemp]>0}
259048c530cSdrh} {0}
260048c530cSdrh
2615383ae5cSdrh# Ticket #334:  REPLACE statement corrupting indices.
2625383ae5cSdrh#
2635383ae5cSdrhdo_test insert-6.1 {
2645383ae5cSdrh  execsql {
2655383ae5cSdrh    CREATE TABLE t1(a INTEGER PRIMARY KEY, b UNIQUE);
2665383ae5cSdrh    INSERT INTO t1 VALUES(1,2);
2675383ae5cSdrh    INSERT INTO t1 VALUES(2,3);
2685383ae5cSdrh    SELECT b FROM t1 WHERE b=2;
2695383ae5cSdrh  }
2705383ae5cSdrh} {2}
2715383ae5cSdrhdo_test insert-6.2 {
2725383ae5cSdrh  execsql {
2735383ae5cSdrh    REPLACE INTO t1 VALUES(1,4);
2745383ae5cSdrh    SELECT b FROM t1 WHERE b=2;
2755383ae5cSdrh  }
2765383ae5cSdrh} {}
2777d02cb73Sdrhdo_test insert-6.3 {
2787d02cb73Sdrh  execsql {
2797d02cb73Sdrh    UPDATE OR REPLACE t1 SET a=2 WHERE b=4;
2807d02cb73Sdrh    SELECT * FROM t1 WHERE b=4;
2817d02cb73Sdrh  }
2827d02cb73Sdrh} {2 4}
2837d02cb73Sdrhdo_test insert-6.4 {
2847d02cb73Sdrh  execsql {
2857d02cb73Sdrh    SELECT * FROM t1 WHERE b=3;
2867d02cb73Sdrh  }
2877d02cb73Sdrh} {}
2887020f651Sdrh
289ed717fe3Sdrhintegrity_check insert-99.0
290ed717fe3Sdrh
29162c68191Sdrhfinish_test
292