Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Fix ORDER BY handling in the schemalint.tcl script. Add internal self-tests to the same script. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | schemalint |
Files: | files | file ages | folders |
SHA1: |
b8f277c9b45c4b30e6690e838a30311a |
User & Date: | dan 2015-11-23 17:10:51.938 |
Context
2015-11-23
| ||
17:14 | Merge latest trunk changes with this branch. (check-in: 8f1ef0904d user: dan tags: schemalint) | |
17:10 | Fix ORDER BY handling in the schemalint.tcl script. Add internal self-tests to the same script. (check-in: b8f277c9b4 user: dan tags: schemalint) | |
2015-11-20
| ||
20:55 | Add support for ORDER BY clauses to schemalint.tcl. (check-in: 93bdf70e85 user: dan tags: schemalint) | |
Changes
Changes to tool/schemalint.tcl.
1 |
| | < < < < < > | | | > > > | > > | > > | < > | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 | 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 {ctxvar argv} { upvar $ctxvar G set nArg [llength $argv] set G(database) [lindex $argv end] for {set i 0} {$i < [llength $argv]-1} {incr i} { set k [lindex $argv $i] switch -- $k { -select { incr i if {$i>=[llength $argv]-1} usage lappend G(lSelect) [lindex $argv $i] } -verbose { set ::VERBOSE 1 } -test { sqlidx_internal_tests } default { usage } } } if {$G(database)=="-test"} { sqlidx_internal_tests } } proc open_database {ctxvar} { upvar $ctxvar G sqlite3 db "" # Check if the "database" file is really an SQLite database. If so, copy # it into the temp db just opened. Otherwise, assume that it is an SQL # schema and execute it directly. set fd [open $G(database)] set hdr [read $fd 16] |
︙ | ︙ | |||
58 59 60 61 62 63 64 | } else { append hdr [read $fd] db eval $hdr close $fd } } | | | | > > > | | | 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 | } else { append hdr [read $fd] db eval $hdr close $fd } } 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} { 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] if {$rc!="SQLITE_OK"} { error "Failed to compile SQL: [sqlite3_errmsg db]" } } db trace "" if {$::VERBOSE} { foreach t $G(trace) { puts "trace: $t" } } # puts $G(trace) } # The argument is a list of the form: |
︙ | ︙ | |||
114 115 116 117 118 119 120 | return $ll } #-------------------------------------------------------------------------- # Formulate a CREATE INDEX statement that creates an index on table $tname. # | | > | | > > > > > > > > > > > > > | 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 | return $ll } #-------------------------------------------------------------------------- # Formulate a CREATE INDEX statement that creates an index on table $tname. # proc eqset_to_index {ctxvar tname eqset {range {}}} { upvar $ctxvar G set lCols [list] set idxname $tname foreach e [lsort $eqset] { if {[llength $e]==0} continue foreach {c collate} $e {} lappend lCols "$c collate $collate" append idxname "_$c" if {[string compare -nocase binary $collate]!=0} { append idxname [string tolower $collate] } } 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 ");" set G(trial.$idxname) $create_index } |
︙ | ︙ | |||
160 161 162 163 164 165 166 | } set lRet $lNew } } return $lRet } | | | > > > > | | > > < > > > > > > > > > > > > > > > > > > > > > > > | > > | | | | | | > > > > | < | < | | > | | | | > | < < < | > > | | | > | | > | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | | | | | | 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 | } set lRet $lNew } } return $lRet } 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]] { # 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 } } # 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(<col>) <collation> # # If there is more than one == constraint for a column, and they use # different collation sequences, <collation> 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 {<col> <collation>}. # catch {array unset eq} 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 } foreach eqset [expand_eq_list [array get eq]] { if {$eqset != ""} { eqset_to_index G $tname $eqset } foreach r $ranges { set tail [list] foreach {c collate dir} $r { set bSeen 0 foreach e $eqset { if {[lindex $e 0] == $c} { set bSeen 1 break } } if {$bSeen==0} { lappend tail {*}$r } } if {[llength $tail]} { eqset_to_index G $tname $eqset $r } } } } } } if {$::VERBOSE} { foreach k [array names G trial.*] { puts "index: $G($k)" } } } proc run_trials {ctxvar} { upvar $ctxvar G set ret [list] foreach k [array names G trial.*] { set idxname [lindex [split $k .] 1] db eval $G($k) set pgno [db one {SELECT rootpage FROM sqlite_master WHERE name = $idxname}] set IDX($pgno) $idxname } db eval ANALYZE catch { array unset used } foreach s $G(lSelect) { db eval "EXPLAIN $s" x { if {($x(opcode)=="OpenRead" || $x(opcode)=="ReopenIdx")} { if {[info exists IDX($x(p2))]} { set used($IDX($x(p2))) 1 } } } foreach idx [array names used] { 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. #------------------------------------------------------------------------- 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 } |