spaceanal.tcl 30 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918
  1. # Run this TCL script using an SQLite-enabled TCL interpreter to get a report
  2. # on how much disk space is used by a particular data to actually store data
  3. # versus how much space is unused.
  4. #
  5. # The dbstat virtual table is required.
  6. #
  7. if {[catch {
  8. # Argument $tname is the name of a table within the database opened by
  9. # database handle [db]. Return true if it is a WITHOUT ROWID table, or
  10. # false otherwise.
  11. #
  12. proc is_without_rowid {tname} {
  13. set t [string map {' ''} $tname]
  14. db eval "PRAGMA index_list = '$t'" o {
  15. if {$o(origin) == "pk"} {
  16. set n $o(name)
  17. if {0==[db one { SELECT count(*) FROM sqlite_schema WHERE name=$n }]} {
  18. return 1
  19. }
  20. }
  21. }
  22. return 0
  23. }
  24. # Read and run TCL commands from standard input. Used to implement
  25. # the --tclsh option.
  26. #
  27. proc tclsh {} {
  28. set line {}
  29. while {![eof stdin]} {
  30. if {$line!=""} {
  31. puts -nonewline "> "
  32. } else {
  33. puts -nonewline "% "
  34. }
  35. flush stdout
  36. append line [gets stdin]
  37. if {[info complete $line]} {
  38. if {[catch {uplevel #0 $line} result]} {
  39. puts stderr "Error: $result"
  40. } elseif {$result!=""} {
  41. puts $result
  42. }
  43. set line {}
  44. } else {
  45. append line \n
  46. }
  47. }
  48. }
  49. # Get the name of the database to analyze
  50. #
  51. proc usage {} {
  52. set argv0 [file rootname [file tail [info nameofexecutable]]]
  53. puts stderr "Usage: $argv0 ?--pageinfo? ?--stats? database-filename"
  54. puts stderr {
  55. Analyze the SQLite3 database file specified by the "database-filename"
  56. argument and output a report detailing size and storage efficiency
  57. information for the database and its constituent tables and indexes.
  58. Options:
  59. --pageinfo Show how each page of the database-file is used
  60. --stats Output SQL text that creates a new database containing
  61. statistics about the database that was analyzed
  62. --tclsh Run the built-in TCL interpreter interactively (for debugging)
  63. --version Show the version number of SQLite
  64. }
  65. exit 1
  66. }
  67. # Exit with given code, but first close db if open.
  68. #
  69. proc exit_clean {exit_code} {
  70. if {0 < [llength [info commands db]]} {
  71. db close
  72. }
  73. exit $exit_code
  74. }
  75. set file_to_analyze {}
  76. set flags(-pageinfo) 0
  77. set flags(-stats) 0
  78. set flags(-debug) 0
  79. append argv {}
  80. foreach arg $argv {
  81. if {[regexp {^-+pageinfo$} $arg]} {
  82. set flags(-pageinfo) 1
  83. } elseif {[regexp {^-+stats$} $arg]} {
  84. set flags(-stats) 1
  85. } elseif {[regexp {^-+debug$} $arg]} {
  86. set flags(-debug) 1
  87. } elseif {[regexp {^-+tclsh$} $arg]} {
  88. tclsh
  89. exit 0
  90. } elseif {[regexp {^-+version$} $arg]} {
  91. sqlite3 mem :memory:
  92. puts [mem one {SELECT sqlite_version()||' '||sqlite_source_id()}]
  93. mem close
  94. exit 0
  95. } elseif {[regexp {^-} $arg]} {
  96. puts stderr "Unknown option: $arg"
  97. usage
  98. } elseif {$file_to_analyze!=""} {
  99. usage
  100. } else {
  101. set file_to_analyze $arg
  102. }
  103. }
  104. if {$file_to_analyze==""} usage
  105. set root_filename $file_to_analyze
  106. regexp {^file:(//)?([^?]*)} $file_to_analyze all x1 root_filename
  107. if {![file exists $root_filename]} {
  108. puts stderr "No such file: $root_filename"
  109. exit 1
  110. }
  111. if {![file readable $root_filename]} {
  112. puts stderr "File is not readable: $root_filename"
  113. exit 1
  114. }
  115. set true_file_size [file size $root_filename]
  116. if {$true_file_size<512} {
  117. puts stderr "Empty or malformed database: $root_filename"
  118. exit 1
  119. }
  120. # Compute the total file size assuming test_multiplexor is being used.
  121. # Assume that SQLITE_ENABLE_8_3_NAMES might be enabled
  122. #
  123. set extension [file extension $root_filename]
  124. set pattern $root_filename
  125. append pattern {[0-3][0-9][0-9]}
  126. foreach f [glob -nocomplain $pattern] {
  127. incr true_file_size [file size $f]
  128. set extension {}
  129. }
  130. if {[string length $extension]>=2 && [string length $extension]<=4} {
  131. set pattern [file rootname $root_filename]
  132. append pattern {.[0-3][0-9][0-9]}
  133. foreach f [glob -nocomplain $pattern] {
  134. incr true_file_size [file size $f]
  135. }
  136. }
  137. # Open the database
  138. #
  139. if {[catch {sqlite3 db $file_to_analyze -uri 1} msg]} {
  140. puts stderr "error trying to open $file_to_analyze: $msg"
  141. exit 1
  142. }
  143. if {$flags(-debug)} {
  144. proc dbtrace {txt} {puts $txt; flush stdout;}
  145. db trace ::dbtrace
  146. }
  147. # Make sure all required compile-time options are available
  148. #
  149. if {![db exists {SELECT 1 FROM pragma_compile_options
  150. WHERE compile_options='ENABLE_DBSTAT_VTAB'}]} {
  151. puts "The SQLite database engine linked with this application\
  152. lacks required capabilities. Recompile using the\
  153. -DSQLITE_ENABLE_DBSTAT_VTAB compile-time option to fix\
  154. this problem."
  155. exit_clean 1
  156. }
  157. db eval {SELECT count(*) FROM sqlite_schema}
  158. set pageSize [expr {wide([db one {PRAGMA page_size}])}]
  159. if {$flags(-pageinfo)} {
  160. db eval {CREATE VIRTUAL TABLE temp.stat USING dbstat}
  161. db eval {SELECT name, path, pageno FROM temp.stat ORDER BY pageno} {
  162. puts "$pageno $name $path"
  163. }
  164. exit_clean 0
  165. }
  166. if {$flags(-stats)} {
  167. db eval {CREATE VIRTUAL TABLE temp.stat USING dbstat}
  168. puts "BEGIN;"
  169. puts "CREATE TABLE stats("
  170. puts " name STRING, /* Name of table or index */"
  171. puts " path INTEGER, /* Path to page from root */"
  172. puts " pageno INTEGER, /* Page number */"
  173. puts " pagetype STRING, /* 'internal', 'leaf' or 'overflow' */"
  174. puts " ncell INTEGER, /* Cells on page (0 for overflow) */"
  175. puts " payload INTEGER, /* Bytes of payload on this page */"
  176. puts " unused INTEGER, /* Bytes of unused space on this page */"
  177. puts " mx_payload INTEGER, /* Largest payload size of all cells */"
  178. puts " pgoffset INTEGER, /* Offset of page in file */"
  179. puts " pgsize INTEGER /* Size of the page */"
  180. puts ");"
  181. db eval {SELECT quote(name) || ',' ||
  182. quote(path) || ',' ||
  183. quote(pageno) || ',' ||
  184. quote(pagetype) || ',' ||
  185. quote(ncell) || ',' ||
  186. quote(payload) || ',' ||
  187. quote(unused) || ',' ||
  188. quote(mx_payload) || ',' ||
  189. quote(pgoffset) || ',' ||
  190. quote(pgsize) AS x FROM stat} {
  191. puts "INSERT INTO stats VALUES($x);"
  192. }
  193. puts "COMMIT;"
  194. exit_clean 0
  195. }
  196. # In-memory database for collecting statistics. This script loops through
  197. # the tables and indices in the database being analyzed, adding a row for each
  198. # to an in-memory database (for which the schema is shown below). It then
  199. # queries the in-memory db to produce the space-analysis report.
  200. #
  201. sqlite3 mem :memory:
  202. if {$flags(-debug)} {
  203. proc dbtrace {txt} {puts $txt; flush stdout;}
  204. mem trace ::dbtrace
  205. }
  206. set tabledef {CREATE TABLE space_used(
  207. name clob, -- Name of a table or index in the database file
  208. tblname clob, -- Name of associated table
  209. is_index boolean, -- TRUE if it is an index, false for a table
  210. is_without_rowid boolean, -- TRUE if WITHOUT ROWID table
  211. nentry int, -- Number of entries in the BTree
  212. leaf_entries int, -- Number of leaf entries
  213. depth int, -- Depth of the b-tree
  214. payload int, -- Total amount of data stored in this table or index
  215. ovfl_payload int, -- Total amount of data stored on overflow pages
  216. ovfl_cnt int, -- Number of entries that use overflow
  217. mx_payload int, -- Maximum payload size
  218. int_pages int, -- Number of interior pages used
  219. leaf_pages int, -- Number of leaf pages used
  220. ovfl_pages int, -- Number of overflow pages used
  221. int_unused int, -- Number of unused bytes on interior pages
  222. leaf_unused int, -- Number of unused bytes on primary pages
  223. ovfl_unused int, -- Number of unused bytes on overflow pages
  224. gap_cnt int, -- Number of gaps in the page layout
  225. compressed_size int -- Total bytes stored on disk
  226. );}
  227. mem eval $tabledef
  228. # Create a temporary "dbstat" virtual table.
  229. #
  230. db eval {CREATE VIRTUAL TABLE temp.stat USING dbstat}
  231. db eval {CREATE TEMP TABLE dbstat AS SELECT * FROM temp.stat
  232. ORDER BY name, path}
  233. db eval {DROP TABLE temp.stat}
  234. set isCompressed 0
  235. set compressOverhead 0
  236. set depth 0
  237. set sql { SELECT name, tbl_name FROM sqlite_schema WHERE rootpage>0 }
  238. foreach {name tblname} [concat sqlite_schema sqlite_schema [db eval $sql]] {
  239. set is_index [expr {$name!=$tblname}]
  240. set is_without_rowid [is_without_rowid $name]
  241. db eval {
  242. SELECT
  243. sum(ncell) AS nentry,
  244. sum((pagetype=='leaf')*ncell) AS leaf_entries,
  245. sum(payload) AS payload,
  246. sum((pagetype=='overflow') * payload) AS ovfl_payload,
  247. sum(path LIKE '%+000000') AS ovfl_cnt,
  248. max(mx_payload) AS mx_payload,
  249. sum(pagetype=='internal') AS int_pages,
  250. sum(pagetype=='leaf') AS leaf_pages,
  251. sum(pagetype=='overflow') AS ovfl_pages,
  252. sum((pagetype=='internal') * unused) AS int_unused,
  253. sum((pagetype=='leaf') * unused) AS leaf_unused,
  254. sum((pagetype=='overflow') * unused) AS ovfl_unused,
  255. sum(pgsize) AS compressed_size,
  256. max((length(CASE WHEN path LIKE '%+%' THEN '' ELSE path END)+3)/4)
  257. AS depth
  258. FROM temp.dbstat WHERE name = $name
  259. } break
  260. set total_pages [expr {$leaf_pages+$int_pages+$ovfl_pages}]
  261. set storage [expr {$total_pages*$pageSize}]
  262. if {!$isCompressed && $storage>$compressed_size} {
  263. set isCompressed 1
  264. set compressOverhead 14
  265. }
  266. # Column 'gap_cnt' is set to the number of non-contiguous entries in the
  267. # list of pages visited if the b-tree structure is traversed in a top-down
  268. # fashion (each node visited before its child-tree is passed). Any overflow
  269. # chains present are traversed from start to finish before any child-tree
  270. # is.
  271. #
  272. set gap_cnt 0
  273. set prev 0
  274. db eval {
  275. SELECT pageno, pagetype FROM temp.dbstat
  276. WHERE name=$name
  277. ORDER BY pageno
  278. } {
  279. if {$prev>0 && $pagetype=="leaf" && $pageno!=$prev+1} {
  280. incr gap_cnt
  281. }
  282. set prev $pageno
  283. }
  284. mem eval {
  285. INSERT INTO space_used VALUES(
  286. $name,
  287. $tblname,
  288. $is_index,
  289. $is_without_rowid,
  290. $nentry,
  291. $leaf_entries,
  292. $depth,
  293. $payload,
  294. $ovfl_payload,
  295. $ovfl_cnt,
  296. $mx_payload,
  297. $int_pages,
  298. $leaf_pages,
  299. $ovfl_pages,
  300. $int_unused,
  301. $leaf_unused,
  302. $ovfl_unused,
  303. $gap_cnt,
  304. $compressed_size
  305. );
  306. }
  307. }
  308. proc integerify {real} {
  309. if {[string is double -strict $real]} {
  310. return [expr {wide($real)}]
  311. } else {
  312. return 0
  313. }
  314. }
  315. mem function int integerify
  316. # Quote a string for use in an SQL query. Examples:
  317. #
  318. # [quote {hello world}] == {'hello world'}
  319. # [quote {hello world's}] == {'hello world''s'}
  320. #
  321. proc quote {txt} {
  322. return [string map {' ''} $txt]
  323. }
  324. # Output a title line
  325. #
  326. proc titleline {title} {
  327. if {$title==""} {
  328. puts [string repeat * 79]
  329. } else {
  330. set len [string length $title]
  331. set stars [string repeat * [expr 79-$len-5]]
  332. puts "*** $title $stars"
  333. }
  334. }
  335. # Generate a single line of output in the statistics section of the
  336. # report.
  337. #
  338. proc statline {title value {extra {}}} {
  339. set len [string length $title]
  340. set dots [string repeat . [expr 50-$len]]
  341. set len [string length $value]
  342. set sp2 [string range { } $len end]
  343. if {$extra ne ""} {
  344. set extra " $extra"
  345. }
  346. puts "$title$dots $value$sp2$extra"
  347. }
  348. # Generate a formatted percentage value for $num/$denom
  349. #
  350. proc percent {num denom {of {}}} {
  351. if {$denom==0.0} {return ""}
  352. set v [expr {$num*100.0/$denom}]
  353. set of {}
  354. if {$v==100.0 || $v<0.001 || ($v>1.0 && $v<99.0)} {
  355. return [format {%5.1f%% %s} $v $of]
  356. } elseif {$v<0.1 || $v>99.9} {
  357. return [format {%7.3f%% %s} $v $of]
  358. } else {
  359. return [format {%6.2f%% %s} $v $of]
  360. }
  361. }
  362. proc divide {num denom} {
  363. if {$denom==0} {return 0.0}
  364. return [format %.2f [expr double($num)/double($denom)]]
  365. }
  366. # Generate a subreport that covers some subset of the database.
  367. # the $where clause determines which subset to analyze.
  368. #
  369. proc subreport {title where showFrag} {
  370. global pageSize file_pgcnt compressOverhead
  371. # Query the in-memory database for the sum of various statistics
  372. # for the subset of tables/indices identified by the WHERE clause in
  373. # $where. Note that even if the WHERE clause matches no rows, the
  374. # following query returns exactly one row (because it is an aggregate).
  375. #
  376. # The results of the query are stored directly by SQLite into local
  377. # variables (i.e. $nentry, $payload etc.).
  378. #
  379. mem eval "
  380. SELECT
  381. int(sum(
  382. CASE WHEN (is_without_rowid OR is_index) THEN nentry
  383. ELSE leaf_entries
  384. END
  385. )) AS nentry,
  386. int(sum(payload)) AS payload,
  387. int(sum(ovfl_payload)) AS ovfl_payload,
  388. max(mx_payload) AS mx_payload,
  389. int(sum(ovfl_cnt)) as ovfl_cnt,
  390. int(sum(leaf_pages)) AS leaf_pages,
  391. int(sum(int_pages)) AS int_pages,
  392. int(sum(ovfl_pages)) AS ovfl_pages,
  393. int(sum(leaf_unused)) AS leaf_unused,
  394. int(sum(int_unused)) AS int_unused,
  395. int(sum(ovfl_unused)) AS ovfl_unused,
  396. int(sum(gap_cnt)) AS gap_cnt,
  397. int(sum(compressed_size)) AS compressed_size,
  398. int(max(depth)) AS depth,
  399. count(*) AS cnt
  400. FROM space_used WHERE $where" {} {}
  401. # Output the sub-report title, nicely decorated with * characters.
  402. #
  403. puts ""
  404. titleline $title
  405. puts ""
  406. # Calculate statistics and store the results in TCL variables, as follows:
  407. #
  408. # total_pages: Database pages consumed.
  409. # total_pages_percent: Pages consumed as a percentage of the file.
  410. # storage: Bytes consumed.
  411. # payload_percent: Payload bytes used as a percentage of $storage.
  412. # total_unused: Unused bytes on pages.
  413. # avg_payload: Average payload per btree entry.
  414. # avg_fanout: Average fanout for internal pages.
  415. # avg_unused: Average unused bytes per btree entry.
  416. # avg_meta: Average metadata overhead per entry.
  417. # ovfl_cnt_percent: Percentage of btree entries that use overflow pages.
  418. #
  419. set total_pages [expr {$leaf_pages+$int_pages+$ovfl_pages}]
  420. set total_pages_percent [percent $total_pages $file_pgcnt]
  421. set storage [expr {$total_pages*$pageSize}]
  422. set payload_percent [percent $payload $storage {of storage consumed}]
  423. set total_unused [expr {$ovfl_unused+$int_unused+$leaf_unused}]
  424. set avg_payload [divide $payload $nentry]
  425. set avg_unused [divide $total_unused $nentry]
  426. set total_meta [expr {$storage - $payload - $total_unused}]
  427. set total_meta [expr {$total_meta + 4*($ovfl_pages - $ovfl_cnt)}]
  428. set meta_percent [percent $total_meta $storage {of metadata}]
  429. set avg_meta [divide $total_meta $nentry]
  430. if {$int_pages>0} {
  431. # TODO: Is this formula correct?
  432. set nTab [mem eval "
  433. SELECT count(*) FROM (
  434. SELECT DISTINCT tblname FROM space_used WHERE $where AND is_index=0
  435. )
  436. "]
  437. set avg_fanout [mem eval "
  438. SELECT (sum(leaf_pages+int_pages)-$nTab)/sum(int_pages) FROM space_used
  439. WHERE $where
  440. "]
  441. set avg_fanout [format %.2f $avg_fanout]
  442. }
  443. set ovfl_cnt_percent [percent $ovfl_cnt $nentry {of all entries}]
  444. # Print out the sub-report statistics.
  445. #
  446. statline {Percentage of total database} $total_pages_percent
  447. statline {Number of entries} $nentry
  448. statline {Bytes of storage consumed} $storage
  449. if {$compressed_size!=$storage} {
  450. set compressed_size [expr {$compressed_size+$compressOverhead*$total_pages}]
  451. set pct [expr {$compressed_size*100.0/$storage}]
  452. set pct [format {%5.1f%%} $pct]
  453. statline {Bytes used after compression} $compressed_size $pct
  454. }
  455. statline {Bytes of payload} $payload $payload_percent
  456. statline {Bytes of metadata} $total_meta $meta_percent
  457. if {$cnt==1} {statline {B-tree depth} $depth}
  458. statline {Average payload per entry} $avg_payload
  459. statline {Average unused bytes per entry} $avg_unused
  460. statline {Average metadata per entry} $avg_meta
  461. if {[info exists avg_fanout]} {
  462. statline {Average fanout} $avg_fanout
  463. }
  464. if {$showFrag && $total_pages>1} {
  465. set fragmentation [percent $gap_cnt [expr {$total_pages-1}]]
  466. statline {Non-sequential pages} $gap_cnt $fragmentation
  467. }
  468. statline {Maximum payload per entry} $mx_payload
  469. statline {Entries that use overflow} $ovfl_cnt $ovfl_cnt_percent
  470. if {$int_pages>0} {
  471. statline {Index pages used} $int_pages
  472. }
  473. statline {Primary pages used} $leaf_pages
  474. statline {Overflow pages used} $ovfl_pages
  475. statline {Total pages used} $total_pages
  476. if {$int_unused>0} {
  477. set int_unused_percent [
  478. percent $int_unused [expr {$int_pages*$pageSize}] {of index space}]
  479. statline "Unused bytes on index pages" $int_unused $int_unused_percent
  480. }
  481. statline "Unused bytes on primary pages" $leaf_unused [
  482. percent $leaf_unused [expr {$leaf_pages*$pageSize}] {of primary space}]
  483. statline "Unused bytes on overflow pages" $ovfl_unused [
  484. percent $ovfl_unused [expr {$ovfl_pages*$pageSize}] {of overflow space}]
  485. statline "Unused bytes on all pages" $total_unused [
  486. percent $total_unused $storage {of all space}]
  487. return 1
  488. }
  489. # Calculate the overhead in pages caused by auto-vacuum.
  490. #
  491. # This procedure calculates and returns the number of pages used by the
  492. # auto-vacuum 'pointer-map'. If the database does not support auto-vacuum,
  493. # then 0 is returned. The two arguments are the size of the database file in
  494. # pages and the page size used by the database (in bytes).
  495. proc autovacuum_overhead {filePages pageSize} {
  496. # Set $autovacuum to non-zero for databases that support auto-vacuum.
  497. set autovacuum [db one {PRAGMA auto_vacuum}]
  498. # If the database is not an auto-vacuum database or the file consists
  499. # of one page only then there is no overhead for auto-vacuum. Return zero.
  500. if {0==$autovacuum || $filePages==1} {
  501. return 0
  502. }
  503. # The number of entries on each pointer map page. The layout of the
  504. # database file is one pointer-map page, followed by $ptrsPerPage other
  505. # pages, followed by a pointer-map page etc. The first pointer-map page
  506. # is the second page of the file overall.
  507. set ptrsPerPage [expr double($pageSize/5)]
  508. # Return the number of pointer map pages in the database.
  509. return [expr wide(ceil( ($filePages-1.0)/($ptrsPerPage+1.0) ))]
  510. }
  511. # Calculate the summary statistics for the database and store the results
  512. # in TCL variables. They are output below. Variables are as follows:
  513. #
  514. # pageSize: Size of each page in bytes.
  515. # file_bytes: File size in bytes.
  516. # file_pgcnt: Number of pages in the file.
  517. # file_pgcnt2: Number of pages in the file (calculated).
  518. # av_pgcnt: Pages consumed by the auto-vacuum pointer-map.
  519. # av_percent: Percentage of the file consumed by auto-vacuum pointer-map.
  520. # inuse_pgcnt: Data pages in the file.
  521. # inuse_percent: Percentage of pages used to store data.
  522. # free_pgcnt: Free pages calculated as (<total pages> - <in-use pages>)
  523. # free_pgcnt2: Free pages in the file according to the file header.
  524. # free_percent: Percentage of file consumed by free pages (calculated).
  525. # free_percent2: Percentage of file consumed by free pages (header).
  526. # ntable: Number of tables in the db.
  527. # nindex: Number of indices in the db.
  528. # nautoindex: Number of indices created automatically.
  529. # nmanindex: Number of indices created manually.
  530. # user_payload: Number of bytes of payload in table btrees
  531. # (not including sqlite_schema)
  532. # user_percent: $user_payload as a percentage of total file size.
  533. ### The following, setting $file_bytes based on the actual size of the file
  534. ### on disk, causes this tool to choke on zipvfs databases. So set it based
  535. ### on the return of [PRAGMA page_count] instead.
  536. if 0 {
  537. set file_bytes [file size $file_to_analyze]
  538. set file_pgcnt [expr {$file_bytes/$pageSize}]
  539. }
  540. set file_pgcnt [db one {PRAGMA page_count}]
  541. set file_bytes [expr {$file_pgcnt * $pageSize}]
  542. set av_pgcnt [autovacuum_overhead $file_pgcnt $pageSize]
  543. set av_percent [percent $av_pgcnt $file_pgcnt]
  544. set sql {SELECT sum(leaf_pages+int_pages+ovfl_pages) FROM space_used}
  545. set inuse_pgcnt [expr wide([mem eval $sql])]
  546. set inuse_percent [percent $inuse_pgcnt $file_pgcnt]
  547. set free_pgcnt [expr {$file_pgcnt-$inuse_pgcnt-$av_pgcnt}]
  548. if {$file_bytes>1073741824 && $free_pgcnt>0} {incr free_pgcnt -1}
  549. set free_percent [percent $free_pgcnt $file_pgcnt]
  550. set free_pgcnt2 [db one {PRAGMA freelist_count}]
  551. set free_percent2 [percent $free_pgcnt2 $file_pgcnt]
  552. set file_pgcnt2 [expr {$inuse_pgcnt+$free_pgcnt2+$av_pgcnt}]
  553. # Account for the lockbyte page
  554. if {$file_pgcnt2*$pageSize>1073742335} {incr file_pgcnt2}
  555. set ntable [db eval {SELECT count(*)+1 FROM sqlite_schema WHERE type='table'}]
  556. set nindex [db eval {SELECT count(*) FROM sqlite_schema WHERE type='index'}]
  557. set sql {SELECT count(*) FROM sqlite_schema WHERE name LIKE 'sqlite_autoindex%'}
  558. set nautoindex [db eval $sql]
  559. set nmanindex [expr {$nindex-$nautoindex}]
  560. set nwithoutrowid [db eval {SELECT count(*) FROM pragma_table_list WHERE wr}]
  561. # set total_payload [mem eval "SELECT sum(payload) FROM space_used"]
  562. set user_payload [mem one {SELECT int(sum(payload)) FROM space_used
  563. WHERE NOT is_index AND name NOT LIKE 'sqlite_schema'}]
  564. set user_percent [percent $user_payload $file_bytes]
  565. # Output the summary statistics calculated above.
  566. #
  567. puts "/** Disk-Space Utilization Report For $root_filename"
  568. puts ""
  569. statline {Page size in bytes} $pageSize
  570. statline {Pages in the whole file (measured)} $file_pgcnt
  571. statline {Pages in the whole file (calculated)} $file_pgcnt2
  572. statline {Pages that store data} $inuse_pgcnt $inuse_percent
  573. statline {Pages on the freelist (per header)} $free_pgcnt2 $free_percent2
  574. statline {Pages on the freelist (calculated)} $free_pgcnt $free_percent
  575. statline {Pages of auto-vacuum overhead} $av_pgcnt $av_percent
  576. statline {Number of tables in the database} $ntable
  577. statline {Number of WITHOUT ROWID tables} $nwithoutrowid
  578. statline {Number of indices} $nindex
  579. statline {Number of defined indices} $nmanindex
  580. statline {Number of implied indices} $nautoindex
  581. if {$isCompressed} {
  582. statline {Size of uncompressed content in bytes} $file_bytes
  583. set efficiency [percent $true_file_size $file_bytes]
  584. statline {Size of compressed file on disk} $true_file_size $efficiency
  585. } else {
  586. statline {Size of the file in bytes} $file_bytes
  587. }
  588. statline {Bytes of user payload stored} $user_payload $user_percent
  589. # Output table rankings
  590. #
  591. puts ""
  592. titleline "Page counts for all tables with their indices"
  593. puts ""
  594. mem eval {SELECT tblname, count(*) AS cnt,
  595. int(sum(int_pages+leaf_pages+ovfl_pages)) AS size
  596. FROM space_used GROUP BY tblname ORDER BY size+0 DESC, tblname} {} {
  597. statline [string toupper $tblname] $size [percent $size $file_pgcnt]
  598. }
  599. puts ""
  600. titleline "Page counts for all tables and indices separately"
  601. puts ""
  602. mem eval {
  603. SELECT
  604. upper(name) AS nm,
  605. int(int_pages+leaf_pages+ovfl_pages) AS size
  606. FROM space_used
  607. ORDER BY size+0 DESC, name} {} {
  608. statline $nm $size [percent $size $file_pgcnt]
  609. }
  610. if {$isCompressed} {
  611. puts ""
  612. titleline "Bytes of disk space used after compression"
  613. puts ""
  614. set csum 0
  615. mem eval {SELECT tblname,
  616. int(sum(compressed_size)) +
  617. $compressOverhead*sum(int_pages+leaf_pages+ovfl_pages)
  618. AS csize
  619. FROM space_used GROUP BY tblname ORDER BY csize+0 DESC, tblname} {} {
  620. incr csum $csize
  621. statline [string toupper $tblname] $csize [percent $csize $true_file_size]
  622. }
  623. set overhead [expr {$true_file_size - $csum}]
  624. if {$overhead>0} {
  625. statline {Header and free space} $overhead [percent $overhead $true_file_size]
  626. }
  627. }
  628. # Output subreports
  629. #
  630. if {$nindex>0} {
  631. subreport {All tables and indices} 1 0
  632. }
  633. subreport {All tables} {NOT is_index} 0
  634. if {$nwithoutrowid>0} {
  635. subreport {All WITHOUT ROWID tables} {is_without_rowid} 0
  636. set nrowidtab [db eval {SELECT count(*) FROM pragma_table_list
  637. WHERE type='table' AND NOT wr}]
  638. if {$nrowidtab>0} {
  639. subreport {ALL rowid tables} {NOT is_without_rowid AND NOT is_index} 0
  640. }
  641. }
  642. if {$nindex>0} {
  643. subreport {All indices} {is_index} 0
  644. }
  645. foreach tbl [mem eval {SELECT DISTINCT tblname name FROM space_used
  646. ORDER BY name}] {
  647. set qn [quote $tbl]
  648. set name [string toupper $tbl]
  649. set n [mem eval {SELECT count(*) FROM space_used WHERE tblname=$tbl}]
  650. if {$n>1} {
  651. set idxlist [mem eval "SELECT name FROM space_used
  652. WHERE tblname='$qn' AND is_index
  653. ORDER BY 1"]
  654. subreport "Table $name and all its indices" "tblname='$qn'" 0
  655. subreport "Table $name w/o any indices" "name='$qn'" 1
  656. if {[llength $idxlist]>1} {
  657. subreport "Indices of table $name" "tblname='$qn' AND is_index" 0
  658. }
  659. foreach idx $idxlist {
  660. set qidx [quote $idx]
  661. subreport "Index [string toupper $idx] of table $name" "name='$qidx'" 1
  662. }
  663. } else {
  664. subreport "Table $name" "name='$qn'" 1
  665. }
  666. }
  667. # Output instructions on what the numbers above mean.
  668. #
  669. puts ""
  670. titleline Definitions
  671. puts {
  672. Page size in bytes
  673. The number of bytes in a single page of the database file.
  674. Usually 1024.
  675. Number of pages in the whole file
  676. }
  677. puts " The number of $pageSize-byte pages that go into forming the complete
  678. database"
  679. puts {
  680. Pages that store data
  681. The number of pages that store data, either as primary B*Tree pages or
  682. as overflow pages. The number at the right is the data pages divided by
  683. the total number of pages in the file.
  684. Pages on the freelist
  685. The number of pages that are not currently in use but are reserved for
  686. future use. The percentage at the right is the number of freelist pages
  687. divided by the total number of pages in the file.
  688. Pages of auto-vacuum overhead
  689. The number of pages that store data used by the database to facilitate
  690. auto-vacuum. This is zero for databases that do not support auto-vacuum.
  691. Number of tables in the database
  692. The number of tables in the database, including the SQLITE_SCHEMA table
  693. used to store schema information.
  694. Number of indices
  695. The total number of indices in the database.
  696. Number of defined indices
  697. The number of indices created using an explicit CREATE INDEX statement.
  698. Number of implied indices
  699. The number of indices used to implement PRIMARY KEY or UNIQUE constraints
  700. on tables.
  701. Size of the file in bytes
  702. The total amount of disk space used by the entire database files.
  703. Bytes of user payload stored
  704. The total number of bytes of user payload stored in the database. The
  705. schema information in the SQLITE_SCHEMA table is not counted when
  706. computing this number. The percentage at the right shows the payload
  707. divided by the total file size.
  708. Percentage of total database
  709. The amount of the complete database file that is devoted to storing
  710. information described by this category.
  711. Number of entries
  712. The total number of B-Tree key/value pairs stored under this category.
  713. Bytes of storage consumed
  714. The total amount of disk space required to store all B-Tree entries
  715. under this category. The is the total number of pages used times
  716. the pages size.
  717. Bytes of payload
  718. The amount of payload stored under this category. Payload is the data
  719. part of table entries and the key part of index entries. The percentage
  720. at the right is the bytes of payload divided by the bytes of storage
  721. consumed.
  722. Bytes of metadata
  723. The amount of formatting and structural information stored in the
  724. table or index. Metadata includes the btree page header, the cell pointer
  725. array, the size field for each cell, the left child pointer or non-leaf
  726. cells, the overflow pointers for overflow cells, and the rowid value for
  727. rowid table cells. In other words, metadata is everything that is neither
  728. unused space nor content. The record header in the payload is counted as
  729. content, not metadata.
  730. Average payload per entry
  731. The average amount of payload on each entry. This is just the bytes of
  732. payload divided by the number of entries.
  733. Average unused bytes per entry
  734. The average amount of free space remaining on all pages under this
  735. category on a per-entry basis. This is the number of unused bytes on
  736. all pages divided by the number of entries.
  737. Non-sequential pages
  738. The number of pages in the table or index that are out of sequence.
  739. Many filesystems are optimized for sequential file access so a small
  740. number of non-sequential pages might result in faster queries,
  741. especially for larger database files that do not fit in the disk cache.
  742. Note that after running VACUUM, the root page of each table or index is
  743. at the beginning of the database file and all other pages are in a
  744. separate part of the database file, resulting in a single non-
  745. sequential page.
  746. Maximum payload per entry
  747. The largest payload size of any entry.
  748. Entries that use overflow
  749. The number of entries that user one or more overflow pages.
  750. Total pages used
  751. This is the number of pages used to hold all information in the current
  752. category. This is the sum of index, primary, and overflow pages.
  753. Index pages used
  754. This is the number of pages in a table B-tree that hold only key (rowid)
  755. information and no data.
  756. Primary pages used
  757. This is the number of B-tree pages that hold both key and data.
  758. Overflow pages used
  759. The total number of overflow pages used for this category.
  760. Unused bytes on index pages
  761. The total number of bytes of unused space on all index pages. The
  762. percentage at the right is the number of unused bytes divided by the
  763. total number of bytes on index pages.
  764. Unused bytes on primary pages
  765. The total number of bytes of unused space on all primary pages. The
  766. percentage at the right is the number of unused bytes divided by the
  767. total number of bytes on primary pages.
  768. Unused bytes on overflow pages
  769. The total number of bytes of unused space on all overflow pages. The
  770. percentage at the right is the number of unused bytes divided by the
  771. total number of bytes on overflow pages.
  772. Unused bytes on all pages
  773. The total number of bytes of unused space on all primary and overflow
  774. pages. The percentage at the right is the number of unused bytes
  775. divided by the total number of bytes.
  776. }
  777. # Output a dump of the in-memory database. This can be used for more
  778. # complex offline analysis.
  779. #
  780. titleline {}
  781. puts "The entire text of this report can be sourced into any SQL database"
  782. puts "engine for further analysis. All of the text above is an SQL comment."
  783. puts "The data used to generate this report follows:"
  784. puts "*/"
  785. puts "BEGIN;"
  786. puts $tabledef
  787. unset -nocomplain x
  788. mem eval {SELECT * FROM space_used} x {
  789. puts -nonewline "INSERT INTO space_used VALUES"
  790. set sep (
  791. foreach col $x(*) {
  792. set v $x($col)
  793. if {$v=="" || ![string is double $v]} {set v '[quote $v]'}
  794. puts -nonewline $sep$v
  795. set sep ,
  796. }
  797. puts ");"
  798. }
  799. puts "COMMIT;"
  800. } err]} {
  801. puts "ERROR: $err"
  802. puts $errorInfo
  803. exit_clean 1
  804. }
  805. exit_clean 0