Skip to content
代码片段 群组 项目
提交 02a2336d 编辑于 作者: pbair's avatar pbair
浏览文件

Fix function and view for autovacuum activity

Changelog: changed
上级 ebfb2e27
No related branches found
No related tags found
无相关合并请求
# 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 OR REPLACE 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 OR REPLACE 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
666eff0892b795c7f1a84dfcdb6fad6266f952bb91b69c81e803d16ecdc0d11d
\ No newline at end of file
...@@ -106,11 +106,11 @@ BEGIN ...@@ -106,11 +106,11 @@ BEGIN
END; END;
$$; $$;
   
CREATE FUNCTION postgres_pg_stat_activity_autovacuum() RETURNS SETOF pg_stat_activity CREATE FUNCTION postgres_pg_stat_activity_autovacuum() RETURNS TABLE(query text, query_start timestamp with time zone)
LANGUAGE sql SECURITY DEFINER LANGUAGE sql SECURITY DEFINER
SET search_path TO 'pg_catalog', 'pg_temp' SET search_path TO 'pg_catalog', 'pg_temp'
AS $$ AS $$
SELECT * SELECT query, query_start
FROM pg_stat_activity FROM pg_stat_activity
WHERE datname = current_database() WHERE datname = current_database()
AND state = 'active' AND state = 'active'
...@@ -18744,7 +18744,7 @@ CREATE VIEW postgres_autovacuum_activity AS ...@@ -18744,7 +18744,7 @@ CREATE VIEW postgres_autovacuum_activity AS
SELECT postgres_pg_stat_activity_autovacuum.query, SELECT postgres_pg_stat_activity_autovacuum.query,
postgres_pg_stat_activity_autovacuum.query_start, postgres_pg_stat_activity_autovacuum.query_start,
regexp_matches(postgres_pg_stat_activity_autovacuum.query, '^autovacuum: VACUUM (w+).(w+)'::text) AS matches regexp_matches(postgres_pg_stat_activity_autovacuum.query, '^autovacuum: VACUUM (w+).(w+)'::text) AS matches
FROM postgres_pg_stat_activity_autovacuum() postgres_pg_stat_activity_autovacuum(datid, datname, pid, usesysid, usename, application_name, client_addr, client_hostname, client_port, backend_start, xact_start, query_start, state_change, wait_event_type, wait_event, state, backend_xid, backend_xmin, query, backend_type) FROM postgres_pg_stat_activity_autovacuum() postgres_pg_stat_activity_autovacuum(query, query_start)
WHERE (postgres_pg_stat_activity_autovacuum.query ~* '^autovacuum: VACUUM w+.w+'::text) WHERE (postgres_pg_stat_activity_autovacuum.query ~* '^autovacuum: VACUUM w+.w+'::text)
) )
SELECT ((processes.matches[1] || '.'::text) || processes.matches[2]) AS table_identifier, SELECT ((processes.matches[1] || '.'::text) || processes.matches[2]) AS table_identifier,
0% 加载中 .
You are about to add 0 people to the discussion. Proceed with caution.
先完成此消息的编辑!
想要评论请 注册