fast_vacuum.c 7.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235
  1. /*
  2. ** 2013-10-01
  3. **
  4. ** The author disclaims copyright to this source code. In place of
  5. ** a legal notice, here is a blessing:
  6. **
  7. ** May you do good and not evil.
  8. ** May you find forgiveness for yourself and forgive others.
  9. ** May you share freely, never taking more than you give.
  10. **
  11. *************************************************************************
  12. **
  13. ** This program implements a high-speed version of the VACUUM command.
  14. ** It repacks an SQLite database to remove as much unused space as
  15. ** possible and to relocate content sequentially in the file.
  16. **
  17. ** This program runs faster and uses less temporary disk space than the
  18. ** built-in VACUUM command. On the other hand, this program has a number
  19. ** of important restrictions relative to the built-in VACUUM command.
  20. **
  21. ** (1) The caller must ensure that no other processes are accessing the
  22. ** database file while the vacuum is taking place. The usual SQLite
  23. ** file locking is insufficient for this. The caller must use
  24. ** external means to make sure only this one routine is reading and
  25. ** writing the database.
  26. **
  27. ** (2) Database reconfiguration such as page size or auto_vacuum changes
  28. ** are not supported by this utility.
  29. **
  30. ** (3) The database file might be renamed if a power loss or crash
  31. ** occurs at just the wrong moment. Recovery must be prepared to
  32. ** to deal with the possibly changed filename.
  33. **
  34. ** This program is intended as a *Demonstration Only*. The intent of this
  35. ** program is to provide example code that application developers can use
  36. ** when creating similar functionality in their applications.
  37. **
  38. ** To compile this program:
  39. **
  40. ** cc fast_vacuum.c sqlite3.c
  41. **
  42. ** Add whatever linker options are required. (Example: "-ldl -lpthread").
  43. ** Then to run the program:
  44. **
  45. ** ./a.out file-to-vacuum
  46. **
  47. */
  48. #include "sqlite3.h"
  49. #include <stdio.h>
  50. #include <stdlib.h>
  51. /*
  52. ** Finalize a prepared statement. If an error has occurred, print the
  53. ** error message and exit.
  54. */
  55. static void vacuumFinalize(sqlite3_stmt *pStmt){
  56. sqlite3 *db = sqlite3_db_handle(pStmt);
  57. int rc = sqlite3_finalize(pStmt);
  58. if( rc ){
  59. fprintf(stderr, "finalize error: %s\n", sqlite3_errmsg(db));
  60. exit(1);
  61. }
  62. }
  63. /*
  64. ** Execute zSql on database db. The SQL text is printed to standard
  65. ** output. If an error occurs, print an error message and exit the
  66. ** process.
  67. */
  68. static void execSql(sqlite3 *db, const char *zSql){
  69. sqlite3_stmt *pStmt;
  70. if( !zSql ){
  71. fprintf(stderr, "out of memory!\n");
  72. exit(1);
  73. }
  74. printf("%s;\n", zSql);
  75. if( SQLITE_OK!=sqlite3_prepare(db, zSql, -1, &pStmt, 0) ){
  76. fprintf(stderr, "Error: %s\n", sqlite3_errmsg(db));
  77. exit(1);
  78. }
  79. sqlite3_step(pStmt);
  80. vacuumFinalize(pStmt);
  81. }
  82. /*
  83. ** Execute zSql on database db. The zSql statement returns exactly
  84. ** one column. Execute this return value as SQL on the same database.
  85. **
  86. ** The zSql statement is printed on standard output prior to being
  87. ** run. If any errors occur, an error is printed and the process
  88. ** exits.
  89. */
  90. static void execExecSql(sqlite3 *db, const char *zSql){
  91. sqlite3_stmt *pStmt;
  92. int rc;
  93. printf("%s;\n", zSql);
  94. rc = sqlite3_prepare(db, zSql, -1, &pStmt, 0);
  95. if( rc!=SQLITE_OK ){
  96. fprintf(stderr, "Error: %s\n", sqlite3_errmsg(db));
  97. exit(1);
  98. }
  99. while( SQLITE_ROW==sqlite3_step(pStmt) ){
  100. execSql(db, (char*)sqlite3_column_text(pStmt, 0));
  101. }
  102. vacuumFinalize(pStmt);
  103. }
  104. int main(int argc, char **argv){
  105. sqlite3 *db; /* Connection to the database file */
  106. int rc; /* Return code from SQLite interface calls */
  107. sqlite3_uint64 r; /* A random number */
  108. const char *zDbToVacuum; /* Database to be vacuumed */
  109. char *zBackupDb; /* Backup copy of the original database */
  110. char *zTempDb; /* Temporary database */
  111. char *zSql; /* An SQL statement */
  112. if( argc!=2 ){
  113. fprintf(stderr, "Usage: %s DATABASE\n", argv[0]);
  114. return 1;
  115. }
  116. /* Identify the database file to be vacuumed and open it.
  117. */
  118. zDbToVacuum = argv[1];
  119. printf("-- open database file \"%s\"\n", zDbToVacuum);
  120. rc = sqlite3_open(zDbToVacuum, &db);
  121. if( rc ){
  122. fprintf(stderr, "%s: %s\n", zDbToVacuum, sqlite3_errstr(rc));
  123. return 1;
  124. }
  125. /* Create names for two other files. zTempDb will be a new database
  126. ** into which we construct a vacuumed copy of zDbToVacuum. zBackupDb
  127. ** will be a new name for zDbToVacuum after it is vacuumed.
  128. */
  129. sqlite3_randomness(sizeof(r), &r);
  130. zTempDb = sqlite3_mprintf("%s-vacuum-%016llx", zDbToVacuum, r);
  131. zBackupDb = sqlite3_mprintf("%s-backup-%016llx", zDbToVacuum, r);
  132. /* Attach the zTempDb database to the database connection.
  133. */
  134. zSql = sqlite3_mprintf("ATTACH '%q' AS vacuum_db;", zTempDb);
  135. execSql(db, zSql);
  136. sqlite3_free(zSql);
  137. /* TODO:
  138. ** Set the page_size and auto_vacuum mode for zTempDb here, if desired.
  139. */
  140. /* The vacuum will occur inside of a transaction. Set writable_schema
  141. ** to ON so that we can directly update the sqlite_schema table in the
  142. ** zTempDb database.
  143. */
  144. execSql(db, "PRAGMA writable_schema=ON");
  145. execSql(db, "BEGIN");
  146. /* Query the schema of the main database. Create a mirror schema
  147. ** in the temporary database.
  148. */
  149. execExecSql(db,
  150. "SELECT 'CREATE TABLE vacuum_db.' || substr(sql,14) "
  151. " FROM sqlite_schema WHERE type='table' AND name!='sqlite_sequence'"
  152. " AND rootpage>0"
  153. );
  154. execExecSql(db,
  155. "SELECT 'CREATE INDEX vacuum_db.' || substr(sql,14)"
  156. " FROM sqlite_schema WHERE sql LIKE 'CREATE INDEX %'"
  157. );
  158. execExecSql(db,
  159. "SELECT 'CREATE UNIQUE INDEX vacuum_db.' || substr(sql,21) "
  160. " FROM sqlite_schema WHERE sql LIKE 'CREATE UNIQUE INDEX %'"
  161. );
  162. /* Loop through the tables in the main database. For each, do
  163. ** an "INSERT INTO vacuum_db.xxx SELECT * FROM main.xxx;" to copy
  164. ** the contents to the temporary database.
  165. */
  166. execExecSql(db,
  167. "SELECT 'INSERT INTO vacuum_db.' || quote(name) "
  168. "|| ' SELECT * FROM main.' || quote(name) "
  169. "FROM main.sqlite_schema "
  170. "WHERE type = 'table' AND name!='sqlite_sequence' "
  171. " AND rootpage>0"
  172. );
  173. /* Copy over the sequence table
  174. */
  175. execExecSql(db,
  176. "SELECT 'DELETE FROM vacuum_db.' || quote(name) "
  177. "FROM vacuum_db.sqlite_schema WHERE name='sqlite_sequence'"
  178. );
  179. execExecSql(db,
  180. "SELECT 'INSERT INTO vacuum_db.' || quote(name) "
  181. "|| ' SELECT * FROM main.' || quote(name) "
  182. "FROM vacuum_db.sqlite_schema WHERE name=='sqlite_sequence'"
  183. );
  184. /* Copy the triggers, views, and virtual tables from the main database
  185. ** over to the temporary database. None of these objects has any
  186. ** associated storage, so all we have to do is copy their entries
  187. ** from the SQLITE_MASTER table.
  188. */
  189. execSql(db,
  190. "INSERT INTO vacuum_db.sqlite_schema "
  191. " SELECT type, name, tbl_name, rootpage, sql"
  192. " FROM main.sqlite_schema"
  193. " WHERE type='view' OR type='trigger'"
  194. " OR (type='table' AND rootpage=0)"
  195. );
  196. /* Commit the transaction and close the database
  197. */
  198. execSql(db, "COMMIT");
  199. printf("-- close database\n");
  200. sqlite3_close(db);
  201. /* At this point, zDbToVacuum is unchanged. zTempDb contains a
  202. ** vacuumed copy of zDbToVacuum. Rearrange filenames so that
  203. ** zTempDb becomes thenew zDbToVacuum.
  204. */
  205. printf("-- rename \"%s\" to \"%s\"\n", zDbToVacuum, zBackupDb);
  206. rename(zDbToVacuum, zBackupDb);
  207. printf("-- rename \"%s\" to \"%s\"\n", zTempDb, zDbToVacuum);
  208. rename(zTempDb, zDbToVacuum);
  209. /* Release allocated memory */
  210. sqlite3_free(zTempDb);
  211. sqlite3_free(zBackupDb);
  212. return 0;
  213. }