xref: /sqlite-3.40.0/test/insert2.test (revision 4b79bde7)
1b19a2bc6Sdrh# 2001 September 15
25974a30fSdrh#
3b19a2bc6Sdrh# The author disclaims copyright to this source code.  In place of
4b19a2bc6Sdrh# a legal notice, here is a blessing:
55974a30fSdrh#
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.
95974a30fSdrh#
105974a30fSdrh#***********************************************************************
115974a30fSdrh# This file implements regression tests for SQLite library.  The
125974a30fSdrh# focus of this file is testing the INSERT statement that takes is
135974a30fSdrh# result from a SELECT.
145974a30fSdrh#
1524acd8f9Sdanielk1977# $Id: insert2.test,v 1.19 2008/01/16 18:20:42 danielk1977 Exp $
165974a30fSdrh
175974a30fSdrhset testdir [file dirname $argv0]
185974a30fSdrhsource $testdir/tester.tcl
19*4b79bde7Sdanset testprefix insert2
205974a30fSdrh
215974a30fSdrh# Create some tables with data that we can select against
225974a30fSdrh#
235974a30fSdrhdo_test insert2-1.0 {
245974a30fSdrh  execsql {CREATE TABLE d1(n int, log int);}
255974a30fSdrh  for {set i 1} {$i<=20} {incr i} {
2624acd8f9Sdanielk1977    for {set j 0} {(1<<$j)<$i} {incr j} {}
275974a30fSdrh    execsql "INSERT INTO d1 VALUES($i,$j)"
285974a30fSdrh  }
295974a30fSdrh  execsql {SELECT * FROM d1 ORDER BY n}
305974a30fSdrh} {1 0 2 1 3 2 4 2 5 3 6 3 7 3 8 3 9 4 10 4 11 4 12 4 13 4 14 4 15 4 16 4 17 5 18 5 19 5 20 5}
315974a30fSdrh
325974a30fSdrh# Insert into a new table from the old one.
335974a30fSdrh#
341bee3d7bSdrhdo_test insert2-1.1.1 {
355974a30fSdrh  execsql {
365974a30fSdrh    CREATE TABLE t1(log int, cnt int);
371bee3d7bSdrh    PRAGMA count_changes=on;
38cc43cabcSdrh  }
39cc43cabcSdrh  ifcapable explain {
40cc43cabcSdrh    execsql {
41cc43cabcSdrh      EXPLAIN INSERT INTO t1 SELECT log, count(*) FROM d1 GROUP BY log;
42cc43cabcSdrh    }
43cc43cabcSdrh  }
44cc43cabcSdrh  execsql {
455974a30fSdrh    INSERT INTO t1 SELECT log, count(*) FROM d1 GROUP BY log;
465974a30fSdrh  }
471bee3d7bSdrh} {6}
481bee3d7bSdrhdo_test insert2-1.1.2 {
49c8d30ac1Sdrh  db changes
50c8d30ac1Sdrh} {6}
51c8d30ac1Sdrhdo_test insert2-1.1.3 {
525974a30fSdrh  execsql {SELECT * FROM t1 ORDER BY log}
535974a30fSdrh} {0 1 1 1 2 2 3 4 4 8 5 4}
543fc190ccSdrh
5527c77438Sdanielk1977ifcapable compound {
561bee3d7bSdrhdo_test insert2-1.2.1 {
575974a30fSdrh  catch {execsql {DROP TABLE t1}}
585974a30fSdrh  execsql {
595974a30fSdrh    CREATE TABLE t1(log int, cnt int);
605974a30fSdrh    INSERT INTO t1
615974a30fSdrh       SELECT log, count(*) FROM d1 GROUP BY log
625974a30fSdrh       EXCEPT SELECT n-1,log FROM d1;
631bee3d7bSdrh  }
641bee3d7bSdrh} {4}
651bee3d7bSdrhdo_test insert2-1.2.2 {
661bee3d7bSdrh  execsql {
675974a30fSdrh    SELECT * FROM t1 ORDER BY log;
685974a30fSdrh  }
695974a30fSdrh} {0 1 3 4 4 8 5 4}
701bee3d7bSdrhdo_test insert2-1.3.1 {
715974a30fSdrh  catch {execsql {DROP TABLE t1}}
725974a30fSdrh  execsql {
735974a30fSdrh    CREATE TABLE t1(log int, cnt int);
741bee3d7bSdrh    PRAGMA count_changes=off;
755974a30fSdrh    INSERT INTO t1
765974a30fSdrh       SELECT log, count(*) FROM d1 GROUP BY log
775974a30fSdrh       INTERSECT SELECT n-1,log FROM d1;
781bee3d7bSdrh  }
791bee3d7bSdrh} {}
801bee3d7bSdrhdo_test insert2-1.3.2 {
811bee3d7bSdrh  execsql {
825974a30fSdrh    SELECT * FROM t1 ORDER BY log;
835974a30fSdrh  }
845974a30fSdrh} {1 1 2 2}
8527c77438Sdanielk1977} ;# ifcapable compound
8627c77438Sdanielk1977execsql {PRAGMA count_changes=off;}
8727c77438Sdanielk1977
88cc85b411Sdrhdo_test insert2-1.4 {
89cc85b411Sdrh  catch {execsql {DROP TABLE t1}}
90cc85b411Sdrh  set r [execsql {
91cc85b411Sdrh    CREATE TABLE t1(log int, cnt int);
92cc85b411Sdrh    CREATE INDEX i1 ON t1(log);
93cc85b411Sdrh    CREATE INDEX i2 ON t1(cnt);
94cc85b411Sdrh    INSERT INTO t1 SELECT log, count() FROM d1 GROUP BY log;
95cc85b411Sdrh    SELECT * FROM t1 ORDER BY log;
96cc85b411Sdrh  }]
97cc85b411Sdrh  lappend r [execsql {SELECT cnt FROM t1 WHERE log=3}]
98cc85b411Sdrh  lappend r [execsql {SELECT log FROM t1 WHERE cnt=4 ORDER BY log}]
99cc85b411Sdrh} {0 1 1 1 2 2 3 4 4 8 5 4 4 {3 5}}
1005974a30fSdrh
10124e97df9Sdrhdo_test insert2-2.0 {
10224e97df9Sdrh  execsql {
10324e97df9Sdrh    CREATE TABLE t3(a,b,c);
10424e97df9Sdrh    CREATE TABLE t4(x,y);
10524e97df9Sdrh    INSERT INTO t4 VALUES(1,2);
10624e97df9Sdrh    SELECT * FROM t4;
10724e97df9Sdrh  }
10824e97df9Sdrh} {1 2}
10924e97df9Sdrhdo_test insert2-2.1 {
11024e97df9Sdrh  execsql {
11124e97df9Sdrh    INSERT INTO t3(a,c) SELECT * FROM t4;
11224e97df9Sdrh    SELECT * FROM t3;
11324e97df9Sdrh  }
11424e97df9Sdrh} {1 {} 2}
11524e97df9Sdrhdo_test insert2-2.2 {
11624e97df9Sdrh  execsql {
11724e97df9Sdrh    DELETE FROM t3;
11824e97df9Sdrh    INSERT INTO t3(c,b) SELECT * FROM t4;
11924e97df9Sdrh    SELECT * FROM t3;
12024e97df9Sdrh  }
12124e97df9Sdrh} {{} 2 1}
12224e97df9Sdrhdo_test insert2-2.3 {
12324e97df9Sdrh  execsql {
12424e97df9Sdrh    DELETE FROM t3;
12524e97df9Sdrh    INSERT INTO t3(c,a,b) SELECT x, 'hi', y FROM t4;
12624e97df9Sdrh    SELECT * FROM t3;
12724e97df9Sdrh  }
12824e97df9Sdrh} {hi 2 1}
12924e97df9Sdrh
1302150432eSdrhintegrity_check insert2-3.0
13124e97df9Sdrh
1321b2e0329Sdrh# File table t4 with lots of data
1331b2e0329Sdrh#
1341b2e0329Sdrhdo_test insert2-3.1 {
1351b2e0329Sdrh  execsql {
1361b2e0329Sdrh    SELECT * from t4;
1371b2e0329Sdrh  }
1381b2e0329Sdrh} {1 2}
1391b2e0329Sdrhdo_test insert2-3.2 {
140b28af71aSdanielk1977  set x [db total_changes]
1411b2e0329Sdrh  execsql {
1421b2e0329Sdrh    BEGIN;
1431b2e0329Sdrh    INSERT INTO t4 VALUES(2,4);
1441b2e0329Sdrh    INSERT INTO t4 VALUES(3,6);
1451b2e0329Sdrh    INSERT INTO t4 VALUES(4,8);
1461b2e0329Sdrh    INSERT INTO t4 VALUES(5,10);
1471b2e0329Sdrh    INSERT INTO t4 VALUES(6,12);
1481b2e0329Sdrh    INSERT INTO t4 VALUES(7,14);
1491b2e0329Sdrh    INSERT INTO t4 VALUES(8,16);
1501b2e0329Sdrh    INSERT INTO t4 VALUES(9,18);
1511b2e0329Sdrh    INSERT INTO t4 VALUES(10,20);
1521b2e0329Sdrh    COMMIT;
153c8d30ac1Sdrh  }
154b28af71aSdanielk1977  expr [db total_changes] - $x
155c8d30ac1Sdrh} {9}
156c8d30ac1Sdrhdo_test insert2-3.2.1 {
157c8d30ac1Sdrh  execsql {
1581b2e0329Sdrh    SELECT count(*) FROM t4;
1591b2e0329Sdrh  }
1601b2e0329Sdrh} {10}
1611b2e0329Sdrhdo_test insert2-3.3 {
1623e8c37e7Sdanielk1977  ifcapable subquery {
1631b2e0329Sdrh    execsql {
1641b2e0329Sdrh      BEGIN;
1651b2e0329Sdrh      INSERT INTO t4 SELECT x+(SELECT max(x) FROM t4),y FROM t4;
1661b2e0329Sdrh      INSERT INTO t4 SELECT x+(SELECT max(x) FROM t4),y FROM t4;
1671b2e0329Sdrh      INSERT INTO t4 SELECT x+(SELECT max(x) FROM t4),y FROM t4;
1681b2e0329Sdrh      INSERT INTO t4 SELECT x+(SELECT max(x) FROM t4),y FROM t4;
1691b2e0329Sdrh      COMMIT;
1701b2e0329Sdrh      SELECT count(*) FROM t4;
1711b2e0329Sdrh    }
1723e8c37e7Sdanielk1977  } else {
1733e8c37e7Sdanielk1977    db function max_x_t4 {execsql {SELECT max(x) FROM t4}}
1743e8c37e7Sdanielk1977    execsql {
1753e8c37e7Sdanielk1977      BEGIN;
1763e8c37e7Sdanielk1977      INSERT INTO t4 SELECT x+max_x_t4() ,y FROM t4;
1773e8c37e7Sdanielk1977      INSERT INTO t4 SELECT x+max_x_t4() ,y FROM t4;
1783e8c37e7Sdanielk1977      INSERT INTO t4 SELECT x+max_x_t4() ,y FROM t4;
1793e8c37e7Sdanielk1977      INSERT INTO t4 SELECT x+max_x_t4() ,y FROM t4;
1803e8c37e7Sdanielk1977      COMMIT;
1813e8c37e7Sdanielk1977      SELECT count(*) FROM t4;
1823e8c37e7Sdanielk1977    }
1833e8c37e7Sdanielk1977  }
1841b2e0329Sdrh} {160}
1851b2e0329Sdrhdo_test insert2-3.4 {
1861b2e0329Sdrh  execsql {
1871b2e0329Sdrh    BEGIN;
1881b2e0329Sdrh    UPDATE t4 SET y='lots of data for the row where x=' || x
1891b2e0329Sdrh                     || ' and y=' || y || ' - even more data to fill space';
1901b2e0329Sdrh    COMMIT;
1911b2e0329Sdrh    SELECT count(*) FROM t4;
1921b2e0329Sdrh  }
1931b2e0329Sdrh} {160}
1941b2e0329Sdrhdo_test insert2-3.5 {
1953e8c37e7Sdanielk1977  ifcapable subquery {
1961b2e0329Sdrh    execsql {
1971b2e0329Sdrh      BEGIN;
1981b2e0329Sdrh      INSERT INTO t4 SELECT x+(SELECT max(x)+1 FROM t4),y FROM t4;
1991b2e0329Sdrh      SELECT count(*) from t4;
2001b2e0329Sdrh      ROLLBACK;
2011b2e0329Sdrh    }
2023e8c37e7Sdanielk1977  } else {
2033e8c37e7Sdanielk1977    execsql {
2043e8c37e7Sdanielk1977      BEGIN;
2053e8c37e7Sdanielk1977      INSERT INTO t4 SELECT x+max_x_t4()+1,y FROM t4;
2063e8c37e7Sdanielk1977      SELECT count(*) from t4;
2073e8c37e7Sdanielk1977      ROLLBACK;
2083e8c37e7Sdanielk1977    }
2093e8c37e7Sdanielk1977  }
2101b2e0329Sdrh} {320}
2111b2e0329Sdrhdo_test insert2-3.6 {
2121b2e0329Sdrh  execsql {
2131b2e0329Sdrh    SELECT count(*) FROM t4;
2141b2e0329Sdrh  }
2151b2e0329Sdrh} {160}
2161b2e0329Sdrhdo_test insert2-3.7 {
2171b2e0329Sdrh  execsql {
2181b2e0329Sdrh    BEGIN;
2191b2e0329Sdrh    DELETE FROM t4 WHERE x!=123;
2201b2e0329Sdrh    SELECT count(*) FROM t4;
2211b2e0329Sdrh    ROLLBACK;
2221b2e0329Sdrh  }
2231b2e0329Sdrh} {1}
224c8d30ac1Sdrhdo_test insert2-3.8 {
225c8d30ac1Sdrh  db changes
226c8d30ac1Sdrh} {159}
2272150432eSdrhintegrity_check insert2-3.9
2281b2e0329Sdrh
229a42707b2Sdrh# Ticket #901
230a42707b2Sdrh#
23153c0f748Sdanielk1977ifcapable tempdb {
232a42707b2Sdrh  do_test insert2-4.1 {
233a42707b2Sdrh    execsql {
234a42707b2Sdrh      CREATE TABLE Dependencies(depId integer primary key,
235a42707b2Sdrh        class integer, name str, flag str);
236a42707b2Sdrh      CREATE TEMPORARY TABLE DepCheck(troveId INT, depNum INT,
237a42707b2Sdrh        flagCount INT, isProvides BOOL, class INTEGER, name STRING,
238a42707b2Sdrh        flag STRING);
239a42707b2Sdrh      INSERT INTO DepCheck
240a42707b2Sdrh         VALUES(-1, 0, 1, 0, 2, 'libc.so.6', 'GLIBC_2.0');
241a42707b2Sdrh      INSERT INTO Dependencies
242a42707b2Sdrh         SELECT DISTINCT
243a42707b2Sdrh             NULL,
244a42707b2Sdrh             DepCheck.class,
245a42707b2Sdrh             DepCheck.name,
246a42707b2Sdrh             DepCheck.flag
247a42707b2Sdrh         FROM DepCheck LEFT OUTER JOIN Dependencies ON
248a42707b2Sdrh             DepCheck.class == Dependencies.class AND
249a42707b2Sdrh             DepCheck.name == Dependencies.name AND
250a42707b2Sdrh             DepCheck.flag == Dependencies.flag
251a42707b2Sdrh         WHERE
252a42707b2Sdrh             Dependencies.depId is NULL;
253a42707b2Sdrh    };
254a42707b2Sdrh  } {}
25553c0f748Sdanielk1977}
256a42707b2Sdrh
2574d88778bSdanielk1977#--------------------------------------------------------------------
2584d88778bSdanielk1977# Test that the INSERT works when the SELECT statement (a) references
2594d88778bSdanielk1977# the table being inserted into and (b) is optimized to use an index
2604d88778bSdanielk1977# only.
2614d88778bSdanielk1977do_test insert2-5.1 {
2624d88778bSdanielk1977  execsql {
2634d88778bSdanielk1977    CREATE TABLE t2(a, b);
2644d88778bSdanielk1977    INSERT INTO t2 VALUES(1, 2);
2654d88778bSdanielk1977    CREATE INDEX t2i1 ON t2(a);
2664d88778bSdanielk1977    INSERT INTO t2 SELECT a, 3 FROM t2 WHERE a = 1;
2674d88778bSdanielk1977    SELECT * FROM t2;
2684d88778bSdanielk1977  }
2694d88778bSdanielk1977} {1 2 1 3}
270a38b4134Sdanielk1977ifcapable subquery {
2714d88778bSdanielk1977  do_test insert2-5.2 {
2724d88778bSdanielk1977    execsql {
2734d88778bSdanielk1977      INSERT INTO t2 SELECT (SELECT a FROM t2), 4;
2744d88778bSdanielk1977      SELECT * FROM t2;
2754d88778bSdanielk1977    }
2764d88778bSdanielk1977  } {1 2 1 3 1 4}
277a38b4134Sdanielk1977}
2784d88778bSdanielk1977
279*4b79bde7Sdando_execsql_test 6.0 {
280*4b79bde7Sdan  CREATE TABLE t5(a, b, c DEFAULT 'c', d);
281*4b79bde7Sdan}
282*4b79bde7Sdando_execsql_test 6.1 {
283*4b79bde7Sdan  INSERT INTO t5(a) SELECT 456 UNION ALL SELECT 123 ORDER BY 1;
284*4b79bde7Sdan  SELECT * FROM t5 ORDER BY rowid;
285*4b79bde7Sdan} {123 {} c {}   456 {} c {}}
286*4b79bde7Sdan
287*4b79bde7Sdanifcapable fts3 {
288*4b79bde7Sdan  do_execsql_test 6.2 {
289*4b79bde7Sdan    CREATE VIRTUAL TABLE t0 USING fts4(a);
290*4b79bde7Sdan  }
291*4b79bde7Sdan  do_execsql_test 6.3 {
292*4b79bde7Sdan    INSERT INTO t0 SELECT 0 UNION SELECT 0 AS 'x' ORDER BY x;
293*4b79bde7Sdan    SELECT * FROM t0;
294*4b79bde7Sdan  } {0}
295*4b79bde7Sdan}
296*4b79bde7Sdan
297*4b79bde7Sdan
2985974a30fSdrhfinish_test
299