Module: PgHero::Methods::Indexes

Included in:
Database
Defined in:
lib/pghero/methods/indexes.rb

Instance Method Summary collapse

Instance Method Details

#duplicate_indexes(indexes: nil) ⇒ Object



171
172
173
174
175
176
177
178
179
180
181
182
183
# File 'lib/pghero/methods/indexes.rb', line 171

def duplicate_indexes(indexes: nil)
  dup_indexes = []

  indexes_by_table = (indexes || self.indexes).group_by { |i| [i[:schema], i[:table]] }
  indexes_by_table.values.flatten.select { |i| i[:valid] && !i[:primary] && !i[:unique] }.each do |index|
    covering_index = indexes_by_table[[index[:schema], index[:table]]].find { |i| i[:valid] && i[:name] != index[:name] && index_covers?(i[:columns], index[:columns]) && i[:using] == index[:using] && i[:indexprs] == index[:indexprs] && i[:indpred] == index[:indpred] }
    if covering_index && (covering_index[:columns] != index[:columns] || index[:name] > covering_index[:name] || covering_index[:primary] || covering_index[:unique])
      dup_indexes << {unneeded_index: index, covering_index: covering_index}
    end
  end

  dup_indexes.sort_by { |i| ui = i[:unneeded_index]; [ui[:table], ui[:columns]] }
end

#index_bloat(min_size: nil) ⇒ Object



187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
# File 'lib/pghero/methods/indexes.rb', line 187

def index_bloat(min_size: nil)
  min_size ||= index_bloat_bytes
  select_all "    WITH btree_index_atts AS (\n      SELECT\n        nspname, relname, reltuples, relpages, indrelid, relam,\n        regexp_split_to_table(indkey::text, ' ')::smallint AS attnum,\n        indexrelid as index_oid\n      FROM\n        pg_index\n      JOIN\n        pg_class ON pg_class.oid = pg_index.indexrelid\n      JOIN\n        pg_namespace ON pg_namespace.oid = pg_class.relnamespace\n      JOIN\n        pg_am ON pg_class.relam = pg_am.oid\n      WHERE\n        pg_am.amname = 'btree'\n    ),\n    index_item_sizes AS (\n      SELECT\n        i.nspname,\n        i.relname,\n        i.reltuples,\n        i.relpages,\n        i.relam,\n        (quote_ident(s.schemaname) || '.' || quote_ident(s.tablename))::regclass AS starelid,\n        a.attrelid AS table_oid, index_oid,\n        current_setting('block_size')::numeric AS bs,\n        /* MAXALIGN: 4 on 32bits, 8 on 64bits (and mingw32 ?) */\n        CASE\n          WHEN version() ~ 'mingw32' OR version() ~ '64-bit' THEN 8\n          ELSE 4\n        END AS maxalign,\n        24 AS pagehdr,\n        /* per tuple header: add index_attribute_bm if some cols are null-able */\n        CASE WHEN max(coalesce(s.null_frac,0)) = 0\n          THEN 2\n          ELSE 6\n        END AS index_tuple_hdr,\n        /* data len: we remove null values save space using it fractionnal part from stats */\n        sum( (1-coalesce(s.null_frac, 0)) * coalesce(s.avg_width, 2048) ) AS nulldatawidth\n      FROM\n        pg_attribute AS a\n      JOIN\n        pg_stats AS s ON (quote_ident(s.schemaname) || '.' || quote_ident(s.tablename))::regclass=a.attrelid AND s.attname = a.attname\n      JOIN\n        btree_index_atts AS i ON i.indrelid = a.attrelid AND a.attnum = i.attnum\n      WHERE\n        a.attnum > 0\n      GROUP BY\n        1, 2, 3, 4, 5, 6, 7, 8, 9\n    ),\n    index_aligned AS (\n      SELECT\n        maxalign,\n        bs,\n        nspname,\n        relname AS index_name,\n        reltuples,\n        relpages,\n        relam,\n        table_oid,\n        index_oid,\n        ( 2 +\n          maxalign - CASE /* Add padding to the index tuple header to align on MAXALIGN */\n            WHEN index_tuple_hdr%maxalign = 0 THEN maxalign\n            ELSE index_tuple_hdr%maxalign\n          END\n        + nulldatawidth + maxalign - CASE /* Add padding to the data to align on MAXALIGN */\n            WHEN nulldatawidth::integer%maxalign = 0 THEN maxalign\n            ELSE nulldatawidth::integer%maxalign\n          END\n        )::numeric AS nulldatahdrwidth, pagehdr\n      FROM\n        index_item_sizes AS s1\n    ),\n    otta_calc AS (\n      SELECT\n        bs,\n        nspname,\n        table_oid,\n        index_oid,\n        index_name,\n        relpages,\n        coalesce(\n          ceil((reltuples*(4+nulldatahdrwidth))/(bs-pagehdr::float)) +\n          CASE WHEN am.amname IN ('hash','btree') THEN 1 ELSE 0 END , 0 /* btree and hash have a metadata reserved block */\n        ) AS otta\n      FROM\n        index_aligned AS s2\n      LEFT JOIN\n        pg_am am ON s2.relam = am.oid\n    ),\n    raw_bloat AS (\n      SELECT\n        nspname,\n        c.relname AS table_name,\n        index_name,\n        bs*(sub.relpages)::bigint AS totalbytes,\n        CASE\n          WHEN sub.relpages <= otta THEN 0\n          ELSE bs*(sub.relpages-otta)::bigint END\n          AS wastedbytes,\n        CASE\n          WHEN sub.relpages <= otta\n          THEN 0 ELSE bs*(sub.relpages-otta)::bigint * 100 / (bs*(sub.relpages)::bigint) END\n          AS realbloat,\n        pg_relation_size(sub.table_oid) as table_bytes,\n        stat.idx_scan as index_scans,\n        stat.indexrelid\n      FROM\n        otta_calc AS sub\n      JOIN\n        pg_class AS c ON c.oid=sub.table_oid\n      JOIN\n        pg_stat_user_indexes AS stat ON sub.index_oid = stat.indexrelid\n    )\n    SELECT\n      nspname AS schema,\n      table_name AS table,\n      index_name AS index,\n      wastedbytes AS bloat_bytes,\n      totalbytes AS index_bytes,\n      pg_get_indexdef(rb.indexrelid) AS definition,\n      indisprimary AS primary\n    FROM\n      raw_bloat rb\n    INNER JOIN\n      pg_index i ON i.indexrelid = rb.indexrelid\n    WHERE\n      wastedbytes >= \#{min_size.to_i}\n    ORDER BY\n      wastedbytes DESC,\n      index_name\n  SQL\nend\n"

#index_cachingObject



13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
# File 'lib/pghero/methods/indexes.rb', line 13

def index_caching
  select_all "    SELECT\n      schemaname AS schema,\n      relname AS table,\n      indexrelname AS index,\n      CASE WHEN idx_blks_hit + idx_blks_read = 0 THEN\n        0\n      ELSE\n        ROUND(1.0 * idx_blks_hit / (idx_blks_hit + idx_blks_read), 2)\n      END AS hit_rate\n    FROM\n      pg_statio_user_indexes\n    ORDER BY\n      3 DESC, 1\n  SQL\nend\n"

#index_hit_rateObject



4
5
6
7
8
9
10
11
# File 'lib/pghero/methods/indexes.rb', line 4

def index_hit_rate
  select_one "    SELECT\n      (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read), 0) AS rate\n    FROM\n      pg_statio_user_indexes\n  SQL\nend\n"

#index_usageObject



31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
# File 'lib/pghero/methods/indexes.rb', line 31

def index_usage
  select_all "    SELECT\n      schemaname AS schema,\n      relname AS table,\n      CASE idx_scan\n        WHEN 0 THEN 'Insufficient data'\n        ELSE (100 * idx_scan / (seq_scan + idx_scan))::text\n      END percent_of_times_index_used,\n      n_live_tup AS estimated_rows\n    FROM\n      pg_stat_user_tables\n    ORDER BY\n      n_live_tup DESC,\n      relname ASC\n   SQL\nend\n"

#indexesObject



128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
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
# File 'lib/pghero/methods/indexes.rb', line 128

def indexes
  indexes = select_all("    SELECT\n      schemaname AS schema,\n      t.relname AS table,\n      ix.relname AS name,\n      regexp_replace(pg_get_indexdef(i.indexrelid), '^[^\\\\(]*\\\\((.*)\\\\)$', '\\\\1') AS columns,\n      regexp_replace(pg_get_indexdef(i.indexrelid), '.* USING ([^ ]*) \\\\(.*', '\\\\1') AS using,\n      indisunique AS unique,\n      indisprimary AS primary,\n      indisvalid AS valid,\n      indexprs::text,\n      indpred::text,\n      pg_get_indexdef(i.indexrelid) AS definition\n    FROM\n      pg_index i\n    INNER JOIN\n      pg_class t ON t.oid = i.indrelid\n    INNER JOIN\n      pg_class ix ON ix.oid = i.indexrelid\n    LEFT JOIN\n      pg_stat_user_indexes ui ON ui.indexrelid = i.indexrelid\n    WHERE\n      schemaname IS NOT NULL\n    ORDER BY\n      1, 2\n  SQL\n  ).map { |v| v[:columns] = v[:columns].sub(\") WHERE (\", \" WHERE \").split(\", \").map { |c| unquote(c) }; v }\n\n  # determine if any invalid indexes being created\n  # hacky, but works for simple cases\n  # can be a race condition, but that's fine\n  invalid_indexes = indexes.select { |i| !i[:valid] }\n  if invalid_indexes.any?\n    create_index_queries = running_queries.select { |q| /\\s*CREATE\\s+INDEX\\s+CONCURRENTLY\\s+/i.match(q[:query]) }\n    invalid_indexes.each do |index|\n      index[:creating] = create_index_queries.any? { |q| q[:query].include?(index[:table]) && index[:columns].all? { |c| q[:query].include?(c) } }\n    end\n  end\n\n  indexes\nend\n"

#invalid_indexes(indexes: nil) ⇒ Object



117
118
119
120
121
122
123
124
# File 'lib/pghero/methods/indexes.rb', line 117

def invalid_indexes(indexes: nil)
  indexes = (indexes || self.indexes).select { |i| !i[:valid] && !i[:creating] }
  indexes.each do |index|
    # map name -> index for backward compatibility
    index[:index] = index[:name]
  end
  indexes
end

#last_stats_reset_timeObject



106
107
108
109
110
111
112
113
114
115
# File 'lib/pghero/methods/indexes.rb', line 106

def last_stats_reset_time
  select_one "    SELECT\n      pg_stat_get_db_stat_reset_time(oid) AS reset_time\n    FROM\n      pg_database\n    WHERE\n      datname = current_database()\n  SQL\nend\n"

#missing_indexesObject



49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
# File 'lib/pghero/methods/indexes.rb', line 49

def missing_indexes
  select_all "    SELECT\n      schemaname AS schema,\n      relname AS table,\n      CASE idx_scan\n        WHEN 0 THEN 'Insufficient data'\n        ELSE (100 * idx_scan / (seq_scan + idx_scan))::text\n      END percent_of_times_index_used,\n      n_live_tup AS estimated_rows\n    FROM\n      pg_stat_user_tables\n    WHERE\n      idx_scan > 0\n      AND (100 * idx_scan / (seq_scan + idx_scan)) < 95\n      AND n_live_tup >= 10000\n    ORDER BY\n      n_live_tup DESC,\n      relname ASC\n   SQL\nend\n"

#reset_statsObject



101
102
103
104
# File 'lib/pghero/methods/indexes.rb', line 101

def reset_stats
  execute("SELECT pg_stat_reset()")
  true
end

#unused_indexes(max_scans: 50, across: []) ⇒ Object



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
# File 'lib/pghero/methods/indexes.rb', line 71

def unused_indexes(max_scans: 50, across: [])
  result = select_all_size "    SELECT\n      schemaname AS schema,\n      relname AS table,\n      indexrelname AS index,\n      pg_relation_size(i.indexrelid) AS size_bytes,\n      idx_scan as index_scans\n    FROM\n      pg_stat_user_indexes ui\n    INNER JOIN\n      pg_index i ON ui.indexrelid = i.indexrelid\n    WHERE\n      NOT indisunique\n      AND idx_scan <= \#{max_scans.to_i}\n    ORDER BY\n      pg_relation_size(i.indexrelid) DESC,\n      relname ASC\n  SQL\n\n  across.each do |database_id|\n    database = PgHero.databases.values.find { |d| d.id == database_id }\n    raise PgHero::Error, \"Database not found: \#{database_id}\" unless database\n    across_result = Set.new(database.unused_indexes(max_scans: max_scans).map { |v| [v[:schema], v[:index]] })\n    result.select! { |v| across_result.include?([v[:schema], v[:index]]) }\n  end\n\n  result\nend\n"