1731dd6ebSdrh /*
2731dd6ebSdrh ** 2018-12-04
3731dd6ebSdrh **
4731dd6ebSdrh ** The author disclaims copyright to this source code. In place of
5731dd6ebSdrh ** a legal notice, here is a blessing:
6731dd6ebSdrh **
7731dd6ebSdrh ** May you do good and not evil.
8731dd6ebSdrh ** May you find forgiveness for yourself and forgive others.
9731dd6ebSdrh ** May you share freely, never taking more than you give.
10731dd6ebSdrh **
11731dd6ebSdrh *************************************************************************
12731dd6ebSdrh **
13731dd6ebSdrh ** This file implements a utility program used to help determine which
14731dd6ebSdrh ** indexes in a database schema are used and unused, and how often specific
15731dd6ebSdrh ** indexes are used.
16731dd6ebSdrh */
17731dd6ebSdrh #include "sqlite3.h"
18731dd6ebSdrh #include <stdio.h>
19731dd6ebSdrh #include <stdlib.h>
20731dd6ebSdrh #include <assert.h>
21731dd6ebSdrh #include <string.h>
22731dd6ebSdrh
usage(const char * argv0)23731dd6ebSdrh static void usage(const char *argv0){
24a8614259Sdrh printf("Usage: %s [OPTIONS] DATABASE LOG\n\n", argv0);
25731dd6ebSdrh printf(
26731dd6ebSdrh "DATABASE is an SQLite database against which various statements\n"
27731dd6ebSdrh "have been run. The SQL text is stored in LOG. LOG is an SQLite\n"
28731dd6ebSdrh "database with this schema:\n"
29731dd6ebSdrh "\n"
30731dd6ebSdrh " CREATE TABLE sqllog(sql TEXT);\n"
31731dd6ebSdrh "\n"
32731dd6ebSdrh "This utility program analyzes statements contained in LOG and prints\n"
33731dd6ebSdrh "a report showing how many times each index in DATABASE is used by the\n"
34731dd6ebSdrh "statements in LOG.\n"
35731dd6ebSdrh "\n"
36731dd6ebSdrh "DATABASE only needs to contain the schema used by the statements in\n"
37731dd6ebSdrh "LOG. The content can be removed from DATABASE.\n"
38731dd6ebSdrh );
39a8614259Sdrh printf(
40a8614259Sdrh "\nOPTIONS:\n\n"
41a8614259Sdrh " --progress N Show a progress message after every N input rows\n"
42a8614259Sdrh " -q Omit error message when parsing log entries\n"
43a8614259Sdrh " --using NAME Print SQL statements that use index NAME\n"
44a8614259Sdrh );
45731dd6ebSdrh printf("\nAnalysis will be done by SQLite version %s dated %.20s\n"
46731dd6ebSdrh "checkin number %.40s. Different versions\n"
47731dd6ebSdrh "of SQLite might use different indexes.\n",
48731dd6ebSdrh sqlite3_libversion(), sqlite3_sourceid(), sqlite3_sourceid()+21);
49731dd6ebSdrh exit(1);
50731dd6ebSdrh }
51731dd6ebSdrh
main(int argc,char ** argv)52731dd6ebSdrh int main(int argc, char **argv){
53731dd6ebSdrh sqlite3 *db = 0; /* The main database */
54731dd6ebSdrh sqlite3_stmt *pStmt = 0; /* a query */
55731dd6ebSdrh char *zSql;
56731dd6ebSdrh int nErr = 0;
57731dd6ebSdrh int rc;
58a8614259Sdrh int bQuiet = 0;
59a8614259Sdrh int i, j;
60a8614259Sdrh const char *zUsing = 0;
61a8614259Sdrh sqlite3_stmt *pIncrCnt = 0;
62a8614259Sdrh int nRow = 0;
63a8614259Sdrh int iProgress = 0;
64a8614259Sdrh
65a8614259Sdrh for(i=j=1; i<argc; i++){
66a8614259Sdrh const char *z = argv[i];
67a8614259Sdrh if( z[0]=='-' ){
68a8614259Sdrh z++;
69a8614259Sdrh if( z[0]=='-' ) z++;
70a8614259Sdrh if( strcmp(z,"progress")==0 ){
71a8614259Sdrh if( i+1<argc ){
72a8614259Sdrh iProgress = strtol(argv[++i],0,0);
73a8614259Sdrh continue;
74a8614259Sdrh }
75a8614259Sdrh printf("The --progress option requires an argument\n");
76a8614259Sdrh exit(0);
77a8614259Sdrh }
78a8614259Sdrh if( strcmp(z,"q")==0 ){
79a8614259Sdrh bQuiet = 1;
80a8614259Sdrh continue;
81a8614259Sdrh }
82a8614259Sdrh if( strcmp(z,"using")==0 ){
83a8614259Sdrh if( i+1<argc ){
84a8614259Sdrh zUsing = argv[++i];
85a8614259Sdrh continue;
86a8614259Sdrh }
87a8614259Sdrh printf("The --using option requires an argument\n");
88a8614259Sdrh exit(0);
89a8614259Sdrh }
90a8614259Sdrh if( strcmp(z, "help")==0 || strcmp(z, "?")==0 ){
91a8614259Sdrh usage(argv[0]);
92a8614259Sdrh }
93a8614259Sdrh printf("Unknown command-line option: \"%s\"\n", argv[i]);
94a8614259Sdrh exit(0);
95a8614259Sdrh }else{
96a8614259Sdrh if( j<i ) argv[j++] = argv[i];
97a8614259Sdrh }
98a8614259Sdrh }
99a8614259Sdrh argc = j;
100731dd6ebSdrh
101731dd6ebSdrh if( argc!=3 ) usage(argv[0]);
102731dd6ebSdrh rc = sqlite3_open_v2(argv[1], &db, SQLITE_OPEN_READONLY, 0);
103731dd6ebSdrh if( rc ){
104731dd6ebSdrh printf("Cannot open \"%s\" for reading: %s\n", argv[1], sqlite3_errmsg(db));
105731dd6ebSdrh goto errorOut;
106731dd6ebSdrh }
107*067b92baSdrh rc = sqlite3_prepare_v2(db, "SELECT * FROM sqlite_schema", -1, &pStmt, 0);
108731dd6ebSdrh if( rc ){
109731dd6ebSdrh printf("Cannot read the schema from \"%s\" - %s\n", argv[1],
110731dd6ebSdrh sqlite3_errmsg(db));
111731dd6ebSdrh goto errorOut;
112731dd6ebSdrh }
113731dd6ebSdrh sqlite3_finalize(pStmt);
114731dd6ebSdrh pStmt = 0;
115731dd6ebSdrh rc = sqlite3_exec(db,
116731dd6ebSdrh "CREATE TABLE temp.idxu(\n"
117a8614259Sdrh " tbl TEXT COLLATE nocase,\n"
118a8614259Sdrh " idx TEXT COLLATE nocase,\n"
119731dd6ebSdrh " cnt INT,\n"
120731dd6ebSdrh " PRIMARY KEY(idx)\n"
121731dd6ebSdrh ") WITHOUT ROWID;", 0, 0, 0);
122731dd6ebSdrh if( rc ){
123731dd6ebSdrh printf("Cannot create the result table - %s\n",
124731dd6ebSdrh sqlite3_errmsg(db));
125731dd6ebSdrh goto errorOut;
126731dd6ebSdrh }
127731dd6ebSdrh rc = sqlite3_exec(db,
128731dd6ebSdrh "INSERT INTO temp.idxu(tbl,idx,cnt)"
129*067b92baSdrh " SELECT tbl_name, name, 0 FROM sqlite_schema"
130731dd6ebSdrh " WHERE type='index' AND sql IS NOT NULL", 0, 0, 0);
131731dd6ebSdrh
132731dd6ebSdrh /* Open the LOG database */
133731dd6ebSdrh zSql = sqlite3_mprintf("ATTACH %Q AS log", argv[2]);
134731dd6ebSdrh rc = sqlite3_exec(db, zSql, 0, 0, 0);
135731dd6ebSdrh sqlite3_free(zSql);
136731dd6ebSdrh if( rc ){
137731dd6ebSdrh printf("Cannot open the LOG database \"%s\" - %s\n",
138731dd6ebSdrh argv[2], sqlite3_errmsg(db));
139731dd6ebSdrh goto errorOut;
140731dd6ebSdrh }
1415a9c6bccSdrh rc = sqlite3_prepare_v2(db,
1425a9c6bccSdrh "SELECT sql, rowid FROM log.sqllog"
1435a9c6bccSdrh " WHERE upper(substr(sql,1,5)) NOT IN ('BEGIN','COMMI','ROLLB','PRAGM')",
144731dd6ebSdrh -1, &pStmt, 0);
145731dd6ebSdrh if( rc ){
146731dd6ebSdrh printf("Cannot read the SQLLOG table in the LOG database \"%s\" - %s\n",
147731dd6ebSdrh argv[2], sqlite3_errmsg(db));
148731dd6ebSdrh goto errorOut;
149731dd6ebSdrh }
150731dd6ebSdrh
151a8614259Sdrh rc = sqlite3_prepare_v2(db,
152a8614259Sdrh "UPDATE temp.idxu SET cnt=cnt+1 WHERE idx=?1",
153a8614259Sdrh -1, &pIncrCnt, 0);
154a8614259Sdrh if( rc ){
155a8614259Sdrh printf("Cannot prepare a statement to increment a counter for "
156a8614259Sdrh "indexes used\n");
157a8614259Sdrh goto errorOut;
158a8614259Sdrh }
159a8614259Sdrh
160731dd6ebSdrh /* Update the counts based on LOG */
161731dd6ebSdrh while( sqlite3_step(pStmt)==SQLITE_ROW ){
162731dd6ebSdrh const char *zLog = (const char*)sqlite3_column_text(pStmt, 0);
163731dd6ebSdrh sqlite3_stmt *pS2;
164731dd6ebSdrh if( zLog==0 ) continue;
165731dd6ebSdrh zSql = sqlite3_mprintf("EXPLAIN QUERY PLAN %s", zLog);
166731dd6ebSdrh rc = sqlite3_prepare_v2(db, zSql, -1, &pS2, 0);
167731dd6ebSdrh sqlite3_free(zSql);
168731dd6ebSdrh if( rc ){
169a8614259Sdrh if( !bQuiet ){
170731dd6ebSdrh printf("Cannot compile LOG entry %d (%s): %s\n",
171731dd6ebSdrh sqlite3_column_int(pStmt, 1), zLog, sqlite3_errmsg(db));
172a8614259Sdrh fflush(stdout);
173a8614259Sdrh }
174731dd6ebSdrh nErr++;
175731dd6ebSdrh }else{
176a8614259Sdrh nRow++;
177a8614259Sdrh if( iProgress>0 && (nRow%iProgress)==0 ){
178a8614259Sdrh printf("%d...\n", nRow);
179a8614259Sdrh fflush(stdout);
180a8614259Sdrh }
181731dd6ebSdrh while( sqlite3_step(pS2)==SQLITE_ROW ){
182731dd6ebSdrh const char *zExplain = (const char*)sqlite3_column_text(pS2,3);
183731dd6ebSdrh const char *z1, *z2;
184731dd6ebSdrh int n;
185731dd6ebSdrh /* printf("EXPLAIN: %s\n", zExplain); */
186731dd6ebSdrh z1 = strstr(zExplain, " USING INDEX ");
187731dd6ebSdrh if( z1==0 ) continue;
188731dd6ebSdrh z1 += 13;
189ba7bd020Sdrh for(z2=z1+1; z2[0] && z2[1]!='('; z2++){}
190731dd6ebSdrh n = z2 - z1;
191a8614259Sdrh if( zUsing && sqlite3_strnicmp(zUsing, z1, n)==0 ){
192a8614259Sdrh printf("Using %s:\n%s\n", zUsing, zLog);
193a8614259Sdrh fflush(stdout);
194a8614259Sdrh }
195a8614259Sdrh sqlite3_bind_text(pIncrCnt,1,z1,n,SQLITE_STATIC);
196a8614259Sdrh sqlite3_step(pIncrCnt);
197a8614259Sdrh sqlite3_reset(pIncrCnt);
198731dd6ebSdrh }
199731dd6ebSdrh }
200731dd6ebSdrh sqlite3_finalize(pS2);
201731dd6ebSdrh }
202731dd6ebSdrh sqlite3_finalize(pStmt);
203731dd6ebSdrh
204731dd6ebSdrh /* Generate the report */
205731dd6ebSdrh rc = sqlite3_prepare_v2(db,
206731dd6ebSdrh "SELECT tbl, idx, cnt, "
207731dd6ebSdrh " (SELECT group_concat(name,',') FROM pragma_index_info(idx))"
208*067b92baSdrh " FROM temp.idxu, main.sqlite_schema"
209*067b92baSdrh " WHERE temp.idxu.tbl=main.sqlite_schema.tbl_name"
210*067b92baSdrh " AND temp.idxu.idx=main.sqlite_schema.name"
211731dd6ebSdrh " ORDER BY cnt DESC, tbl, idx",
212731dd6ebSdrh -1, &pStmt, 0);
213731dd6ebSdrh if( rc ){
214731dd6ebSdrh printf("Cannot query the result table - %s\n",
215731dd6ebSdrh sqlite3_errmsg(db));
216731dd6ebSdrh goto errorOut;
217731dd6ebSdrh }
218731dd6ebSdrh while( sqlite3_step(pStmt)==SQLITE_ROW ){
219731dd6ebSdrh printf("%10d %s on %s(%s)\n",
220731dd6ebSdrh sqlite3_column_int(pStmt, 2),
221731dd6ebSdrh sqlite3_column_text(pStmt, 1),
222731dd6ebSdrh sqlite3_column_text(pStmt, 0),
223731dd6ebSdrh sqlite3_column_text(pStmt, 3));
224731dd6ebSdrh }
225731dd6ebSdrh sqlite3_finalize(pStmt);
226731dd6ebSdrh pStmt = 0;
227731dd6ebSdrh
228731dd6ebSdrh errorOut:
229a8614259Sdrh sqlite3_finalize(pIncrCnt);
230731dd6ebSdrh sqlite3_finalize(pStmt);
231731dd6ebSdrh sqlite3_close(db);
232731dd6ebSdrh return nErr;
233731dd6ebSdrh }
234