1# 2005 February 19 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. The 12# focus of this script is testing that SQLite can handle a subtle 13# file format change that may be used in the future to implement 14# "ALTER TABLE ... ADD COLUMN". 15# 16# $Id: alter3.test,v 1.8 2006/01/16 16:24:25 danielk1977 Exp $ 17# 18 19set testdir [file dirname $argv0] 20 21source $testdir/tester.tcl 22 23# If SQLITE_OMIT_ALTERTABLE is defined, omit this file. 24ifcapable !altertable { 25 finish_test 26 return 27} 28 29# Determine if there is a codec available on this test. 30# 31if {[catch {sqlite3 -has_codec} r] || $r} { 32 set has_codec 1 33} else { 34 set has_codec 0 35} 36 37 38# Test Organisation: 39# ------------------ 40# 41# alter3-1.*: Test that ALTER TABLE correctly modifies the CREATE TABLE sql. 42# alter3-2.*: Test error messages. 43# alter3-3.*: Test adding columns with default value NULL. 44# alter3-4.*: Test adding columns with default values other than NULL. 45# alter3-5.*: Test adding columns to tables in ATTACHed databases. 46# alter3-6.*: Test that temp triggers are not accidentally dropped. 47# alter3-7.*: Test that VACUUM resets the file-format. 48# 49 50# This procedure returns the value of the file-format in file 'test.db'. 51# 52proc get_file_format {{fname test.db}} { 53 set bt [btree_open $fname 10 0] 54 set meta [btree_get_meta $bt] 55 btree_close $bt 56 lindex $meta 2 57} 58 59do_test alter3-1.1 { 60 execsql { 61 CREATE TABLE abc(a, b, c); 62 SELECT sql FROM sqlite_master; 63 } 64} {{CREATE TABLE abc(a, b, c)}} 65do_test alter3-1.2 { 66 execsql {ALTER TABLE abc ADD d INTEGER;} 67 execsql { 68 SELECT sql FROM sqlite_master; 69 } 70} {{CREATE TABLE abc(a, b, c, d INTEGER)}} 71do_test alter3-1.3 { 72 execsql {ALTER TABLE abc ADD e} 73 execsql { 74 SELECT sql FROM sqlite_master; 75 } 76} {{CREATE TABLE abc(a, b, c, d INTEGER, e)}} 77do_test alter3-1.4 { 78 execsql { 79 CREATE TABLE main.t1(a, b); 80 ALTER TABLE t1 ADD c; 81 SELECT sql FROM sqlite_master WHERE tbl_name = 't1'; 82 } 83} {{CREATE TABLE t1(a, b, c)}} 84do_test alter3-1.5 { 85 execsql { 86 ALTER TABLE t1 ADD d CHECK (a>d); 87 SELECT sql FROM sqlite_master WHERE tbl_name = 't1'; 88 } 89} {{CREATE TABLE t1(a, b, c, d CHECK (a>d))}} 90ifcapable foreignkey { 91 do_test alter3-1.6 { 92 execsql { 93 CREATE TABLE t2(a, b, UNIQUE(a, b)); 94 ALTER TABLE t2 ADD c REFERENCES t1(c) ; 95 SELECT sql FROM sqlite_master WHERE tbl_name = 't2' AND type = 'table'; 96 } 97 } {{CREATE TABLE t2(a, b, c REFERENCES t1(c), UNIQUE(a, b))}} 98} 99do_test alter3-1.7 { 100 execsql { 101 CREATE TABLE t3(a, b, UNIQUE(a, b)); 102 ALTER TABLE t3 ADD COLUMN c VARCHAR(10, 20); 103 SELECT sql FROM sqlite_master WHERE tbl_name = 't3' AND type = 'table'; 104 } 105} {{CREATE TABLE t3(a, b, c VARCHAR(10, 20), UNIQUE(a, b))}} 106do_test alter3-1.99 { 107 catchsql { 108 # May not exist if foriegn-keys are omitted at compile time. 109 DROP TABLE t2; 110 } 111 execsql { 112 DROP TABLE abc; 113 DROP TABLE t1; 114 DROP TABLE t3; 115 } 116} {} 117 118do_test alter3-2.1 { 119 execsql { 120 CREATE TABLE t1(a, b); 121 } 122 catchsql { 123 ALTER TABLE t1 ADD c PRIMARY KEY; 124 } 125} {1 {Cannot add a PRIMARY KEY column}} 126do_test alter3-2.2 { 127 catchsql { 128 ALTER TABLE t1 ADD c UNIQUE 129 } 130} {1 {Cannot add a UNIQUE column}} 131do_test alter3-2.3 { 132 catchsql { 133 ALTER TABLE t1 ADD b VARCHAR(10) 134 } 135} {1 {duplicate column name: b}} 136do_test alter3-2.3 { 137 catchsql { 138 ALTER TABLE t1 ADD c NOT NULL; 139 } 140} {1 {Cannot add a NOT NULL column with default value NULL}} 141do_test alter3-2.4 { 142 catchsql { 143 ALTER TABLE t1 ADD c NOT NULL DEFAULT 10; 144 } 145} {0 {}} 146do_test alter3-2.5 { 147 execsql { 148 CREATE VIEW v1 AS SELECT * FROM t1; 149 } 150 catchsql { 151 alter table v1 add column d; 152 } 153} {1 {Cannot add a column to a view}} 154do_test alter3-2.6 { 155 catchsql { 156 alter table t1 add column d DEFAULT CURRENT_TIME; 157 } 158} {1 {Cannot add a column with non-constant default}} 159do_test alter3-2.99 { 160 execsql { 161 DROP TABLE t1; 162 } 163} {} 164 165do_test alter3-3.1 { 166 execsql { 167 CREATE TABLE t1(a, b); 168 INSERT INTO t1 VALUES(1, 100); 169 INSERT INTO t1 VALUES(2, 300); 170 SELECT * FROM t1; 171 } 172} {1 100 2 300} 173do_test alter3-3.1 { 174 execsql { 175 PRAGMA schema_version = 10; 176 } 177} {} 178do_test alter3-3.2 { 179 execsql { 180 ALTER TABLE t1 ADD c; 181 SELECT * FROM t1; 182 } 183} {1 100 {} 2 300 {}} 184if {!$has_codec} { 185 do_test alter3-3.3 { 186 get_file_format 187 } {3} 188} 189do_test alter3-3.4 { 190 execsql { 191 PRAGMA schema_version; 192 } 193} {11} 194 195do_test alter3-4.1 { 196 db close 197 file delete -force test.db 198 set ::DB [sqlite3 db test.db] 199 execsql { 200 CREATE TABLE t1(a, b); 201 INSERT INTO t1 VALUES(1, 100); 202 INSERT INTO t1 VALUES(2, 300); 203 SELECT * FROM t1; 204 } 205} {1 100 2 300} 206do_test alter3-4.1 { 207 execsql { 208 PRAGMA schema_version = 20; 209 } 210} {} 211do_test alter3-4.2 { 212 execsql { 213 ALTER TABLE t1 ADD c DEFAULT 'hello world'; 214 SELECT * FROM t1; 215 } 216} {1 100 {hello world} 2 300 {hello world}} 217if {!$has_codec} { 218 do_test alter3-4.3 { 219 get_file_format 220 } {3} 221} 222do_test alter3-4.4 { 223 execsql { 224 PRAGMA schema_version; 225 } 226} {21} 227do_test alter3-4.99 { 228 execsql { 229 DROP TABLE t1; 230 } 231} {} 232 233do_test alter3-5.1 { 234 file delete -force test2.db 235 file delete -force test2.db-journal 236 execsql { 237 CREATE TABLE t1(a, b); 238 INSERT INTO t1 VALUES(1, 'one'); 239 INSERT INTO t1 VALUES(2, 'two'); 240 ATTACH 'test2.db' AS aux; 241 CREATE TABLE aux.t1 AS SELECT * FROM t1; 242 PRAGMA aux.schema_version = 30; 243 SELECT sql FROM aux.sqlite_master; 244 } 245} {{CREATE TABLE t1(a,b)}} 246do_test alter3-5.2 { 247 execsql { 248 ALTER TABLE aux.t1 ADD COLUMN c VARCHAR(128); 249 SELECT sql FROM aux.sqlite_master; 250 } 251} {{CREATE TABLE t1(a,b, c VARCHAR(128))}} 252do_test alter3-5.3 { 253 execsql { 254 SELECT * FROM aux.t1; 255 } 256} {1 one {} 2 two {}} 257do_test alter3-5.4 { 258 execsql { 259 PRAGMA aux.schema_version; 260 } 261} {31} 262if {!$has_codec} { 263 do_test alter3-5.5 { 264 list [get_file_format test2.db] [get_file_format] 265 } {2 3} 266} 267do_test alter3-5.6 { 268 execsql { 269 ALTER TABLE aux.t1 ADD COLUMN d DEFAULT 1000; 270 SELECT sql FROM aux.sqlite_master; 271 } 272} {{CREATE TABLE t1(a,b, c VARCHAR(128), d DEFAULT 1000)}} 273do_test alter3-5.7 { 274 execsql { 275 SELECT * FROM aux.t1; 276 } 277} {1 one {} 1000 2 two {} 1000} 278do_test alter3-5.8 { 279 execsql { 280 PRAGMA aux.schema_version; 281 } 282} {32} 283do_test alter3-5.9 { 284 execsql { 285 SELECT * FROM t1; 286 } 287} {1 one 2 two} 288do_test alter3-5.99 { 289 execsql { 290 DROP TABLE aux.t1; 291 DROP TABLE t1; 292 } 293} {} 294 295#---------------------------------------------------------------- 296# Test that the table schema is correctly reloaded when a column 297# is added to a table. 298# 299ifcapable trigger&&tempdb { 300 do_test alter3-6.1 { 301 execsql { 302 CREATE TABLE t1(a, b); 303 CREATE TABLE log(trig, a, b); 304 305 CREATE TRIGGER t1_a AFTER INSERT ON t1 BEGIN 306 INSERT INTO log VALUES('a', new.a, new.b); 307 END; 308 CREATE TEMP TRIGGER t1_b AFTER INSERT ON t1 BEGIN 309 INSERT INTO log VALUES('b', new.a, new.b); 310 END; 311 312 INSERT INTO t1 VALUES(1, 2); 313 SELECT * FROM log; 314 } 315 } {b 1 2 a 1 2} 316 do_test alter3-6.2 { 317 execsql { 318 ALTER TABLE t1 ADD COLUMN c DEFAULT 'c'; 319 INSERT INTO t1(a, b) VALUES(3, 4); 320 SELECT * FROM log; 321 } 322 } {b 1 2 a 1 2 b 3 4 a 3 4} 323} 324 325if {!$has_codec} { 326 ifcapable vacuum { 327 do_test alter3-7.1 { 328 execsql { 329 VACUUM; 330 } 331 get_file_format 332 } {1} 333 do_test alter3-7.2 { 334 execsql { 335 CREATE TABLE abc(a, b, c); 336 ALTER TABLE abc ADD d DEFAULT NULL; 337 } 338 get_file_format 339 } {2} 340 do_test alter3-7.3 { 341 execsql { 342 ALTER TABLE abc ADD e DEFAULT 10; 343 } 344 get_file_format 345 } {3} 346 do_test alter3-7.4 { 347 execsql { 348 ALTER TABLE abc ADD f DEFAULT NULL; 349 } 350 get_file_format 351 } {3} 352 do_test alter3-7.5 { 353 execsql { 354 VACUUM; 355 } 356 get_file_format 357 } {1} 358 } 359} 360 361# Ticket #1183 - Make sure adding columns to large tables does not cause 362# memory corruption (as was the case before this bug was fixed). 363do_test alter3-8.1 { 364 execsql { 365 CREATE TABLE t4(c1); 366 } 367} {} 368set ::sql "" 369do_test alter3-8.2 { 370 set cols c1 371 for {set i 2} {$i < 100} {incr i} { 372 execsql " 373 ALTER TABLE t4 ADD c$i 374 " 375 lappend cols c$i 376 } 377 set ::sql "CREATE TABLE t4([join $cols {, }])" 378 list 379} {} 380do_test alter3-8.2 { 381 execsql { 382 SELECT sql FROM sqlite_master WHERE name = 't4'; 383 } 384} [list $::sql] 385 386finish_test 387