1# 2010 August 4 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# 12# The focus of this file is testing the CLI shell tool. 13# These tests are specific to the .import command. 14# 15# $Id: shell5.test,v 1.7 2009/07/17 16:54:48 shaneh Exp $ 16# 17 18# Test plan: 19# 20# shell5-1.*: Basic tests specific to the ".import" command. 21# 22set testdir [file dirname $argv0] 23source $testdir/tester.tcl 24set CLI [test_find_cli] 25db close 26forcedelete test.db test.db-journal test.db-wal 27 28#---------------------------------------------------------------------------- 29# Test cases shell5-1.*: Basic handling of the .import and .separator commands. 30# 31 32# .import FILE TABLE Import data from FILE into TABLE 33do_test shell5-1.1.1 { 34 catchcmd "test.db" ".import" 35} {1 {Usage: .import FILE TABLE}} 36do_test shell5-1.1.2 { 37 catchcmd "test.db" ".import FOO" 38} {1 {Usage: .import FILE TABLE}} 39#do_test shell5-1.1.2 { 40# catchcmd "test.db" ".import FOO BAR" 41#} {1 {Error: no such table: BAR}} 42do_test shell5-1.1.3 { 43 # too many arguments 44 catchcmd "test.db" ".import FOO BAR BAD" 45} {1 {Usage: .import FILE TABLE}} 46 47# .separator STRING Change separator used by output mode and .import 48do_test shell5-1.2.1 { 49 catchcmd "test.db" ".separator" 50} {1 {Usage: .separator COL ?ROW?}} 51do_test shell5-1.2.2 { 52 catchcmd "test.db" ".separator ONE" 53} {0 {}} 54do_test shell5-1.2.3 { 55 catchcmd "test.db" ".separator ONE TWO" 56} {0 {}} 57do_test shell5-1.2.4 { 58 # too many arguments 59 catchcmd "test.db" ".separator ONE TWO THREE" 60} {1 {Usage: .separator COL ?ROW?}} 61 62# column separator should default to "|" 63do_test shell5-1.3.1.1 { 64 set res [catchcmd "test.db" ".show"] 65 list [regexp {colseparator: \"\|\"} $res] 66} {1} 67 68# row separator should default to "\n" 69do_test shell5-1.3.1.2 { 70 set res [catchcmd "test.db" ".show"] 71 list [regexp {rowseparator: \"\\n\"} $res] 72} {1} 73 74# set separator to different value. 75# check that .show reports new value 76do_test shell5-1.3.2 { 77 set res [catchcmd "test.db" {.separator , 78.show}] 79 list [regexp {separator: \",\"} $res] 80} {1} 81 82# import file doesn't exist 83do_test shell5-1.4.1 { 84 forcedelete FOO 85 set res [catchcmd "test.db" {CREATE TABLE t1(a, b); 86.import FOO t1}] 87} {1 {Error: cannot open "FOO"}} 88 89# empty import file 90do_test shell5-1.4.2 { 91 forcedelete shell5.csv 92 set in [open shell5.csv w] 93 close $in 94 set res [catchcmd "test.db" {.import shell5.csv t1 95SELECT COUNT(*) FROM t1;}] 96} {0 0} 97 98# import file with 1 row, 1 column (expecting 2 cols) 99do_test shell5-1.4.3 { 100 set in [open shell5.csv w] 101 puts $in "1" 102 close $in 103 set res [catchcmd "test.db" {.import shell5.csv t1}] 104} {1 {shell5.csv:1: expected 2 columns but found 1 - filling the rest with NULL}} 105 106# import file with 1 row, 3 columns (expecting 2 cols) 107do_test shell5-1.4.4 { 108 set in [open shell5.csv w] 109 puts $in "1|2|3" 110 close $in 111 set res [catchcmd "test.db" {.import shell5.csv t1}] 112} {1 {shell5.csv:1: expected 2 columns but found 3 - extras ignored}} 113 114# import file with 1 row, 2 columns 115do_test shell5-1.4.5 { 116 set in [open shell5.csv w] 117 puts $in "1|2" 118 close $in 119 set res [catchcmd "test.db" {DELETE FROM t1; 120.import shell5.csv t1 121SELECT COUNT(*) FROM t1;}] 122} {0 1} 123 124# import file with 2 rows, 2 columns 125# note we end up with 3 rows because of the 1 row 126# imported above. 127do_test shell5-1.4.6 { 128 set in [open shell5.csv w] 129 puts $in "2|3" 130 puts $in "3|4" 131 close $in 132 set res [catchcmd "test.db" {.import shell5.csv t1 133SELECT COUNT(*) FROM t1;}] 134} {0 3} 135 136# import file with 1 row, 2 columns, using a comma 137do_test shell5-1.4.7 { 138 set in [open shell5.csv w] 139 puts $in "4,5" 140 close $in 141 set res [catchcmd "test.db" {.separator , 142.import shell5.csv t1 143SELECT COUNT(*) FROM t1;}] 144} {0 4} 145 146# import file with 1 row, 2 columns, text data 147do_test shell5-1.4.8.1 { 148 set in [open shell5.csv w] 149 puts $in "5|Now is the time for all good men to come to the aid of their country." 150 close $in 151 set res [catchcmd "test.db" {.import shell5.csv t1 152SELECT COUNT(*) FROM t1;}] 153} {0 5} 154 155do_test shell5-1.4.8.2 { 156 catchcmd "test.db" {SELECT b FROM t1 WHERE a='5';} 157} {0 {Now is the time for all good men to come to the aid of their country.}} 158 159# import file with 1 row, 2 columns, quoted text data 160# note that currently sqlite doesn't support quoted fields, and 161# imports the entire field, quotes and all. 162do_test shell5-1.4.9.1 { 163 set in [open shell5.csv w] 164 puts $in "6|'Now is the time for all good men to come to the aid of their country.'" 165 close $in 166 set res [catchcmd "test.db" {.import shell5.csv t1 167SELECT COUNT(*) FROM t1;}] 168} {0 6} 169 170do_test shell5-1.4.9.2 { 171 catchcmd "test.db" {SELECT b FROM t1 WHERE a='6';} 172} {0 {'Now is the time for all good men to come to the aid of their country.'}} 173 174# import file with 1 row, 2 columns, quoted text data 175do_test shell5-1.4.10.1 { 176 set in [open shell5.csv w] 177 puts $in "7|\"Now is the time for all good men to come to the aid of their country.\"" 178 close $in 179 set res [catchcmd "test.db" {.import shell5.csv t1 180SELECT COUNT(*) FROM t1;}] 181} {0 7} 182 183do_test shell5-1.4.10.2 { 184 catchcmd "test.db" {SELECT b FROM t1 WHERE a='7';} 185} {0 {Now is the time for all good men to come to the aid of their country.}} 186 187# import file with 2 rows, 2 columns and an initial BOM 188# 189do_test shell5-1.4.11 { 190 set in [open shell5.csv wb] 191 puts $in "\xef\xbb\xbf2|3" 192 puts $in "4|5" 193 close $in 194 set res [catchcmd "test.db" {CREATE TABLE t2(x INT, y INT); 195.import shell5.csv t2 196.mode quote 197.header on 198SELECT * FROM t2;}] 199 string map {\n | \n\r |} $res 200} {0 {'x','y'|2,3|4,5}} 201 202# import file with 2 rows, 2 columns or text with an initial BOM 203# 204do_test shell5-1.4.12 { 205 set in [open shell5.csv wb] 206 puts $in "\xef\xbb\xbf\"two\"|3" 207 puts $in "4|5" 208 close $in 209 set res [catchcmd "test.db" {DELETE FROM t2; 210.import shell5.csv t2 211.mode quote 212.header on 213SELECT * FROM t2;}] 214 string map {\n | \n\r |} $res 215} {0 {'x','y'|'two',3|4,5}} 216 217# check importing very long field 218do_test shell5-1.5.1 { 219 set str [string repeat X 999] 220 set in [open shell5.csv w] 221 puts $in "8|$str" 222 close $in 223 set res [catchcmd "test.db" {.import shell5.csv t1 224SELECT length(b) FROM t1 WHERE a='8';}] 225} {0 999} 226 227# try importing into a table with a large number of columns. 228# This is limited by SQLITE_MAX_VARIABLE_NUMBER, which defaults to 999. 229set cols 999 230do_test shell5-1.6.1 { 231 set data {} 232 for {set i 1} {$i<$cols} {incr i} { 233 append data "c$i|" 234 } 235 append data "c$cols\n"; 236 for {set i 1} {$i<$cols} {incr i} { 237 append data "$i|" 238 } 239 append data "$cols" 240 set in [open shell5.csv w] 241 puts $in $data 242 close $in 243 set res [catchcmd "test.db" {DROP TABLE IF EXISTS t2; 244.import shell5.csv t2 245SELECT COUNT(*) FROM t2;}] 246} {0 1} 247 248# try importing a large number of rows 249set rows 9999 250do_test shell5-1.7.1 { 251 set in [open shell5.csv w] 252 puts $in a 253 for {set i 1} {$i<=$rows} {incr i} { 254 puts $in $i 255 } 256 close $in 257 set res [catchcmd "test.db" {.mode csv 258.import shell5.csv t3 259SELECT COUNT(*) FROM t3;}] 260} [list 0 $rows] 261 262# Inport from a pipe. (Unix only, as it requires "awk") 263if {$tcl_platform(platform)=="unix"} { 264 do_test shell5-1.8 { 265 forcedelete test.db 266 catchcmd test.db {.mode csv 267.import "|awk 'END{print \"x,y\";for(i=1;i<=5;i++){print i \",this is \" i}}'" t1 268SELECT * FROM t1;} 269 } {0 {1,"this is 1" 2702,"this is 2" 2713,"this is 3" 2724,"this is 4" 2735,"this is 5"}} 274} 275 276# Import columns containing quoted strings 277do_test shell5-1.9 { 278 set out [open shell5.csv w] 279 fconfigure $out -translation lf 280 puts $out {1,"",11} 281 puts $out {2,"x",22} 282 puts $out {3,"""",33} 283 puts $out {4,"hello",44} 284 puts $out "5,55,\"\"\r" 285 puts $out {6,66,"x"} 286 puts $out {7,77,""""} 287 puts $out {8,88,"hello"} 288 puts $out {"",9,99} 289 puts $out {"x",10,110} 290 puts $out {"""",11,121} 291 puts $out {"hello",12,132} 292 close $out 293 forcedelete test.db 294 catchcmd test.db {.mode csv 295 CREATE TABLE t1(a,b,c); 296.import shell5.csv t1 297 } 298 sqlite3 db test.db 299 db eval {SELECT *, '|' FROM t1 ORDER BY rowid} 300} {1 {} 11 | 2 x 22 | 3 {"} 33 | 4 hello 44 | 5 55 {} | 6 66 x | 7 77 {"} | 8 88 hello | {} 9 99 | x 10 110 | {"} 11 121 | hello 12 132 |} 301db close 302 303# Import columns containing quoted strings 304do_test shell5-1.10 { 305 set out [open shell5.csv w] 306 fconfigure $out -translation lf 307 puts $out {column1,column2,column3,column4} 308 puts $out "field1,field2,\"x3 \"\"\r\ndata\"\" 3\",field4" 309 puts $out "x1,x2,\"x3 \"\"\ndata\"\" 3\",x4" 310 close $out 311 forcedelete test.db 312 catchcmd test.db {.mode csv 313 CREATE TABLE t1(a,b,c,d); 314.import shell5.csv t1 315 } 316 sqlite3 db test.db 317 db eval {SELECT hex(c) FROM t1 ORDER BY rowid} 318} {636F6C756D6E33 783320220D0A64617461222033 783320220A64617461222033} 319 320# Blank last column with \r\n line endings. 321do_test shell5-1.11 { 322 set out [open shell5.csv w] 323 fconfigure $out -translation binary 324 puts $out "column1,column2,column3\r" 325 puts $out "a,b, \r" 326 puts $out "x,y,\r" 327 puts $out "p,q,r\r" 328 close $out 329 catch {db close} 330 forcedelete test.db 331 catchcmd test.db {.mode csv 332.import shell5.csv t1 333 } 334 sqlite3 db test.db 335 db eval {SELECT *, '|' FROM t1} 336} {a b { } | x y {} | p q r |} 337db close 338 339#---------------------------------------------------------------------------- 340# 341reset_db 342sqlite3 db test.db 343do_test shell5-2.1 { 344 set fd [open shell5.csv w] 345 puts $fd ",hello" 346 close $fd 347 catchcmd test.db [string trim { 348.mode csv 349CREATE TABLE t1(a, b); 350.import shell5.csv t1 351 }] 352 db eval { SELECT * FROM t1 } 353} {{} hello} 354 355do_test shell5-2.2 { 356 set fd [open shell5.csv w] 357 puts $fd {"",hello} 358 close $fd 359 catchcmd test.db [string trim { 360.mode csv 361CREATE TABLE t2(a, b); 362.import shell5.csv t2 363 }] 364 db eval { SELECT * FROM t2 } 365} {{} hello} 366 367do_test shell5-2.3 { 368 set fd [open shell5.csv w] 369 puts $fd {"x""y",hello} 370 close $fd 371 catchcmd test.db [string trim { 372.mode csv 373CREATE TABLE t3(a, b); 374.import shell5.csv t3 375 }] 376 db eval { SELECT * FROM t3 } 377} {x\"y hello} 378 379do_test shell5-2.4 { 380 set fd [open shell5.csv w] 381 puts $fd {"xy""",hello} 382 close $fd 383 catchcmd test.db [string trim { 384.mode csv 385CREATE TABLE t4(a, b); 386.import shell5.csv t4 387 }] 388 db eval { SELECT * FROM t4 } 389} {xy\" hello} 390 391do_test shell5-2.5 { 392 set fd [open shell5.csv w] 393 puts $fd {"one","2"} 394 puts $fd {} 395 close $fd 396 catchcmd test.db [string trim { 397.mode csv 398CREATE TABLE t4(a, b); 399.import shell5.csv t4 400 }] 401 db eval { SELECT * FROM t4 } 402} {xy\" hello one 2 {} {}} 403 404#---------------------------------------------------------------------------- 405# Tests for the shell "ascii" import/export mode. 406# 407do_test shell5-3.1 { 408 set fd [open shell5.csv w] 409 fconfigure $fd -encoding binary -translation binary 410 puts -nonewline $fd "\"test 1\"\x1F,test 2\r\n\x1E" 411 puts -nonewline $fd "test 3\x1Ftest 4\n" 412 close $fd 413 catchcmd test.db { 414.mode ascii 415CREATE TABLE t5(a, b); 416.import shell5.csv t5 417 } 418 db eval { SELECT * FROM t5 } 419} "\{\"test 1\"} \{,test 2\r\n\} \{test 3\} \{test 4\n\}" 420 421do_test shell5-3.2 { 422 set x [catchcmd test.db { 423.mode ascii 424SELECT * FROM t5; 425 }] 426 # Handle platform end-of-line differences 427 regsub -all {[\n\r]?\n} $x <EOL> x 428 set x 429} "0 \{\"test 1\"\x1F,test 2<EOL>\x1Etest 3\x1Ftest 4<EOL>\x1E\}" 430 431do_test shell5-4.1 { 432 forcedelete shell5.csv 433 set fd [open shell5.csv w] 434 puts $fd "1,2,3" 435 puts $fd "4,5" 436 puts $fd "6,7,8" 437 close $fd 438 catchcmd test.db [string trim { 439.mode csv 440CREATE TABLE t6(a, b, c); 441.import shell5.csv t6 442 }] 443 db eval { SELECT * FROM t6 ORDER BY a } 444} {1 2 3 4 5 {} 6 7 8} 445 446do_test shell5-4.2 { 447 forcedelete shell5.csv 448 set fd [open shell5.csv w] 449 puts $fd "1,2,3" 450 puts $fd "4,5" 451 puts $fd "6,7,8,9" 452 close $fd 453 catchcmd test.db [string trim { 454.mode csv 455CREATE TABLE t7(a, b, c); 456.import shell5.csv t7 457 }] 458 db eval { SELECT * FROM t7 ORDER BY a } 459} {1 2 3 4 5 {} 6 7 8} 460 461finish_test 462