#include "sqlite3.h"
#include <stdio.h>
#include <stdlib.h>
static void vacuumFinalize(sqlite3_stmt *pStmt){
sqlite3 *db = sqlite3_db_handle(pStmt);
int rc = sqlite3_finalize(pStmt);
if( rc ){
fprintf(stderr, "finalize error: %s\n", sqlite3_errmsg(db));
exit(1);
}
}
static void execSql(sqlite3 *db, const char *zSql){
sqlite3_stmt *pStmt;
if( !zSql ){
fprintf(stderr, "out of memory!\n");
exit(1);
}
printf("%s;\n", zSql);
if( SQLITE_OK!=sqlite3_prepare(db, zSql, -1, &pStmt, 0) ){
fprintf(stderr, "Error: %s\n", sqlite3_errmsg(db));
exit(1);
}
sqlite3_step(pStmt);
vacuumFinalize(pStmt);
}
static void execExecSql(sqlite3 *db, const char *zSql){
sqlite3_stmt *pStmt;
int rc;
printf("%s;\n", zSql);
rc = sqlite3_prepare(db, zSql, -1, &pStmt, 0);
if( rc!=SQLITE_OK ){
fprintf(stderr, "Error: %s\n", sqlite3_errmsg(db));
exit(1);
}
while( SQLITE_ROW==sqlite3_step(pStmt) ){
execSql(db, (char*)sqlite3_column_text(pStmt, 0));
}
vacuumFinalize(pStmt);
}
int main(int argc, char **argv){
sqlite3 *db;
int rc;
sqlite3_uint64 r;
const char *zDbToVacuum;
char *zBackupDb;
char *zTempDb;
char *zSql;
if( argc!=2 ){
fprintf(stderr, "Usage: %s DATABASE\n", argv[0]);
return 1;
}
zDbToVacuum = argv[1];
printf("-- open database file \"%s\"\n", zDbToVacuum);
rc = sqlite3_open(zDbToVacuum, &db);
if( rc ){
fprintf(stderr, "%s: %s\n", zDbToVacuum, sqlite3_errstr(rc));
return 1;
}
sqlite3_randomness(sizeof(r), &r);
zTempDb = sqlite3_mprintf("%s-vacuum-%016llx", zDbToVacuum, r);
zBackupDb = sqlite3_mprintf("%s-backup-%016llx", zDbToVacuum, r);
zSql = sqlite3_mprintf("ATTACH '%q' AS vacuum_db;", zTempDb);
execSql(db, zSql);
sqlite3_free(zSql);
execSql(db, "PRAGMA writable_schema=ON");
execSql(db, "BEGIN");
execExecSql(db,
"SELECT 'CREATE TABLE vacuum_db.' || substr(sql,14) "
" FROM sqlite_schema WHERE type='table' AND name!='sqlite_sequence'"
" AND rootpage>0"
);
execExecSql(db,
"SELECT 'CREATE INDEX vacuum_db.' || substr(sql,14)"
" FROM sqlite_schema WHERE sql LIKE 'CREATE INDEX %'"
);
execExecSql(db,
"SELECT 'CREATE UNIQUE INDEX vacuum_db.' || substr(sql,21) "
" FROM sqlite_schema WHERE sql LIKE 'CREATE UNIQUE INDEX %'"
);
execExecSql(db,
"SELECT 'INSERT INTO vacuum_db.' || quote(name) "
"|| ' SELECT * FROM main.' || quote(name) "
"FROM main.sqlite_schema "
"WHERE type = 'table' AND name!='sqlite_sequence' "
" AND rootpage>0"
);
execExecSql(db,
"SELECT 'DELETE FROM vacuum_db.' || quote(name) "
"FROM vacuum_db.sqlite_schema WHERE name='sqlite_sequence'"
);
execExecSql(db,
"SELECT 'INSERT INTO vacuum_db.' || quote(name) "
"|| ' SELECT * FROM main.' || quote(name) "
"FROM vacuum_db.sqlite_schema WHERE name=='sqlite_sequence'"
);
execSql(db,
"INSERT INTO vacuum_db.sqlite_schema "
" SELECT type, name, tbl_name, rootpage, sql"
" FROM main.sqlite_schema"
" WHERE type='view' OR type='trigger'"
" OR (type='table' AND rootpage=0)"
);
execSql(db, "COMMIT");
printf("-- close database\n");
sqlite3_close(db);
printf("-- rename \"%s\" to \"%s\"\n", zDbToVacuum, zBackupDb);
rename(zDbToVacuum, zBackupDb);
printf("-- rename \"%s\" to \"%s\"\n", zTempDb, zDbToVacuum);
rename(zTempDb, zDbToVacuum);
sqlite3_free(zTempDb);
sqlite3_free(zBackupDb);
return 0;
}