From: dan Date: Mon, 23 Nov 2015 17:10:51 +0000 (+0000) Subject: Fix ORDER BY handling in the schemalint.tcl script. Add internal self-tests to the... X-Git-Tag: version-3.22.0~147^2~65 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=1b8b839a8db3692a559c1ca3f90fb18bb3e82624;p=thirdparty%2Fsqlite.git Fix ORDER BY handling in the schemalint.tcl script. Add internal self-tests to the same script. FossilOrigin-Name: b8f277c9b45c4b30e6690e838a30311aa8d84876 --- diff --git a/manifest b/manifest index e9c4624905..fb61058c44 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Add\ssupport\sfor\sORDER\sBY\sclauses\sto\sschemalint.tcl. -D 2015-11-20T20:55:27.428 +C Fix\sORDER\sBY\shandling\sin\sthe\sschemalint.tcl\sscript.\sAdd\sinternal\sself-tests\sto\sthe\ssame\sscript. +D 2015-11-23T17:10:51.938 F Makefile.in d828db6afa6c1fa060d01e33e4674408df1942a1 F Makefile.linux-gcc 7bc79876b875010e8c8f9502eb935ca92aa3c434 F Makefile.msc e928e68168df69b353300ac87c10105206653a03 @@ -1379,7 +1379,7 @@ F tool/replace.tcl 7727c60a04299b65a92f5e1590896fea0f25b9e0 F tool/restore_jrnl.tcl 6957a34f8f1f0f8285e07536225ec3b292a9024a F tool/rollback-test.c 9fc98427d1e23e84429d7e6d07d9094fbdec65a5 F tool/run-speed-test.sh 0ae485af4fe9f826e2b494be8c81f8ca9e222a4a -F tool/schemalint.tcl 160fe2ed74df02e859ab32a522fa1f2e8e0c4230 +F tool/schemalint.tcl e49c9b25c8c43f0531eca96edaf85ce8bd7f308b F tool/showdb.c d4476e000a64eca9f5e2c2f68741e747b9778e8d F tool/showjournal.c 5bad7ae8784a43d2b270d953060423b8bd480818 F tool/showlocks.c 9920bcc64f58378ff1118caead34147201f48c68 @@ -1404,7 +1404,7 @@ F tool/vdbe_profile.tcl 246d0da094856d72d2c12efec03250d71639d19f F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4 F tool/warnings.sh 48bd54594752d5be3337f12c72f28d2080cb630b F tool/win/sqlite.vsix deb315d026cc8400325c5863eef847784a219a2f -P c6fa01c28ef7ceea2963a92dfffe62eed451b05c -R 6fc6a71e3dbe84052a5d99204cd615ee +P 93bdf70e859915ff3696ba0fc68f91ceb2e1a971 +R 4554e59743437c1fee4689a6514241d8 U dan -Z 64248603e4a564821f72e660b22a8811 +Z f43cf07c3dedebc0e4a9e76dc40982d5 diff --git a/manifest.uuid b/manifest.uuid index a959ffa2b1..7790e3b6f1 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -93bdf70e859915ff3696ba0fc68f91ceb2e1a971 \ No newline at end of file +b8f277c9b45c4b30e6690e838a30311aa8d84876 \ No newline at end of file diff --git a/tool/schemalint.tcl b/tool/schemalint.tcl index 94e1ec02ec..933b277ea2 100644 --- a/tool/schemalint.tcl +++ b/tool/schemalint.tcl @@ -1,22 +1,18 @@ - - -set ::G(lSelect) [list] ;# List of SELECT statements to analyze -set ::G(database) "" ;# Name of database or SQL schema file -set ::G(trace) [list] ;# List of data from xTrace() -set ::G(verbose) 0 ;# True if -verbose option was passed +set ::VERBOSE 0 proc usage {} { puts stderr "Usage: $::argv0 ?SWITCHES? DATABASE/SCHEMA" puts stderr " Switches are:" puts stderr " -select SQL (recommend indexes for SQL statement)" puts stderr " -verbose (increase verbosity of output)" + puts stderr " -test (run internal tests and then exit)" puts stderr "" exit } -proc process_cmdline_args {argv} { - global G +proc process_cmdline_args {ctxvar argv} { + upvar $ctxvar G set nArg [llength $argv] set G(database) [lindex $argv end] @@ -29,17 +25,24 @@ proc process_cmdline_args {argv} { lappend G(lSelect) [lindex $argv $i] } -verbose { - set G(verbose) 1 + set ::VERBOSE 1 + } + -test { + sqlidx_internal_tests } default { usage } } } + + if {$G(database)=="-test"} { + sqlidx_internal_tests + } } -proc open_database {} { - global G +proc open_database {ctxvar} { + upvar $ctxvar G sqlite3 db "" # Check if the "database" file is really an SQLite database. If so, copy @@ -62,14 +65,17 @@ proc open_database {} { } } -proc analyze_selects {} { - global G +proc analyze_selects {ctxvar} { + upvar $ctxvar G set G(trace) "" # Collect a line of xTrace output for each loop in the set of SELECT # statements. - proc xTrace {zMsg} { lappend ::G(trace) $zMsg } - db trace "lappend ::G(trace)" + proc xTrace {zMsg} { + upvar G G + lappend G(trace) $zMsg + } + db trace xTrace foreach s $G(lSelect) { set stmt [sqlite3_prepare_v2 db $s -1 dummy] set rc [sqlite3_finalize $stmt] @@ -79,7 +85,7 @@ proc analyze_selects {} { } db trace "" - if {$G(verbose)} { + if {$::VERBOSE} { foreach t $G(trace) { puts "trace: $t" } } @@ -118,11 +124,12 @@ proc expand_eq_list {L} { #-------------------------------------------------------------------------- # Formulate a CREATE INDEX statement that creates an index on table $tname. # -proc eqset_to_index {tname eqset {range {}}} { - global G +proc eqset_to_index {ctxvar tname eqset {range {}}} { + upvar $ctxvar G + set lCols [list] set idxname $tname - foreach e [concat [lsort $eqset] [list $range]] { + foreach e [lsort $eqset] { if {[llength $e]==0} continue foreach {c collate} $e {} lappend lCols "$c collate $collate" @@ -132,6 +139,19 @@ proc eqset_to_index {tname eqset {range {}}} { } } + foreach {c collate dir} $range { + append idxname "_$c" + if {[string compare -nocase binary $collate]!=0} { + append idxname [string tolower $collate] + } + if {$dir=="DESC"} { + lappend lCols "$c collate $collate DESC" + append idxname "desc" + } else { + lappend lCols "$c collate $collate" + } + } + set create_index "CREATE INDEX $idxname ON ${tname}(" append create_index [join $lCols ", "] append create_index ");" @@ -164,64 +184,97 @@ proc expand_or_cons {L} { return $lRet } -proc find_trial_indexes {} { - global G +proc find_trial_indexes {ctxvar} { + upvar $ctxvar G foreach t $G(trace) { set tname [lindex $t 0] catch { array unset mask } + set orderby [list] if {[lindex $t end 0]=="orderby"} { set orderby [lrange [lindex $t end] 1 end] } foreach lCons [expand_or_cons [lrange $t 2 end]] { - set constraints [list] + # Populate the array mask() so that it contains an entry for each + # combination of prerequisite scans that may lead to distinct sets + # of constraints being usable. + # + catch { array unset mask } + set mask(0) 1 foreach a $lCons { set type [lindex $a 0] if {$type=="eq" || $type=="range"} { set m [lindex $a 3] foreach k [array names mask] { set mask([expr ($k & $m)]) 1 } set mask($m) 1 - lappend constraints $a } } + # Loop once for each distinct prerequisite scan mask identified in + # the previous block. + # foreach k [array names mask] { + + # Identify the constraints available for prerequisite mask $k. For + # each == constraint, set an entry in the eq() array as follows: + # + # set eq() + # + # If there is more than one == constraint for a column, and they use + # different collation sequences, is replaced with a list + # of the possible collation sequences. For example, for: + # + # SELECT * FROM t1 WHERE a=? COLLATE BINARY AND a=? COLLATE NOCASE + # + # Set the following entry in the eq() array: + # + # set eq(a) {binary nocase} + # + # For each range constraint found an entry is appended to the $ranges + # list. The entry is itself a list of the form { }. + # catch {array unset eq} - foreach a $constraints { - foreach {type col collate m} $a { - if {($m & $k)==$m} { - if {$type=="eq"} { - lappend eq($col) $collate - } else { - set range($col.$collate) 1 + set ranges [list] + foreach a $lCons { + set type [lindex $a 0] + if {$type=="eq" || $type=="range"} { + foreach {type col collate m} $a { + if {($m & $k)==$m} { + if {$type=="eq"} { + lappend eq($col) $collate + } else { + lappend ranges [list $col $collate ASC] + } } } } } + set ranges [lsort -unique $ranges] + if {$orderby != ""} { + lappend ranges $orderby + } - #puts "mask=$k eq=[array get eq] range=[array get range]" - - set ranges [array names range] foreach eqset [expand_eq_list [array get eq]] { - if {[llength $ranges]==0} { - eqset_to_index $tname $eqset - } else { - foreach r $ranges { + if {$eqset != ""} { + eqset_to_index G $tname $eqset + } + + foreach r $ranges { + set tail [list] + foreach {c collate dir} $r { set bSeen 0 - foreach {c collate} [split $r .] {} foreach e $eqset { if {[lindex $e 0] == $c} { set bSeen 1 break } } - if {$bSeen} { - eqset_to_index $tname $eqset - } else { - eqset_to_index $tname $eqset [list $c $collate] - } + if {$bSeen==0} { lappend tail {*}$r } + } + if {[llength $tail]} { + eqset_to_index G $tname $eqset $r } } } @@ -229,13 +282,14 @@ proc find_trial_indexes {} { } } - if {$G(verbose)} { + if {$::VERBOSE} { foreach k [array names G trial.*] { puts "index: $G($k)" } } } -proc run_trials {} { - global G +proc run_trials {ctxvar} { + upvar $ctxvar G + set ret [list] foreach k [array names G trial.*] { set idxname [lindex [split $k .] 1] @@ -253,14 +307,121 @@ proc run_trials {} { } } foreach idx [array names used] { - puts $G(trial.$idx) + lappend ret $G(trial.$idx) } } + + set ret +} + +proc sqlidx_init_context {varname} { + upvar $varname G + set G(lSelect) [list] ;# List of SELECT statements to analyze + set G(database) "" ;# Name of database or SQL schema file + set G(trace) [list] ;# List of data from xTrace() +} + +#------------------------------------------------------------------------- +# The following is test code only. +# +proc sqlidx_one_test {tn schema select expected} { +# if {$tn!=2} return + sqlidx_init_context C + + sqlite3 db "" + db eval $schema + lappend C(lSelect) $select + analyze_selects C + find_trial_indexes C + + set idxlist [run_trials C] + if {$idxlist != [list {*}$expected]} { + puts stderr "Test $tn failed" + puts stderr "Expected: $expected" + puts stderr "Got: $idxlist" + exit -1 + } + + db close +} + +proc sqlidx_internal_tests {} { + + # No indexes for a query with no constraints. + sqlidx_one_test 0 { + CREATE TABLE t1(a, b, c); + } { + SELECT * FROM t1; + } { + } + + sqlidx_one_test 1 { + CREATE TABLE t1(a, b, c); + CREATE TABLE t2(x, y, z); + } { + SELECT a FROM t1, t2 WHERE a=? AND x=c + } { + {CREATE INDEX t2_x ON t2(x collate BINARY);} + {CREATE INDEX t1_a_c ON t1(a collate BINARY, c collate BINARY);} + } + + sqlidx_one_test 2 { + CREATE TABLE t1(a, b, c); + } { + SELECT * FROM t1 WHERE b>?; + } { + {CREATE INDEX t1_b ON t1(b collate BINARY);} + } + + sqlidx_one_test 3 { + CREATE TABLE t1(a, b, c); + } { + SELECT * FROM t1 WHERE b COLLATE nocase BETWEEN ? AND ? + } { + {CREATE INDEX t1_bnocase ON t1(b collate NOCASE);} + } + + sqlidx_one_test 4 { + CREATE TABLE t1(a, b, c); + } { + SELECT a FROM t1 ORDER BY b; + } { + {CREATE INDEX t1_b ON t1(b collate BINARY);} + } + + sqlidx_one_test 5 { + CREATE TABLE t1(a, b, c); + } { + SELECT a FROM t1 WHERE a=? ORDER BY b; + } { + {CREATE INDEX t1_a_b ON t1(a collate BINARY, b collate BINARY);} + } + + sqlidx_one_test 5 { + CREATE TABLE t1(a, b, c); + } { + SELECT min(a) FROM t1 + } { + {CREATE INDEX t1_a ON t1(a collate BINARY);} + } + + sqlidx_one_test 6 { + CREATE TABLE t1(a, b, c); + } { + SELECT * FROM t1 ORDER BY a ASC, b COLLATE nocase DESC, c ASC; + } { + {CREATE INDEX t1_a_bnocasedesc_c ON t1(a collate BINARY, b collate NOCASE DESC, c collate BINARY);} + } + + exit } +# End of internal test code. +#------------------------------------------------------------------------- -process_cmdline_args $argv -open_database -analyze_selects -find_trial_indexes -run_trials +sqlidx_init_context D +process_cmdline_args D $argv +open_database D +analyze_selects D +find_trial_indexes D +foreach idx [run_trials D] { puts $idx }