SQLite

Artifact [df158dcc81]
Login

Artifact df158dcc81f1a43ce7eef361af03c48ec91f1e06:


# 2011 March 2
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# Make sure the rtreenode() testing function can handle entries with
# 64-bit rowids.
# 

if {![info exists testdir]} {
  set testdir [file join [file dirname [info script]] .. .. test]
} 
source $testdir/tester.tcl
ifcapable !rtree { finish_test ; return }
set testprefix rtreeC

do_execsql_test 1.0 {
  CREATE VIRTUAL TABLE r_tree USING rtree(id, min_x, max_x, min_y, max_y);
  CREATE TABLE t(x, y);
}

do_eqp_test 1.1 {
  SELECT * FROM r_tree, t 
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y
} {
  0 0 1 {SCAN TABLE t}
  0 1 0 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 1.2 {
  SELECT * FROM t, r_tree
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y
} {
  0 0 0 {SCAN TABLE t}
  0 1 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 1.3 {
  SELECT * FROM t, r_tree
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND ?<=max_y
} {
  0 0 0 {SCAN TABLE t}
  0 1 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 1.5 {
  SELECT * FROM t, r_tree
} {
  0 0 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:}
  0 1 0 {SCAN TABLE t} 
}

do_execsql_test 2.0 {
  INSERT INTO t VALUES(0, 0);
  INSERT INTO t VALUES(0, 1);
  INSERT INTO t VALUES(0, 2);
  INSERT INTO t VALUES(0, 3);
  INSERT INTO t VALUES(0, 4);
  INSERT INTO t VALUES(0, 5);
  INSERT INTO t VALUES(0, 6);
  INSERT INTO t VALUES(0, 7);
  INSERT INTO t VALUES(0, 8);
  INSERT INTO t VALUES(0, 9);

  INSERT INTO t SELECT x+1, y FROM t;
  INSERT INTO t SELECT x+2, y FROM t;
  INSERT INTO t SELECT x+4, y FROM t;
  INSERT INTO r_tree SELECT NULL, x-1, x+1, y-1, y+1 FROM t;
  ANALYZE;
}

db close
sqlite3 db test.db

do_eqp_test 2.1 {
  SELECT * FROM r_tree, t 
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y
} {
  0 0 1 {SCAN TABLE t}
  0 1 0 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 2.2 {
  SELECT * FROM t, r_tree
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND t.x<=max_y
} {
  0 0 0 {SCAN TABLE t}
  0 1 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 2.3 {
  SELECT * FROM t, r_tree
  WHERE t.x>=min_x AND t.x<=max_x AND t.y>=min_y AND ?<=max_y
} {
  0 0 0 {SCAN TABLE t}
  0 1 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:D3B2D1B0}
}

do_eqp_test 2.5 {
  SELECT * FROM t, r_tree
} {
  0 0 1 {SCAN TABLE r_tree VIRTUAL TABLE INDEX 2:}
  0 1 0 {SCAN TABLE t} 
}

#-------------------------------------------------------------------------
# Test that the special CROSS JOIN handling works with rtree tables.
#
do_execsql_test 3.1 {
  CREATE TABLE t1(x);
  CREATE TABLE t2(y);
  CREATE VIRTUAL TABLE t3 USING rtree(z, x1,x2, y1,y2);
}

do_eqp_test 3.2.1 { SELECT * FROM t1 CROSS JOIN t2 } {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SCAN TABLE t2}
}
do_eqp_test 3.2.2 { SELECT * FROM t2 CROSS JOIN t1 } {
  0 0 0 {SCAN TABLE t2} 0 1 1 {SCAN TABLE t1}
}

do_eqp_test 3.3.1 { SELECT * FROM t1 CROSS JOIN t3 } {
  0 0 0 {SCAN TABLE t1}
  0 1 1 {SCAN TABLE t3 VIRTUAL TABLE INDEX 2:} 
}
do_eqp_test 3.3.2 { SELECT * FROM t3 CROSS JOIN t1 } {
  0 0 0 {SCAN TABLE t3 VIRTUAL TABLE INDEX 2:} 
  0 1 1 {SCAN TABLE t1}
}

#--------------------------------------------------------------------
# Test that LEFT JOINs are not reordered if the right-hand-side is
# a virtual table.
#
reset_db
do_execsql_test 4.1 {
  CREATE TABLE t1(a);
  CREATE VIRTUAL TABLE t2 USING rtree(b, x1,x2);

  INSERT INTO t1 VALUES(1);
  INSERT INTO t1 VALUES(2);

  INSERT INTO t2 VALUES(1, 0.0, 0.1);
  INSERT INTO t2 VALUES(3, 0.0, 0.1);
}

do_execsql_test 4.2 {
  SELECT a, b FROM t1 LEFT JOIN t2 ON (+a = +b);
} {1 1 2 {}}

do_execsql_test 4.3 {
  SELECT b, a FROM t2 LEFT JOIN t1 ON (+a = +b);
} {1 1 3 {}}

#--------------------------------------------------------------------
# Test that the sqlite_stat1 data is used correctly.
#
reset_db
do_execsql_test 5.1 {
  CREATE TABLE t1(x PRIMARY KEY, y);
  CREATE VIRTUAL TABLE rt USING rtree(id, x1, x2);

  INSERT INTO t1(x) VALUES(1);
  INSERT INTO t1(x) SELECT x+1 FROM t1;   --   2
  INSERT INTO t1(x) SELECT x+2 FROM t1;   --   4
  INSERT INTO t1(x) SELECT x+4 FROM t1;   --   8
  INSERT INTO t1(x) SELECT x+8 FROM t1;   --  16
  INSERT INTO t1(x) SELECT x+16 FROM t1;  --  32
  INSERT INTO t1(x) SELECT x+32 FROM t1;  --  64
  INSERT INTO t1(x) SELECT x+64 FROM t1;  -- 128
  INSERT INTO t1(x) SELECT x+128 FROM t1; -- 256
  INSERT INTO t1(x) SELECT x+256 FROM t1; -- 512
  INSERT INTO t1(x) SELECT x+512 FROM t1; --1024

  INSERT INTO rt SELECT x, x, x+1 FROM t1 WHERE x<=5;
}

# First test a query with no ANALYZE data at all. The outer loop is
# real table "t1".
#
do_eqp_test 5.2 {
  SELECT * FROM t1, rt WHERE x==id;
} {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SCAN TABLE rt VIRTUAL TABLE INDEX 1:}
}

# Now create enough ANALYZE data to tell SQLite that virtual table "rt"
# contains very few rows. This causes it to move "rt" to the outer loop.
#
do_execsql_test 5.3 {
  ANALYZE;
  DELETE FROM sqlite_stat1 WHERE tbl='t1';
}
db close
sqlite3 db test.db
do_eqp_test 5.4 {
  SELECT * FROM t1, rt WHERE x==id;
} {
  0 0 1 {SCAN TABLE rt VIRTUAL TABLE INDEX 2:} 
  0 1 0 {SEARCH TABLE t1 USING INDEX sqlite_autoindex_t1_1 (x=?)}
}

# Delete the ANALYZE data. "t1" should be the outer loop again.
#
do_execsql_test 5.5 { DROP TABLE sqlite_stat1; }
db close
sqlite3 db test.db
do_eqp_test 5.6 {
  SELECT * FROM t1, rt WHERE x==id;
} {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SCAN TABLE rt VIRTUAL TABLE INDEX 1:}
}

# This time create and attach a database that contains ANALYZE data for
# tables of the same names as those used internally by virtual table
# "rt". Check that the rtree module is not fooled into using this data.
# Table "t1" should remain the outer loop.
#
do_test 5.7 {
  db backup test.db2
  sqlite3 db2 test.db2
  db2 eval {
    ANALYZE;
    DELETE FROM sqlite_stat1 WHERE tbl='t1';
  }
  db2 close
  db close
  sqlite3 db test.db
  execsql { ATTACH 'test.db2' AS aux; }
} {}
do_eqp_test 5.8 {
  SELECT * FROM t1, rt WHERE x==id;
} {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SCAN TABLE rt VIRTUAL TABLE INDEX 1:}
}

#--------------------------------------------------------------------
# Test that having a second connection drop the sqlite_stat1 table
# before it is required by rtreeConnect() does not cause problems.
#
ifcapable rtree {
  reset_db
  do_execsql_test 6.1 {
    CREATE TABLE t1(x);
    CREATE VIRTUAL TABLE rt USING rtree(id, x1, x2);
    INSERT INTO t1 VALUES(1);
    INSERT INTO rt VALUES(1,2,3);
    ANALYZE;
  }
  db close
  sqlite3 db test.db
  do_execsql_test 6.2 { SELECT * FROM t1 } {1}
  
  do_test 6.3 {
    sqlite3 db2 test.db
    db2 eval { DROP TABLE sqlite_stat1 }
    db2 close
    execsql { SELECT * FROM rt }
  } {1 2.0 3.0}
  db close
}


finish_test