SQLite

Check-in [a5e6be7cbc]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Add the --progress, --using, and -q options to the index_usage utility program.
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA3-256: a5e6be7cbc5d931308ddcc073c9cd6275c9711cae055d72a7c4aa71c1d15914c
User & Date: drh 2019-01-30 15:47:38.444
Context
2019-01-30
16:58
Fix an off-by-one error when parsing the names of indexes that do not have arguments in the index_usage utility. (check-in: dc794d8f51 user: drh tags: trunk)
15:47
Add the --progress, --using, and -q options to the index_usage utility program. (check-in: a5e6be7cbc user: drh tags: trunk)
14:01
Enhancements to the index_usage utility program. (check-in: 19c739b4a8 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to tool/index_usage.c.
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
#include "sqlite3.h"
#include <stdio.h>
#include <stdlib.h>
#include <assert.h>
#include <string.h>

static void usage(const char *argv0){
  printf("Usage: %s DATABASE LOG\n\n", argv0);
  printf(
    "DATABASE is an SQLite database against which various statements\n"
    "have been run.  The SQL text is stored in LOG.  LOG is an SQLite\n"
    "database with this schema:\n"
    "\n"
    "    CREATE TABLE sqllog(sql TEXT);\n"
    "\n"
    "This utility program analyzes statements contained in LOG and prints\n"
    "a report showing how many times each index in DATABASE is used by the\n"
    "statements in LOG.\n"
    "\n"
    "DATABASE only needs to contain the schema used by the statements in\n"
    "LOG. The content can be removed from DATABASE.\n"
  );






  printf("\nAnalysis will be done by SQLite version %s dated %.20s\n"
         "checkin number %.40s. Different versions\n"
         "of SQLite might use different indexes.\n",
         sqlite3_libversion(), sqlite3_sourceid(), sqlite3_sourceid()+21);
  exit(1);
}

int main(int argc, char **argv){
  sqlite3 *db = 0;          /* The main database */
  sqlite3_stmt *pStmt = 0;  /* a query */
  char *zSql;
  int nErr = 0;
  int rc;











































  if( argc!=3 ) usage(argv[0]);
  rc = sqlite3_open_v2(argv[1], &db, SQLITE_OPEN_READONLY, 0);
  if( rc ){
    printf("Cannot open \"%s\" for reading: %s\n", argv[1], sqlite3_errmsg(db));
    goto errorOut;
  }
  rc = sqlite3_prepare_v2(db, "SELECT * FROM sqlite_master", -1, &pStmt, 0);
  if( rc ){
    printf("Cannot read the schema from \"%s\" - %s\n", argv[1],
           sqlite3_errmsg(db));
    goto errorOut;
  }
  sqlite3_finalize(pStmt);
  pStmt = 0;
  rc = sqlite3_exec(db, 
     "CREATE TABLE temp.idxu(\n"
     "  tbl TEXT,\n"
     "  idx TEXT,\n"
     "  cnt INT,\n"
     "  PRIMARY KEY(idx)\n"
     ") WITHOUT ROWID;", 0, 0, 0);
  if( rc ){
    printf("Cannot create the result table - %s\n",
           sqlite3_errmsg(db));
    goto errorOut;







|














>
>
>
>
>
>













>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>

















|
|







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
#include "sqlite3.h"
#include <stdio.h>
#include <stdlib.h>
#include <assert.h>
#include <string.h>

static void usage(const char *argv0){
  printf("Usage: %s [OPTIONS] DATABASE LOG\n\n", argv0);
  printf(
    "DATABASE is an SQLite database against which various statements\n"
    "have been run.  The SQL text is stored in LOG.  LOG is an SQLite\n"
    "database with this schema:\n"
    "\n"
    "    CREATE TABLE sqllog(sql TEXT);\n"
    "\n"
    "This utility program analyzes statements contained in LOG and prints\n"
    "a report showing how many times each index in DATABASE is used by the\n"
    "statements in LOG.\n"
    "\n"
    "DATABASE only needs to contain the schema used by the statements in\n"
    "LOG. The content can be removed from DATABASE.\n"
  );
  printf(
    "\nOPTIONS:\n\n"
    "    --progress N   Show a progress message after every N input rows\n"
    "    -q             Omit error message when parsing log entries\n"
    "    --using NAME   Print SQL statements that use index NAME\n"
  );
  printf("\nAnalysis will be done by SQLite version %s dated %.20s\n"
         "checkin number %.40s. Different versions\n"
         "of SQLite might use different indexes.\n",
         sqlite3_libversion(), sqlite3_sourceid(), sqlite3_sourceid()+21);
  exit(1);
}

int main(int argc, char **argv){
  sqlite3 *db = 0;          /* The main database */
  sqlite3_stmt *pStmt = 0;  /* a query */
  char *zSql;
  int nErr = 0;
  int rc;
  int bQuiet = 0;
  int i, j;
  const char *zUsing = 0;
  sqlite3_stmt *pIncrCnt = 0;
  int nRow = 0;
  int iProgress = 0;

  for(i=j=1; i<argc; i++){
    const char *z = argv[i];
    if( z[0]=='-' ){
      z++;
      if( z[0]=='-' ) z++;
      if( strcmp(z,"progress")==0 ){
        if( i+1<argc ){
          iProgress = strtol(argv[++i],0,0);
          continue;
        }
        printf("The --progress option requires an argument\n");
        exit(0);
      }
      if( strcmp(z,"q")==0 ){
        bQuiet = 1;
        continue;
      }
      if( strcmp(z,"using")==0 ){
        if( i+1<argc ){
          zUsing = argv[++i];
          continue;
        }
        printf("The --using option requires an argument\n");
        exit(0);
      }
      if( strcmp(z, "help")==0 || strcmp(z, "?")==0 ){
        usage(argv[0]);
      }
      printf("Unknown command-line option: \"%s\"\n", argv[i]);
      exit(0);
    }else{
      if( j<i ) argv[j++] = argv[i];
    }
  }
  argc = j;

  if( argc!=3 ) usage(argv[0]);
  rc = sqlite3_open_v2(argv[1], &db, SQLITE_OPEN_READONLY, 0);
  if( rc ){
    printf("Cannot open \"%s\" for reading: %s\n", argv[1], sqlite3_errmsg(db));
    goto errorOut;
  }
  rc = sqlite3_prepare_v2(db, "SELECT * FROM sqlite_master", -1, &pStmt, 0);
  if( rc ){
    printf("Cannot read the schema from \"%s\" - %s\n", argv[1],
           sqlite3_errmsg(db));
    goto errorOut;
  }
  sqlite3_finalize(pStmt);
  pStmt = 0;
  rc = sqlite3_exec(db, 
     "CREATE TABLE temp.idxu(\n"
     "  tbl TEXT COLLATE nocase,\n"
     "  idx TEXT COLLATE nocase,\n"
     "  cnt INT,\n"
     "  PRIMARY KEY(idx)\n"
     ") WITHOUT ROWID;", 0, 0, 0);
  if( rc ){
    printf("Cannot create the result table - %s\n",
           sqlite3_errmsg(db));
    goto errorOut;
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
     " WHERE upper(substr(sql,1,5)) NOT IN ('BEGIN','COMMI','ROLLB','PRAGM')",
                          -1, &pStmt, 0);
  if( rc ){
    printf("Cannot read the SQLLOG table in the LOG database \"%s\" - %s\n",
           argv[2], sqlite3_errmsg(db));
    goto errorOut;
  }










  /* Update the counts based on LOG */
  while( sqlite3_step(pStmt)==SQLITE_ROW ){
    const char *zLog = (const char*)sqlite3_column_text(pStmt, 0);
    sqlite3_stmt *pS2;
    if( zLog==0 ) continue;
    zSql = sqlite3_mprintf("EXPLAIN QUERY PLAN %s", zLog);
    rc = sqlite3_prepare_v2(db, zSql, -1, &pS2, 0);
    sqlite3_free(zSql);
    if( rc ){

      printf("Cannot compile LOG entry %d (%s): %s\n",
             sqlite3_column_int(pStmt, 1), zLog, sqlite3_errmsg(db));


      nErr++;
    }else{





      while( sqlite3_step(pS2)==SQLITE_ROW ){
        const char *zExplain = (const char*)sqlite3_column_text(pS2,3);
        const char *z1, *z2;
        int n;
        /* printf("EXPLAIN: %s\n", zExplain); */
        z1 = strstr(zExplain, " USING INDEX ");
        if( z1==0 ) continue;
        z1 += 13;
        for(z2=z1+1; z2[1] && z2[1]!='('; z2++){}
        n = z2 - z1;
        zSql = sqlite3_mprintf(
          "UPDATE temp.idxu SET cnt=cnt+1 WHERE idx='%.*q'", n, z1
        );
        /* printf("sql: %s\n", zSql); */


        sqlite3_exec(db, zSql, 0, 0, 0);
        sqlite3_free(zSql);
      }
    }
    sqlite3_finalize(pS2);
  }
  sqlite3_finalize(pStmt);

  /* Generate the report */







>
>
>
>
>
>
>
>
>










>
|

>
>


>
>
>
>
>










|
|
|
<
>
>
|
|







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
     " WHERE upper(substr(sql,1,5)) NOT IN ('BEGIN','COMMI','ROLLB','PRAGM')",
                          -1, &pStmt, 0);
  if( rc ){
    printf("Cannot read the SQLLOG table in the LOG database \"%s\" - %s\n",
           argv[2], sqlite3_errmsg(db));
    goto errorOut;
  }

  rc = sqlite3_prepare_v2(db,
    "UPDATE temp.idxu SET cnt=cnt+1 WHERE idx=?1",
    -1, &pIncrCnt, 0);
  if( rc ){
    printf("Cannot prepare a statement to increment a counter for "
           "indexes used\n");
    goto errorOut;
  }

  /* Update the counts based on LOG */
  while( sqlite3_step(pStmt)==SQLITE_ROW ){
    const char *zLog = (const char*)sqlite3_column_text(pStmt, 0);
    sqlite3_stmt *pS2;
    if( zLog==0 ) continue;
    zSql = sqlite3_mprintf("EXPLAIN QUERY PLAN %s", zLog);
    rc = sqlite3_prepare_v2(db, zSql, -1, &pS2, 0);
    sqlite3_free(zSql);
    if( rc ){
      if( !bQuiet ){
        printf("Cannot compile LOG entry %d (%s): %s\n",
             sqlite3_column_int(pStmt, 1), zLog, sqlite3_errmsg(db));
        fflush(stdout);
      }
      nErr++;
    }else{
      nRow++;
      if( iProgress>0 && (nRow%iProgress)==0 ){
        printf("%d...\n", nRow);
        fflush(stdout);
      }
      while( sqlite3_step(pS2)==SQLITE_ROW ){
        const char *zExplain = (const char*)sqlite3_column_text(pS2,3);
        const char *z1, *z2;
        int n;
        /* printf("EXPLAIN: %s\n", zExplain); */
        z1 = strstr(zExplain, " USING INDEX ");
        if( z1==0 ) continue;
        z1 += 13;
        for(z2=z1+1; z2[1] && z2[1]!='('; z2++){}
        n = z2 - z1;
        if( zUsing && sqlite3_strnicmp(zUsing, z1, n)==0 ){
          printf("Using %s:\n%s\n", zUsing, zLog);
          fflush(stdout);

        }
        sqlite3_bind_text(pIncrCnt,1,z1,n,SQLITE_STATIC);
        sqlite3_step(pIncrCnt);
        sqlite3_reset(pIncrCnt);
      }
    }
    sqlite3_finalize(pS2);
  }
  sqlite3_finalize(pStmt);

  /* Generate the report */
156
157
158
159
160
161
162

163
164
165
166
       sqlite3_column_text(pStmt, 0),
       sqlite3_column_text(pStmt, 3));
  }
  sqlite3_finalize(pStmt);
  pStmt = 0;

errorOut:

  sqlite3_finalize(pStmt);
  sqlite3_close(db);
  return nErr;
}







>




222
223
224
225
226
227
228
229
230
231
232
233
       sqlite3_column_text(pStmt, 0),
       sqlite3_column_text(pStmt, 3));
  }
  sqlite3_finalize(pStmt);
  pStmt = 0;

errorOut:
  sqlite3_finalize(pIncrCnt);
  sqlite3_finalize(pStmt);
  sqlite3_close(db);
  return nErr;
}