1# 2002 February 26 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 file is testing VIEW statements. 13# 14# $Id: view.test,v 1.39 2008/12/14 14:45:21 danielk1977 Exp $ 15set testdir [file dirname $argv0] 16source $testdir/tester.tcl 17 18# Omit this entire file if the library is not configured with views enabled. 19ifcapable !view { 20 finish_test 21 return 22} 23 24do_test view-1.0 { 25 execsql { 26 CREATE TABLE t1(a,b,c); 27 INSERT INTO t1 VALUES(1,2,3); 28 INSERT INTO t1 VALUES(4,5,6); 29 INSERT INTO t1 VALUES(7,8,9); 30 SELECT * FROM t1; 31 } 32} {1 2 3 4 5 6 7 8 9} 33 34do_test view-1.1 { 35 execsql { 36 BEGIN; 37 CREATE VIEW IF NOT EXISTS v1 AS SELECT a,b FROM t1; 38 SELECT * FROM v1 ORDER BY a; 39 } 40} {1 2 4 5 7 8} 41do_test view-1.1.100 { 42 db config enable_view off 43 catchsql { 44 SELECT * FROM v1 ORDER BY a; 45 } 46} {1 {access to view "v1" prohibited}} 47do_execsql_test view-1.1.101 { 48 CREATE TEMP VIEW v1temp AS SELECT a, b FROM t1; 49 SELECT * FROM v1temp ORDER BY a; 50} {1 2 4 5 7 8} 51do_test view-1.1.110 { 52 db config enable_view on 53 catchsql { 54 SELECT * FROM v1 ORDER BY a; 55 SELECT * FROM v1temp ORDER BY a; 56 } 57} {0 {1 2 4 5 7 8 1 2 4 5 7 8}} 58do_test view-1.2 { 59 catchsql { 60 ROLLBACK; 61 SELECT * FROM v1 ORDER BY a; 62 } 63} {1 {no such table: v1}} 64do_test view-1.3 { 65 execsql { 66 CREATE VIEW v1 AS SELECT a,b FROM t1; 67 SELECT * FROM v1 ORDER BY a; 68 } 69} {1 2 4 5 7 8} 70do_test view-1.3.1 { 71 db close 72 sqlite3 db test.db 73 execsql { 74 SELECT * FROM v1 ORDER BY a; 75 } 76} {1 2 4 5 7 8} 77do_test view-1.4 { 78 catchsql { 79 DROP VIEW IF EXISTS v1; 80 SELECT * FROM v1 ORDER BY a; 81 } 82} {1 {no such table: v1}} 83do_test view-1.5 { 84 execsql { 85 CREATE VIEW v1 AS SELECT a,b FROM t1; 86 SELECT * FROM v1 ORDER BY a; 87 } 88} {1 2 4 5 7 8} 89do_test view-1.6 { 90 catchsql { 91 DROP TABLE t1; 92 SELECT * FROM v1 ORDER BY a; 93 } 94} {1 {no such table: main.t1}} 95do_test view-1.7 { 96 execsql { 97 CREATE TABLE t1(x,a,b,c); 98 INSERT INTO t1 VALUES(1,2,3,4); 99 INSERT INTO t1 VALUES(4,5,6,7); 100 INSERT INTO t1 VALUES(7,8,9,10); 101 SELECT * FROM v1 ORDER BY a; 102 } 103} {2 3 5 6 8 9} 104do_test view-1.8 { 105 db close 106 sqlite3 db test.db 107 execsql { 108 SELECT * FROM v1 ORDER BY a; 109 } 110} {2 3 5 6 8 9} 111 112do_execsql_test view-1.10 { 113 CREATE TABLE t9(x INTEGER); 114 CREATE VIEW v9a AS SELECT x FROM t9; 115 CREATE VIEW v9b AS SELECT * FROM t9; 116 CREATE VIEW v9c(x) AS SELECT x FROM t9; 117 CREATE VIEW v9d(x) AS SELECT * FROM t9; 118} {} 119do_execsql_test view-1.11 { 120 PRAGMA table_info(v9a); 121} {0 x INTEGER 0 {} 0} 122do_execsql_test view-1.12 { 123 PRAGMA table_info(v9b); 124} {0 x INTEGER 0 {} 0} 125do_execsql_test view-1.13 { 126 PRAGMA table_info(v9c); 127} {0 x INTEGER 0 {} 0} 128do_execsql_test view-1.14 { 129 PRAGMA table_info(v9d); 130} {0 x INTEGER 0 {} 0} 131 132do_test view-2.1 { 133 execsql { 134 CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5 135 }; # No semicolon 136 execsql2 { 137 SELECT * FROM v2; 138 } 139} {x 7 a 8 b 9 c 10} 140do_test view-2.2 { 141 catchsql { 142 INSERT INTO v2 VALUES(1,2,3,4); 143 } 144} {1 {cannot modify v2 because it is a view}} 145do_test view-2.3 { 146 catchsql { 147 UPDATE v2 SET a=10 WHERE a=5; 148 } 149} {1 {cannot modify v2 because it is a view}} 150do_test view-2.4 { 151 catchsql { 152 DELETE FROM v2; 153 } 154} {1 {cannot modify v2 because it is a view}} 155do_test view-2.5 { 156 execsql { 157 INSERT INTO t1 VALUES(11,12,13,14); 158 SELECT * FROM v2 ORDER BY x; 159 } 160} {7 8 9 10 11 12 13 14} 161do_test view-2.6 { 162 execsql { 163 SELECT x FROM v2 WHERE a>10 164 } 165} {11} 166 167# Test that column name of views are generated correctly. 168# 169do_test view-3.1 { 170 execsql2 { 171 SELECT * FROM v1 LIMIT 1 172 } 173} {a 2 b 3} 174do_test view-3.2 { 175 execsql2 { 176 SELECT * FROM v2 LIMIT 1 177 } 178} {x 7 a 8 b 9 c 10} 179do_test view-3.3.1 { 180 execsql2 { 181 DROP VIEW v1; 182 CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1; 183 SELECT * FROM v1 LIMIT 1 184 } 185} {xyz 2 pqr 7 c-b 1} 186do_test view-3.3.2 { 187 execsql2 { 188 CREATE VIEW v1b AS SELECT t1.a, b+c, t1.c FROM t1; 189 SELECT * FROM v1b LIMIT 1 190 } 191} {a 2 b+c 7 c 4} 192do_test view-3.3.3 { 193 execsql2 { 194 CREATE VIEW v1c(x,y,z) AS SELECT a, b+c, c-b FROM t1; 195 SELECT * FROM v1c LIMIT 1; 196 } 197} {x 2 y 7 z 1} 198do_catchsql_test view-3.3.4 { 199 CREATE VIEW v1err(x,y DESC,z) AS SELECT a, b+c, c-b FROM t1; 200} {1 {syntax error after column name "y"}} 201do_catchsql_test view-3.3.5 { 202 DROP VIEW IF EXISTS v1err; 203 CREATE VIEW v1err(x,y) AS SELECT a, b+c, c-b FROM t1; 204 SELECT * FROM v1err; 205} {1 {expected 2 columns for 'v1err' but got 3}} 206do_catchsql_test view-3.3.6 { 207 DROP VIEW IF EXISTS v1err; 208 CREATE VIEW v1err(w,x,y,z) AS SELECT a, b+c, c-b FROM t1; 209 SELECT * FROM v1err; 210} {1 {expected 4 columns for 'v1err' but got 3}} 211 212ifcapable compound { 213do_test view-3.4 { 214 execsql2 { 215 CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b; 216 SELECT * FROM v3 LIMIT 4; 217 } 218} {a 2 a 3 a 5 a 6} 219do_test view-3.5 { 220 execsql2 { 221 CREATE VIEW v4 AS 222 SELECT a, b FROM t1 223 UNION 224 SELECT b AS 'x', a AS 'y' FROM t1 225 ORDER BY x, y; 226 SELECT b FROM v4 ORDER BY b LIMIT 4; 227 } 228} {b 2 b 3 b 5 b 6} 229} ;# ifcapable compound 230 231 232do_test view-4.1 { 233 catchsql { 234 DROP VIEW t1; 235 } 236} {1 {use DROP TABLE to delete table t1}} 237do_test view-4.2 { 238 execsql { 239 SELECT 1 FROM t1 LIMIT 1; 240 } 241} 1 242do_test view-4.3 { 243 catchsql { 244 DROP TABLE v1; 245 } 246} {1 {use DROP VIEW to delete view v1}} 247do_test view-4.4 { 248 execsql { 249 SELECT 1 FROM v1 LIMIT 1; 250 } 251} {1} 252do_test view-4.5 { 253 catchsql { 254 CREATE INDEX i1v1 ON v1(xyz); 255 } 256} {1 {views may not be indexed}} 257 258do_test view-5.1 { 259 execsql { 260 CREATE TABLE t2(y,a); 261 INSERT INTO t2 VALUES(22,2); 262 INSERT INTO t2 VALUES(33,3); 263 INSERT INTO t2 VALUES(44,4); 264 INSERT INTO t2 VALUES(55,5); 265 SELECT * FROM t2; 266 } 267} {22 2 33 3 44 4 55 5} 268do_test view-5.2 { 269 execsql { 270 CREATE VIEW v5 AS 271 SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a); 272 SELECT * FROM v5; 273 } 274} {1 22 4 55} 275 276# Verify that the view v5 gets flattened. see sqliteFlattenSubquery(). 277# This will only work if EXPLAIN is enabled. 278# Ticket #272 279# 280ifcapable {explain} { 281do_test view-5.3 { 282 lsearch [execsql { 283 EXPLAIN SELECT * FROM v5; 284 }] OpenEphemeral 285} {-1} 286do_test view-5.4 { 287 execsql { 288 SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y; 289 } 290} {1 22 22 2 4 55 55 5} 291do_test view-5.5 { 292 lsearch [execsql { 293 EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y; 294 }] OpenEphemeral 295} {-1} 296do_test view-5.6 { 297 execsql { 298 SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y; 299 } 300} {22 2 1 22 55 5 4 55} 301do_test view-5.7 { 302 lsearch [execsql { 303 EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y; 304 }] OpenEphemeral 305} {-1} 306do_test view-5.8 { 307 execsql { 308 SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y; 309 } 310} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5} 311do_test view-5.9 { 312 lsearch [execsql { 313 EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y; 314 }] OpenEphemeral 315} {-1} 316} ;# endif explain 317 318do_test view-6.1 { 319 execsql { 320 SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2; 321 } 322} {7 8 9 10 27} 323do_test view-6.2 { 324 execsql { 325 SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2; 326 } 327} {11 12 13 14 39} 328 329do_test view-7.1 { 330 execsql { 331 CREATE TABLE test1(id integer primary key, a); 332 CREATE TABLE test2(id integer, b); 333 INSERT INTO test1 VALUES(1,2); 334 INSERT INTO test2 VALUES(1,3); 335 CREATE VIEW test AS 336 SELECT test1.id, a, b 337 FROM test1 JOIN test2 ON test2.id=test1.id; 338 SELECT * FROM test; 339 } 340} {1 2 3} 341do_test view-7.2 { 342 db close 343 sqlite3 db test.db 344 execsql { 345 SELECT * FROM test; 346 } 347} {1 2 3} 348do_test view-7.3 { 349 execsql { 350 DROP VIEW test; 351 CREATE VIEW test AS 352 SELECT test1.id, a, b 353 FROM test1 JOIN test2 USING(id); 354 SELECT * FROM test; 355 } 356} {1 2 3} 357do_test view-7.4 { 358 db close 359 sqlite3 db test.db 360 execsql { 361 SELECT * FROM test; 362 } 363} {1 2 3} 364do_test view-7.5 { 365 execsql { 366 DROP VIEW test; 367 CREATE VIEW test AS 368 SELECT test1.id, a, b 369 FROM test1 NATURAL JOIN test2; 370 SELECT * FROM test; 371 } 372} {1 2 3} 373do_test view-7.6 { 374 db close 375 sqlite3 db test.db 376 execsql { 377 SELECT * FROM test; 378 } 379} {1 2 3} 380 381do_test view-8.1 { 382 execsql { 383 CREATE VIEW v6 AS SELECT pqr, xyz FROM v1; 384 SELECT * FROM v6 ORDER BY xyz; 385 } 386} {7 2 13 5 19 8 27 12} 387do_test view-8.2 { 388 db close 389 sqlite3 db test.db 390 execsql { 391 SELECT * FROM v6 ORDER BY xyz; 392 } 393} {7 2 13 5 19 8 27 12} 394do_test view-8.3 { 395 execsql { 396 CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6; 397 SELECT * FROM v7 ORDER BY a; 398 } 399} {9 18 27 39} 400 401ifcapable subquery { 402 do_test view-8.4 { 403 execsql { 404 CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM 405 (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo); 406 SELECT * FROM v8; 407 } 408 } 3 409 do_test view-8.5 { 410 execsql { 411 SELECT mx+10, mx*2 FROM v8; 412 } 413 } {13 6} 414 do_test view-8.6 { 415 execsql { 416 SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2; 417 } 418 } {13 7} 419 do_test view-8.7 { 420 execsql { 421 SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2; 422 } 423 } {13 13 13 19 13 27} 424} ;# ifcapable subquery 425 426# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW. 427# 428do_test view-9.1 { 429 execsql { 430 INSERT INTO t2 SELECT * FROM t2 WHERE a<5; 431 INSERT INTO t2 SELECT * FROM t2 WHERE a<4; 432 INSERT INTO t2 SELECT * FROM t2 WHERE a<3; 433 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1; 434 } 435} {1 2 4 8} 436do_test view-9.2 { 437 execsql { 438 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3; 439 } 440} {1 2 4} 441do_test view-9.3 { 442 execsql { 443 CREATE VIEW v9 AS 444 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3; 445 SELECT * FROM v9; 446 } 447} {1 2 4} 448do_test view-9.4 { 449 execsql { 450 SELECT * FROM v9 ORDER BY 1 DESC; 451 } 452} {4 2 1} 453do_test view-9.5 { 454 execsql { 455 CREATE VIEW v10 AS 456 SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3; 457 SELECT * FROM v10; 458 } 459} {5 1 4 2 3 4} 460do_test view-9.6 { 461 execsql { 462 SELECT * FROM v10 ORDER BY 1; 463 } 464} {3 4 4 2 5 1} 465 466# Tables with columns having peculiar quoted names used in views 467# Ticket #756. 468# 469do_test view-10.1 { 470 execsql { 471 CREATE TABLE t3("9" integer, [4] text); 472 INSERT INTO t3 VALUES(1,2); 473 CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a; 474 CREATE VIEW v_t3_b AS SELECT "4" FROM t3; 475 SELECT * FROM v_t3_a; 476 } 477} {1} 478do_test view-10.2 { 479 execsql { 480 SELECT * FROM v_t3_b; 481 } 482} {2} 483 484do_test view-11.1 { 485 execsql { 486 CREATE TABLE t4(a COLLATE NOCASE); 487 INSERT INTO t4 VALUES('This'); 488 INSERT INTO t4 VALUES('this'); 489 INSERT INTO t4 VALUES('THIS'); 490 SELECT * FROM t4 WHERE a = 'THIS'; 491 } 492} {This this THIS} 493ifcapable subquery { 494 do_test view-11.2 { 495 execsql { 496 SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS'; 497 } 498 } {This this THIS} 499} 500do_test view-11.3 { 501 execsql { 502 CREATE VIEW v11 AS SELECT * FROM t4; 503 SELECT * FROM v11 WHERE a = 'THIS'; 504 } 505} {This this THIS} 506 507# Ticket #1270: Do not allow parameters in view definitions. 508# 509do_test view-12.1 { 510 catchsql { 511 CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=? 512 } 513} {1 {parameters are not allowed in views}} 514do_test view-12.2 { 515 catchsql { 516 CREATE VIEW v12(x) AS SELECT a FROM t1 WHERE b=? 517 } 518} {1 {parameters are not allowed in views}} 519 520ifcapable attach { 521 do_test view-13.1 { 522 forcedelete test2.db 523 catchsql { 524 ATTACH 'test2.db' AS two; 525 CREATE TABLE two.t2(x,y); 526 CREATE VIEW v13 AS SELECT y FROM two.t2; 527 } 528 } {1 {view v13 cannot reference objects in database two}} 529} 530 531# Ticket #1658 532# 533do_test view-14.1 { 534 catchsql { 535 CREATE TEMP VIEW t1 AS SELECT a,b FROM t1; 536 SELECT * FROM temp.t1; 537 } 538} {1 {view t1 is circularly defined}} 539do_test view-14.2 { 540 catchsql { 541 DROP VIEW IF EXISTS temp.t1; 542 CREATE TEMP VIEW t1(a,b) AS SELECT a,b FROM t1; 543 SELECT * FROM temp.t1; 544 } 545} {1 {view t1 is circularly defined}} 546 547# Tickets #1688, #1709 548# 549do_test view-15.1 { 550 execsql2 { 551 CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1; 552 SELECT * FROM v15 LIMIT 1; 553 } 554} {x 2 y 3} 555do_test view-15.2 { 556 execsql2 { 557 SELECT x, y FROM v15 LIMIT 1 558 } 559} {x 2 y 3} 560 561do_test view-16.1 { 562 catchsql { 563 CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1; 564 } 565} {0 {}} 566do_test view-16.2 { 567 execsql { 568 SELECT sql FROM sqlite_master WHERE name='v1' 569 } 570} {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}} 571do_test view-16.3 { 572 catchsql { 573 DROP VIEW IF EXISTS nosuchview 574 } 575} {0 {}} 576 577# correct error message when attempting to drop a view that does not 578# exist. 579# 580do_test view-17.1 { 581 catchsql { 582 DROP VIEW nosuchview 583 } 584} {1 {no such view: nosuchview}} 585do_test view-17.2 { 586 catchsql { 587 DROP VIEW main.nosuchview 588 } 589} {1 {no such view: main.nosuchview}} 590 591do_test view-18.1 { 592 execsql { 593 DROP VIEW t1; 594 DROP TABLE t1; 595 CREATE TABLE t1(a, b, c); 596 INSERT INTO t1 VALUES(1, 2, 3); 597 INSERT INTO t1 VALUES(4, 5, 6); 598 599 CREATE VIEW vv1 AS SELECT * FROM t1; 600 CREATE VIEW vv2 AS SELECT * FROM vv1; 601 CREATE VIEW vv3 AS SELECT * FROM vv2; 602 CREATE VIEW vv4 AS SELECT * FROM vv3; 603 CREATE VIEW vv5 AS SELECT * FROM vv4; 604 605 SELECT * FROM vv5; 606 } 607} {1 2 3 4 5 6} 608 609# Ticket #3308 610# Make sure "rowid" columns in a view are named correctly. 611# 612do_test view-19.1 { 613 execsql { 614 CREATE VIEW v3308a AS SELECT rowid, * FROM t1; 615 } 616 execsql2 { 617 SELECT * FROM v3308a 618 } 619} {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6} 620do_test view-19.2 { 621 execsql { 622 CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1; 623 } 624 execsql2 { 625 SELECT * FROM v3308b 626 } 627} {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11} 628do_test view-19.3 { 629 execsql { 630 CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1; 631 } 632 execsql2 { 633 SELECT * FROM v3308c 634 } 635} {rowid 1 a 1 x 5 rowid 2 a 4 x 11} 636 637# Ticket #3539 had this crashing (see commit [5940]). 638do_test view-20.1 { 639 execsql { 640 DROP TABLE IF EXISTS t1; 641 DROP VIEW IF EXISTS v1; 642 CREATE TABLE t1(c1); 643 CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1); 644 } 645} {} 646 647# Ticket [d58ccbb3f1b]: Prevent Table.nRef overflow. 648db close 649sqlite3 db :memory: 650do_test view-21.1 { 651 catchsql { 652 CREATE TABLE t1(x); 653 INSERT INTO t1 VALUES(5); 654 CREATE VIEW v1 AS SELECT x*2 FROM t1; 655 CREATE VIEW v2 AS SELECT * FROM v1 UNION SELECT * FROM v1; 656 CREATE VIEW v4 AS SELECT * FROM v2 UNION SELECT * FROM v2; 657 CREATE VIEW v8 AS SELECT * FROM v4 UNION SELECT * FROM v4; 658 CREATE VIEW v16 AS SELECT * FROM v8 UNION SELECT * FROM v8; 659 CREATE VIEW v32 AS SELECT * FROM v16 UNION SELECT * FROM v16; 660 CREATE VIEW v64 AS SELECT * FROM v32 UNION SELECT * FROM v32; 661 CREATE VIEW v128 AS SELECT * FROM v64 UNION SELECT * FROM v64; 662 CREATE VIEW v256 AS SELECT * FROM v128 UNION SELECT * FROM v128; 663 CREATE VIEW v512 AS SELECT * FROM v256 UNION SELECT * FROM v256; 664 CREATE VIEW v1024 AS SELECT * FROM v512 UNION SELECT * FROM v512; 665 CREATE VIEW v2048 AS SELECT * FROM v1024 UNION SELECT * FROM v1024; 666 CREATE VIEW v4096 AS SELECT * FROM v2048 UNION SELECT * FROM v2048; 667 CREATE VIEW v8192 AS SELECT * FROM v4096 UNION SELECT * FROM v4096; 668 CREATE VIEW v16384 AS SELECT * FROM v8192 UNION SELECT * FROM v8192; 669 CREATE VIEW v32768 AS SELECT * FROM v16384 UNION SELECT * FROM v16384; 670 SELECT * FROM v32768 UNION SELECT * FROM v32768; 671 } 672} {1 {too many references to "v1": max 65535}} 673ifcapable progress { 674 do_test view-21.2 { 675 db progress 1000 {expr 1} 676 catchsql { 677 SELECT * FROM v32768; 678 } 679 } {1 interrupted} 680} 681 682db close 683sqlite3 db :memory: 684do_execsql_test view-22.1 { 685 CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS ''; 686 SELECT * FROM x1; 687} {123 234 345} 688do_test view-22.2 { 689 unset -nocomplain x 690 db eval {SELECT * FROM x1} x break 691 lsort [array names x] 692} {{} * :1 :2} 693 694do_test view-25.1 { 695 db eval { 696 CREATE TABLE t25 (x); 697 INSERT INTO t25 (x) VALUES (1); 698 ANALYZE; 699 } 700 proc authLogDelete {code arg1 arg2 arg3 arg4 args} { 701 if {$code=="SQLITE_DELETE" && [string match sqlite_stat* $arg1]} { 702 # lappend ::log [list $code $arg1 $arg2 $arg3 $arg4 $args] 703 lappend ::log [list $code $arg1 $arg2 $arg3 $arg4] 704 } 705 return SQLITE_OK 706 } 707 set log "" 708 db authorizer ::authLogDelete 709 db eval {DROP VIEW x1;} 710 set log 711} {} 712 713set res [list {SQLITE_DELETE sqlite_stat1 {} main {}}] 714ifcapable stat4 { lappend res {SQLITE_DELETE sqlite_stat4 {} main {}} } 715do_test view-25.2 { 716 set log "" 717 db eval {DROP TABLE t25;} 718 set log 719} $res 720 721#------------------------------------------------------------------------- 722do_execsql_test view-26.0 { 723 CREATE TABLE t16(a, b, c UNIQUE); 724 INSERT INTO t16 VALUES(1, 1, 1); 725 INSERT INTO t16 VALUES(2, 2, 2); 726 INSERT INTO t16 VALUES(3, 3, 3); 727 CREATE VIEW v16 AS SELECT max(a) AS mx, min(b) AS mn FROM t16 GROUP BY c; 728 729 SELECT * FROM v16 AS one, v16 AS two WHERE one.mx=1; 730} { 731 1 1 1 1 732 1 1 2 2 733 1 1 3 3 734} 735do_execsql_test view-26.1 { 736 WITH v17(x,y) AS (SELECT max(a), min(b) FROM t16 GROUP BY c) 737 SELECT * FROM v17 AS one, v17 AS two WHERE one.x=1; 738} { 739 1 1 1 1 740 1 1 2 2 741 1 1 3 3 742} 743 744#------------------------------------------------------------------------- 745reset_db 746do_execsql_test view-27.0 { 747 CREATE TABLE t0(c0 TEXT, c1); 748 INSERT INTO t0(c0, c1) VALUES (-1, 0); 749 CREATE VIEW v0(c0, c1) AS SELECT t0.c0, AVG(t0.c1) FROM t0; 750} 751 752do_execsql_test view-27.1 { 753 SELECT c0, typeof(c0), c1, typeof(c1) FROM v0; 754} { 755 -1 text 756 0.0 real 757} 758 759do_execsql_test view-27.2 { SELECT c0<c1 FROM v0 } 1 760do_execsql_test view-27.3 { SELECT c1<c0 FROM v0 } 0 761do_execsql_test view-27.4 { 762 SELECT 1 FROM v0 WHERE c1<c0 763} {} 764do_execsql_test view-27.5 { 765 SELECT 1 FROM v0 WHERE c0<c1 766} {1} 767 768do_execsql_test view-27.6 { 769 SELECT c0<c1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) 770} 1 771do_execsql_test view-27.7 { 772 SELECT c1<c0 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) 773} 0 774do_execsql_test view-27.8 { 775 SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c1<c0 776} {} 777do_execsql_test view-27.9 { 778 SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c0<c1 779} {1} 780 781#------------------------------------------------------------------------- 782reset_db 783do_execsql_test view-28.0 { 784 CREATE TABLE t0(c0 TEXT); 785 CREATE VIEW v0(c0) AS SELECT t0.c0 FROM t0; 786 INSERT INTO t0(c0) VALUES ('0'); 787} 788do_execsql_test view-28.1 { 789 SELECT 0 IN (c0) FROM t0; 790} {0} 791do_execsql_test view-28.2 { 792 SELECT 0 IN (c0) FROM (SELECT c0 FROM t0); 793} {0} 794 795#------------------------------------------------------------------------- 796# 2020-10-26. https://sqlite.org/forum/forumpost/daa2c728cc 797# 798reset_db 799do_catchsql_test view-29.0 { 800 CREATE TABLE t1(a,b,c); 801 CREATE VIEW IF NOT EXISTS IF AS SELECT null; 802} {1 {malformed database schema (IF) - near "AS": syntax error}} 803do_catchsql_test view-29.1 { 804 CREATE TABLE t2(c,d,e); 805 SELECT name FROM sqlite_schema ORDER BY name; 806} {0 {t1 t2}} 807 808 809finish_test 810