Module: PgHero

Defined in:
lib/pghero.rb,
lib/pghero/engine.rb,
lib/pghero/version.rb,
app/controllers/pg_hero/home_controller.rb

Defined Under Namespace

Classes: Connection, Engine, HomeController

Constant Summary collapse

VERSION =
"0.1.6"

Class Method Summary collapse

Class Method Details

.access_key_idObject



384
385
386
# File 'lib/pghero.rb', line 384

def access_key_id
  ENV["PGHERO_ACCESS_KEY_ID"] || ENV["AWS_ACCESS_KEY_ID"]
end

.connectionObject



436
437
438
# File 'lib/pghero.rb', line 436

def connection
  @connection ||= Connection.connection
end

.cpu_usageObject



293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
# File 'lib/pghero.rb', line 293

def cpu_usage
  if system_stats_enabled?
    cw = AWS::CloudWatch.new(access_key_id: access_key_id, secret_access_key: secret_access_key)
    now = Time.now
    resp = cw.client.get_metric_statistics(
      namespace: "AWS/RDS",
      metric_name: "CPUUtilization",
      dimensions: [{name: "DBInstanceIdentifier", value: db_instance_identifier}],
      start_time: (now - 1 * 3600).iso8601,
      end_time: now.iso8601,
      period: 60,
      statistics: ["Average"]
    )
    data = {}
    resp[:datapoints].sort_by{|d| d[:timestamp] }.each do |d|
      data[d[:timestamp]] = d[:average]
    end
    data
  else
    {}
  end
end

.create_user(user, options = {}) ⇒ Object



325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
# File 'lib/pghero.rb', line 325

def create_user(user, options = {})
  password = options[:password] || random_password
  schema = options[:schema] || "public"
  database = options[:database] || Connection.connection_config[:database]

  commands =
    [
      "CREATE ROLE #{user} LOGIN PASSWORD #{Connection.connection.quote(password)}",
      "GRANT CONNECT ON DATABASE #{database} TO #{user}",
      "GRANT USAGE ON SCHEMA #{schema} TO #{user}"
    ]
  if options[:readonly]
    commands << "GRANT SELECT ON ALL TABLES IN SCHEMA #{schema} TO #{user}"
    commands << "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} GRANT SELECT ON TABLES TO #{user}"
  else
    commands << "GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA #{schema} TO #{user}"
    commands << "GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA #{schema} TO #{user}"
    commands << "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} GRANT ALL PRIVILEGES ON TABLES TO #{user}"
    commands << "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} GRANT ALL PRIVILEGES ON SEQUENCES TO #{user}"
  end

  # run commands
  Connection.transaction do
    commands.each do |command|
      execute command
    end
  end

  {password: password}
end

.database_sizeObject



188
189
190
# File 'lib/pghero.rb', line 188

def database_size
  select_all("SELECT pg_size_pretty(pg_database_size(current_database()))").first["pg_size_pretty"]
end

.db_instance_identifierObject



392
393
394
# File 'lib/pghero.rb', line 392

def db_instance_identifier
  ENV["PGHERO_DB_INSTANCE_IDENTIFIER"]
end

.disable_query_statsObject



279
280
281
282
# File 'lib/pghero.rb', line 279

def disable_query_stats
  execute("DROP EXTENSION IF EXISTS pg_stat_statements")
  true
end

.drop_user(user, options = {}) ⇒ Object



356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
# File 'lib/pghero.rb', line 356

def drop_user(user, options = {})
  schema = options[:schema] || "public"
  database = options[:database] || Connection.connection_config[:database]

  # thanks shiftb
  commands =
    [
      "REVOKE CONNECT ON DATABASE #{database} FROM #{user}",
      "REVOKE USAGE ON SCHEMA #{schema} FROM #{user}",
      "REVOKE ALL PRIVILEGES ON ALL TABLES IN SCHEMA #{schema} FROM #{user}",
      "REVOKE ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA #{schema} FROM #{user}",
      "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} REVOKE SELECT ON TABLES FROM #{user}",
      "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} REVOKE SELECT ON SEQUENCES FROM #{user}",
      "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} REVOKE ALL ON SEQUENCES FROM #{user}",
      "ALTER DEFAULT PRIVILEGES IN SCHEMA #{schema} REVOKE ALL ON TABLES FROM #{user}",
      "DROP ROLE #{user}"
    ]

  # run commands
  Connection.transaction do
    commands.each do |command|
      execute command
    end
  end

  true
end

.enable_query_statsObject



275
276
277
# File 'lib/pghero.rb', line 275

def enable_query_stats
  execute("CREATE EXTENSION pg_stat_statements")
end

.execute(sql) ⇒ Object



432
433
434
# File 'lib/pghero.rb', line 432

def execute(sql)
  connection.execute(sql)
end

.explain(sql) ⇒ Object



401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
# File 'lib/pghero.rb', line 401

def explain(sql)
  sql = squish(sql)
  explanation = nil
  explain_safe = explain_safe?

  # use transaction for safety
  Connection.transaction do
    if !explain_safe and (sql.sub(/;\z/, "").include?(";") or sql.upcase.include?("COMMIT"))
      raise ActiveRecord::StatementInvalid, "Unsafe statement"
    end
    explanation = select_all("EXPLAIN #{sql}").map{|v| v["QUERY PLAN"] }.join("\n")
    raise ActiveRecord::Rollback
  end

  explanation
end

.explain_safe?Boolean

Returns:

  • (Boolean)


418
419
420
421
422
423
424
425
# File 'lib/pghero.rb', line 418

def explain_safe?
  begin
    select_all("SELECT 1; SELECT 1")
    false
  rescue ActiveRecord::StatementInvalid
    true
  end
end

.index_hit_rateObject



76
77
78
79
80
81
82
83
# File 'lib/pghero.rb', line 76

def index_hit_rate
  select_all(%Q{
    SELECT
      (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read),0) AS rate
    FROM
      pg_statio_user_indexes
  }).first["rate"].to_f
end

.index_usageObject



94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
# File 'lib/pghero.rb', line 94

def index_usage
  select_all %Q{
    SELECT
      relname AS table,
      CASE idx_scan
        WHEN 0 THEN 'Insufficient data'
        ELSE (100 * idx_scan / (seq_scan + idx_scan))::text
      END percent_of_times_index_used,
      n_live_tup rows_in_table
    FROM
      pg_stat_user_tables
    ORDER BY
      n_live_tup DESC,
      relname ASC
   }
end

.kill(pid) ⇒ Object



192
193
194
# File 'lib/pghero.rb', line 192

def kill(pid)
  execute("SELECT pg_terminate_backend(#{pid.to_i})").first["pg_terminate_backend"] == "t"
end

.kill_allObject



196
197
198
199
200
201
202
203
204
205
206
207
# File 'lib/pghero.rb', line 196

def kill_all
  select_all %Q{
    SELECT
      pg_terminate_backend(pid)
    FROM
      pg_stat_activity
    WHERE
      pid <> pg_backend_pid()
      AND query <> '<insufficient privilege>'
  }
  true
end

.locksObject



56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
# File 'lib/pghero.rb', line 56

def locks
  select_all %Q{
    SELECT DISTINCT ON (pid)
      pg_stat_activity.pid,
      pg_stat_activity.query,
      age(now(), pg_stat_activity.query_start) AS age
    FROM
      pg_stat_activity
    INNER JOIN
      pg_locks ON pg_locks.pid = pg_stat_activity.pid
    WHERE
      pg_stat_activity.query <> '<insufficient privilege>'
      AND pg_locks.mode = 'ExclusiveLock'
      AND pg_stat_activity.pid <> pg_backend_pid()
    ORDER BY
      pid,
      query_start
  }
end

.long_running_queriesObject



34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
# File 'lib/pghero.rb', line 34

def long_running_queries
  select_all %Q{
    SELECT
      pid,
      state,
      application_name AS source,
      age(now(), xact_start) AS duration,
      waiting,
      query,
      xact_start AS started_at
    FROM
      pg_stat_activity
    WHERE
      query <> '<insufficient privilege>'
      AND state <> 'idle'
      AND pid <> pg_backend_pid()
      AND now() - query_start > interval '1 minutes'
    ORDER BY
      query_start DESC
  }
end

.missing_indexesObject



111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
# File 'lib/pghero.rb', line 111

def missing_indexes
  select_all %Q{
    SELECT
      relname AS table,
      CASE idx_scan
        WHEN 0 THEN 'Insufficient data'
        ELSE (100 * idx_scan / (seq_scan + idx_scan))::text
      END percent_of_times_index_used,
      n_live_tup rows_in_table
    FROM
      pg_stat_user_tables
    WHERE
      idx_scan > 0
      AND (100 * idx_scan / (seq_scan + idx_scan)) < 95
      AND n_live_tup >= 10000
    ORDER BY
      n_live_tup DESC,
      relname ASC
   }
end

.query_statsObject



210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
# File 'lib/pghero.rb', line 210

def query_stats
  if query_stats_enabled?
    select_all %Q{
      SELECT
        query,
        (total_time / 1000 / 60) as total_minutes,
        (total_time / calls) as average_time,
        calls
      FROM
        pg_stat_statements
      INNER JOIN
        pg_database ON pg_database.oid = pg_stat_statements.dbid
      WHERE
        pg_database.datname = current_database()
      ORDER BY
        total_minutes DESC
      LIMIT 100
    }
  else
    []
  end
end

.query_stats_available?Boolean

Returns:

  • (Boolean)


258
259
260
# File 'lib/pghero.rb', line 258

def query_stats_available?
  select_all("SELECT COUNT(*) AS count FROM pg_available_extensions WHERE name = 'pg_stat_statements'").first["count"].to_i > 0 && !rds?
end

.query_stats_enabled?Boolean

Returns:

  • (Boolean)


262
263
264
# File 'lib/pghero.rb', line 262

def query_stats_enabled?
  select_all("SELECT COUNT(*) AS count FROM pg_extension WHERE extname = 'pg_stat_statements'").first["count"].to_i > 0 && query_stats_readable?
end

.query_stats_readable?Boolean

Returns:

  • (Boolean)


266
267
268
269
270
271
272
273
# File 'lib/pghero.rb', line 266

def query_stats_readable?
  begin
    # ensure the user has access to the table
    select_all("SELECT has_table_privilege(current_user, 'pg_stat_statements', 'SELECT')").first["has_table_privilege"] == "t"
  rescue ActiveRecord::StatementInvalid
    false
  end
end

.random_passwordObject



320
321
322
323
# File 'lib/pghero.rb', line 320

def random_password
  require "securerandom"
  SecureRandom.base64(40).delete("+/=")[0...24]
end

.rds?Boolean

TODO better RDS check

Returns:

  • (Boolean)


397
398
399
# File 'lib/pghero.rb', line 397

def rds?
  !!(Connection.connection_config[:host].to_s =~ /rds\.amazonaws\.com\z/)
end

.relation_sizesObject



168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
# File 'lib/pghero.rb', line 168

def relation_sizes
  select_all %Q{
    SELECT
      c.relname AS name,
      CASE WHEN c.relkind = 'r' THEN 'table' ELSE 'index' END AS type,
      pg_size_pretty(pg_table_size(c.oid)) AS size
    FROM
      pg_class c
    LEFT JOIN
      pg_namespace n ON (n.oid = c.relnamespace)
    WHERE
      n.nspname NOT IN ('pg_catalog', 'information_schema')
      AND n.nspname !~ '^pg_toast'
      AND c.relkind IN ('r', 'i')
    ORDER BY
      pg_table_size(c.oid) DESC,
      name ASC
  }
end

.reset_query_statsObject



284
285
286
287
288
289
290
291
# File 'lib/pghero.rb', line 284

def reset_query_stats
  if query_stats_enabled?
    execute("SELECT pg_stat_statements_reset()")
    true
  else
    false
  end
end

.running_queriesObject



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

def running_queries
  select_all %Q{
    SELECT
      pid,
      state,
      application_name AS source,
      age(now(), xact_start) AS duration,
      waiting,
      query,
      xact_start AS started_at
    FROM
      pg_stat_activity
    WHERE
      query <> '<insufficient privilege>'
      AND state <> 'idle'
      AND pid <> pg_backend_pid()
    ORDER BY
      query_start DESC
  }
end

.secret_access_keyObject



388
389
390
# File 'lib/pghero.rb', line 388

def secret_access_key
  ENV["PGHERO_SECRET_ACCESS_KEY"] || ENV["AWS_SECRET_ACCESS_KEY"]
end

.select_all(sql) ⇒ Object



427
428
429
430
# File 'lib/pghero.rb', line 427

def select_all(sql)
  # squish for logs
  connection.select_all(squish(sql)).to_a
end

.slow_queriesObject



233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
# File 'lib/pghero.rb', line 233

def slow_queries
  if query_stats_enabled?
    select_all %Q{
      SELECT
        query,
        (total_time / 1000 / 60) as total_minutes,
        (total_time / calls) as average_time,
        calls
      FROM
        pg_stat_statements
      INNER JOIN
        pg_database ON pg_database.oid = pg_stat_statements.dbid
      WHERE
        pg_database.datname = current_database()
        AND calls >= 100
        AND (total_time / calls) >= 20
      ORDER BY
        total_minutes DESC
      LIMIT 100
    }
  else
    []
  end
end

.squish(str) ⇒ Object

from ActiveSupport



441
442
443
# File 'lib/pghero.rb', line 441

def squish(str)
  str.to_s.gsub(/\A[[:space:]]+/, '').gsub(/[[:space:]]+\z/, '').gsub(/[[:space:]]+/, ' ')
end

.system_stats_enabled?Boolean

Returns:

  • (Boolean)


316
317
318
# File 'lib/pghero.rb', line 316

def system_stats_enabled?
  !!(defined?(AWS) && access_key_id && secret_access_key && db_instance_identifier)
end

.table_hit_rateObject



85
86
87
88
89
90
91
92
# File 'lib/pghero.rb', line 85

def table_hit_rate
  select_all(%Q{
    SELECT
      sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read),0) AS rate
    FROM
      pg_statio_user_tables
  }).first["rate"].to_f
end

.unused_indexesObject



147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
# File 'lib/pghero.rb', line 147

def unused_indexes
  select_all %Q{
    SELECT
      relname AS table,
      indexrelname AS index,
      pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size,
      idx_scan as index_scans
    FROM
      pg_stat_user_indexes ui
    INNER JOIN
      pg_index i ON ui.indexrelid = i.indexrelid
    WHERE
      NOT indisunique
      AND idx_scan < 50
      AND pg_relation_size(i.indexrelid) > 1024 * 1024
    ORDER BY
      pg_relation_size(i.indexrelid) DESC,
      relname ASC
  }
end

.unused_tablesObject



132
133
134
135
136
137
138
139
140
141
142
143
144
145
# File 'lib/pghero.rb', line 132

def unused_tables
  select_all %Q{
    SELECT
      relname AS table,
      n_live_tup rows_in_table
    FROM
      pg_stat_user_tables
    WHERE
      idx_scan = 0
    ORDER BY
      n_live_tup DESC,
      relname ASC
   }
end