UNPKG

3.06 kBJavaScriptView Raw
1'use strict'
2
3const co = require('co')
4const cli = require('heroku-cli-util')
5const pg = require('heroku-pg')
6
7function * run (context, heroku) {
8 let db = yield pg.fetcher(heroku).database(context.app, context.args.database)
9
10 let query = `
11WITH constants AS (
12 SELECT current_setting('block_size')::numeric AS bs, 23 AS hdr, 4 AS ma
13), bloat_info AS (
14 SELECT
15 ma,bs,schemaname,tablename,
16 (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr,
17 (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2
18 FROM (
19 SELECT
20 schemaname, tablename, hdr, ma, bs,
21 SUM((1-null_frac)*avg_width) AS datawidth,
22 MAX(null_frac) AS maxfracsum,
23 hdr+(
24 SELECT 1+count(*)/8
25 FROM pg_stats s2
26 WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename
27 ) AS nullhdr
28 FROM pg_stats s, constants
29 GROUP BY 1,2,3,4,5
30 ) AS foo
31), table_bloat AS (
32 SELECT
33 schemaname, tablename, cc.relpages, bs,
34 CEIL((cc.reltuples*((datahdr+ma-
35 (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta
36 FROM bloat_info
37 JOIN pg_class cc ON cc.relname = bloat_info.tablename
38 JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema'
39), index_bloat AS (
40 SELECT
41 schemaname, tablename, bs,
42 COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages,
43 COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols
44 FROM bloat_info
45 JOIN pg_class cc ON cc.relname = bloat_info.tablename
46 JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = bloat_info.schemaname AND nn.nspname <> 'information_schema'
47 JOIN pg_index i ON indrelid = cc.oid
48 JOIN pg_class c2 ON c2.oid = i.indexrelid
49)
50SELECT
51 type, schemaname, object_name, bloat, pg_size_pretty(raw_waste) as waste
52FROM
53(SELECT
54 'table' as type,
55 schemaname,
56 tablename as object_name,
57 ROUND(CASE WHEN otta=0 THEN 0.0 ELSE table_bloat.relpages/otta::numeric END,1) AS bloat,
58 CASE WHEN relpages < otta THEN '0' ELSE (bs*(table_bloat.relpages-otta)::bigint)::bigint END AS raw_waste
59FROM
60 table_bloat
61 UNION
62SELECT
63 'index' as type,
64 schemaname,
65 tablename || '::' || iname as object_name,
66 ROUND(CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages/iotta::numeric END,1) AS bloat,
67 CASE WHEN ipages < iotta THEN '0' ELSE (bs*(ipages-iotta))::bigint END AS raw_waste
68FROM
69 index_bloat) bloat_summary
70ORDER BY raw_waste DESC, bloat DESC
71`
72
73 let output = yield pg.psql.exec(db, query)
74 process.stdout.write(output)
75}
76
77const cmd = {
78 topic: 'pg',
79 description: 'show table and index bloat in your database ordered by most wasteful',
80 needsApp: true,
81 needsAuth: true,
82 args: [{name: 'database', optional: true}],
83 run: cli.command(co.wrap(run))
84}
85
86module.exports = [
87 Object.assign({command: 'bloat'}, cmd)
88]