xref: /sqlite-3.40.0/test/vacuum.test (revision 1696124d)
1b19a2bc6Sdrh# 2001 September 15
27020f651Sdrh#
3b19a2bc6Sdrh# The author disclaims copyright to this source code.  In place of
4b19a2bc6Sdrh# a legal notice, here is a blessing:
57020f651Sdrh#
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.
97020f651Sdrh#
107020f651Sdrh#***********************************************************************
117020f651Sdrh# This file implements regression tests for SQLite library.  The
127020f651Sdrh# focus of this file is testing the VACUUM statement.
137020f651Sdrh#
1464beba43Sdanielk1977# $Id: vacuum.test,v 1.43 2009/01/31 14:54:07 danielk1977 Exp $
157020f651Sdrh
167020f651Sdrhset testdir [file dirname $argv0]
177020f651Sdrhsource $testdir/tester.tcl
187020f651Sdrh
19798da52cSdrh# If the VACUUM statement is disabled in the current build, skip all
20798da52cSdrh# the tests in this file.
21798da52cSdrh#
22798da52cSdrhifcapable {!vacuum} {
23521cc849Sdrh  omit_test vacuum.test {Compiled with SQLITE_OMIT_VACUUM}
24798da52cSdrh  finish_test
25798da52cSdrh  return
26798da52cSdrh}
2745901d62Sdanielk1977if $AUTOVACUUM {
28521cc849Sdrh  omit_test vacuum.test {Auto-vacuum is enabled}
2945901d62Sdanielk1977  finish_test
3045901d62Sdanielk1977  return
3145901d62Sdanielk1977}
32798da52cSdrh
33cced337eSdrhset fcnt 1
3445a304eeSdrhdo_test vacuum-1.1 {
3545a304eeSdrh  execsql {
3645a304eeSdrh    BEGIN;
3745a304eeSdrh    CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
3845a304eeSdrh    INSERT INTO t1 VALUES(NULL,randstr(10,100),randstr(5,50));
3945a304eeSdrh    INSERT INTO t1 VALUES(123456,randstr(10,100),randstr(5,50));
4045a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4145a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4245a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4345a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4445a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4545a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4645a304eeSdrh    INSERT INTO t1 SELECT NULL, b||'-'||rowid, c||'-'||rowid FROM t1;
4745a304eeSdrh    CREATE INDEX i1 ON t1(b,c);
48cced337eSdrh    CREATE UNIQUE INDEX i2 ON t1(c,a);
4945a304eeSdrh    CREATE TABLE t2 AS SELECT * FROM t1;
5045a304eeSdrh    COMMIT;
5145a304eeSdrh    DROP TABLE t2;
5245a304eeSdrh  }
5345a304eeSdrh  set ::size1 [file size test.db]
541db639ceSdrh  set ::cksum [cksum]
5545a304eeSdrh  expr {$::cksum!=""}
5645a304eeSdrh} {1}
57545f587fSdrh
58545f587fSdrh# Create bogus application-defined functions for functions used
59545f587fSdrh# internally by VACUUM, to ensure that VACUUM falls back
60545f587fSdrh# to the built-in functions.
61545f587fSdrh#
62545f587fSdrhproc failing_app_func {args} {error "bad function"}
63545f587fSdrhdo_test vacuum-1.1b {
64545f587fSdrh  db func substr failing_app_func
65545f587fSdrh  db func like failing_app_func
66545f587fSdrh  db func quote failing_app_func
67545f587fSdrh  catchsql {SELECT substr(name,1,3) FROM sqlite_master}
68545f587fSdrh} {1 {bad function}}
69545f587fSdrh
7045a304eeSdrhdo_test vacuum-1.2 {
7145a304eeSdrh  execsql {
7245a304eeSdrh    VACUUM;
7345a304eeSdrh  }
741db639ceSdrh  cksum
7545a304eeSdrh} $cksum
7627d258a3Sdrhifcapable vacuum {
7745a304eeSdrh  do_test vacuum-1.3 {
7845a304eeSdrh    expr {[file size test.db]<$::size1}
7945a304eeSdrh  } {1}
8027d258a3Sdrh}
8145a304eeSdrhdo_test vacuum-1.4 {
820fa8ddbdSdanielk1977  set sql_script {
8345a304eeSdrh    BEGIN;
8445a304eeSdrh    CREATE TABLE t2 AS SELECT * FROM t1;
8545a304eeSdrh    CREATE TABLE t3 AS SELECT * FROM t1;
8645a304eeSdrh    CREATE VIEW v1 AS SELECT b, c FROM t3;
8781650dc6Sdanielk1977    CREATE TRIGGER r1 AFTER DELETE ON t2 BEGIN SELECT 1; END;
8845a304eeSdrh    COMMIT;
8945a304eeSdrh    DROP TABLE t2;
9045a304eeSdrh  }
910fa8ddbdSdanielk1977  # If the library was compiled to omit view support, comment out the
9281650dc6Sdanielk1977  # create view in the script $sql_script before executing it. Similarly,
9381650dc6Sdanielk1977  # if triggers are not supported, comment out the trigger definition.
940fa8ddbdSdanielk1977  ifcapable !view {
950fa8ddbdSdanielk1977    regsub {CREATE VIEW} $sql_script {-- CREATE VIEW} sql_script
960fa8ddbdSdanielk1977  }
9781650dc6Sdanielk1977  ifcapable !trigger {
9881650dc6Sdanielk1977    regsub {CREATE TRIGGER} $sql_script {-- CREATE TRIGGER} sql_script
9981650dc6Sdanielk1977  }
1000fa8ddbdSdanielk1977  execsql $sql_script
10145a304eeSdrh  set ::size1 [file size test.db]
1021db639ceSdrh  set ::cksum [cksum]
10345a304eeSdrh  expr {$::cksum!=""}
10445a304eeSdrh} {1}
10545a304eeSdrhdo_test vacuum-1.5 {
10645a304eeSdrh  execsql {
10745a304eeSdrh    VACUUM;
10845a304eeSdrh  }
1091db639ceSdrh  cksum
11045a304eeSdrh} $cksum
1110fa8ddbdSdanielk1977
11227d258a3Sdrhifcapable vacuum {
11345a304eeSdrh  do_test vacuum-1.6 {
11445a304eeSdrh    expr {[file size test.db]<$::size1}
11545a304eeSdrh  } {1}
11627d258a3Sdrh}
11727d258a3Sdrhifcapable vacuum {
118663d56d4Sdrh  do_test vacuum-2.1.1 {
11945a304eeSdrh    catchsql {
12045a304eeSdrh      BEGIN;
12145a304eeSdrh      VACUUM;
12245a304eeSdrh    }
12345a304eeSdrh  } {1 {cannot VACUUM from within a transaction}}
124663d56d4Sdrh  do_test vacuum-2.1.2 {
125663d56d4Sdrh    sqlite3_get_autocommit db
126663d56d4Sdrh  } {0}
127663d56d4Sdrh  do_test vacuum-2.1.3 {
128663d56d4Sdrh    db eval {COMMIT}
129663d56d4Sdrh  } {}
13027d258a3Sdrh}
131f7c57531Sdrhdo_test vacuum-2.2 {
132ef4ac8f9Sdrh  sqlite3 db2 test.db
133f7c57531Sdrh  execsql {
134f7c57531Sdrh    BEGIN;
135f7c57531Sdrh    CREATE TABLE t4 AS SELECT * FROM t1;
136f7c57531Sdrh    CREATE TABLE t5 AS SELECT * FROM t1;
137f7c57531Sdrh    COMMIT;
138f7c57531Sdrh    DROP TABLE t4;
139f7c57531Sdrh    DROP TABLE t5;
140f7c57531Sdrh  } db2
1411db639ceSdrh  set ::cksum [cksum db2]
142f7c57531Sdrh  catchsql {
143f7c57531Sdrh    VACUUM
144f7c57531Sdrh  }
145a1f9b5eeSdrh} {0 {}}
146f7c57531Sdrhdo_test vacuum-2.3 {
1471db639ceSdrh  cksum
148f7c57531Sdrh} $cksum
149f7c57531Sdrhdo_test vacuum-2.4 {
150f7c57531Sdrh  catch {db2 eval {SELECT count(*) FROM sqlite_master}}
1511db639ceSdrh  cksum db2
152f7c57531Sdrh} $cksum
153f7c57531Sdrh
1548cbd373cSdrh# Make sure the schema cookie is incremented by vacuum.
1558cbd373cSdrh#
1568cbd373cSdrhdo_test vacuum-2.5 {
1578cbd373cSdrh  execsql {
1588cbd373cSdrh    BEGIN;
1598cbd373cSdrh    CREATE TABLE t6 AS SELECT * FROM t1;
1608cbd373cSdrh    CREATE TABLE t7 AS SELECT * FROM t1;
1618cbd373cSdrh    COMMIT;
1628cbd373cSdrh  }
1638cbd373cSdrh  sqlite3 db3 test.db
1648cbd373cSdrh  execsql {
165b82e7edaSdanielk1977    -- The "SELECT * FROM sqlite_master" statement ensures that this test
166b82e7edaSdanielk1977    -- works when shared-cache is enabled. If shared-cache is enabled, then
167b82e7edaSdanielk1977    -- db3 shares a cache with db2 (but not db - it was opened as
168b82e7edaSdanielk1977    -- "./test.db").
169b82e7edaSdanielk1977    SELECT * FROM sqlite_master;
1708cbd373cSdrh    SELECT * FROM t7 LIMIT 1
1718cbd373cSdrh  } db3
1728cbd373cSdrh  execsql {
1738cbd373cSdrh    VACUUM;
1748cbd373cSdrh  }
1758cbd373cSdrh  execsql {
1768cbd373cSdrh    INSERT INTO t7 VALUES(1234567890,'hello','world');
1778cbd373cSdrh  } db3
1788cbd373cSdrh  execsql {
1798cbd373cSdrh    SELECT * FROM t7 WHERE a=1234567890
1808cbd373cSdrh  }
1818cbd373cSdrh} {1234567890 hello world}
1828cbd373cSdrhintegrity_check vacuum-2.6
1838cbd373cSdrhdo_test vacuum-2.7 {
1848cbd373cSdrh  execsql {
1858cbd373cSdrh    SELECT * FROM t7 WHERE a=1234567890
1868cbd373cSdrh  } db3
1878cbd373cSdrh} {1234567890 hello world}
1888cbd373cSdrhdo_test vacuum-2.8 {
1898cbd373cSdrh  execsql {
1908cbd373cSdrh    INSERT INTO t7 SELECT * FROM t6;
1918cbd373cSdrh    SELECT count(*) FROM t7;
1928cbd373cSdrh  }
1938cbd373cSdrh} 513
1948cbd373cSdrhintegrity_check vacuum-2.9
1958cbd373cSdrhdo_test vacuum-2.10 {
1968cbd373cSdrh  execsql {
1978cbd373cSdrh    DELETE FROM t7;
1988cbd373cSdrh    SELECT count(*) FROM t7;
1998cbd373cSdrh  } db3
2008cbd373cSdrh} 0
2018cbd373cSdrhintegrity_check vacuum-2.11
2028cbd373cSdrhdb3 close
2038cbd373cSdrh
2048cbd373cSdrh
2058e18bac7Sdrh# Ticket #427.  Make sure VACUUM works when the EMPTY_RESULT_CALLBACKS
2068e18bac7Sdrh# pragma is turned on.
2078e18bac7Sdrh#
2088e18bac7Sdrhdo_test vacuum-3.1 {
2098e18bac7Sdrh  db close
210263659beSdrh  db2 close
211fda06befSmistachkin  delete_file test.db
212ef4ac8f9Sdrh  sqlite3 db test.db
2138e18bac7Sdrh  execsql {
2148e18bac7Sdrh    PRAGMA empty_result_callbacks=on;
2158e18bac7Sdrh    VACUUM;
2168e18bac7Sdrh  }
2178e18bac7Sdrh} {}
218f7c57531Sdrh
2194ad1713cSdanielk1977# Ticket #464.  Make sure VACUUM works with the sqlite3_prepare() API.
2205b8424b9Sdrh#
2215b8424b9Sdrhdo_test vacuum-4.1 {
2225b8424b9Sdrh  db close
223dddca286Sdrh  sqlite3 db test.db; set DB [sqlite3_connection_pointer db]
2244ad1713cSdanielk1977  set VM [sqlite3_prepare $DB {VACUUM} -1 TAIL]
2253cf86063Sdanielk1977  sqlite3_step $VM
2265b8424b9Sdrh} {SQLITE_DONE}
2275b8424b9Sdrhdo_test vacuum-4.2 {
228106bb236Sdanielk1977  sqlite3_finalize $VM
2293cf86063Sdanielk1977} SQLITE_OK
2305b8424b9Sdrh
2316f8c91caSdrh# Ticket #515.  VACUUM after deleting and recreating the table that
2320fa8ddbdSdanielk1977# a view refers to. Omit this test if the library is not view-enabled.
2336f8c91caSdrh#
2340fa8ddbdSdanielk1977ifcapable view {
2356f8c91caSdrhdo_test vacuum-5.1 {
2366f8c91caSdrh  db close
237fda06befSmistachkin  forcedelete test.db
238ef4ac8f9Sdrh  sqlite3 db test.db
2396f8c91caSdrh  catchsql {
2406f8c91caSdrh    CREATE TABLE Test (TestID int primary key);
2416f8c91caSdrh    INSERT INTO Test VALUES (NULL);
2426f8c91caSdrh    CREATE VIEW viewTest AS SELECT * FROM Test;
2436f8c91caSdrh
2446f8c91caSdrh    BEGIN;
24553c0f748Sdanielk1977    CREATE TABLE tempTest (TestID int primary key, Test2 int NULL);
2466f8c91caSdrh    INSERT INTO tempTest SELECT TestID, 1 FROM Test;
2476f8c91caSdrh    DROP TABLE Test;
2486f8c91caSdrh    CREATE TABLE Test(TestID int primary key, Test2 int NULL);
2496f8c91caSdrh    INSERT INTO Test SELECT * FROM tempTest;
25053c0f748Sdanielk1977    DROP TABLE tempTest;
2516f8c91caSdrh    COMMIT;
2526f8c91caSdrh    VACUUM;
2536f8c91caSdrh  }
2546f8c91caSdrh} {0 {}}
2556f8c91caSdrhdo_test vacuum-5.2 {
2566f8c91caSdrh  catchsql {
2576f8c91caSdrh    VACUUM;
2586f8c91caSdrh  }
2596f8c91caSdrh} {0 {}}
2600fa8ddbdSdanielk1977} ;# ifcapable view
2613fc190ccSdrh
262bd26f925Sdanielk1977# Ensure vacuum works with complicated tables names.
263bd26f925Sdanielk1977do_test vacuum-6.1 {
264bd26f925Sdanielk1977  execsql {
265bd26f925Sdanielk1977    CREATE TABLE "abc abc"(a, b, c);
266bd26f925Sdanielk1977    INSERT INTO "abc abc" VALUES(1, 2, 3);
267bd26f925Sdanielk1977    VACUUM;
268bd26f925Sdanielk1977  }
269bd26f925Sdanielk1977} {}
270bd26f925Sdanielk1977do_test vacuum-6.2 {
271bd26f925Sdanielk1977  execsql {
272bd26f925Sdanielk1977    select * from "abc abc";
273bd26f925Sdanielk1977  }
274bd26f925Sdanielk1977} {1 2 3}
275bd26f925Sdanielk1977
276bd26f925Sdanielk1977# Also ensure that blobs survive a vacuum.
277a71aa001Sdrhifcapable {bloblit} {
278bd26f925Sdanielk1977  do_test vacuum-6.3 {
279bd26f925Sdanielk1977    execsql {
280bd26f925Sdanielk1977      DELETE FROM "abc abc";
281bd26f925Sdanielk1977      INSERT INTO "abc abc" VALUES(X'00112233', NULL, NULL);
282bd26f925Sdanielk1977      VACUUM;
283bd26f925Sdanielk1977    }
284bd26f925Sdanielk1977  } {}
285bd26f925Sdanielk1977  do_test vacuum-6.4 {
286bd26f925Sdanielk1977    execsql {
287bd26f925Sdanielk1977      select count(*) from "abc abc" WHERE a = X'00112233';
288bd26f925Sdanielk1977    }
289bd26f925Sdanielk1977  } {1}
290a71aa001Sdrh}
291bd26f925Sdanielk1977
29203aded49Sdanielk1977# Check what happens when an in-memory database is vacuumed. The
293fda06befSmistachkin# [delete_file] command covers us in case the library was compiled
29403aded49Sdanielk1977# without in-memory database support.
29503aded49Sdanielk1977#
296fda06befSmistachkinforcedelete :memory:
29796fb0dd5Sdanielk1977do_test vacuum-7.0 {
29896fb0dd5Sdanielk1977  sqlite3 db2 :memory:
29996fb0dd5Sdanielk1977  execsql {
30096fb0dd5Sdanielk1977    CREATE TABLE t1(t);
30196fb0dd5Sdanielk1977    VACUUM;
30296fb0dd5Sdanielk1977  } db2
303712322dfSdan} {}
304712322dfSdando_test vacuum-7.1 {
30564beba43Sdanielk1977  execsql {
30664beba43Sdanielk1977    CREATE TABLE t2(t);
30764beba43Sdanielk1977    CREATE TABLE t3(t);
30864beba43Sdanielk1977    DROP TABLE t2;
309712322dfSdan    PRAGMA freelist_count;
310712322dfSdan  }
311712322dfSdan} {1}
312712322dfSdando_test vacuum-7.2 {
313712322dfSdan  execsql {
31464beba43Sdanielk1977    VACUUM;
31564beba43Sdanielk1977    pragma integrity_check;
31664beba43Sdanielk1977  } db2
31764beba43Sdanielk1977} {ok}
318712322dfSdando_test vacuum-7.3 {
319712322dfSdan  execsql { PRAGMA freelist_count; } db2
320712322dfSdan} {0}
321712322dfSdanifcapable autovacuum {
322712322dfSdan  do_test vacuum-7.4 {
323712322dfSdan    execsql { PRAGMA auto_vacuum } db2
324712322dfSdan  } {0}
325712322dfSdan  do_test vacuum-7.5 {
326712322dfSdan    execsql { PRAGMA auto_vacuum = 1} db2
327712322dfSdan    execsql { PRAGMA auto_vacuum } db2
328712322dfSdan  } {0}
329712322dfSdan  do_test vacuum-7.6 {
330712322dfSdan    execsql { PRAGMA auto_vacuum = 1} db2
331712322dfSdan    execsql { VACUUM } db2
332712322dfSdan    execsql { PRAGMA auto_vacuum } db2
333712322dfSdan  } {1}
334712322dfSdan}
33505056307Sdanielk1977db2 close
33696fb0dd5Sdanielk1977
33751a6ec48Sdrh# Ticket #873.  VACUUM a database that has ' in its name.
33851a6ec48Sdrh#
33951a6ec48Sdrhdo_test vacuum-8.1 {
340fda06befSmistachkin  forcedelete a'z.db
341fda06befSmistachkin  forcedelete a'z.db-journal
34251a6ec48Sdrh  sqlite3 db2 a'z.db
34351a6ec48Sdrh  execsql {
34451a6ec48Sdrh    CREATE TABLE t1(t);
34551a6ec48Sdrh    VACUUM;
34651a6ec48Sdrh  } db2
34751a6ec48Sdrh} {}
34851a6ec48Sdrhdb2 close
34951a6ec48Sdrh
35062d54916Sdrh# Ticket #1095:  Vacuum a table that uses AUTOINCREMENT
35162d54916Sdrh#
35262d54916Sdrhifcapable {autoinc} {
35362d54916Sdrh  do_test vacuum-9.1 {
35462d54916Sdrh    execsql {
35562d54916Sdrh      DROP TABLE 'abc abc';
35662d54916Sdrh      CREATE TABLE autoinc(a INTEGER PRIMARY KEY AUTOINCREMENT, b);
35762d54916Sdrh      INSERT INTO autoinc(b) VALUES('hi');
35862d54916Sdrh      INSERT INTO autoinc(b) VALUES('there');
35962d54916Sdrh      DELETE FROM autoinc;
36062d54916Sdrh    }
3611db639ceSdrh    set ::cksum [cksum]
36262d54916Sdrh    expr {$::cksum!=""}
36362d54916Sdrh  } {1}
36462d54916Sdrh  do_test vacuum-9.2 {
36562d54916Sdrh    execsql {
36662d54916Sdrh      VACUUM;
36762d54916Sdrh    }
3681db639ceSdrh    cksum
36962d54916Sdrh  } $::cksum
37062d54916Sdrh  do_test vacuum-9.3 {
37162d54916Sdrh    execsql {
37262d54916Sdrh      INSERT INTO autoinc(b) VALUES('one');
37362d54916Sdrh      INSERT INTO autoinc(b) VALUES('two');
37462d54916Sdrh    }
3751db639ceSdrh    set ::cksum [cksum]
37662d54916Sdrh    expr {$::cksum!=""}
37762d54916Sdrh  } {1}
37862d54916Sdrh  do_test vacuum-9.4 {
37962d54916Sdrh    execsql {
38062d54916Sdrh      VACUUM;
38162d54916Sdrh    }
3821db639ceSdrh    cksum
38362d54916Sdrh  } $::cksum
38462d54916Sdrh}
38562d54916Sdrh
386fda06befSmistachkinforcedelete {a'z.db}
3878cbd373cSdrh
388*1696124dSdan# Test that "PRAGMA count_changes" does not interfere with VACUUM or cause
389*1696124dSdan# it to return any rows to the user.
390*1696124dSdan#
391*1696124dSdando_test vacuum-10.1 {
392*1696124dSdan  db close
393*1696124dSdan  forcedelete test.db
394*1696124dSdan  sqlite3 db test.db
395*1696124dSdan  execsql {
396*1696124dSdan    CREATE TABLE t8(a, b);
397*1696124dSdan    INSERT INTO t8 VALUES('a', 'b');
398*1696124dSdan    INSERT INTO t8 VALUES('c', 'd');
399*1696124dSdan    PRAGMA count_changes = 1;
400*1696124dSdan  }
401*1696124dSdan} {}
402*1696124dSdando_test vacuum-10.2 { execsql VACUUM } {}
403*1696124dSdan
4048cbd373cSdrhfinish_test
405