drh | b19a2bc | 2001-09-16 00:13:26 +0000 | [diff] [blame] | 1 | # 2001 September 15 |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 2 | # |
drh | b19a2bc | 2001-09-16 00:13:26 +0000 | [diff] [blame] | 3 | # The author disclaims copyright to this source code. In place of |
| 4 | # a legal notice, here is a blessing: |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 5 | # |
drh | b19a2bc | 2001-09-16 00:13:26 +0000 | [diff] [blame] | 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. |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 9 | # |
| 10 | #*********************************************************************** |
| 11 | # This file implements regression tests for SQLite library. The |
| 12 | # focus of this file is testing the CREATE TABLE statement. |
| 13 | # |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 14 | |
| 15 | set testdir [file dirname $argv0] |
| 16 | source $testdir/tester.tcl |
| 17 | |
| 18 | # Create a basic table and verify it is added to sqlite_master |
| 19 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 20 | do_test table-1.1 { |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 21 | execsql { |
| 22 | CREATE TABLE test1 ( |
| 23 | one varchar(10), |
| 24 | two text |
| 25 | ) |
| 26 | } |
| 27 | execsql { |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 28 | SELECT sql FROM sqlite_master WHERE type!='meta' |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 29 | } |
| 30 | } {{CREATE TABLE test1 ( |
| 31 | one varchar(10), |
| 32 | two text |
| 33 | )}} |
| 34 | |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 35 | |
| 36 | # Verify the other fields of the sqlite_master file. |
| 37 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 38 | do_test table-1.3 { |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 39 | execsql {SELECT name, tbl_name, type FROM sqlite_master WHERE type!='meta'} |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 40 | } {test1 test1 table} |
| 41 | |
| 42 | # Close and reopen the database. Verify that everything is |
| 43 | # still the same. |
| 44 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 45 | do_test table-1.4 { |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 46 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 47 | sqlite3 db test.db |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 48 | execsql {SELECT name, tbl_name, type from sqlite_master WHERE type!='meta'} |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 49 | } {test1 test1 table} |
| 50 | |
| 51 | # Drop the database and make sure it disappears. |
| 52 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 53 | do_test table-1.5 { |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 54 | execsql {DROP TABLE test1} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 55 | execsql {SELECT * FROM sqlite_master WHERE type!='meta'} |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 56 | } {} |
| 57 | |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 58 | # Close and reopen the database. Verify that the table is |
| 59 | # still gone. |
| 60 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 61 | do_test table-1.6 { |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 62 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 63 | sqlite3 db test.db |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 64 | execsql {SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 65 | } {} |
| 66 | |
drh | 982cef7 | 2000-05-30 16:27:03 +0000 | [diff] [blame] | 67 | # Repeat the above steps, but this time quote the table name. |
| 68 | # |
| 69 | do_test table-1.10 { |
| 70 | execsql {CREATE TABLE "create" (f1 int)} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 71 | execsql {SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | 982cef7 | 2000-05-30 16:27:03 +0000 | [diff] [blame] | 72 | } {create} |
| 73 | do_test table-1.11 { |
| 74 | execsql {DROP TABLE "create"} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 75 | execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'} |
drh | 982cef7 | 2000-05-30 16:27:03 +0000 | [diff] [blame] | 76 | } {} |
| 77 | do_test table-1.12 { |
| 78 | execsql {CREATE TABLE test1("f1 ho" int)} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 79 | execsql {SELECT name as "X" FROM sqlite_master WHERE type!='meta'} |
drh | 982cef7 | 2000-05-30 16:27:03 +0000 | [diff] [blame] | 80 | } {test1} |
| 81 | do_test table-1.13 { |
| 82 | execsql {DROP TABLE "TEST1"} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 83 | execsql {SELECT name FROM "sqlite_master" WHERE type!='meta'} |
drh | 982cef7 | 2000-05-30 16:27:03 +0000 | [diff] [blame] | 84 | } {} |
| 85 | |
| 86 | |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 87 | |
| 88 | # Verify that we cannot make two tables with the same name |
| 89 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 90 | do_test table-2.1 { |
drh | 4cfa793 | 2000-06-08 15:10:46 +0000 | [diff] [blame] | 91 | execsql {CREATE TABLE TEST2(one text)} |
drh | 42b9d7c | 2005-08-13 00:56:27 +0000 | [diff] [blame] | 92 | catchsql {CREATE TABLE test2(two text default 'hi')} |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 93 | } {1 {table test2 already exists}} |
drh | e4df0e7 | 2006-03-29 00:24:06 +0000 | [diff] [blame] | 94 | do_test table-2.1.1 { |
| 95 | catchsql {CREATE TABLE "test2" (two)} |
| 96 | } {1 {table "test2" already exists}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 97 | do_test table-2.1b { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 98 | set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg] |
| 99 | lappend v $msg |
danielk1977 | d812336 | 2004-06-12 09:25:12 +0000 | [diff] [blame] | 100 | } {1 {object name reserved for internal use: sqlite_master}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 101 | do_test table-2.1c { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 102 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 103 | sqlite3 db test.db |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 104 | set v [catch {execsql {CREATE TABLE sqlite_master(two text)}} msg] |
| 105 | lappend v $msg |
danielk1977 | d812336 | 2004-06-12 09:25:12 +0000 | [diff] [blame] | 106 | } {1 {object name reserved for internal use: sqlite_master}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 107 | do_test table-2.1d { |
drh | faa5955 | 2005-12-29 23:33:54 +0000 | [diff] [blame] | 108 | catchsql {CREATE TABLE IF NOT EXISTS test2(x,y)} |
| 109 | } {0 {}} |
| 110 | do_test table-2.1e { |
drh | a6370df | 2006-01-04 21:40:06 +0000 | [diff] [blame] | 111 | catchsql {CREATE TABLE IF NOT EXISTS test2(x UNIQUE, y TEXT PRIMARY KEY)} |
| 112 | } {0 {}} |
| 113 | do_test table-2.1f { |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 114 | execsql {DROP TABLE test2; SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 115 | } {} |
| 116 | |
| 117 | # Verify that we cannot make a table with the same name as an index |
| 118 | # |
drh | dcc581c | 2000-05-30 13:44:19 +0000 | [diff] [blame] | 119 | do_test table-2.2a { |
drh | 8a1e594 | 2009-04-28 15:43:45 +0000 | [diff] [blame] | 120 | execsql {CREATE TABLE test2(one text)} |
| 121 | execsql {CREATE INDEX test3 ON test2(one)} |
| 122 | catchsql {CREATE TABLE test3(two text)} |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 123 | } {1 {there is already an index named test3}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 124 | do_test table-2.2b { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 125 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 126 | sqlite3 db test.db |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 127 | set v [catch {execsql {CREATE TABLE test3(two text)}} msg] |
| 128 | lappend v $msg |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 129 | } {1 {there is already an index named test3}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 130 | do_test table-2.2c { |
drh | 3fc190c | 2001-09-14 03:24:23 +0000 | [diff] [blame] | 131 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
| 132 | } {test2 test3} |
| 133 | do_test table-2.2d { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 134 | execsql {DROP INDEX test3} |
| 135 | set v [catch {execsql {CREATE TABLE test3(two text)}} msg] |
| 136 | lappend v $msg |
| 137 | } {0 {}} |
drh | 3fc190c | 2001-09-14 03:24:23 +0000 | [diff] [blame] | 138 | do_test table-2.2e { |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 139 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 140 | } {test2 test3} |
drh | 3fc190c | 2001-09-14 03:24:23 +0000 | [diff] [blame] | 141 | do_test table-2.2f { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 142 | execsql {DROP TABLE test2; DROP TABLE test3} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 143 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 144 | } {} |
| 145 | |
| 146 | # Create a table with many field names |
| 147 | # |
| 148 | set big_table \ |
| 149 | {CREATE TABLE big( |
| 150 | f1 varchar(20), |
| 151 | f2 char(10), |
drh | dcc581c | 2000-05-30 13:44:19 +0000 | [diff] [blame] | 152 | f3 varchar(30) primary key, |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 153 | f4 text, |
| 154 | f5 text, |
| 155 | f6 text, |
| 156 | f7 text, |
| 157 | f8 text, |
| 158 | f9 text, |
| 159 | f10 text, |
| 160 | f11 text, |
| 161 | f12 text, |
| 162 | f13 text, |
| 163 | f14 text, |
| 164 | f15 text, |
| 165 | f16 text, |
| 166 | f17 text, |
| 167 | f18 text, |
| 168 | f19 text, |
| 169 | f20 text |
| 170 | )} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 171 | do_test table-3.1 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 172 | execsql $big_table |
drh | adbca9c | 2001-09-27 15:11:53 +0000 | [diff] [blame] | 173 | execsql {SELECT sql FROM sqlite_master WHERE type=='table'} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 174 | } \{$big_table\} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 175 | do_test table-3.2 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 176 | set v [catch {execsql {CREATE TABLE BIG(xyz foo)}} msg] |
| 177 | lappend v $msg |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 178 | } {1 {table BIG already exists}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 179 | do_test table-3.3 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 180 | set v [catch {execsql {CREATE TABLE biG(xyz foo)}} msg] |
| 181 | lappend v $msg |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 182 | } {1 {table biG already exists}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 183 | do_test table-3.4 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 184 | set v [catch {execsql {CREATE TABLE bIg(xyz foo)}} msg] |
| 185 | lappend v $msg |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 186 | } {1 {table bIg already exists}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 187 | do_test table-3.5 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 188 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 189 | sqlite3 db test.db |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 190 | set v [catch {execsql {CREATE TABLE Big(xyz foo)}} msg] |
| 191 | lappend v $msg |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 192 | } {1 {table Big already exists}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 193 | do_test table-3.6 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 194 | execsql {DROP TABLE big} |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 195 | execsql {SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 196 | } {} |
| 197 | |
| 198 | # Try creating large numbers of tables |
| 199 | # |
| 200 | set r {} |
| 201 | for {set i 1} {$i<=100} {incr i} { |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 202 | lappend r [format test%03d $i] |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 203 | } |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 204 | do_test table-4.1 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 205 | for {set i 1} {$i<=100} {incr i} { |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 206 | set sql "CREATE TABLE [format test%03d $i] (" |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 207 | for {set k 1} {$k<$i} {incr k} { |
| 208 | append sql "field$k text," |
| 209 | } |
| 210 | append sql "last_field text)" |
| 211 | execsql $sql |
| 212 | } |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 213 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 214 | } $r |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 215 | do_test table-4.1b { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 216 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 217 | sqlite3 db test.db |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 218 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 219 | } $r |
| 220 | |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 221 | # Drop the even numbered tables |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 222 | # |
| 223 | set r {} |
| 224 | for {set i 1} {$i<=100} {incr i 2} { |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 225 | lappend r [format test%03d $i] |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 226 | } |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 227 | do_test table-4.2 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 228 | for {set i 2} {$i<=100} {incr i 2} { |
drh | 428ae8c | 2003-01-04 16:48:09 +0000 | [diff] [blame] | 229 | # if {$i==38} {execsql {pragma vdbe_trace=on}} |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 230 | set sql "DROP TABLE [format TEST%03d $i]" |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 231 | execsql $sql |
| 232 | } |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 233 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 234 | } $r |
drh | 3fc190c | 2001-09-14 03:24:23 +0000 | [diff] [blame] | 235 | #exit |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 236 | |
| 237 | # Drop the odd number tables |
| 238 | # |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 239 | do_test table-4.3 { |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 240 | for {set i 1} {$i<=100} {incr i 2} { |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 241 | set sql "DROP TABLE [format test%03d $i]" |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 242 | execsql $sql |
| 243 | } |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 244 | execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name} |
drh | b24fcbe | 2000-05-29 23:30:50 +0000 | [diff] [blame] | 245 | } {} |
| 246 | |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 247 | # Try to drop a table that does not exist |
| 248 | # |
drh | a073384 | 2005-12-29 01:11:36 +0000 | [diff] [blame] | 249 | do_test table-5.1.1 { |
| 250 | catchsql {DROP TABLE test009} |
drh | a9e99ae | 2002-08-13 23:02:57 +0000 | [diff] [blame] | 251 | } {1 {no such table: test009}} |
drh | a073384 | 2005-12-29 01:11:36 +0000 | [diff] [blame] | 252 | do_test table-5.1.2 { |
| 253 | catchsql {DROP TABLE IF EXISTS test009} |
| 254 | } {0 {}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 255 | |
| 256 | # Try to drop sqlite_master |
| 257 | # |
| 258 | do_test table-5.2 { |
drh | a073384 | 2005-12-29 01:11:36 +0000 | [diff] [blame] | 259 | catchsql {DROP TABLE IF EXISTS sqlite_master} |
drh | 1d37e28 | 2000-05-30 03:12:21 +0000 | [diff] [blame] | 260 | } {1 {table sqlite_master may not be dropped}} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 261 | |
drh | 08ccfaa | 2011-10-07 23:52:25 +0000 | [diff] [blame] | 262 | # Dropping sqlite_statN tables is OK. |
| 263 | # |
| 264 | do_test table-5.2.1 { |
| 265 | db eval { |
| 266 | ANALYZE; |
| 267 | DROP TABLE IF EXISTS sqlite_stat1; |
| 268 | DROP TABLE IF EXISTS sqlite_stat2; |
dan | 8ad169a | 2013-08-12 20:14:04 +0000 | [diff] [blame] | 269 | DROP TABLE IF EXISTS sqlite_stat3; |
dan | c55521a | 2013-08-05 05:34:30 +0000 | [diff] [blame] | 270 | DROP TABLE IF EXISTS sqlite_stat4; |
drh | 08ccfaa | 2011-10-07 23:52:25 +0000 | [diff] [blame] | 271 | SELECT name FROM sqlite_master WHERE name GLOB 'sqlite_stat*'; |
| 272 | } |
| 273 | } {} |
| 274 | |
drh | 97ab32b | 2015-04-17 18:22:53 +0000 | [diff] [blame] | 275 | do_test table-5.2.2 { |
| 276 | db close |
| 277 | forcedelete test.db |
| 278 | sqlite3 db test.db |
| 279 | db eval { |
| 280 | CREATE TABLE t0(a,b); |
| 281 | CREATE INDEX t ON t0(a); |
| 282 | PRAGMA writable_schema=ON; |
| 283 | UPDATE sqlite_master SET sql='CREATE TABLE a.b(a UNIQUE'; |
| 284 | BEGIN; |
| 285 | CREATE TABLE t1(x); |
| 286 | ROLLBACK; |
| 287 | DROP TABLE IF EXISTS t99; |
| 288 | } |
| 289 | } {} |
| 290 | db close |
| 291 | forcedelete test.db |
| 292 | sqlite3 db test.db |
| 293 | |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 294 | # Make sure an EXPLAIN does not really create a new table |
| 295 | # |
| 296 | do_test table-5.3 { |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 297 | ifcapable {explain} { |
| 298 | execsql {EXPLAIN CREATE TABLE test1(f1 int)} |
| 299 | } |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 300 | execsql {SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 301 | } {} |
| 302 | |
| 303 | # Make sure an EXPLAIN does not really drop an existing table |
| 304 | # |
| 305 | do_test table-5.4 { |
| 306 | execsql {CREATE TABLE test1(f1 int)} |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 307 | ifcapable {explain} { |
| 308 | execsql {EXPLAIN DROP TABLE test1} |
| 309 | } |
drh | 2803757 | 2000-08-02 13:47:41 +0000 | [diff] [blame] | 310 | execsql {SELECT name FROM sqlite_master WHERE type!='meta'} |
drh | 1b6a71f | 2000-05-29 23:58:11 +0000 | [diff] [blame] | 311 | } {test1} |
| 312 | |
drh | 4cfa793 | 2000-06-08 15:10:46 +0000 | [diff] [blame] | 313 | # Create a table with a goofy name |
| 314 | # |
drh | 3fc190c | 2001-09-14 03:24:23 +0000 | [diff] [blame] | 315 | #do_test table-6.1 { |
| 316 | # execsql {CREATE TABLE 'Spaces In This Name!'(x int)} |
| 317 | # execsql {INSERT INTO 'spaces in this name!' VALUES(1)} |
| 318 | # set list [glob -nocomplain testdb/spaces*.tbl] |
| 319 | #} {testdb/spaces+in+this+name+.tbl} |
drh | 4cfa793 | 2000-06-08 15:10:46 +0000 | [diff] [blame] | 320 | |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 321 | # Try using keywords as table names or column names. |
| 322 | # |
| 323 | do_test table-7.1 { |
| 324 | set v [catch {execsql { |
| 325 | CREATE TABLE weird( |
| 326 | desc text, |
| 327 | asc text, |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 328 | key int, |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 329 | [14_vac] boolean, |
| 330 | fuzzy_dog_12 varchar(10), |
drh | d400728 | 2001-04-12 23:21:58 +0000 | [diff] [blame] | 331 | begin blob, |
| 332 | end clob |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 333 | ) |
| 334 | }} msg] |
| 335 | lappend v $msg |
| 336 | } {0 {}} |
| 337 | do_test table-7.2 { |
| 338 | execsql { |
drh | d400728 | 2001-04-12 23:21:58 +0000 | [diff] [blame] | 339 | INSERT INTO weird VALUES('a','b',9,0,'xyz','hi','y''all'); |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 340 | SELECT * FROM weird; |
| 341 | } |
drh | d400728 | 2001-04-12 23:21:58 +0000 | [diff] [blame] | 342 | } {a b 9 0 xyz hi y'all} |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 343 | do_test table-7.3 { |
| 344 | execsql2 { |
| 345 | SELECT * FROM weird; |
| 346 | } |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 347 | } {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all} |
danielk1977 | 78c2e6d | 2009-01-16 11:04:58 +0000 | [diff] [blame] | 348 | do_test table-7.3 { |
| 349 | execsql { |
| 350 | CREATE TABLE savepoint(release); |
| 351 | INSERT INTO savepoint(release) VALUES(10); |
| 352 | UPDATE savepoint SET release = 5; |
| 353 | SELECT release FROM savepoint; |
| 354 | } |
| 355 | } {5} |
drh | c4a3c77 | 2001-04-04 11:48:57 +0000 | [diff] [blame] | 356 | |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 357 | # Try out the CREATE TABLE AS syntax |
| 358 | # |
| 359 | do_test table-8.1 { |
| 360 | execsql2 { |
| 361 | CREATE TABLE t2 AS SELECT * FROM weird; |
| 362 | SELECT * FROM t2; |
| 363 | } |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 364 | } {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all} |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 365 | do_test table-8.1.1 { |
| 366 | execsql { |
| 367 | SELECT sql FROM sqlite_master WHERE name='t2'; |
| 368 | } |
| 369 | } {{CREATE TABLE t2( |
drh | c4a64fa | 2009-05-11 20:53:28 +0000 | [diff] [blame] | 370 | "desc" TEXT, |
| 371 | "asc" TEXT, |
| 372 | "key" INT, |
| 373 | "14_vac" NUM, |
| 374 | fuzzy_dog_12 TEXT, |
| 375 | "begin", |
| 376 | "end" TEXT |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 377 | )}} |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 378 | do_test table-8.2 { |
| 379 | execsql { |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 380 | CREATE TABLE "t3""xyz"(a,b,c); |
| 381 | INSERT INTO [t3"xyz] VALUES(1,2,3); |
| 382 | SELECT * FROM [t3"xyz]; |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 383 | } |
| 384 | } {1 2 3} |
| 385 | do_test table-8.3 { |
| 386 | execsql2 { |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 387 | CREATE TABLE [t4"abc] AS SELECT count(*) as cnt, max(b+c) FROM [t3"xyz]; |
| 388 | SELECT * FROM [t4"abc]; |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 389 | } |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 390 | } {cnt 1 max(b+c) 5} |
danielk1977 | 00e279d | 2004-06-21 07:36:32 +0000 | [diff] [blame] | 391 | |
| 392 | # Update for v3: The declaration type of anything except a column is now a |
| 393 | # NULL pointer, so the created table has no column types. (Changed result |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 394 | # from {{CREATE TABLE 't4"abc'(cnt NUMERIC,"max(b+c)" NUMERIC)}}). |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 395 | do_test table-8.3.1 { |
| 396 | execsql { |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 397 | SELECT sql FROM sqlite_master WHERE name='t4"abc' |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 398 | } |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 399 | } {{CREATE TABLE "t4""abc"(cnt,"max(b+c)")}} |
danielk1977 | 53c0f74 | 2005-03-29 03:10:59 +0000 | [diff] [blame] | 400 | |
| 401 | ifcapable tempdb { |
| 402 | do_test table-8.4 { |
| 403 | execsql2 { |
| 404 | CREATE TEMPORARY TABLE t5 AS SELECT count(*) AS [y'all] FROM [t3"xyz]; |
| 405 | SELECT * FROM t5; |
| 406 | } |
| 407 | } {y'all 1} |
| 408 | } |
| 409 | |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 410 | do_test table-8.5 { |
| 411 | db close |
drh | ef4ac8f | 2004-06-19 00:16:31 +0000 | [diff] [blame] | 412 | sqlite3 db test.db |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 413 | execsql2 { |
drh | 234c39d | 2004-07-24 03:30:47 +0000 | [diff] [blame] | 414 | SELECT * FROM [t4"abc]; |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 415 | } |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 416 | } {cnt 1 max(b+c) 5} |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 417 | do_test table-8.6 { |
| 418 | execsql2 { |
| 419 | SELECT * FROM t2; |
| 420 | } |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 421 | } {desc a asc b key 9 14_vac 0 fuzzy_dog_12 xyz begin hi end y'all} |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 422 | do_test table-8.7 { |
| 423 | catchsql { |
| 424 | SELECT * FROM t5; |
| 425 | } |
| 426 | } {1 {no such table: t5}} |
drh | 17f7193 | 2002-02-21 12:01:27 +0000 | [diff] [blame] | 427 | do_test table-8.8 { |
| 428 | catchsql { |
| 429 | CREATE TABLE t5 AS SELECT * FROM no_such_table; |
| 430 | } |
| 431 | } {1 {no such table: no_such_table}} |
drh | 969fa7c | 2002-02-18 18:30:32 +0000 | [diff] [blame] | 432 | |
danielk1977 | 1b870de | 2009-03-14 08:37:23 +0000 | [diff] [blame] | 433 | do_test table-8.9 { |
| 434 | execsql { |
| 435 | CREATE TABLE t10("col.1" [char.3]); |
| 436 | CREATE TABLE t11 AS SELECT * FROM t10; |
| 437 | SELECT sql FROM sqlite_master WHERE name = 't11'; |
| 438 | } |
drh | c4a64fa | 2009-05-11 20:53:28 +0000 | [diff] [blame] | 439 | } {{CREATE TABLE t11("col.1" TEXT)}} |
danielk1977 | 1b870de | 2009-03-14 08:37:23 +0000 | [diff] [blame] | 440 | do_test table-8.10 { |
| 441 | execsql { |
| 442 | CREATE TABLE t12( |
| 443 | a INTEGER, |
| 444 | b VARCHAR(10), |
| 445 | c VARCHAR(1,10), |
| 446 | d VARCHAR(+1,-10), |
| 447 | e VARCHAR (+1,-10), |
| 448 | f "VARCHAR (+1,-10, 5)", |
| 449 | g BIG INTEGER |
| 450 | ); |
| 451 | CREATE TABLE t13 AS SELECT * FROM t12; |
| 452 | SELECT sql FROM sqlite_master WHERE name = 't13'; |
| 453 | } |
| 454 | } {{CREATE TABLE t13( |
drh | c4a64fa | 2009-05-11 20:53:28 +0000 | [diff] [blame] | 455 | a INT, |
| 456 | b TEXT, |
| 457 | c TEXT, |
| 458 | d TEXT, |
| 459 | e TEXT, |
| 460 | f TEXT, |
| 461 | g INT |
danielk1977 | 1b870de | 2009-03-14 08:37:23 +0000 | [diff] [blame] | 462 | )}} |
| 463 | |
drh | 97fc3d0 | 2002-05-22 21:27:03 +0000 | [diff] [blame] | 464 | # Make sure we cannot have duplicate column names within a table. |
| 465 | # |
| 466 | do_test table-9.1 { |
| 467 | catchsql { |
| 468 | CREATE TABLE t6(a,b,a); |
| 469 | } |
| 470 | } {1 {duplicate column name: a}} |
drh | d891967 | 2005-09-10 15:35:06 +0000 | [diff] [blame] | 471 | do_test table-9.2 { |
| 472 | catchsql { |
| 473 | CREATE TABLE t6(a varchar(100), b blob, a integer); |
| 474 | } |
| 475 | } {1 {duplicate column name: a}} |
drh | 97fc3d0 | 2002-05-22 21:27:03 +0000 | [diff] [blame] | 476 | |
drh | 04738cb | 2002-06-02 18:19:00 +0000 | [diff] [blame] | 477 | # Check the foreign key syntax. |
| 478 | # |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 479 | ifcapable {foreignkey} { |
drh | 04738cb | 2002-06-02 18:19:00 +0000 | [diff] [blame] | 480 | do_test table-10.1 { |
| 481 | catchsql { |
| 482 | CREATE TABLE t6(a REFERENCES t4(a) NOT NULL); |
| 483 | INSERT INTO t6 VALUES(NULL); |
| 484 | } |
drh | f9c8ce3 | 2013-11-05 13:33:55 +0000 | [diff] [blame] | 485 | } {1 {NOT NULL constraint failed: t6.a}} |
drh | 04738cb | 2002-06-02 18:19:00 +0000 | [diff] [blame] | 486 | do_test table-10.2 { |
| 487 | catchsql { |
| 488 | DROP TABLE t6; |
| 489 | CREATE TABLE t6(a REFERENCES t4(a) MATCH PARTIAL); |
| 490 | } |
| 491 | } {0 {}} |
| 492 | do_test table-10.3 { |
| 493 | catchsql { |
| 494 | DROP TABLE t6; |
| 495 | CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON DELETE SET NULL NOT NULL); |
| 496 | } |
| 497 | } {0 {}} |
| 498 | do_test table-10.4 { |
| 499 | catchsql { |
| 500 | DROP TABLE t6; |
| 501 | CREATE TABLE t6(a REFERENCES t4 MATCH FULL ON UPDATE SET DEFAULT DEFAULT 1); |
| 502 | } |
| 503 | } {0 {}} |
| 504 | do_test table-10.5 { |
| 505 | catchsql { |
| 506 | DROP TABLE t6; |
| 507 | CREATE TABLE t6(a NOT NULL NOT DEFERRABLE INITIALLY IMMEDIATE); |
| 508 | } |
| 509 | } {0 {}} |
| 510 | do_test table-10.6 { |
| 511 | catchsql { |
| 512 | DROP TABLE t6; |
| 513 | CREATE TABLE t6(a NOT NULL DEFERRABLE INITIALLY DEFERRED); |
| 514 | } |
| 515 | } {0 {}} |
| 516 | do_test table-10.7 { |
| 517 | catchsql { |
| 518 | DROP TABLE t6; |
| 519 | CREATE TABLE t6(a, |
| 520 | FOREIGN KEY (a) REFERENCES t4(b) DEFERRABLE INITIALLY DEFERRED |
| 521 | ); |
| 522 | } |
| 523 | } {0 {}} |
| 524 | do_test table-10.8 { |
| 525 | catchsql { |
| 526 | DROP TABLE t6; |
| 527 | CREATE TABLE t6(a,b,c, |
| 528 | FOREIGN KEY (b,c) REFERENCES t4(x,y) MATCH PARTIAL |
| 529 | ON UPDATE SET NULL ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED |
| 530 | ); |
| 531 | } |
| 532 | } {0 {}} |
drh | c2eef3b | 2002-08-31 18:53:06 +0000 | [diff] [blame] | 533 | do_test table-10.9 { |
| 534 | catchsql { |
| 535 | DROP TABLE t6; |
| 536 | CREATE TABLE t6(a,b,c, |
| 537 | FOREIGN KEY (b,c) REFERENCES t4(x) |
| 538 | ); |
| 539 | } |
| 540 | } {1 {number of columns in foreign key does not match the number of columns in the referenced table}} |
| 541 | do_test table-10.10 { |
| 542 | catchsql {DROP TABLE t6} |
| 543 | catchsql { |
| 544 | CREATE TABLE t6(a,b,c, |
| 545 | FOREIGN KEY (b,c) REFERENCES t4(x,y,z) |
| 546 | ); |
| 547 | } |
| 548 | } {1 {number of columns in foreign key does not match the number of columns in the referenced table}} |
| 549 | do_test table-10.11 { |
| 550 | catchsql {DROP TABLE t6} |
| 551 | catchsql { |
| 552 | CREATE TABLE t6(a,b, c REFERENCES t4(x,y)); |
| 553 | } |
| 554 | } {1 {foreign key on c should reference only one column of table t4}} |
| 555 | do_test table-10.12 { |
| 556 | catchsql {DROP TABLE t6} |
| 557 | catchsql { |
| 558 | CREATE TABLE t6(a,b,c, |
| 559 | FOREIGN KEY (b,x) REFERENCES t4(x,y) |
| 560 | ); |
| 561 | } |
| 562 | } {1 {unknown column "x" in foreign key definition}} |
| 563 | do_test table-10.13 { |
| 564 | catchsql {DROP TABLE t6} |
| 565 | catchsql { |
| 566 | CREATE TABLE t6(a,b,c, |
| 567 | FOREIGN KEY (x,b) REFERENCES t4(x,y) |
| 568 | ); |
| 569 | } |
| 570 | } {1 {unknown column "x" in foreign key definition}} |
drh | 6bf8957 | 2004-11-03 16:27:01 +0000 | [diff] [blame] | 571 | } ;# endif foreignkey |
drh | 04738cb | 2002-06-02 18:19:00 +0000 | [diff] [blame] | 572 | |
danielk1977 | 35bb9d0 | 2004-05-24 12:55:54 +0000 | [diff] [blame] | 573 | # Test for the "typeof" function. More tests for the |
| 574 | # typeof() function are found in bind.test and types.test. |
drh | 38640e1 | 2002-07-05 21:42:36 +0000 | [diff] [blame] | 575 | # |
| 576 | do_test table-11.1 { |
| 577 | execsql { |
| 578 | CREATE TABLE t7( |
| 579 | a integer primary key, |
| 580 | b number(5,10), |
| 581 | c character varying (8), |
| 582 | d VARCHAR(9), |
| 583 | e clob, |
| 584 | f BLOB, |
| 585 | g Text, |
| 586 | h |
| 587 | ); |
| 588 | INSERT INTO t7(a) VALUES(1); |
| 589 | SELECT typeof(a), typeof(b), typeof(c), typeof(d), |
| 590 | typeof(e), typeof(f), typeof(g), typeof(h) |
| 591 | FROM t7 LIMIT 1; |
| 592 | } |
danielk1977 | 35bb9d0 | 2004-05-24 12:55:54 +0000 | [diff] [blame] | 593 | } {integer null null null null null null null} |
drh | 38640e1 | 2002-07-05 21:42:36 +0000 | [diff] [blame] | 594 | do_test table-11.2 { |
| 595 | execsql { |
| 596 | SELECT typeof(a+b), typeof(a||b), typeof(c+d), typeof(c||d) |
| 597 | FROM t7 LIMIT 1; |
| 598 | } |
danielk1977 | 35bb9d0 | 2004-05-24 12:55:54 +0000 | [diff] [blame] | 599 | } {null null null null} |
drh | 97fc3d0 | 2002-05-22 21:27:03 +0000 | [diff] [blame] | 600 | |
danielk1977 | 00e279d | 2004-06-21 07:36:32 +0000 | [diff] [blame] | 601 | # Test that when creating a table using CREATE TABLE AS, column types are |
| 602 | # assigned correctly for (SELECT ...) and 'x AS y' expressions. |
| 603 | do_test table-12.1 { |
danielk1977 | 3e8c37e | 2005-01-21 03:12:14 +0000 | [diff] [blame] | 604 | ifcapable subquery { |
| 605 | execsql { |
| 606 | CREATE TABLE t8 AS SELECT b, h, a as i, (SELECT f FROM t7) as j FROM t7; |
| 607 | } |
| 608 | } else { |
| 609 | execsql { |
| 610 | CREATE TABLE t8 AS SELECT b, h, a as i, f as j FROM t7; |
| 611 | } |
danielk1977 | 00e279d | 2004-06-21 07:36:32 +0000 | [diff] [blame] | 612 | } |
| 613 | } {} |
| 614 | do_test table-12.2 { |
| 615 | execsql { |
| 616 | SELECT sql FROM sqlite_master WHERE tbl_name = 't8' |
| 617 | } |
drh | c4a64fa | 2009-05-11 20:53:28 +0000 | [diff] [blame] | 618 | } {{CREATE TABLE t8(b NUM,h,i INT,j)}} |
danielk1977 | 00e279d | 2004-06-21 07:36:32 +0000 | [diff] [blame] | 619 | |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 620 | #-------------------------------------------------------------------- |
| 621 | # Test cases table-13.* |
| 622 | # |
danielk1977 | 7977a17 | 2004-11-09 12:44:37 +0000 | [diff] [blame] | 623 | # Test the ability to have default values of CURRENT_TIME, CURRENT_DATE |
| 624 | # and CURRENT_TIMESTAMP. |
| 625 | # |
| 626 | do_test table-13.1 { |
| 627 | execsql { |
| 628 | CREATE TABLE tablet8( |
| 629 | a integer primary key, |
| 630 | tm text DEFAULT CURRENT_TIME, |
| 631 | dt text DEFAULT CURRENT_DATE, |
| 632 | dttm text DEFAULT CURRENT_TIMESTAMP |
| 633 | ); |
| 634 | SELECT * FROM tablet8; |
| 635 | } |
| 636 | } {} |
| 637 | set i 0 |
drh | d0b2677 | 2010-05-03 19:20:46 +0000 | [diff] [blame] | 638 | unset -nocomplain date time seconds |
drh | 9645d8d | 2006-09-01 15:49:05 +0000 | [diff] [blame] | 639 | foreach {date time seconds} { |
| 640 | 1976-07-04 12:00:00 205329600 |
| 641 | 1994-04-16 14:00:00 766504800 |
| 642 | 2000-01-01 00:00:00 946684800 |
| 643 | 2003-12-31 12:34:56 1072874096 |
danielk1977 | 7977a17 | 2004-11-09 12:44:37 +0000 | [diff] [blame] | 644 | } { |
| 645 | incr i |
drh | 9645d8d | 2006-09-01 15:49:05 +0000 | [diff] [blame] | 646 | set sqlite_current_time $seconds |
danielk1977 | 7977a17 | 2004-11-09 12:44:37 +0000 | [diff] [blame] | 647 | do_test table-13.2.$i { |
| 648 | execsql " |
| 649 | INSERT INTO tablet8(a) VALUES($i); |
| 650 | SELECT tm, dt, dttm FROM tablet8 WHERE a=$i; |
| 651 | " |
| 652 | } [list $time $date [list $date $time]] |
| 653 | } |
| 654 | set sqlite_current_time 0 |
| 655 | |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 656 | #-------------------------------------------------------------------- |
| 657 | # Test cases table-14.* |
| 658 | # |
| 659 | # Test that a table cannot be created or dropped while other virtual |
| 660 | # machines are active. This is required because otherwise when in |
| 661 | # auto-vacuum mode the btree-layer may need to move the root-pages of |
| 662 | # a table for which there is an open cursor. |
| 663 | # |
drh | b7af445 | 2007-05-02 17:54:55 +0000 | [diff] [blame] | 664 | # 2007-05-02: A open btree cursor no longer blocks CREATE TABLE. |
| 665 | # But DROP TABLE is still prohibited because we do not want to |
| 666 | # delete a table out from under a running query. |
| 667 | # |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 668 | |
danielk1977 | a21c6b6 | 2005-01-24 10:25:59 +0000 | [diff] [blame] | 669 | # db eval { |
| 670 | # pragma vdbe_trace = 0; |
| 671 | # } |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 672 | # Try to create a table from within a callback: |
drh | 251b067 | 2004-11-23 22:16:39 +0000 | [diff] [blame] | 673 | unset -nocomplain result |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 674 | do_test table-14.1 { |
| 675 | set rc [ |
| 676 | catch { |
| 677 | db eval {SELECT * FROM tablet8 LIMIT 1} {} { |
| 678 | db eval {CREATE TABLE t9(a, b, c)} |
| 679 | } |
| 680 | } msg |
| 681 | ] |
| 682 | set result [list $rc $msg] |
drh | b7af445 | 2007-05-02 17:54:55 +0000 | [diff] [blame] | 683 | } {0 {}} |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 684 | |
| 685 | # Try to drop a table from within a callback: |
danielk1977 | 5a8f937 | 2007-10-09 08:29:32 +0000 | [diff] [blame] | 686 | do_test table-14.2 { |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 687 | set rc [ |
| 688 | catch { |
| 689 | db eval {SELECT * FROM tablet8 LIMIT 1} {} { |
| 690 | db eval {DROP TABLE t9;} |
| 691 | } |
| 692 | } msg |
| 693 | ] |
| 694 | set result [list $rc $msg] |
| 695 | } {1 {database table is locked}} |
| 696 | |
danielk1977 | 5a8f937 | 2007-10-09 08:29:32 +0000 | [diff] [blame] | 697 | ifcapable attach { |
| 698 | # Now attach a database and ensure that a table can be created in the |
| 699 | # attached database whilst in a callback from a query on the main database. |
| 700 | do_test table-14.3 { |
mistachkin | fda06be | 2011-08-02 00:57:34 +0000 | [diff] [blame] | 701 | forcedelete test2.db |
| 702 | forcedelete test2.db-journal |
danielk1977 | 5a8f937 | 2007-10-09 08:29:32 +0000 | [diff] [blame] | 703 | execsql { |
| 704 | ATTACH 'test2.db' as aux; |
| 705 | } |
| 706 | db eval {SELECT * FROM tablet8 LIMIT 1} {} { |
| 707 | db eval {CREATE TABLE aux.t1(a, b, c)} |
| 708 | } |
| 709 | } {} |
| 710 | |
| 711 | # On the other hand, it should be impossible to drop a table when any VMs |
| 712 | # are active. This is because VerifyCookie instructions may have already |
| 713 | # been executed, and btree root-pages may not move after this (which a |
| 714 | # delete table might do). |
| 715 | do_test table-14.4 { |
| 716 | set rc [ |
| 717 | catch { |
| 718 | db eval {SELECT * FROM tablet8 LIMIT 1} {} { |
| 719 | db eval {DROP TABLE aux.t1;} |
| 720 | } |
| 721 | } msg |
| 722 | ] |
| 723 | set result [list $rc $msg] |
| 724 | } {1 {database table is locked}} |
| 725 | } |
danielk1977 | e6efa74 | 2004-11-10 11:55:10 +0000 | [diff] [blame] | 726 | |
danielk1977 | ae82558 | 2004-11-23 09:06:55 +0000 | [diff] [blame] | 727 | # Create and drop 2000 tables. This is to check that the balance_shallow() |
| 728 | # routine works correctly on the sqlite_master table. At one point it |
| 729 | # contained a bug that would prevent the right-child pointer of the |
| 730 | # child page from being copied to the root page. |
| 731 | # |
| 732 | do_test table-15.1 { |
| 733 | execsql {BEGIN} |
| 734 | for {set i 0} {$i<2000} {incr i} { |
| 735 | execsql "CREATE TABLE tbl$i (a, b, c)" |
| 736 | } |
| 737 | execsql {COMMIT} |
| 738 | } {} |
| 739 | do_test table-15.2 { |
| 740 | execsql {BEGIN} |
| 741 | for {set i 0} {$i<2000} {incr i} { |
| 742 | execsql "DROP TABLE tbl$i" |
| 743 | } |
| 744 | execsql {COMMIT} |
| 745 | } {} |
| 746 | |
drh | 1cfc9aa | 2014-08-05 21:31:08 +0000 | [diff] [blame] | 747 | # Ticket 3a88d85f36704eebe134f7f48aebf00cd6438c1a (2014-08-05) |
| 748 | # The following SQL script segfaults while running the INSERT statement: |
| 749 | # |
| 750 | # CREATE TABLE t1(x DEFAULT(max(1))); |
| 751 | # INSERT INTO t1(rowid) VALUES(1); |
| 752 | # |
| 753 | # The problem appears to be the use of an aggregate function as part of |
| 754 | # the default value for a column. This problem has been in the code since |
| 755 | # at least 2006-01-01 and probably before that. This problem was detected |
| 756 | # and reported on the sqlite-users@sqlite.org mailing list by Zsbán Ambrus. |
| 757 | # |
| 758 | do_execsql_test table-16.1 { |
| 759 | CREATE TABLE t16(x DEFAULT(max(1))); |
| 760 | INSERT INTO t16(x) VALUES(123); |
| 761 | SELECT rowid, x FROM t16; |
| 762 | } {1 123} |
| 763 | do_catchsql_test table-16.2 { |
| 764 | INSERT INTO t16(rowid) VALUES(4); |
drh | 0c4de2d | 2014-08-06 00:29:06 +0000 | [diff] [blame] | 765 | } {1 {unknown function: max()}} |
drh | 1cfc9aa | 2014-08-05 21:31:08 +0000 | [diff] [blame] | 766 | do_execsql_test table-16.3 { |
| 767 | DROP TABLE t16; |
| 768 | CREATE TABLE t16(x DEFAULT(abs(1))); |
| 769 | INSERT INTO t16(rowid) VALUES(4); |
| 770 | SELECT rowid, x FROM t16; |
| 771 | } {4 1} |
| 772 | do_catchsql_test table-16.4 { |
| 773 | DROP TABLE t16; |
| 774 | CREATE TABLE t16(x DEFAULT(avg(1))); |
| 775 | INSERT INTO t16(rowid) VALUES(123); |
| 776 | SELECT rowid, x FROM t16; |
drh | 0c4de2d | 2014-08-06 00:29:06 +0000 | [diff] [blame] | 777 | } {1 {unknown function: avg()}} |
drh | 1cfc9aa | 2014-08-05 21:31:08 +0000 | [diff] [blame] | 778 | do_catchsql_test table-16.5 { |
| 779 | DROP TABLE t16; |
| 780 | CREATE TABLE t16(x DEFAULT(count())); |
| 781 | INSERT INTO t16(rowid) VALUES(123); |
| 782 | SELECT rowid, x FROM t16; |
drh | 0c4de2d | 2014-08-06 00:29:06 +0000 | [diff] [blame] | 783 | } {1 {unknown function: count()}} |
drh | 1cfc9aa | 2014-08-05 21:31:08 +0000 | [diff] [blame] | 784 | do_catchsql_test table-16.6 { |
| 785 | DROP TABLE t16; |
| 786 | CREATE TABLE t16(x DEFAULT(group_concat('x',','))); |
| 787 | INSERT INTO t16(rowid) VALUES(123); |
| 788 | SELECT rowid, x FROM t16; |
drh | 0c4de2d | 2014-08-06 00:29:06 +0000 | [diff] [blame] | 789 | } {1 {unknown function: group_concat()}} |
| 790 | do_catchsql_test table-16.7 { |
| 791 | INSERT INTO t16 DEFAULT VALUES; |
| 792 | } {1 {unknown function: group_concat()}} |
drh | 1cfc9aa | 2014-08-05 21:31:08 +0000 | [diff] [blame] | 793 | |
drh | 6b5631e | 2014-11-05 15:57:39 +0000 | [diff] [blame] | 794 | # Ticket [https://www.sqlite.org/src/info/094d39a4c95ee4abbc417f04214617675ba15c63] |
| 795 | # describes a assertion fault that occurs on a CREATE TABLE .. AS SELECT statement. |
| 796 | # the following test verifies that the problem has been fixed. |
| 797 | # |
| 798 | do_execsql_test table-17.1 { |
| 799 | DROP TABLE IF EXISTS t1; |
| 800 | CREATE TABLE t1(a TEXT); |
| 801 | INSERT INTO t1(a) VALUES(1),(2); |
| 802 | DROP TABLE IF EXISTS t2; |
| 803 | CREATE TABLE t2(x TEXT, y TEXT); |
| 804 | INSERT INTO t2(x,y) VALUES(3,4); |
| 805 | DROP TABLE IF EXISTS t3; |
| 806 | CREATE TABLE t3 AS |
| 807 | SELECT a AS p, coalesce(y,a) AS q FROM t1 LEFT JOIN t2 ON a=x; |
| 808 | SELECT p, q, '|' FROM t3 ORDER BY p; |
| 809 | } {1 1 | 2 2 |} |
| 810 | |
drh | 0dd5cda | 2015-06-16 16:39:01 +0000 | [diff] [blame] | 811 | # 2015-06-16 |
| 812 | # Ticket [https://www.sqlite.org/src/tktview/873cae2b6e25b1991ce5e9b782f9cd0409b96063] |
| 813 | # Make sure a CREATE TABLE AS statement correctly rolls back partial changes to the |
| 814 | # sqlite_master table when the SELECT on the right-hand side aborts. |
| 815 | # |
| 816 | do_catchsql_test table-18.1 { |
| 817 | DROP TABLE IF EXISTS t1; |
| 818 | BEGIN; |
| 819 | CREATE TABLE t1 AS SELECT zeroblob(2e20); |
| 820 | } {1 {string or blob too big}} |
| 821 | do_execsql_test table-18.2 { |
| 822 | COMMIT; |
| 823 | PRAGMA integrity_check; |
| 824 | } {ok} |
| 825 | |
drh | 3c03afd | 2015-09-09 13:28:06 +0000 | [diff] [blame] | 826 | # 2015-09-09 |
| 827 | # Ticket [https://www.sqlite.org/src/info/acd12990885d9276] |
| 828 | # "CREATE TABLE ... AS SELECT ... FROM sqlite_master" fails because the row |
| 829 | # in the sqlite_master table for the next table is initially populated |
| 830 | # with a NULL instead of a record created by OP_Record. |
| 831 | # |
| 832 | do_execsql_test table-19.1 { |
| 833 | CREATE TABLE t19 AS SELECT * FROM sqlite_master; |
| 834 | SELECT name FROM t19 ORDER BY name; |
| 835 | } {{} savepoint t10 t11 t12 t13 t16 t2 t3 t3\"xyz t4\"abc t7 t8 t9 tablet8 test1 weird} |
| 836 | |
| 837 | |
drh | 0dd5cda | 2015-06-16 16:39:01 +0000 | [diff] [blame] | 838 | |
drh | 348784e | 2000-05-29 20:41:49 +0000 | [diff] [blame] | 839 | finish_test |