Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | First cut at a analysis tool for version 3.0 databases. (CVS 1862) |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
7c7f698b2eda7b1b34f5ca7fe104145d |
User & Date: | drh 2004-07-23 00:01:39.000 |
Context
2004-07-24
| ||
03:30 | Progress towards getting prepared statements and CREATE and DROP to play nicely together. Work is incomplete. Some tests are known to fail. (CVS 1864) (check-in: 49b9914924 user: drh tags: trunk) | |
2004-07-23
| ||
00:01 | First cut at a analysis tool for version 3.0 databases. (CVS 1862) (check-in: 7c7f698b2e user: drh tags: trunk) | |
2004-07-22
| ||
19:06 | Home page updates. (CVS 1861) (check-in: 15774aab7d user: drh tags: trunk) | |
Changes
Changes to main.mk.
︙ | ︙ | |||
362 363 364 365 366 367 368 369 370 371 372 373 374 375 | libsqlite3.a $(LIBTCL) $(THREADLIB) fulltest: testfixture$(EXE) sqlite3$(EXE) crashtest ./testfixture$(EXE) $(TOP)/test/all.test test: testfixture$(EXE) sqlite3$(EXE) ./testfixture$(EXE) $(TOP)/test/quick.test # Rules used to build documentation # arch.html: $(TOP)/www/arch.tcl tclsh $(TOP)/www/arch.tcl >arch.html arch.png: $(TOP)/www/arch.png | > > > > > > > > > > > > > | 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 | libsqlite3.a $(LIBTCL) $(THREADLIB) fulltest: testfixture$(EXE) sqlite3$(EXE) crashtest ./testfixture$(EXE) $(TOP)/test/all.test test: testfixture$(EXE) sqlite3$(EXE) ./testfixture$(EXE) $(TOP)/test/quick.test sqlite3_analyzer$(EXE): $(TOP)/src/tclsqlite.c libsqlite3.a $(TESTSRC) \ $(TOP)/tool/spaceanal.tcl sed \ -e '/^#/d' \ -e 's,\\,\\\\,g' \ -e 's,",\\",g' \ -e 's,^,",' \ -e 's,$$,\\n",' \ $(TOP)/tool/spaceanal.tcl >spaceanal_tcl.h $(TCCX) $(TCL_FLAGS) -DTCLSH=2 -DSQLITE_TEST=1 -static -o \ sqlite3_analyzer$(EXE) $(TESTSRC) $(TOP)/src/tclsqlite.c \ libsqlite3.a $(LIBTCL) $(THREADLIB) # Rules used to build documentation # arch.html: $(TOP)/www/arch.tcl tclsh $(TOP)/www/arch.tcl >arch.html arch.png: $(TOP)/www/arch.png |
︙ | ︙ |
Changes to src/btree.c.
1 2 3 4 5 6 7 8 9 10 11 | /* ** 2004 April 6 ** ** 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. ** ************************************************************************* | | | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | /* ** 2004 April 6 ** ** 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. ** ************************************************************************* ** $Id: btree.c,v 1.180 2004/07/23 00:01:39 drh Exp $ ** ** This file implements a external (disk-based) database using BTrees. ** For a detailed discussion of BTrees, refer to ** ** Donald E. Knuth, THE ART OF COMPUTER PROGRAMMING, Volume 3: ** "Sorting And Searching", pages 473-480. Addison-Wesley ** Publishing Company, Reading, Massachusetts. |
︙ | ︙ | |||
3897 3898 3899 3900 3901 3902 3903 | /* ** Fill aResult[] with information about the entry and page that the ** cursor is pointing to. ** ** aResult[0] = The page number ** aResult[1] = The entry number ** aResult[2] = Total number of entries on this page | | | | > > | > > > > > > > | | | | | > > > > > | > > > > | 3897 3898 3899 3900 3901 3902 3903 3904 3905 3906 3907 3908 3909 3910 3911 3912 3913 3914 3915 3916 3917 3918 3919 3920 3921 3922 3923 3924 3925 3926 3927 3928 3929 3930 3931 3932 3933 3934 3935 3936 3937 3938 3939 3940 3941 3942 3943 3944 3945 3946 3947 3948 3949 3950 3951 3952 3953 3954 3955 3956 3957 3958 3959 3960 3961 3962 3963 | /* ** Fill aResult[] with information about the entry and page that the ** cursor is pointing to. ** ** aResult[0] = The page number ** aResult[1] = The entry number ** aResult[2] = Total number of entries on this page ** aResult[3] = Cell size (local payload + header) ** aResult[4] = Number of free bytes on this page ** aResult[5] = Number of free blocks on the page ** aResult[6] = Total payload size (local + overflow) ** aResult[7] = Header size in bytes ** aResult[8] = Local payload size ** aResult[9] = Parent page number ** ** This routine is used for testing and debugging only. */ int sqlite3BtreeCursorInfo(BtCursor *pCur, int *aResult, int upCnt){ int cnt, idx; MemPage *pPage = pCur->pPage; BtCursor tmpCur; pageIntegrity(pPage); assert( pPage->isInit ); getTempCursor(pCur, &tmpCur); while( upCnt-- ){ moveToParent(&tmpCur); } pPage = tmpCur.pPage; pageIntegrity(pPage); aResult[0] = sqlite3pager_pagenumber(pPage->aData); assert( aResult[0]==pPage->pgno ); aResult[1] = tmpCur.idx; aResult[2] = pPage->nCell; if( tmpCur.idx>=0 && tmpCur.idx<pPage->nCell ){ getCellInfo(&tmpCur); aResult[3] = tmpCur.info.nSize; aResult[6] = tmpCur.info.nData; aResult[7] = tmpCur.info.nHeader; aResult[8] = tmpCur.info.nLocal; }else{ aResult[3] = 0; aResult[6] = 0; aResult[7] = 0; aResult[8] = 0; } aResult[4] = pPage->nFree; cnt = 0; idx = get2byte(&pPage->aData[pPage->hdrOffset+1]); while( idx>0 && idx<pPage->pBt->usableSize ){ cnt++; idx = get2byte(&pPage->aData[idx]); } aResult[5] = cnt; if( pPage->pParent==0 || isRootPage(pPage) ){ aResult[9] = 0; }else{ aResult[9] = pPage->pParent->pgno; } releaseTempCursor(&tmpCur); return SQLITE_OK; } #endif /* ** Return the pager associated with a BTree. This routine is used for ** testing and debugging only. |
︙ | ︙ |
Changes to src/btree.h.
︙ | ︙ | |||
9 10 11 12 13 14 15 | ** May you share freely, never taking more than you give. ** ************************************************************************* ** This header file defines the interface that the sqlite B-Tree file ** subsystem. See comments in the source code for a detailed description ** of what each interface routine does. ** | | | 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | ** May you share freely, never taking more than you give. ** ************************************************************************* ** This header file defines the interface that the sqlite B-Tree file ** subsystem. See comments in the source code for a detailed description ** of what each interface routine does. ** ** @(#) $Id: btree.h,v 1.58 2004/07/23 00:01:39 drh Exp $ */ #ifndef _BTREE_H_ #define _BTREE_H_ /* TODO: This definition is just included so other modules compile. It ** needs to be revisited. */ |
︙ | ︙ | |||
111 112 113 114 115 116 117 | int sqlite3BtreeData(BtCursor*, u32 offset, u32 amt, void*); char *sqlite3BtreeIntegrityCheck(Btree*, int *aRoot, int nRoot); struct Pager *sqlite3BtreePager(Btree*); #ifdef SQLITE_TEST | | | 111 112 113 114 115 116 117 118 119 120 121 122 123 124 | int sqlite3BtreeData(BtCursor*, u32 offset, u32 amt, void*); char *sqlite3BtreeIntegrityCheck(Btree*, int *aRoot, int nRoot); struct Pager *sqlite3BtreePager(Btree*); #ifdef SQLITE_TEST int sqlite3BtreeCursorInfo(BtCursor*, int*, int); void sqlite3BtreeCursorList(Btree*); int sqlite3BtreePageDump(Btree*, int, int recursive); #endif #endif /* _BTREE_H_ */ |
Changes to src/tclsqlite.c.
1 2 3 4 5 6 7 8 9 10 11 12 13 | /* ** 2001 September 15 ** ** 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. ** ************************************************************************* ** A TCL Interface to SQLite ** | | | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 | /* ** 2001 September 15 ** ** 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. ** ************************************************************************* ** A TCL Interface to SQLite ** ** $Id: tclsqlite.c,v 1.97 2004/07/23 00:01:39 drh Exp $ */ #ifndef NO_TCL /* Omit this whole file if TCL is unavailable */ #include "sqliteInt.h" #include "tcl.h" #include <stdlib.h> #include <string.h> |
︙ | ︙ | |||
1127 1128 1129 1130 1131 1132 1133 | int Sqlite3_SafeInit(Tcl_Interp *interp){ return TCL_OK; } int Tclsqlite3_SafeInit(Tcl_Interp *interp){ return TCL_OK; } | | | | < < < | < < | | > | | 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 | int Sqlite3_SafeInit(Tcl_Interp *interp){ return TCL_OK; } int Tclsqlite3_SafeInit(Tcl_Interp *interp){ return TCL_OK; } #ifdef TCLSH /***************************************************************************** ** The code that follows is used to build standalone TCL interpreters */ /* ** If the macro TCLSH is one, then put in code this for the ** "main" routine that will initialize Tcl and take input from ** standard input. */ #if TCLSH==1 static char zMainloop[] = "set line {}\n" "while {![eof stdin]} {\n" "if {$line!=\"\"} {\n" "puts -nonewline \"> \"\n" "} else {\n" "puts -nonewline \"% \"\n" |
︙ | ︙ | |||
1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 | "}\n" "set line {}\n" "} else {\n" "append line \\n\n" "}\n" "}\n" ; #define TCLSH_MAIN main /* Needed to fake out mktclapp */ int TCLSH_MAIN(int argc, char **argv){ Tcl_Interp *interp; Tcl_FindExecutable(argv[0]); interp = Tcl_CreateInterp(); Sqlite3_Init(interp); | > > > > > > > > > > > | 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 | "}\n" "set line {}\n" "} else {\n" "append line \\n\n" "}\n" "}\n" ; #endif /* ** If the macro TCLSH is two, then get the main loop code out of ** the separate file "spaceanal_tcl.h". */ #if TCLSH==2 static char zMainloop[] = #include "spaceanal_tcl.h" ; #endif #define TCLSH_MAIN main /* Needed to fake out mktclapp */ int TCLSH_MAIN(int argc, char **argv){ Tcl_Interp *interp; Tcl_FindExecutable(argv[0]); interp = Tcl_CreateInterp(); Sqlite3_Init(interp); |
︙ | ︙ | |||
1187 1188 1189 1190 1191 1192 1193 | Sqlitetest2_Init(interp); Sqlitetest3_Init(interp); Sqlitetest4_Init(interp); Sqlitetest5_Init(interp); Md5_Init(interp); } #endif | | | < > > | 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 | Sqlitetest2_Init(interp); Sqlitetest3_Init(interp); Sqlitetest4_Init(interp); Sqlitetest5_Init(interp); Md5_Init(interp); } #endif if( argc>=2 || TCLSH==2 ){ int i; Tcl_SetVar(interp,"argv0",argv[1],TCL_GLOBAL_ONLY); Tcl_SetVar(interp,"argv", "", TCL_GLOBAL_ONLY); for(i=2; i<argc; i++){ Tcl_SetVar(interp, "argv", argv[i], TCL_GLOBAL_ONLY | TCL_LIST_ELEMENT | TCL_APPEND_VALUE); } if( TCLSH==1 && Tcl_EvalFile(interp, argv[1])!=TCL_OK ){ const char *zInfo = Tcl_GetVar(interp, "errorInfo", TCL_GLOBAL_ONLY); if( zInfo==0 ) zInfo = interp->result; fprintf(stderr,"%s: %s\n", *argv, zInfo); return 1; } } if( argc<=1 || TCLSH==2 ){ Tcl_GlobalEval(interp, zMainloop); } return 0; } #endif /* TCLSH */ #endif /* !defined(NO_TCL) */ |
Changes to src/test3.c.
︙ | ︙ | |||
9 10 11 12 13 14 15 | ** May you share freely, never taking more than you give. ** ************************************************************************* ** Code for testing the btree.c module in SQLite. This code ** is not included in the SQLite library. It is used for automated ** testing of the SQLite library. ** | | | 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | ** May you share freely, never taking more than you give. ** ************************************************************************* ** Code for testing the btree.c module in SQLite. This code ** is not included in the SQLite library. It is used for automated ** testing of the SQLite library. ** ** $Id: test3.c,v 1.50 2004/07/23 00:01:39 drh Exp $ */ #include "sqliteInt.h" #include "pager.h" #include "btree.h" #include "tcl.h" #include <stdlib.h> #include <string.h> |
︙ | ︙ | |||
1158 1159 1160 1161 1162 1163 1164 | sqlite3BtreeDataSize(pCur, &n2); sprintf(zBuf, "%d", (int)(n1+n2)); Tcl_AppendResult(interp, zBuf, 0); return SQLITE_OK; } /* | | | | | | > > > | | | > > > > > | | 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 | sqlite3BtreeDataSize(pCur, &n2); sprintf(zBuf, "%d", (int)(n1+n2)); Tcl_AppendResult(interp, zBuf, 0); return SQLITE_OK; } /* ** Usage: btree_cursor_info ID ?UP-CNT? ** ** Return integers containing information about the entry the ** cursor is pointing to: ** ** aResult[0] = The page number ** aResult[1] = The entry number ** aResult[2] = Total number of entries on this page ** aResult[3] = Cell size (local payload + header) ** aResult[4] = Number of free bytes on this page ** aResult[5] = Number of free blocks on the page ** aResult[6] = Total payload size (local + overflow) ** aResult[7] = Header size in bytes ** aResult[8] = Local payload size ** aResult[9] = Parent page number */ static int btree_cursor_info( void *NotUsed, Tcl_Interp *interp, /* The TCL interpreter that invoked this command */ int argc, /* Number of arguments */ const char **argv /* Text of each argument */ ){ BtCursor *pCur; int rc; int i, j; int up; int aResult[10]; char zBuf[400]; if( argc!=2 && argc!=3 ){ Tcl_AppendResult(interp, "wrong # args: should be \"", argv[0], " ID ?UP-CNT?\"", 0); return TCL_ERROR; } if( Tcl_GetInt(interp, argv[1], (int*)&pCur) ) return TCL_ERROR; if( argc==3 ){ if( Tcl_GetInt(interp, argv[2], &up) ) return TCL_ERROR; }else{ up = 0; } rc = sqlite3BtreeCursorInfo(pCur, aResult, up); if( rc ){ Tcl_AppendResult(interp, errorName(rc), 0); return TCL_ERROR; } j = 0; for(i=0; i<sizeof(aResult)/sizeof(aResult[0]); i++){ sprintf(&zBuf[j]," %d", aResult[i]); |
︙ | ︙ |
Added tool/spaceanal.tcl.
> > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 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 53 54 55 56 57 58 59 60 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 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 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 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 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 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 | # Run this TCL script using "testfixture" in order get a report that shows # how much disk space is used by a particular data to actually store data # versus how much space is unused. # # Get the name of the database to analyze # set argv $argv0 if {[llength $argv]!=1} { puts stderr "Usage: $argv0 database-name" exit 1 } set file_to_analyze [lindex $argv 0] if {![file exists $file_to_analyze]} { puts stderr "No such file: $file_to_analyze" exit 1 } if {![file readable $file_to_analyze]} { puts stderr "File is not readable: $file_to_analyze" exit 1 } if {[file size $file_to_analyze]<512} { puts stderr "Empty or malformed database: $file_to_analyze" exit 1 } # Open the database # sqlite3 db [lindex $argv 0] set DB [btree_open [lindex $argv 0] 1000 0] # In-memory database for collecting statistics # sqlite3 mem :memory: set tabledef\ {CREATE TABLE space_used( name clob, -- Name of a table or index in the database file tblname clob, -- Name of associated table is_index boolean, -- TRUE if it is an index, false for a table nentry int, -- Number of entries in the BTree leaf_entries int, -- Number of leaf entries payload int, -- Total amount of data stored in this table or index ovfl_payload int, -- Total amount of data stored on overflow pages ovfl_cnt int, -- Number of entries that use overflow mx_payload int, -- Maximum payload size int_pages int, -- Number of interior pages used leaf_pages int, -- Number of leaf pages used ovfl_pages int, -- Number of overflow pages used int_unused int, -- Number of unused bytes on interior pages leaf_unused int, -- Number of unused bytes on primary pages ovfl_unused int -- Number of unused bytes on overflow pages );} mem eval $tabledef # This query will be used to find the root page number for every table # in the database. # set sql { SELECT name, rootpage FROM sqlite_master WHERE type='table' UNION ALL SELECT 'sqlite_master', 1 ORDER BY 1 } # Quote a string for SQL # proc quote txt { regsub -all ' $txt '' q return '$q' } # Analyze every table in the database, one at a time. # set pageSize [db eval {PRAGMA page_size}] foreach {name rootpage} [db eval $sql] { puts stderr "Analyzing table $name..." set cursor [btree_cursor $DB $rootpage 0] set go [btree_first $cursor] catch {unset seen} set total_payload 0 ;# Payload space used by all entries set total_ovfl 0 ;# Payload space on overflow pages set unused_int 0 ;# Unused space on interior nodes set unused_leaf 0 ;# Unused space on leaf nodes set unused_ovfl 0 ;# Unused space on overflow pages set cnt_ovfl 0 ;# Number of entries that use overflows set cnt_leaf_entry 0 ;# Number of leaf entries set cnt_int_entry 0 ;# Number of interor entries set mx_payload 0 ;# Maximum payload size set ovfl_pages 0 ;# Number of overflow pages used set leaf_pages 0 ;# Number of leaf pages set int_pages 0 ;# Number of interior pages while {$go==0} { incr cnt_leaf_entry set stat [btree_cursor_info $cursor] set payload [lindex $stat 6] if {$payload>$mx_payload} {set mx_payload $payload} incr total_payload $payload set local [lindex $stat 8] set ovfl [expr {$payload-$local}] if {$ovfl} { incr cnt_ovfl incr total_ovfl $ovfl set n [expr {int(ceil($ovfl/($pageSize-4.0)))}] incr ovfl_pages $n incr unused_ovfl [expr {$n*($pageSize-4) - $ovfl}] } set pgno [lindex $stat 0] if {![info exists seen($pgno)]} { set seen($pgno) 1 incr leaf_pages incr unused_leaf [lindex $stat 4] set parent [lindex $stat 9] set up 0 while {$parent!=0 && ![info exists seen($parent)]} { incr up set stat [btree_cursor_info $cursor $up] set seen($parent) 1 incr int_pages incr cnt_int_entry [lindex $stat 2] incr unused_int [lindex $stat 4] set parent [lindex $stat 9] } } set go [btree_next $cursor] } btree_close_cursor $cursor if {[llength [array names seen]]==0} { set leaf_pages 1 set unused_leaf [expr {$pageSize-8}] } elseif {$rootpage==1 && ![info exists seen(1)]} { incr int_pages incr unused_int [expr {$pageSize-112}] } set sql "INSERT INTO space_used VALUES(" append sql [quote $name] append sql ",[quote $name]" append sql ",0" append sql ",[expr {$cnt_leaf_entry+$cnt_int_entry}]" append sql ",$cnt_leaf_entry" append sql ",$total_payload" append sql ",$total_ovfl" append sql ",$cnt_ovfl" append sql ",$mx_payload" append sql ",$int_pages" append sql ",$leaf_pages" append sql ",$ovfl_pages" append sql ",$unused_int" append sql ",$unused_leaf" append sql ",$unused_ovfl" append sql ); mem eval $sql } # This query will be used to find the root page number for every index # in the database. # set sql { SELECT name, tbl_name, rootpage FROM sqlite_master WHERE type='index' ORDER BY 2, 1 } # Analyze every index in the database, one at a time. # set pageSize [db eval {PRAGMA page_size}] foreach {name tbl_name rootpage} [db eval $sql] { puts stderr "Analyzing index $name of table $tbl_name..." set cursor [btree_cursor $DB $rootpage 0] set go [btree_first $cursor] catch {unset seen} set total_payload 0 ;# Payload space used by all entries set total_ovfl 0 ;# Payload space on overflow pages set unused_leaf 0 ;# Unused space on leaf nodes set unused_ovfl 0 ;# Unused space on overflow pages set cnt_ovfl 0 ;# Number of entries that use overflows set cnt_leaf_entry 0 ;# Number of leaf entries set mx_payload 0 ;# Maximum payload size set ovfl_pages 0 ;# Number of overflow pages used set leaf_pages 0 ;# Number of leaf pages while {$go==0} { incr cnt_leaf_entry set stat [btree_cursor_info $cursor] set payload [btree_keysize $cursor] if {$payload>$mx_payload} {set mx_payload $payload} incr total_payload $payload set local [lindex $stat 8] set ovfl [expr {$payload-$local}] if {$ovfl} { incr cnt_ovfl incr total_ovfl $ovfl set n [expr {int(ceil($ovfl/($pageSize-4.0)))}] incr ovfl_pages $n incr unused_ovfl [expr {$n*($pageSize-4) - $ovfl}] } set pgno [lindex $stat 0] if {![info exists seen($pgno)]} { set seen($pgno) 1 incr leaf_pages incr unused_leaf [lindex $stat 4] } set go [btree_next $cursor] } btree_close_cursor $cursor if {[llength [array names seen]]==0} { set leaf_pages 1 set unused_leaf [expr {$pageSize-8}] } set sql "INSERT INTO space_used VALUES(" append sql [quote $name] append sql ",[quote $tbl_name]" append sql ",1" append sql ",$cnt_leaf_entry" append sql ",$cnt_leaf_entry" append sql ",$total_payload" append sql ",$total_ovfl" append sql ",$cnt_ovfl" append sql ",$mx_payload" append sql ",0" append sql ",$leaf_pages" append sql ",$ovfl_pages" append sql ",0" append sql ",$unused_leaf" append sql ",$unused_ovfl" append sql ); mem eval $sql } # Generate a single line of output in the statistics section of the # report. # proc statline {title value {extra {}}} { set len [string length $title] set dots [string range {......................................} $len end] set len [string length $value] set sp2 [string range { } $len end] if {$extra ne ""} { set extra " $extra" } puts "$title$dots $value$sp2$extra" } # Generate a formatted percentage value for $num/$denom # proc percent {num denom {of {}}} { if {$denom==0.0} {return ""} set v [expr {$num*100.0/$denom}] set of {} if {$v==1.0 || $v==0.0 || ($v>1.0 && $v<99.0)} { return [format {%5.1f%% %s} $v $of] } elseif {$v<0.1 || $v>99.9} { return [format {%7.3f%% %s} $v $of] } else { return [format {%6.2f%% %s} $v $of] } } # Generate a subreport that covers some subset of the database. # the $where clause determines which subset to analyze. # proc subreport {title where} { global pageSize set hit 0 mem eval " SELECT sum(nentry) AS nentry, sum(leaf_entries) AS nleaf, sum(payload) AS payload, sum(ovfl_payload) AS ovfl_payload, max(mx_payload) AS mx_payload, sum(ovfl_cnt) as ovfl_cnt, sum(leaf_pages) AS leaf_pages, sum(int_pages) AS int_pages, sum(ovfl_pages) AS ovfl_pages, sum(leaf_unused) AS leaf_unused, sum(int_unused) AS int_unused, sum(ovfl_unused) AS ovfl_unused FROM space_used WHERE $where" {} {set hit 1} if {!$hit} {return 0} puts "" set len [string length $title] incr len 5 set stars "***********************************" append stars $stars set stars [string range $stars $len end] puts "*** $title $stars" puts "" set total_pages [expr {$leaf_pages+$int_pages+$ovfl_pages}] statline "Percentage of total database" [percent $total_pages $::file_pgcnt] statline "Number of entries" $nleaf set total_unused [expr {$ovfl_unused+$int_unused+$leaf_unused}] set storage [expr {$total_pages*$pageSize}] statline "Bytes of storage consumed" $storage statline "Bytes of payload" $payload \ [percent $payload $storage {of storage consumed}] statline "Average payload per entry" [expr {$nleaf>0?$payload/$nleaf:0}] set avgunused [expr {$nleaf>0?$total_unused/$nleaf:0}] statline "Average unused bytes per entry" $avgunused set nint [expr {$nentry-$nleaf}] if {$int_pages>0} { statline "Average fanout" [format %.2f [expr {($nint+0.0)/$int_pages}]] } statline "Maximum payload per entry" $mx_payload statline "Entries that use overflow" $ovfl_cnt \ [percent $ovfl_cnt $nleaf {of all entries}] if {$int_pages>0} { statline "Index pages used" $int_pages } statline "Primary pages used" $leaf_pages statline "Overflow pages used" $ovfl_pages statline "Total pages used" $total_pages if {$int_unused>0} { statline "Unused bytes on index pages" $int_unused \ [percent $int_unused [expr {$int_pages*$pageSize}] {of index space}] } statline "Unused bytes on primary pages" $leaf_unused \ [percent $leaf_unused [expr {$leaf_pages*$pageSize}] {of primary space}] statline "Unused bytes on overflow pages" $ovfl_unused \ [percent $ovfl_unused [expr {$ovfl_pages*$pageSize}] {of overflow space}] statline "Unused bytes on all pages" $total_unused \ [percent $total_unused $storage {of all space}] return 1 } # Output summary statistics: # puts "/** Disk-Space Utilization Report For $file_to_analyze" puts "*** As of [clock format [clock seconds] -format {%Y-%b-%d %H:%M:%S}]" puts "" statline {Page size in bytes} $pageSize set fsize [file size $file_to_analyze] set file_pgcnt [expr {$fsize/$pageSize}] set usedcnt [mem eval \ {SELECT sum(leaf_pages+int_pages+ovfl_pages) FROM space_used}] set freecnt [expr {$file_pgcnt-$usedcnt}] set freecnt2 [lindex [btree_get_meta $DB] 0] statline {Pages in the whole file (measured)} $file_pgcnt set file_pgcnt2 [expr {$usedcnt+$freecnt2}] statline {Pages in the whole file (calculated)} $file_pgcnt2 statline {Pages that store data} $usedcnt [percent $usedcnt $file_pgcnt] statline {Pages on the freelist (per header)}\ $freecnt2 [percent $freecnt2 $file_pgcnt] statline {Pages on the freelist (calculated)}\ $freecnt [percent $freecnt $file_pgcnt] set ntable [db eval {SELECT count(*)+1 FROM sqlite_master WHERE type='table'}] statline {Number of tables in the database} $ntable set nindex [db eval {SELECT count(*) FROM sqlite_master WHERE type='index'}] set autoindex [db eval {SELECT count(*) FROM sqlite_master WHERE type='index' AND name LIKE '(% autoindex %)'}] set manindex [expr {$nindex-$autoindex}] statline {Number of indices} $nindex statline {Number of named indices} $manindex statline {Automatically generated indices} $autoindex set total_payload [mem eval "SELECT sum(payload) FROM space_used"] statline "Size of the file in bytes" $fsize set user_payload [mem one {SELECT sum(payload) FROM space_used WHERE NOT is_index AND name NOT LIKE 'sqlite_master'}] statline "Bytes of user payload stored" $user_payload \ [percent $user_payload $fsize] # Output table rankings # puts "" puts "*** Page counts for all tables with their indices ********************" puts "" mem eval {SELECT tblname, count(*) AS cnt, sum(int_pages+leaf_pages+ovfl_pages) AS size FROM space_used GROUP BY tblname ORDER BY size DESC, tblname} {} { statline [string toupper $tblname] $size [percent $size $file_pgcnt] } # Output subreports # if {$nindex>0} { subreport {All tables and indices} 1 } subreport {All tables} {NOT is_index} if {$nindex>0} { subreport {All indices} {is_index} } foreach tbl [mem eval {SELECT name FROM space_used WHERE NOT is_index ORDER BY name}] { regsub ' $tbl '' qn set name [string toupper $tbl] set n [mem eval "SELECT count(*) FROM space_used WHERE tblname='$qn'"] if {$n>1} { subreport "Table $name and all its indices" "tblname='$qn'" subreport "Table $name w/o any indices" "name='$qn'" subreport "Indices of table $name" "tblname='$qn' AND is_index" } else { subreport "Table $name" "name='$qn'" } } # Output instructions on what the numbers above mean. # puts { *** Definitions ****************************************************** Page size in bytes The number of bytes in a single page of the database file. Usually 1024. Number of pages in the whole file } puts \ " The number of $pageSize-byte pages that go into forming the complete database" puts \ { Pages that store data The number of pages that store data, either as primary B*Tree pages or as overflow pages. The number at the right is the data pages divided by the total number of pages in the file. Pages on the freelist The number of pages that are not currently in use but are reserved for future use. The percentage at the right is the number of freelist pages divided by the total number of pages in the file. Number of tables in the database The number of tables in the database, including the SQLITE_MASTER table used to store schema information. Number of indices The total number of indices in the database. Number of named indices The number of indices created using an explicit CREATE INDEX statement. Automatically generated indices The number of indices used to implement PRIMARY KEY or UNIQUE constraints on tables. Size of the file in bytes The total amount of disk space used by the entire database files. Bytes of user payload stored The total number of bytes of user payload stored in the database. The schema information in the SQLITE_MASTER table is not counted when computing this number. The percentage at the right shows the payload divided by the total file size. Percentage of total database The amount of the complete database file that is devoted to storing information described by this category. Number of entries The total number of B-Tree key/value pairs stored under this category. Bytes of storage consumed The total amount of disk space required to store all B-Tree entries under this category. The is the total number of pages used times the pages size. Bytes of payload The amount of payload stored under this category. Payload is the data part of table entries and the key part of index entries. The percentage at the right is the bytes of payload divided by the bytes of storage consumed. Average payload per entry The average amount of payload on each entry. This is just the bytes of payload divided by the number of entries. Average unused bytes per entry The average amount of free space remaining on all pages under this category on a per-entry basis. This is the number of unused bytes on all pages divided by the number of entries. Maximum payload per entry The largest payload size of any entry. Entries that use overflow The number of entries that user one or more overflow pages. Total pages used This is the number of pages used to hold all information in the current category. This is the sum of index, primary, and overflow pages. Index pages used This is the number of pages in a table B-tree that hold only key (rowid) information and no data. Primary pages used This is the number of B-tree pages that hold both key and data. Overflow pages used The total number of overflow pages used for this category. Unused bytes on index pages The total number of bytes of unused space on all index pages. The percentage at the right is the number of unused bytes divided by the total number of bytes on index pages. Unused bytes on primary pages The total number of bytes of unused space on all primary pages. The percentage at the right is the number of unused bytes divided by the total number of bytes on primary pages. Unused bytes on overflow pages The total number of bytes of unused space on all overflow pages. The percentage at the right is the number of unused bytes divided by the total number of bytes on overflow pages. Unused bytes on all pages The total number of bytes of unused space on all primary and overflow pages. The percentage at the right is the number of unused bytes divided by the total number of bytes. } # Output the database # puts "**********************************************************************" puts "The entire text of this report can be sourced into any SQL database" puts "engine for further analysis. All of the text above is an SQL comment." puts "The data used to generate this report follows:" puts "*/" puts "BEGIN;" puts $tabledef unset -nocomplain x mem eval {SELECT * FROM space_used} x { puts -nonewline "INSERT INTO space_used VALUES" set sep ( foreach col $x(*) { set v $x($col) if {$v=="" || ![string is double $v]} {set v [quote $v]} puts -nonewline $sep$v set sep , } puts ");" } puts "COMMIT;" |