xref: /sqlite-3.40.0/test/e_select2.test (revision a820c05a)
15f90f52aSdan# 2010 September 24
25f90f52aSdan#
35f90f52aSdan# The author disclaims copyright to this source code.  In place of
45f90f52aSdan# a legal notice, here is a blessing:
55f90f52aSdan#
65f90f52aSdan#    May you do good and not evil.
75f90f52aSdan#    May you find forgiveness for yourself and forgive others.
85f90f52aSdan#    May you share freely, never taking more than you give.
95f90f52aSdan#
105f90f52aSdan#***********************************************************************
115f90f52aSdan#
125f90f52aSdan# This file implements tests to verify that the "testable statements" in
135f90f52aSdan# the lang_select.html document are correct.
145f90f52aSdan#
155f90f52aSdan
165f90f52aSdanset testdir [file dirname $argv0]
175f90f52aSdansource $testdir/tester.tcl
185f90f52aSdan
195f90f52aSdan#-------------------------------------------------------------------------
205f90f52aSdan# te_* commands:
215f90f52aSdan#
225f90f52aSdan#
235f90f52aSdan#   te_read_sql DB SELECT-STATEMENT
245f90f52aSdan#   te_read_tbl DB TABLENAME
255f90f52aSdan#
265f90f52aSdan# These two commands are used to read a dataset from the database. A dataset
275f90f52aSdan# consists of N rows of M named columns of values each, where each value has a
285f90f52aSdan# type (null, integer, real, text or blob) and a value within the types domain.
295f90f52aSdan# The tcl format for a "dataset" is a list of two elements:
305f90f52aSdan#
315f90f52aSdan#   * A list of the column names.
325f90f52aSdan#   * A list of data rows. Each row is itself a list, where each element is
335f90f52aSdan#     the contents of a column of the row. Each of these is a list of two
345f90f52aSdan#     elements, the type name and the actual value.
355f90f52aSdan#
365f90f52aSdan# For example, the contents of table [t1] as a dataset is:
375f90f52aSdan#
385f90f52aSdan#   CREATE TABLE t1(a, b);
395f90f52aSdan#   INSERT INTO t1 VALUES('abc', NULL);
405f90f52aSdan#   INSERT INTO t1 VALUES(43.1, 22);
415f90f52aSdan#
425f90f52aSdan#   {a b} {{{TEXT abc} {NULL {}}} {{REAL 43.1} {INTEGER 22}}}
435f90f52aSdan#
445f90f52aSdan# The [te_read_tbl] command returns a dataset read from a table. The
455f90f52aSdan# [te_read_sql] returns the dataset that results from executing a SELECT
465f90f52aSdan# command.
475f90f52aSdan#
485f90f52aSdan#
495f90f52aSdan#   te_tbljoin ?SWITCHES? LHS-TABLE RHS-TABLE
505f90f52aSdan#   te_join ?SWITCHES? LHS-DATASET RHS-DATASET
515f90f52aSdan#
525f90f52aSdan# This command joins the two datasets and returns the resulting dataset. If
535f90f52aSdan# there are no switches specified, then the results is the cartesian product
545f90f52aSdan# of the two inputs.  The [te_tbljoin] command reads the left and right-hand
555f90f52aSdan# datasets from the specified tables. The [te_join] command is passed the
565f90f52aSdan# datasets directly.
575f90f52aSdan#
585f90f52aSdan# Optional switches are as follows:
595f90f52aSdan#
605f90f52aSdan#   -on SCRIPT
615f90f52aSdan#   -using COLUMN-LIST
625f90f52aSdan#   -left
635f90f52aSdan#
645f90f52aSdan# The -on option specifies a tcl script that is executed for each row in the
655f90f52aSdan# cartesian product of the two datasets. The script has 4 arguments appended
665f90f52aSdan# to it, in the following order:
675f90f52aSdan#
685f90f52aSdan#   * The list of column-names from the left-hand dataset.
695f90f52aSdan#   * A single row from the left-hand dataset (one "data row" list as
705f90f52aSdan#     described above.
715f90f52aSdan#   * The list of column-names from the right-hand dataset.
725f90f52aSdan#   * A single row from the right-hand dataset.
735f90f52aSdan#
745f90f52aSdan# The script must return a boolean value - true if the combination of rows
755f90f52aSdan# should be included in the output dataset, or false otherwise.
765f90f52aSdan#
775f90f52aSdan# The -using option specifies a list of the columns from the right-hand
785f90f52aSdan# dataset that should be omitted from the output dataset.
795f90f52aSdan#
805f90f52aSdan# If the -left option is present, the join is done LEFT JOIN style.
815f90f52aSdan# Specifically, an extra row is inserted if after the -on script is run there
825f90f52aSdan# exist rows in the left-hand dataset that have no corresponding rows in
835f90f52aSdan# the output. See the implementation for more specific comments.
845f90f52aSdan#
855f90f52aSdan#
865f90f52aSdan#   te_equals ?SWITCHES? COLNAME1 COLNAME2 <-on script args>
875f90f52aSdan#
885f90f52aSdan# The only supported switch is "-nocase". If it is present, then text values
895f90f52aSdan# are compared in a case-independent fashion. Otherwise, they are compared
905f90f52aSdan# as if using the SQLite BINARY collation sequence.
915f90f52aSdan#
925f90f52aSdan#
935f90f52aSdan#   te_and ONSCRIPT1 ONSCRIPT2...
945f90f52aSdan#
955f90f52aSdan#
965f90f52aSdan
975f90f52aSdan
985f90f52aSdan#
995f90f52aSdan#   te_read_tbl DB TABLENAME
1005f90f52aSdan#   te_read_sql DB SELECT-STATEMENT
1015f90f52aSdan#
1025f90f52aSdan# These two procs are used to extract datasets from the database, either
1035f90f52aSdan# by reading the contents of a named table (te_read_tbl), or by executing
1045f90f52aSdan# a SELECT statement (t3_read_sql).
1055f90f52aSdan#
1065f90f52aSdan# See the comment above, describing "te_* commands", for details of the
1075f90f52aSdan# return values.
1085f90f52aSdan#
1095f90f52aSdanproc te_read_tbl {db tbl} {
1105f90f52aSdan te_read_sql $db "SELECT * FROM '$tbl'"
1115f90f52aSdan}
1125f90f52aSdanproc te_read_sql {db sql} {
1135f90f52aSdan  set S [sqlite3_prepare_v2 $db $sql -1 DUMMY]
1145f90f52aSdan
1155f90f52aSdan  set cols [list]
1165f90f52aSdan  for {set i 0} {$i < [sqlite3_column_count $S]} {incr i} {
1175f90f52aSdan    lappend cols [sqlite3_column_name $S $i]
1185f90f52aSdan  }
1195f90f52aSdan
1205f90f52aSdan  set rows [list]
1215f90f52aSdan  while {[sqlite3_step $S] == "SQLITE_ROW"} {
1225f90f52aSdan    set r [list]
1235f90f52aSdan    for {set i 0} {$i < [sqlite3_column_count $S]} {incr i} {
1245f90f52aSdan      lappend r [list [sqlite3_column_type $S $i] [sqlite3_column_text $S $i]]
1255f90f52aSdan    }
1265f90f52aSdan    lappend rows $r
1275f90f52aSdan  }
1285f90f52aSdan  sqlite3_finalize $S
1295f90f52aSdan
1305f90f52aSdan  return [list $cols $rows]
1315f90f52aSdan}
1325f90f52aSdan
1335f90f52aSdan#-------
1345f90f52aSdan# Usage:   te_join <table-data1> <table-data2> <join spec>...
1355f90f52aSdan#
1365f90f52aSdan# Where a join-spec is an optional list of arguments as follows:
1375f90f52aSdan#
1385f90f52aSdan#   ?-left?
1395f90f52aSdan#   ?-using colname-list?
1405f90f52aSdan#   ?-on on-expr-proc?
1415f90f52aSdan#
1425f90f52aSdanproc te_join {data1 data2 args} {
1435f90f52aSdan
1445f90f52aSdan  set testproc ""
1455f90f52aSdan  set usinglist [list]
1465f90f52aSdan  set isleft 0
1475f90f52aSdan  for {set i 0} {$i < [llength $args]} {incr i} {
1485f90f52aSdan    set a [lindex $args $i]
1495f90f52aSdan    switch -- $a {
1505f90f52aSdan      -on     { set testproc [lindex $args [incr i]] }
1515f90f52aSdan      -using  { set usinglist [lindex $args [incr i]] }
1525f90f52aSdan      -left   { set isleft 1 }
1535f90f52aSdan      default {
1545f90f52aSdan        error "Unknown argument: $a"
1555f90f52aSdan      }
1565f90f52aSdan    }
1575f90f52aSdan  }
1585f90f52aSdan
1595f90f52aSdan  set c1 [lindex $data1 0]
1605f90f52aSdan  set c2 [lindex $data2 0]
1615f90f52aSdan  set omitlist [list]
1625f90f52aSdan  set nullrowlist [list]
1635f90f52aSdan  set cret $c1
1645f90f52aSdan
1655f90f52aSdan  set cidx 0
1665f90f52aSdan  foreach col $c2 {
1675f90f52aSdan    set idx [lsearch $usinglist $col]
1685f90f52aSdan    if {$idx>=0} {lappend omitlist $cidx}
1695f90f52aSdan    if {$idx<0} {
1705f90f52aSdan      lappend nullrowlist {NULL {}}
1715f90f52aSdan      lappend cret $col
1725f90f52aSdan    }
1735f90f52aSdan    incr cidx
1745f90f52aSdan  }
1755f90f52aSdan  set omitlist [lsort -integer -decreasing $omitlist]
1765f90f52aSdan
1775f90f52aSdan
1785f90f52aSdan  set rret [list]
1795f90f52aSdan  foreach r1 [lindex $data1 1] {
1805f90f52aSdan    set one 0
1815f90f52aSdan    foreach r2 [lindex $data2 1] {
1825f90f52aSdan      set ok 1
1835f90f52aSdan      if {$testproc != ""} {
1845f90f52aSdan        set ok [eval $testproc [list $c1 $r1 $c2 $r2]]
1855f90f52aSdan      }
1865f90f52aSdan      if {$ok} {
1875f90f52aSdan        set one 1
1885f90f52aSdan        foreach idx $omitlist {set r2 [lreplace $r2 $idx $idx]}
1895f90f52aSdan        lappend rret [concat $r1 $r2]
1905f90f52aSdan      }
1915f90f52aSdan    }
1925f90f52aSdan
1935f90f52aSdan    if {$isleft && $one==0} {
1945f90f52aSdan      lappend rret [concat $r1 $nullrowlist]
1955f90f52aSdan    }
1965f90f52aSdan  }
1975f90f52aSdan
1985f90f52aSdan  list $cret $rret
1995f90f52aSdan}
2005f90f52aSdan
2015f90f52aSdanproc te_tbljoin {db t1 t2 args} {
2025f90f52aSdan  te_join [te_read_tbl $db $t1] [te_read_tbl $db $t2] {*}$args
2035f90f52aSdan}
2045f90f52aSdan
2055f90f52aSdanproc te_apply_affinity {affinity typevar valvar} {
2065f90f52aSdan  upvar $typevar type
2075f90f52aSdan  upvar $valvar val
2085f90f52aSdan
2095f90f52aSdan  switch -- $affinity {
2105f90f52aSdan    integer {
2115f90f52aSdan      if {[string is double $val]} { set type REAL }
2125f90f52aSdan      if {[string is wideinteger $val]} { set type INTEGER }
2135f90f52aSdan      if {$type == "REAL" && int($val)==$val} {
2145f90f52aSdan        set type INTEGER
2155f90f52aSdan        set val [expr {int($val)}]
2165f90f52aSdan      }
2175f90f52aSdan    }
2185f90f52aSdan    text {
2195f90f52aSdan      set type TEXT
2205f90f52aSdan    }
2215f90f52aSdan    none { }
2225f90f52aSdan
2235f90f52aSdan    default { error "invalid affinity: $affinity" }
2245f90f52aSdan  }
2255f90f52aSdan}
2265f90f52aSdan
2275f90f52aSdan#----------
2285f90f52aSdan# te_equals ?SWITCHES? c1 c2 cols1 row1 cols2 row2
2295f90f52aSdan#
2305f90f52aSdanproc te_equals {args} {
2315f90f52aSdan
2325f90f52aSdan  if {[llength $args]<6} {error "invalid arguments to te_equals"}
2335f90f52aSdan  foreach {c1 c2 cols1 row1 cols2 row2} [lrange $args end-5 end] break
2345f90f52aSdan
2355f90f52aSdan  set nocase 0
2365f90f52aSdan  set affinity none
2375f90f52aSdan
2385f90f52aSdan  for {set i 0} {$i < ([llength $args]-6)} {incr i} {
2395f90f52aSdan    set a [lindex $args $i]
2405f90f52aSdan    switch -- $a {
2415f90f52aSdan      -nocase {
2425f90f52aSdan        set nocase 1
2435f90f52aSdan      }
2445f90f52aSdan      -affinity {
2455f90f52aSdan        set affinity [string tolower [lindex $args [incr i]]]
2465f90f52aSdan      }
2475f90f52aSdan      default {
2485f90f52aSdan        error "invalid arguments to te_equals"
2495f90f52aSdan      }
2505f90f52aSdan    }
2515f90f52aSdan  }
2525f90f52aSdan
2535f90f52aSdan  set idx2 [if {[string is integer $c2]} { set c2 } else { lsearch $cols2 $c2 }]
2545f90f52aSdan  set idx1 [if {[string is integer $c1]} { set c1 } else { lsearch $cols1 $c1 }]
2555f90f52aSdan
2565f90f52aSdan  set t1 [lindex $row1 $idx1 0]
2575f90f52aSdan  set t2 [lindex $row2 $idx2 0]
2585f90f52aSdan  set v1 [lindex $row1 $idx1 1]
2595f90f52aSdan  set v2 [lindex $row2 $idx2 1]
2605f90f52aSdan
2615f90f52aSdan  te_apply_affinity $affinity t1 v1
2625f90f52aSdan  te_apply_affinity $affinity t2 v2
2635f90f52aSdan
2645f90f52aSdan  if {$t1 == "NULL" || $t2 == "NULL"} { return 0 }
2655f90f52aSdan  if {$nocase && $t1 == "TEXT"} { set v1 [string tolower $v1] }
2665f90f52aSdan  if {$nocase && $t2 == "TEXT"} { set v2 [string tolower $v2] }
2675f90f52aSdan
2685f90f52aSdan
2695f90f52aSdan  set res [expr {$t1 == $t2 && [string equal $v1 $v2]}]
2705f90f52aSdan  return $res
2715f90f52aSdan}
2725f90f52aSdan
2735f90f52aSdanproc te_false {args} { return 0 }
2745f90f52aSdanproc te_true  {args} { return 1 }
2755f90f52aSdan
2765f90f52aSdanproc te_and {args} {
2775f90f52aSdan  foreach a [lrange $args 0 end-4] {
2785f90f52aSdan    set res [eval $a [lrange $args end-3 end]]
2795f90f52aSdan    if {$res == 0} {return 0}
2805f90f52aSdan  }
2815f90f52aSdan  return 1
2825f90f52aSdan}
2835f90f52aSdan
2845f90f52aSdan
2855f90f52aSdanproc te_dataset_eq {testname got expected} {
2865f90f52aSdan  uplevel #0 [list do_test $testname [list set {} $got] $expected]
2875f90f52aSdan}
2885f90f52aSdanproc te_dataset_eq_unordered {testname got expected} {
2895f90f52aSdan  lset got      1 [lsort [lindex $got 1]]
2905f90f52aSdan  lset expected 1 [lsort [lindex $expected 1]]
2915f90f52aSdan  te_dataset_eq $testname $got $expected
2925f90f52aSdan}
2935f90f52aSdan
2945f90f52aSdanproc te_dataset_ne {testname got unexpected} {
2955f90f52aSdan  uplevel #0 [list do_test $testname [list string equal $got $unexpected] 0]
2965f90f52aSdan}
2975f90f52aSdanproc te_dataset_ne_unordered {testname got unexpected} {
2985f90f52aSdan  lset got      1 [lsort [lindex $got 1]]
2995f90f52aSdan  lset unexpected 1 [lsort [lindex $unexpected 1]]
3005f90f52aSdan  te_dataset_ne $testname $got $unexpected
3015f90f52aSdan}
3025f90f52aSdan
3035f90f52aSdan
3045f90f52aSdan#-------------------------------------------------------------------------
3055f90f52aSdan#
3065f90f52aSdanproc test_join {tn sqljoin tbljoinargs} {
3075f90f52aSdan  set sql [te_read_sql db "SELECT * FROM $sqljoin"]
3085f90f52aSdan  set te  [te_tbljoin db {*}$tbljoinargs]
3095f90f52aSdan  te_dataset_eq_unordered $tn $sql $te
3105f90f52aSdan}
3115f90f52aSdan
3125f90f52aSdandrop_all_tables
3135f90f52aSdando_execsql_test e_select-2.0 {
3145f90f52aSdan  CREATE TABLE t1(a, b);
3155f90f52aSdan  CREATE TABLE t2(a, b);
3165f90f52aSdan  CREATE TABLE t3(b COLLATE nocase);
3175f90f52aSdan
3185f90f52aSdan  INSERT INTO t1 VALUES(2, 'B');
3195f90f52aSdan  INSERT INTO t1 VALUES(1, 'A');
3205f90f52aSdan  INSERT INTO t1 VALUES(4, 'D');
3215f90f52aSdan  INSERT INTO t1 VALUES(NULL, NULL);
3225f90f52aSdan  INSERT INTO t1 VALUES(3, NULL);
3235f90f52aSdan
3245f90f52aSdan  INSERT INTO t2 VALUES(1, 'A');
3255f90f52aSdan  INSERT INTO t2 VALUES(2, NULL);
3265f90f52aSdan  INSERT INTO t2 VALUES(5, 'E');
3275f90f52aSdan  INSERT INTO t2 VALUES(NULL, NULL);
3285f90f52aSdan  INSERT INTO t2 VALUES(3, 'C');
3295f90f52aSdan
3305f90f52aSdan  INSERT INTO t3 VALUES('a');
3315f90f52aSdan  INSERT INTO t3 VALUES('c');
3325f90f52aSdan  INSERT INTO t3 VALUES('b');
3335f90f52aSdan} {}
3345f90f52aSdan
3355f90f52aSdanforeach {tn indexes} {
3365f90f52aSdan  e_select-2.1.1 { }
3375f90f52aSdan  e_select-2.1.2 { CREATE INDEX i1 ON t1(a) }
3385f90f52aSdan  e_select-2.1.3 { CREATE INDEX i1 ON t2(a) }
3395f90f52aSdan  e_select-2.1.4 { CREATE INDEX i1 ON t3(b) }
3405f90f52aSdan} {
3415f90f52aSdan
3425f90f52aSdan  catchsql { DROP INDEX i1 }
3435f90f52aSdan  catchsql { DROP INDEX i2 }
3445f90f52aSdan  catchsql { DROP INDEX i3 }
3455f90f52aSdan  execsql $indexes
3465f90f52aSdan
347*a820c05aSdrh  # EVIDENCE-OF: R-49872-03192 If the join-operator is "CROSS JOIN",
348*a820c05aSdrh  # "INNER JOIN", "JOIN" or a comma (",") and there is no ON or USING
349*a820c05aSdrh  # clause, then the result of the join is simply the cartesian product of
350*a820c05aSdrh  # the left and right-hand datasets.
3515f90f52aSdan  #
3525f90f52aSdan  # EVIDENCE-OF: R-46256-57243 There is no difference between the "INNER
3535f90f52aSdan  # JOIN", "JOIN" and "," join operators.
3545f90f52aSdan  #
35539759747Sdrh  # EVIDENCE-OF: R-25071-21202 The "CROSS JOIN" join operator produces the
35639759747Sdrh  # same result as the "INNER JOIN", "JOIN" and "," operators
3575f90f52aSdan  #
3585f90f52aSdan  test_join $tn.1.1  "t1, t2"                {t1 t2}
3595f90f52aSdan  test_join $tn.1.2  "t1 INNER JOIN t2"      {t1 t2}
3605f90f52aSdan  test_join $tn.1.3  "t1 CROSS JOIN t2"      {t1 t2}
3615f90f52aSdan  test_join $tn.1.4  "t1 JOIN t2"            {t1 t2}
3625f90f52aSdan  test_join $tn.1.5  "t2, t3"                {t2 t3}
3635f90f52aSdan  test_join $tn.1.6  "t2 INNER JOIN t3"      {t2 t3}
3645f90f52aSdan  test_join $tn.1.7  "t2 CROSS JOIN t3"      {t2 t3}
3655f90f52aSdan  test_join $tn.1.8  "t2 JOIN t3"            {t2 t3}
3665f90f52aSdan  test_join $tn.1.9  "t2, t2 AS x"           {t2 t2}
3675f90f52aSdan  test_join $tn.1.10 "t2 INNER JOIN t2 AS x" {t2 t2}
3685f90f52aSdan  test_join $tn.1.11 "t2 CROSS JOIN t2 AS x" {t2 t2}
3695f90f52aSdan  test_join $tn.1.12 "t2 JOIN t2 AS x"       {t2 t2}
3705f90f52aSdan
371*a820c05aSdrh  # EVIDENCE-OF: R-38465-03616 If there is an ON clause then the ON
372*a820c05aSdrh  # expression is evaluated for each row of the cartesian product as a
373*a820c05aSdrh  # boolean expression. Only rows for which the expression evaluates to
374*a820c05aSdrh  # true are included from the dataset.
3755f90f52aSdan  #
3765f90f52aSdan  test_join $tn.2.1  "t1, t2 ON (t1.a=t2.a)"  {t1 t2 -on {te_equals a a}}
3775f90f52aSdan  test_join $tn.2.2  "t2, t1 ON (t1.a=t2.a)"  {t2 t1 -on {te_equals a a}}
3785f90f52aSdan  test_join $tn.2.3  "t2, t1 ON (1)"          {t2 t1 -on te_true}
3795f90f52aSdan  test_join $tn.2.4  "t2, t1 ON (NULL)"       {t2 t1 -on te_false}
3805f90f52aSdan  test_join $tn.2.5  "t2, t1 ON (1.1-1.1)"    {t2 t1 -on te_false}
3815f90f52aSdan  test_join $tn.2.6  "t1, t2 ON (1.1-1.0)"    {t1 t2 -on te_true}
3825f90f52aSdan
3835f90f52aSdan
3845f90f52aSdan  test_join $tn.3 "t1 LEFT JOIN t2 ON (t1.a=t2.a)" {t1 t2 -left -on {te_equals a a}}
3855f90f52aSdan  test_join $tn.4 "t1 LEFT JOIN t2 USING (a)" {
3865f90f52aSdan    t1 t2 -left -using a -on {te_equals a a}
3875f90f52aSdan  }
3885f90f52aSdan  test_join $tn.5 "t1 CROSS JOIN t2 USING(b, a)" {
3895f90f52aSdan    t1 t2 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
3905f90f52aSdan  }
3915f90f52aSdan  test_join $tn.6 "t1 NATURAL JOIN t2" {
3925f90f52aSdan    t1 t2 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
3935f90f52aSdan  }
3945f90f52aSdan  test_join $tn.7 "t1 NATURAL INNER JOIN t2" {
3955f90f52aSdan    t1 t2 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
3965f90f52aSdan  }
3975f90f52aSdan  test_join $tn.8 "t1 NATURAL CROSS JOIN t2" {
3985f90f52aSdan    t1 t2 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
3995f90f52aSdan  }
4005f90f52aSdan  test_join $tn.9 "t1 NATURAL INNER JOIN t2" {
4015f90f52aSdan    t1 t2 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4025f90f52aSdan  }
4035f90f52aSdan  test_join $tn.10 "t1 NATURAL LEFT JOIN t2" {
4045f90f52aSdan    t1 t2 -left -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4055f90f52aSdan  }
4065f90f52aSdan  test_join $tn.11 "t1 NATURAL LEFT OUTER JOIN t2" {
4075f90f52aSdan    t1 t2 -left -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4085f90f52aSdan  }
4095f90f52aSdan  test_join $tn.12 "t2 NATURAL JOIN t1" {
4105f90f52aSdan    t2 t1 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4115f90f52aSdan  }
4125f90f52aSdan  test_join $tn.13 "t2 NATURAL INNER JOIN t1" {
4135f90f52aSdan    t2 t1 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4145f90f52aSdan  }
4155f90f52aSdan  test_join $tn.14 "t2 NATURAL CROSS JOIN t1" {
4165f90f52aSdan    t2 t1 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4175f90f52aSdan  }
4185f90f52aSdan  test_join $tn.15 "t2 NATURAL INNER JOIN t1" {
4195f90f52aSdan    t2 t1 -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4205f90f52aSdan  }
4215f90f52aSdan  test_join $tn.16 "t2 NATURAL LEFT JOIN t1" {
4225f90f52aSdan    t2 t1 -left -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4235f90f52aSdan  }
4245f90f52aSdan  test_join $tn.17 "t2 NATURAL LEFT OUTER JOIN t1" {
4255f90f52aSdan    t2 t1 -left -using {a b} -on {te_and {te_equals a a} {te_equals b b}}
4265f90f52aSdan  }
4275f90f52aSdan  test_join $tn.18 "t1 LEFT JOIN t2 USING (b)" {
4285f90f52aSdan    t1 t2 -left -using b -on {te_equals b b}
4295f90f52aSdan  }
4305f90f52aSdan  test_join $tn.19 "t1 JOIN t3 USING(b)" {t1 t3 -using b -on {te_equals b b}}
4315f90f52aSdan  test_join $tn.20 "t3 JOIN t1 USING(b)" {
4325f90f52aSdan    t3 t1 -using b -on {te_equals -nocase b b}
4335f90f52aSdan  }
4345f90f52aSdan  test_join $tn.21 "t1 NATURAL JOIN t3"  {
4355f90f52aSdan    t1 t3 -using b -on {te_equals b b}
4365f90f52aSdan  }
4375f90f52aSdan  test_join $tn.22 "t3 NATURAL JOIN t1"  {
4385f90f52aSdan    t3 t1 -using b -on {te_equals -nocase b b}
4395f90f52aSdan  }
4405f90f52aSdan  test_join $tn.23 "t1 NATURAL LEFT JOIN t3" {
4415f90f52aSdan    t1 t3 -left -using b -on {te_equals b b}
4425f90f52aSdan  }
4435f90f52aSdan  test_join $tn.24 "t3 NATURAL LEFT JOIN t1" {
4445f90f52aSdan    t3 t1 -left -using b -on {te_equals -nocase b b}
4455f90f52aSdan  }
4465f90f52aSdan  test_join $tn.25 "t1 LEFT JOIN t3 ON (t3.b=t1.b)" {
4475f90f52aSdan    t1 t3 -left -on {te_equals -nocase b b}
4485f90f52aSdan  }
4495f90f52aSdan  test_join $tn.26 "t1 LEFT JOIN t3 ON (t1.b=t3.b)" {
4505f90f52aSdan    t1 t3 -left -on {te_equals b b}
4515f90f52aSdan  }
4525f90f52aSdan  test_join $tn.27 "t1 JOIN t3 ON (t1.b=t3.b)" { t1 t3 -on {te_equals b b} }
4535f90f52aSdan
4545f90f52aSdan  # EVIDENCE-OF: R-28760-53843 When more than two tables are joined
4555f90f52aSdan  # together as part of a FROM clause, the join operations are processed
4565f90f52aSdan  # in order from left to right. In other words, the FROM clause (A
4575f90f52aSdan  # join-op-1 B join-op-2 C) is computed as ((A join-op-1 B) join-op-2 C).
4585f90f52aSdan  #
4595f90f52aSdan  #   Tests 28a and 28b show that the statement above is true for this case.
4605f90f52aSdan  #   Test 28c shows that if the parenthesis force a different order of
4615f90f52aSdan  #   evaluation the result is different. Test 28d verifies that the result
4625f90f52aSdan  #   of the query with the parenthesis forcing a different order of evaluation
4635f90f52aSdan  #   is as calculated by the [te_*] procs.
4645f90f52aSdan  #
4655f90f52aSdan  set t3_natural_left_join_t2 [
4665f90f52aSdan    te_tbljoin db t3 t2 -left -using {b} -on {te_equals -nocase b b}
4675f90f52aSdan  ]
4685f90f52aSdan  set t1 [te_read_tbl db t1]
4695f90f52aSdan  te_dataset_eq_unordered $tn.28a [
4705f90f52aSdan    te_read_sql db "SELECT * FROM t3 NATURAL LEFT JOIN t2 NATURAL JOIN t1"
4715f90f52aSdan  ] [te_join $t3_natural_left_join_t2 $t1                                \
4725f90f52aSdan      -using {a b} -on {te_and {te_equals a a} {te_equals -nocase b b}}  \
4735f90f52aSdan  ]
4745f90f52aSdan
4755f90f52aSdan  te_dataset_eq_unordered $tn.28b [
4765f90f52aSdan    te_read_sql db "SELECT * FROM (t3 NATURAL LEFT JOIN t2) NATURAL JOIN t1"
4775f90f52aSdan  ] [te_join $t3_natural_left_join_t2 $t1                                \
4785f90f52aSdan      -using {a b} -on {te_and {te_equals a a} {te_equals -nocase b b}}  \
4795f90f52aSdan  ]
4805f90f52aSdan
4815f90f52aSdan  te_dataset_ne_unordered $tn.28c [
4825f90f52aSdan    te_read_sql db "SELECT * FROM (t3 NATURAL LEFT JOIN t2) NATURAL JOIN t1"
4835f90f52aSdan  ] [
4845f90f52aSdan    te_read_sql db "SELECT * FROM t3 NATURAL LEFT JOIN (t2 NATURAL JOIN t1)"
4855f90f52aSdan  ]
4865f90f52aSdan
4875f90f52aSdan  set t2_natural_join_t1 [te_tbljoin db t2 t1 -using {a b}                 \
4885f90f52aSdan        -using {a b} -on {te_and {te_equals a a} {te_equals -nocase b b}}  \
4895f90f52aSdan  ]
4905f90f52aSdan  set t3 [te_read_tbl db t3]
4915f90f52aSdan  te_dataset_eq_unordered $tn.28d [
4925f90f52aSdan    te_read_sql db "SELECT * FROM t3 NATURAL LEFT JOIN (t2 NATURAL JOIN t1)"
4935f90f52aSdan  ] [te_join $t3 $t2_natural_join_t1                                       \
4945f90f52aSdan      -left -using {b} -on {te_equals -nocase b b}                         \
4955f90f52aSdan  ]
4965f90f52aSdan}
4975f90f52aSdan
4985f90f52aSdando_execsql_test e_select-2.2.0 {
4995f90f52aSdan  CREATE TABLE t4(x TEXT COLLATE nocase);
5005f90f52aSdan  CREATE TABLE t5(y INTEGER, z TEXT COLLATE binary);
5015f90f52aSdan
5025f90f52aSdan  INSERT INTO t4 VALUES('2.0');
5035f90f52aSdan  INSERT INTO t4 VALUES('TWO');
5045f90f52aSdan  INSERT INTO t5 VALUES(2, 'two');
5055f90f52aSdan} {}
5065f90f52aSdan
507*a820c05aSdrh# EVIDENCE-OF: R-59237-46742 A subquery specified in the
508*a820c05aSdrh# table-or-subquery following the FROM clause in a simple SELECT
509*a820c05aSdrh# statement is handled as if it was a table containing the data returned
510*a820c05aSdrh# by executing the subquery statement.
5115f90f52aSdan#
512*a820c05aSdrh# EVIDENCE-OF: R-27438-53558 Each column of the subquery has the
513*a820c05aSdrh# collation sequence and affinity of the corresponding expression in the
514*a820c05aSdrh# subquery statement.
5155f90f52aSdan#
5165f90f52aSdanforeach {tn subselect select spec} {
5175f90f52aSdan  1   "SELECT * FROM t2"   "SELECT * FROM t1 JOIN %ss%"
5185f90f52aSdan      {t1 %ss%}
5195f90f52aSdan
5205f90f52aSdan  2   "SELECT * FROM t2"   "SELECT * FROM t1 JOIN %ss% AS x ON (t1.a=x.a)"
5215f90f52aSdan      {t1 %ss% -on {te_equals 0 0}}
5225f90f52aSdan
5235f90f52aSdan  3   "SELECT * FROM t2"   "SELECT * FROM %ss% AS x JOIN t1 ON (t1.a=x.a)"
5245f90f52aSdan      {%ss% t1 -on {te_equals 0 0}}
5255f90f52aSdan
5265f90f52aSdan  4   "SELECT * FROM t1, t2" "SELECT * FROM %ss% AS x JOIN t3"
5275f90f52aSdan      {%ss% t3}
5285f90f52aSdan
5295f90f52aSdan  5   "SELECT * FROM t1, t2" "SELECT * FROM %ss% NATURAL JOIN t3"
5305f90f52aSdan      {%ss% t3 -using b -on {te_equals 1 0}}
5315f90f52aSdan
5325f90f52aSdan  6   "SELECT * FROM t1, t2" "SELECT * FROM t3 NATURAL JOIN %ss%"
5335f90f52aSdan      {t3 %ss% -using b -on {te_equals -nocase 0 1}}
5345f90f52aSdan
5355f90f52aSdan  7   "SELECT * FROM t1, t2" "SELECT * FROM t3 NATURAL LEFT JOIN %ss%"
5365f90f52aSdan      {t3 %ss% -left -using b -on {te_equals -nocase 0 1}}
5375f90f52aSdan
5385f90f52aSdan  8   "SELECT count(*) AS y FROM t4"   "SELECT * FROM t5, %ss% USING (y)"
5395f90f52aSdan      {t5 %ss% -using y -on {te_equals -affinity text 0 0}}
5405f90f52aSdan
5415f90f52aSdan  9   "SELECT count(*) AS y FROM t4"   "SELECT * FROM %ss%, t5 USING (y)"
5425f90f52aSdan      {%ss% t5 -using y -on {te_equals -affinity text 0 0}}
5435f90f52aSdan
5445f90f52aSdan  10  "SELECT x AS y FROM t4"   "SELECT * FROM %ss% JOIN t5 USING (y)"
5455f90f52aSdan      {%ss% t5 -using y -on {te_equals -nocase -affinity integer 0 0}}
5465f90f52aSdan
5475f90f52aSdan  11  "SELECT x AS y FROM t4"   "SELECT * FROM t5 JOIN %ss% USING (y)"
5485f90f52aSdan      {t5 %ss% -using y -on {te_equals -nocase -affinity integer 0 0}}
5495f90f52aSdan
5505f90f52aSdan  12  "SELECT y AS x FROM t5"   "SELECT * FROM %ss% JOIN t4 USING (x)"
5515f90f52aSdan      {%ss% t4 -using x -on {te_equals -nocase -affinity integer 0 0}}
5525f90f52aSdan
5535f90f52aSdan  13  "SELECT y AS x FROM t5"   "SELECT * FROM t4 JOIN %ss% USING (x)"
5545f90f52aSdan      {t4 %ss% -using x -on {te_equals -nocase -affinity integer 0 0}}
5555f90f52aSdan
5565f90f52aSdan  14  "SELECT +y AS x FROM t5"   "SELECT * FROM %ss% JOIN t4 USING (x)"
5575f90f52aSdan      {%ss% t4 -using x -on {te_equals -nocase -affinity text 0 0}}
5585f90f52aSdan
5595f90f52aSdan  15  "SELECT +y AS x FROM t5"   "SELECT * FROM t4 JOIN %ss% USING (x)"
5605f90f52aSdan      {t4 %ss% -using x -on {te_equals -nocase -affinity text 0 0}}
5615f90f52aSdan} {
5625f90f52aSdan
5635f90f52aSdan  # Create a temporary table named %ss% containing the data returned by
5645f90f52aSdan  # the sub-select. Then have the [te_tbljoin] proc use this table to
5655f90f52aSdan  # compute the expected results of the $select query. Drop the temporary
5665f90f52aSdan  # table before continuing.
5675f90f52aSdan  #
5685f90f52aSdan  execsql "CREATE TEMP TABLE '%ss%' AS $subselect"
5695f90f52aSdan  set te [eval te_tbljoin db $spec]
5705f90f52aSdan  execsql "DROP TABLE '%ss%'"
5715f90f52aSdan
5725f90f52aSdan  # Check that the actual data returned by the $select query is the same
5735f90f52aSdan  # as the expected data calculated using [te_tbljoin] above.
5745f90f52aSdan  #
5755f90f52aSdan  te_dataset_eq_unordered e_select-2.2.1.$tn [
5765f90f52aSdan    te_read_sql db [string map [list %ss% "($subselect)"] $select]
5775f90f52aSdan  ] $te
5785f90f52aSdan}
5795f90f52aSdan
5805f90f52aSdanfinish_test
581