summaryrefslogtreecommitdiff
path: root/db/migrate/20220422200633_fix_view_for_per_table_autovacuum_status.rb
blob: 0af56d32674165c1d5dbfc36531a8a22f50e7a2a (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
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
# frozen_string_literal: true

class FixViewForPerTableAutovacuumStatus < Gitlab::Database::Migration[2.0]
  def up
    execute <<~SQL
      DROP VIEW IF EXISTS postgres_autovacuum_activity;
      DROP FUNCTION IF EXISTS postgres_pg_stat_activity_autovacuum;

      CREATE FUNCTION postgres_pg_stat_activity_autovacuum() RETURNS TABLE(query text, query_start timestamptz) AS
      $$
        SELECT query, query_start
        FROM pg_stat_activity
        WHERE datname = current_database()
          AND state = 'active'
          AND backend_type = 'autovacuum worker'
      $$
      LANGUAGE sql
      VOLATILE
      SECURITY DEFINER
      SET search_path = 'pg_catalog', 'pg_temp';

      CREATE VIEW postgres_autovacuum_activity AS
        WITH processes as
          (
            SELECT query, query_start, (regexp_matches(query, '^autovacuum: VACUUM (\w+)\.(\w+)')) as matches
            FROM postgres_pg_stat_activity_autovacuum()
            WHERE query ~* '^autovacuum: VACUUM \w+\.\w+'
          )
        SELECT matches[1] || '.' || matches[2] as table_identifier,
              matches[1] as schema,
              matches[2] as table,
              query_start as vacuum_start
        FROM processes;

      COMMENT ON VIEW postgres_autovacuum_activity IS 'Contains information about PostgreSQL backends currently performing autovacuum operations on the tables indicated here.';
    SQL
  end

  def down
    execute(<<~SQL)
      DROP VIEW IF EXISTS postgres_autovacuum_activity;
      DROP FUNCTION IF EXISTS postgres_pg_stat_activity_autovacuum;

      CREATE FUNCTION postgres_pg_stat_activity_autovacuum() RETURNS SETOF pg_catalog.pg_stat_activity AS
      $$
        SELECT *
        FROM pg_stat_activity
        WHERE datname = current_database()
          AND state = 'active'
          AND backend_type = 'autovacuum worker'
      $$
      LANGUAGE sql
      VOLATILE
      SECURITY DEFINER
      SET search_path = 'pg_catalog', 'pg_temp';

      CREATE VIEW postgres_autovacuum_activity AS
        WITH processes as
          (
            SELECT query, query_start, (regexp_matches(query, '^autovacuum: VACUUM (\w+)\.(\w+)')) as matches
            FROM postgres_pg_stat_activity_autovacuum()
            WHERE query ~* '^autovacuum: VACUUM \w+\.\w+'
          )
        SELECT matches[1] || '.' || matches[2] as table_identifier,
              matches[1] as schema,
              matches[2] as table,
              query_start as vacuum_start
        FROM processes;

      COMMENT ON VIEW postgres_autovacuum_activity IS 'Contains information about PostgreSQL backends currently performing autovacuum operations on the tables indicated here.';
    SQL
  end
end