xref: /sqlite-3.40.0/src/vacuum.c (revision e89feee5)
1 /*
2 ** 2003 April 6
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 ** This file contains code used to implement the VACUUM command.
13 **
14 ** Most of the code in this file may be omitted by defining the
15 ** SQLITE_OMIT_VACUUM macro.
16 */
17 #include "sqliteInt.h"
18 #include "vdbeInt.h"
19 
20 #if !defined(SQLITE_OMIT_VACUUM) && !defined(SQLITE_OMIT_ATTACH)
21 
22 /*
23 ** Execute zSql on database db.
24 **
25 ** If zSql returns rows, then each row will have exactly one
26 ** column.  (This will only happen if zSql begins with "SELECT".)
27 ** Take each row of result and call execSql() again recursively.
28 **
29 ** The execSqlF() routine does the same thing, except it accepts
30 ** a format string as its third argument
31 */
32 static int execSql(sqlite3 *db, char **pzErrMsg, const char *zSql){
33   sqlite3_stmt *pStmt;
34   int rc;
35 
36   /* printf("SQL: [%s]\n", zSql); fflush(stdout); */
37   rc = sqlite3_prepare_v2(db, zSql, -1, &pStmt, 0);
38   if( rc!=SQLITE_OK ) return rc;
39   while( SQLITE_ROW==(rc = sqlite3_step(pStmt)) ){
40     const char *zSubSql = (const char*)sqlite3_column_text(pStmt,0);
41     assert( sqlite3_strnicmp(zSql,"SELECT",6)==0 );
42     /* The secondary SQL must be one of CREATE TABLE, CREATE INDEX,
43     ** or INSERT.  Historically there have been attacks that first
44     ** corrupt the sqlite_master.sql field with other kinds of statements
45     ** then run VACUUM to get those statements to execute at inappropriate
46     ** times. */
47     if( zSubSql
48      && (strncmp(zSubSql,"CRE",3)==0 || strncmp(zSubSql,"INS",3)==0)
49     ){
50       rc = execSql(db, pzErrMsg, zSubSql);
51       if( rc!=SQLITE_OK ) break;
52     }
53   }
54   assert( rc!=SQLITE_ROW );
55   if( rc==SQLITE_DONE ) rc = SQLITE_OK;
56   if( rc ){
57     sqlite3SetString(pzErrMsg, db, sqlite3_errmsg(db));
58   }
59   (void)sqlite3_finalize(pStmt);
60   return rc;
61 }
62 static int execSqlF(sqlite3 *db, char **pzErrMsg, const char *zSql, ...){
63   char *z;
64   va_list ap;
65   int rc;
66   va_start(ap, zSql);
67   z = sqlite3VMPrintf(db, zSql, ap);
68   va_end(ap);
69   if( z==0 ) return SQLITE_NOMEM;
70   rc = execSql(db, pzErrMsg, z);
71   sqlite3DbFree(db, z);
72   return rc;
73 }
74 
75 /*
76 ** The VACUUM command is used to clean up the database,
77 ** collapse free space, etc.  It is modelled after the VACUUM command
78 ** in PostgreSQL.  The VACUUM command works as follows:
79 **
80 **   (1)  Create a new transient database file
81 **   (2)  Copy all content from the database being vacuumed into
82 **        the new transient database file
83 **   (3)  Copy content from the transient database back into the
84 **        original database.
85 **
86 ** The transient database requires temporary disk space approximately
87 ** equal to the size of the original database.  The copy operation of
88 ** step (3) requires additional temporary disk space approximately equal
89 ** to the size of the original database for the rollback journal.
90 ** Hence, temporary disk space that is approximately 2x the size of the
91 ** original database is required.  Every page of the database is written
92 ** approximately 3 times:  Once for step (2) and twice for step (3).
93 ** Two writes per page are required in step (3) because the original
94 ** database content must be written into the rollback journal prior to
95 ** overwriting the database with the vacuumed content.
96 **
97 ** Only 1x temporary space and only 1x writes would be required if
98 ** the copy of step (3) were replaced by deleting the original database
99 ** and renaming the transient database as the original.  But that will
100 ** not work if other processes are attached to the original database.
101 ** And a power loss in between deleting the original and renaming the
102 ** transient would cause the database file to appear to be deleted
103 ** following reboot.
104 */
105 void sqlite3Vacuum(Parse *pParse, Token *pNm){
106   Vdbe *v = sqlite3GetVdbe(pParse);
107   int iDb = 0;
108   if( v==0 ) return;
109   if( pNm ){
110 #ifndef SQLITE_BUG_COMPATIBLE_20160819
111     /* Default behavior:  Report an error if the argument to VACUUM is
112     ** not recognized */
113     iDb = sqlite3TwoPartName(pParse, pNm, pNm, &pNm);
114     if( iDb<0 ) return;
115 #else
116     /* When SQLITE_BUG_COMPATIBLE_20160819 is defined, unrecognized arguments
117     ** to VACUUM are silently ignored.  This is a back-out of a bug fix that
118     ** occurred on 2016-08-19 (https://www.sqlite.org/src/info/083f9e6270).
119     ** The buggy behavior is required for binary compatibility with some
120     ** legacy applications. */
121     iDb = sqlite3FindDb(pParse->db, pNm);
122     if( iDb<0 ) iDb = 0;
123 #endif
124   }
125   if( iDb!=1 ){
126     sqlite3VdbeAddOp1(v, OP_Vacuum, iDb);
127     sqlite3VdbeUsesBtree(v, iDb);
128   }
129   return;
130 }
131 
132 /*
133 ** This routine implements the OP_Vacuum opcode of the VDBE.
134 */
135 int sqlite3RunVacuum(char **pzErrMsg, sqlite3 *db, int iDb){
136   int rc = SQLITE_OK;     /* Return code from service routines */
137   Btree *pMain;           /* The database being vacuumed */
138   Btree *pTemp;           /* The temporary database we vacuum into */
139   u16 saved_mDbFlags;     /* Saved value of db->mDbFlags */
140   u32 saved_flags;        /* Saved value of db->flags */
141   int saved_nChange;      /* Saved value of db->nChange */
142   int saved_nTotalChange; /* Saved value of db->nTotalChange */
143   u8 saved_mTrace;        /* Saved trace settings */
144   Db *pDb = 0;            /* Database to detach at end of vacuum */
145   int isMemDb;            /* True if vacuuming a :memory: database */
146   int nRes;               /* Bytes of reserved space at the end of each page */
147   int nDb;                /* Number of attached databases */
148   const char *zDbMain;    /* Schema name of database to vacuum */
149 
150   if( !db->autoCommit ){
151     sqlite3SetString(pzErrMsg, db, "cannot VACUUM from within a transaction");
152     return SQLITE_ERROR;
153   }
154   if( db->nVdbeActive>1 ){
155     sqlite3SetString(pzErrMsg, db,"cannot VACUUM - SQL statements in progress");
156     return SQLITE_ERROR;
157   }
158 
159   /* Save the current value of the database flags so that it can be
160   ** restored before returning. Then set the writable-schema flag, and
161   ** disable CHECK and foreign key constraints.  */
162   saved_flags = db->flags;
163   saved_mDbFlags = db->mDbFlags;
164   saved_nChange = db->nChange;
165   saved_nTotalChange = db->nTotalChange;
166   saved_mTrace = db->mTrace;
167   db->flags |= SQLITE_WriteSchema | SQLITE_IgnoreChecks;
168   db->mDbFlags |= DBFLAG_PreferBuiltin | DBFLAG_Vacuum;
169   db->flags &= ~(SQLITE_ForeignKeys | SQLITE_ReverseOrder
170                    | SQLITE_Defensive | SQLITE_CountRows);
171   db->mTrace = 0;
172 
173   zDbMain = db->aDb[iDb].zDbSName;
174   pMain = db->aDb[iDb].pBt;
175   isMemDb = sqlite3PagerIsMemdb(sqlite3BtreePager(pMain));
176 
177   /* Attach the temporary database as 'vacuum_db'. The synchronous pragma
178   ** can be set to 'off' for this file, as it is not recovered if a crash
179   ** occurs anyway. The integrity of the database is maintained by a
180   ** (possibly synchronous) transaction opened on the main database before
181   ** sqlite3BtreeCopyFile() is called.
182   **
183   ** An optimisation would be to use a non-journaled pager.
184   ** (Later:) I tried setting "PRAGMA vacuum_db.journal_mode=OFF" but
185   ** that actually made the VACUUM run slower.  Very little journalling
186   ** actually occurs when doing a vacuum since the vacuum_db is initially
187   ** empty.  Only the journal header is written.  Apparently it takes more
188   ** time to parse and run the PRAGMA to turn journalling off than it does
189   ** to write the journal header file.
190   */
191   nDb = db->nDb;
192   rc = execSql(db, pzErrMsg, "ATTACH''AS vacuum_db");
193   if( rc!=SQLITE_OK ) goto end_of_vacuum;
194   assert( (db->nDb-1)==nDb );
195   pDb = &db->aDb[nDb];
196   assert( strcmp(pDb->zDbSName,"vacuum_db")==0 );
197   pTemp = pDb->pBt;
198 
199   /* The call to execSql() to attach the temp database has left the file
200   ** locked (as there was more than one active statement when the transaction
201   ** to read the schema was concluded. Unlock it here so that this doesn't
202   ** cause problems for the call to BtreeSetPageSize() below.  */
203   sqlite3BtreeCommit(pTemp);
204 
205   nRes = sqlite3BtreeGetOptimalReserve(pMain);
206 
207   /* A VACUUM cannot change the pagesize of an encrypted database. */
208 #ifdef SQLITE_HAS_CODEC
209   if( db->nextPagesize ){
210     extern void sqlite3CodecGetKey(sqlite3*, int, void**, int*);
211     int nKey;
212     char *zKey;
213     sqlite3CodecGetKey(db, iDb, (void**)&zKey, &nKey);
214     if( nKey ) db->nextPagesize = 0;
215   }
216 #endif
217 
218   sqlite3BtreeSetCacheSize(pTemp, db->aDb[iDb].pSchema->cache_size);
219   sqlite3BtreeSetSpillSize(pTemp, sqlite3BtreeSetSpillSize(pMain,0));
220   sqlite3BtreeSetPagerFlags(pTemp, PAGER_SYNCHRONOUS_OFF|PAGER_CACHESPILL);
221 
222   /* Begin a transaction and take an exclusive lock on the main database
223   ** file. This is done before the sqlite3BtreeGetPageSize(pMain) call below,
224   ** to ensure that we do not try to change the page-size on a WAL database.
225   */
226   rc = execSql(db, pzErrMsg, "BEGIN");
227   if( rc!=SQLITE_OK ) goto end_of_vacuum;
228   rc = sqlite3BtreeBeginTrans(pMain, 2, 0);
229   if( rc!=SQLITE_OK ) goto end_of_vacuum;
230 
231   /* Do not attempt to change the page size for a WAL database */
232   if( sqlite3PagerGetJournalMode(sqlite3BtreePager(pMain))
233                                                ==PAGER_JOURNALMODE_WAL ){
234     db->nextPagesize = 0;
235   }
236 
237   if( sqlite3BtreeSetPageSize(pTemp, sqlite3BtreeGetPageSize(pMain), nRes, 0)
238    || (!isMemDb && sqlite3BtreeSetPageSize(pTemp, db->nextPagesize, nRes, 0))
239    || NEVER(db->mallocFailed)
240   ){
241     rc = SQLITE_NOMEM_BKPT;
242     goto end_of_vacuum;
243   }
244 
245 #ifndef SQLITE_OMIT_AUTOVACUUM
246   sqlite3BtreeSetAutoVacuum(pTemp, db->nextAutovac>=0 ? db->nextAutovac :
247                                            sqlite3BtreeGetAutoVacuum(pMain));
248 #endif
249 
250   /* Query the schema of the main database. Create a mirror schema
251   ** in the temporary database.
252   */
253   db->init.iDb = nDb; /* force new CREATE statements into vacuum_db */
254   rc = execSqlF(db, pzErrMsg,
255       "SELECT sql FROM \"%w\".sqlite_master"
256       " WHERE type='table'AND name<>'sqlite_sequence'"
257       " AND coalesce(rootpage,1)>0",
258       zDbMain
259   );
260   if( rc!=SQLITE_OK ) goto end_of_vacuum;
261   rc = execSqlF(db, pzErrMsg,
262       "SELECT sql FROM \"%w\".sqlite_master"
263       " WHERE type='index'",
264       zDbMain
265   );
266   if( rc!=SQLITE_OK ) goto end_of_vacuum;
267   db->init.iDb = 0;
268 
269   /* Loop through the tables in the main database. For each, do
270   ** an "INSERT INTO vacuum_db.xxx SELECT * FROM main.xxx;" to copy
271   ** the contents to the temporary database.
272   */
273   rc = execSqlF(db, pzErrMsg,
274       "SELECT'INSERT INTO vacuum_db.'||quote(name)"
275       "||' SELECT*FROM\"%w\".'||quote(name)"
276       "FROM vacuum_db.sqlite_master "
277       "WHERE type='table'AND coalesce(rootpage,1)>0",
278       zDbMain
279   );
280   assert( (db->mDbFlags & DBFLAG_Vacuum)!=0 );
281   db->mDbFlags &= ~DBFLAG_Vacuum;
282   if( rc!=SQLITE_OK ) goto end_of_vacuum;
283 
284   /* Copy the triggers, views, and virtual tables from the main database
285   ** over to the temporary database.  None of these objects has any
286   ** associated storage, so all we have to do is copy their entries
287   ** from the SQLITE_MASTER table.
288   */
289   rc = execSqlF(db, pzErrMsg,
290       "INSERT INTO vacuum_db.sqlite_master"
291       " SELECT*FROM \"%w\".sqlite_master"
292       " WHERE type IN('view','trigger')"
293       " OR(type='table'AND rootpage=0)",
294       zDbMain
295   );
296   if( rc ) goto end_of_vacuum;
297 
298   /* At this point, there is a write transaction open on both the
299   ** vacuum database and the main database. Assuming no error occurs,
300   ** both transactions are closed by this block - the main database
301   ** transaction by sqlite3BtreeCopyFile() and the other by an explicit
302   ** call to sqlite3BtreeCommit().
303   */
304   {
305     u32 meta;
306     int i;
307 
308     /* This array determines which meta meta values are preserved in the
309     ** vacuum.  Even entries are the meta value number and odd entries
310     ** are an increment to apply to the meta value after the vacuum.
311     ** The increment is used to increase the schema cookie so that other
312     ** connections to the same database will know to reread the schema.
313     */
314     static const unsigned char aCopy[] = {
315        BTREE_SCHEMA_VERSION,     1,  /* Add one to the old schema cookie */
316        BTREE_DEFAULT_CACHE_SIZE, 0,  /* Preserve the default page cache size */
317        BTREE_TEXT_ENCODING,      0,  /* Preserve the text encoding */
318        BTREE_USER_VERSION,       0,  /* Preserve the user version */
319        BTREE_APPLICATION_ID,     0,  /* Preserve the application id */
320     };
321 
322     assert( 1==sqlite3BtreeIsInTrans(pTemp) );
323     assert( 1==sqlite3BtreeIsInTrans(pMain) );
324 
325     /* Copy Btree meta values */
326     for(i=0; i<ArraySize(aCopy); i+=2){
327       /* GetMeta() and UpdateMeta() cannot fail in this context because
328       ** we already have page 1 loaded into cache and marked dirty. */
329       sqlite3BtreeGetMeta(pMain, aCopy[i], &meta);
330       rc = sqlite3BtreeUpdateMeta(pTemp, aCopy[i], meta+aCopy[i+1]);
331       if( NEVER(rc!=SQLITE_OK) ) goto end_of_vacuum;
332     }
333 
334     rc = sqlite3BtreeCopyFile(pMain, pTemp);
335     if( rc!=SQLITE_OK ) goto end_of_vacuum;
336     rc = sqlite3BtreeCommit(pTemp);
337     if( rc!=SQLITE_OK ) goto end_of_vacuum;
338 #ifndef SQLITE_OMIT_AUTOVACUUM
339     sqlite3BtreeSetAutoVacuum(pMain, sqlite3BtreeGetAutoVacuum(pTemp));
340 #endif
341   }
342 
343   assert( rc==SQLITE_OK );
344   rc = sqlite3BtreeSetPageSize(pMain, sqlite3BtreeGetPageSize(pTemp), nRes,1);
345 
346 end_of_vacuum:
347   /* Restore the original value of db->flags */
348   db->init.iDb = 0;
349   db->mDbFlags = saved_mDbFlags;
350   db->flags = saved_flags;
351   db->nChange = saved_nChange;
352   db->nTotalChange = saved_nTotalChange;
353   db->mTrace = saved_mTrace;
354   sqlite3BtreeSetPageSize(pMain, -1, -1, 1);
355 
356   /* Currently there is an SQL level transaction open on the vacuum
357   ** database. No locks are held on any other files (since the main file
358   ** was committed at the btree level). So it safe to end the transaction
359   ** by manually setting the autoCommit flag to true and detaching the
360   ** vacuum database. The vacuum_db journal file is deleted when the pager
361   ** is closed by the DETACH.
362   */
363   db->autoCommit = 1;
364 
365   if( pDb ){
366     sqlite3BtreeClose(pDb->pBt);
367     pDb->pBt = 0;
368     pDb->pSchema = 0;
369   }
370 
371   /* This both clears the schemas and reduces the size of the db->aDb[]
372   ** array. */
373   sqlite3ResetAllSchemasOfConnection(db);
374 
375   return rc;
376 }
377 
378 #endif  /* SQLITE_OMIT_VACUUM && SQLITE_OMIT_ATTACH */
379