From efe08e4e4ac3dfe432af4888edb8caa477939d87 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 14:14:16 -0500 Subject: [PATCH 01/14] use Identifier format instead of string format --- pgmq-extension/pgmq.control | 2 +- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 744 ++++++++++++++++++++++ pgmq-extension/sql/pgmq.sql | 140 ++-- 3 files changed, 815 insertions(+), 71 deletions(-) create mode 100644 pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql diff --git a/pgmq-extension/pgmq.control b/pgmq-extension/pgmq.control index 2b145bbf..5fbcabc0 100644 --- a/pgmq-extension/pgmq.control +++ b/pgmq-extension/pgmq.control @@ -1,5 +1,5 @@ comment = 'A lightweight message queue. Like AWS SQS and RSMQ but on Postgres.' -default_version = '1.4.0' +default_version = '1.4.1' module_pathname = '$libdir/pgmq' schema = 'pgmq' relocatable = false diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql new file mode 100644 index 00000000..5ff08ba9 --- /dev/null +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -0,0 +1,744 @@ +CREATE OR REPLACE FUNCTION pgmq.read( + queue_name TEXT, + vt INTEGER, + qty INTEGER +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%I + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.q_%I m + SET + vt = clock_timestamp() + interval '%I seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + queue_name, queue_name, vt + ); + RETURN QUERY EXECUTE sql USING qty; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.read_with_poll( + queue_name TEXT, + vt INTEGER, + qty INTEGER, + max_poll_seconds INTEGER DEFAULT 5, + poll_interval_ms INTEGER DEFAULT 100 +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + r pgmq.message_record; + stop_at TIMESTAMP; + sql TEXT; +BEGIN + stop_at := clock_timestamp() + FORMAT('%I seconds', max_poll_seconds)::interval; + LOOP + IF (SELECT clock_timestamp() >= stop_at) THEN + RETURN; + END IF; + + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%I + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.q_%I m + SET + vt = clock_timestamp() + interval '%I seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + queue_name, queue_name, vt + ); + + FOR r IN + EXECUTE sql USING qty + LOOP + RETURN NEXT r; + END LOOP; + IF FOUND THEN + RETURN; + ELSE + PERFORM pg_sleep(poll_interval_ms / 1000); + END IF; + END LOOP; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.archive( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.q_%I + WHERE msg_id = $1 + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + queue_name, queue_name + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.archive( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.q_%I + WHERE msg_id = ANY($1) + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + queue_name, queue_name + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.delete( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.q_%I + WHERE msg_id = $1 + RETURNING msg_id + $QUERY$, + queue_name + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.delete( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.q_%I + WHERE msg_id = ANY($1) + RETURNING msg_id + $QUERY$, + queue_name + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.send( + queue_name TEXT, + msg JSONB, + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.q_%I (vt, message) + VALUES ((clock_timestamp() + interval '%I seconds'), $1) + RETURNING msg_id; + $QUERY$, + queue_name, delay + ); + RETURN QUERY EXECUTE sql USING msg; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.send_batch( + queue_name TEXT, + msgs JSONB[], + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.q_%I (vt, message) + SELECT clock_timestamp() + interval '%I seconds', unnest($1) + RETURNING msg_id; + $QUERY$, + queue_name, delay + ); + RETURN QUERY EXECUTE sql USING msgs; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT) +RETURNS pgmq.metrics_result AS $$ +DECLARE + result_row pgmq.metrics_result; + query TEXT; +BEGIN + query := FORMAT( + $QUERY$ + WITH q_summary AS ( + SELECT + count(*) as queue_length, + EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, + EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, + NOW() as scrape_time + FROM pgmq.q_%I + ), + all_metrics AS ( + SELECT CASE + WHEN is_called THEN last_value ELSE 0 + END as total_messages + FROM pgmq.q_%I_msg_id_seq + ) + SELECT + '%I' as queue_name, + q_summary.queue_length, + q_summary.newest_msg_age_sec, + q_summary.oldest_msg_age_sec, + all_metrics.total_messages, + q_summary.scrape_time + FROM q_summary, all_metrics + $QUERY$, + queue_name, queue_name, queue_name + ); + EXECUTE query INTO result_row; + RETURN result_row; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) +RETURNS BIGINT AS $$ +DECLARE + deleted_count INTEGER; +BEGIN + EXECUTE format('DELETE FROM pgmq.q_%I', queue_name); + GET DIAGNOSTICS deleted_count = ROW_COUNT; + RETURN deleted_count; +END +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq."detach_archive"(queue_name TEXT) +RETURNS VOID AS $$ +BEGIN + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I', queue_name); +END +$$ LANGUAGE plpgsql; + +-- pop a single message +CREATE OR REPLACE FUNCTION pgmq.pop(queue_name TEXT) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%I + WHERE vt <= now() + ORDER BY msg_id ASC + LIMIT 1 + FOR UPDATE SKIP LOCKED + ) + DELETE from pgmq.q_%I + WHERE msg_id = (select msg_id from cte) + RETURNING *; + $QUERY$, + queue_name, queue_name + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; +BEGIN + sql := FORMAT( + $QUERY$ + UPDATE pgmq.q_%I + SET vt = (now() + interval '%I seconds') + WHERE msg_id = %I + RETURNING *; + $QUERY$, + queue_name, vt, msg_id + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +RETURNS BOOLEAN AS $$ +BEGIN + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.q_%I + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.q_%I + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.a_%I + $QUERY$, + queue_name + ); + + IF EXISTS ( + SELECT 1 + FROM information_schema.tables + WHERE table_name = 'meta' and table_schema = 'pgmq' + ) THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM pgmq.meta WHERE queue_name = '%I' + $QUERY$, + queue_name + ); + END IF; + + IF partitioned THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM public.part_config where parent_table = '%I' + $QUERY$, + queue_name + ); + END IF; + + RETURN TRUE; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.validate_queue_name(queue_name TEXT) +RETURNS void AS $$ +BEGIN + IF length(queue_name) >= 48 THEN + RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_depend + WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') + AND objid = ( + SELECT oid + FROM pg_class + WHERE relname = table_name + ) + ) INTO result; + RETURN result; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + queue_name + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%I', false, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.create_unlogged(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + + EXECUTE FORMAT( + $QUERY$ + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%I ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + queue_name + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%I', false, true) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.create_partitioned( + queue_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000' +) +RETURNS void AS $$ +DECLARE + partition_col TEXT; + a_partition_col TEXT; +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + PERFORM pgmq._ensure_pg_partman_installed(); + SELECT pgmq._get_partition_col(partition_interval) INTO partition_col; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + msg_id BIGINT GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%I) + $QUERY$, + queue_name, partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + SELECT public.create_parent('pgmq.q_%I', '%I', 'native', '%I'); + $QUERY$, + queue_name, partition_col, partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%I_part_idx ON pgmq.q_%I (%I); + $QUERY$, + queue_name, queue_name, partition_col + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%I', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.q_%I'; + $QUERY$, + retention_interval, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%I', true, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); + + IF partition_col = 'enqueued_at' THEN + a_partition_col := 'archived_at'; + ELSE + a_partition_col := partition_col; + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + msg_id BIGINT, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%I); + $QUERY$, + queue_name, a_partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + SELECT public.create_parent('pgmq.a_%I', '%I', 'native', '%I'); + $QUERY$, + queue_name, a_partition_col, partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%I', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.a_%I'; + $QUERY$, + retention_interval, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + $QUERY$, + queue_name, queue_name + ); + +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION pgmq.create(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.create_non_partitioned(queue_name); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000', + leading_partition INT DEFAULT 10) +RETURNS void AS $$ +DECLARE +a_table_name TEXT := 'a_' || table_name; +a_table_name_old TEXT := 'a_'|| table_name || '_old'; +qualified_a_table_name TEXT := format('%I.%I', 'pgmq', 'a_' || table_name); +qualified_a_table_name_old TEXT := format ('%I.%I', 'pgmq', 'a_' || table_name || '_old'); +BEGIN + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'p'; + + IF FOUND THEN + RAISE NOTICE 'Table %I is already partitioned', a_table_name; + RETURN; + END IF; + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'r'; + + IF NOT FOUND THEN + RAISE NOTICE 'Table %I doesnot exists', a_table_name; + RETURN; + END IF; + + EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; + + EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', 'a_' || table_name, 'a_'|| table_name || '_old' ); + + EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; + EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; + + PERFORM create_parent(qualified_a_table_name, 'msg_id', 'native', partition_interval, + p_premake := leading_partition); + + UPDATE part_config + SET retention = retention_interval, + retention_keep_table = false, + retention_keep_index = false, + infinite_time_partitions = true + WHERE parent_table = qualified_a_table_name; +END; +$$ LANGUAGE plpgsql; diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 46d3cd8b..6bdb8a72 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -55,15 +55,15 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%s + FROM pgmq.q_%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%s m + UPDATE pgmq.q_%I m SET - vt = clock_timestamp() + interval '%s seconds', + vt = clock_timestamp() + interval '%I seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id @@ -90,7 +90,7 @@ DECLARE stop_at TIMESTAMP; sql TEXT; BEGIN - stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; + stop_at := clock_timestamp() + FORMAT('%I seconds', max_poll_seconds)::interval; LOOP IF (SELECT clock_timestamp() >= stop_at) THEN RETURN; @@ -101,15 +101,15 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%s + FROM pgmq.q_%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%s m + UPDATE pgmq.q_%I m SET - vt = clock_timestamp() + interval '%s seconds', + vt = clock_timestamp() + interval '%I seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id @@ -147,11 +147,11 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%s + DELETE FROM pgmq.q_%I WHERE msg_id = $1 RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; @@ -177,11 +177,11 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%s + DELETE FROM pgmq.q_%I WHERE msg_id = ANY($1) RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; @@ -205,7 +205,7 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%s + DELETE FROM pgmq.q_%I WHERE msg_id = $1 RETURNING msg_id $QUERY$, @@ -228,7 +228,7 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%s + DELETE FROM pgmq.q_%I WHERE msg_id = ANY($1) RETURNING msg_id $QUERY$, @@ -250,8 +250,8 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%s (vt, message) - VALUES ((clock_timestamp() + interval '%s seconds'), $1) + INSERT INTO pgmq.q_%I (vt, message) + VALUES ((clock_timestamp() + interval '%I seconds'), $1) RETURNING msg_id; $QUERY$, queue_name, delay @@ -272,8 +272,8 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%s (vt, message) - SELECT clock_timestamp() + interval '%s seconds', unnest($1) + INSERT INTO pgmq.q_%I (vt, message) + SELECT clock_timestamp() + interval '%I seconds', unnest($1) RETURNING msg_id; $QUERY$, queue_name, delay @@ -307,16 +307,16 @@ BEGIN EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, NOW() as scrape_time - FROM pgmq.q_%s + FROM pgmq.q_%I ), all_metrics AS ( SELECT CASE WHEN is_called THEN last_value ELSE 0 END as total_messages - FROM pgmq.q_%s_msg_id_seq + FROM pgmq.q_%I_msg_id_seq ) SELECT - '%s' as queue_name, + '%I' as queue_name, q_summary.queue_length, q_summary.newest_msg_age_sec, q_summary.oldest_msg_age_sec, @@ -359,7 +359,7 @@ RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; BEGIN - EXECUTE format('DELETE FROM pgmq.q_%s', queue_name); + EXECUTE format('DELETE FROM pgmq.q_%I', queue_name); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END @@ -369,7 +369,7 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s', queue_name); + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I', queue_name); END $$ LANGUAGE plpgsql; @@ -385,13 +385,13 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%s + FROM pgmq.q_%I WHERE vt <= now() ORDER BY msg_id ASC LIMIT 1 FOR UPDATE SKIP LOCKED ) - DELETE from pgmq.q_%s + DELETE from pgmq.q_%I WHERE msg_id = (select msg_id from cte) RETURNING *; $QUERY$, @@ -410,9 +410,9 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - UPDATE pgmq.q_%s - SET vt = (now() + interval '%s seconds') - WHERE msg_id = %s + UPDATE pgmq.q_%I + SET vt = (now() + interval '%I seconds') + WHERE msg_id = %I RETURNING *; $QUERY$, queue_name, vt, msg_id @@ -426,28 +426,28 @@ RETURNS BOOLEAN AS $$ BEGIN EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.q_%s + ALTER EXTENSION pgmq DROP TABLE pgmq.q_%I $QUERY$, queue_name ); EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s + ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I $QUERY$, queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.q_%s + DROP TABLE IF EXISTS pgmq.q_%I $QUERY$, queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.a_%s + DROP TABLE IF EXISTS pgmq.a_%I $QUERY$, queue_name ); @@ -459,7 +459,7 @@ BEGIN ) THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%s' + DELETE FROM pgmq.meta WHERE queue_name = '%I' $QUERY$, queue_name ); @@ -468,7 +468,7 @@ BEGIN IF partitioned THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM public.part_config where parent_table = '%s' + DELETE FROM public.part_config where parent_table = '%I' $QUERY$, queue_name ); @@ -514,7 +514,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%s ( + CREATE TABLE IF NOT EXISTS pgmq.q_%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -527,7 +527,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -539,24 +539,24 @@ BEGIN queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); + CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); $QUERY$, queue_name, queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); $QUERY$, queue_name, queue_name ); @@ -564,7 +564,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, false) + VALUES ('%I', false, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -580,7 +580,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%s ( + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -593,7 +593,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -605,24 +605,24 @@ BEGIN queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); + CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); $QUERY$, queue_name, queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); $QUERY$, queue_name, queue_name ); @@ -630,7 +630,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, true) + VALUES ('%I', false, true) ON CONFLICT DO NOTHING; $QUERY$, @@ -687,31 +687,31 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%s ( + CREATE TABLE IF NOT EXISTS pgmq.q_%I ( msg_id BIGINT GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%s) + ) PARTITION BY RANGE (%I) $QUERY$, queue_name, partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.q_%s', '%s', 'native', '%s'); + SELECT public.create_parent('pgmq.q_%I', '%I', 'native', '%I'); $QUERY$, queue_name, partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_part_idx ON pgmq.q_%s (%s); + CREATE INDEX IF NOT EXISTS q_%I_part_idx ON pgmq.q_%I (%I); $QUERY$, queue_name, queue_name, partition_col ); @@ -720,11 +720,11 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%s', + retention = '%I', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.q_%s'; + WHERE parent_table = 'pgmq.q_%I'; $QUERY$, retention_interval, queue_name ); @@ -732,7 +732,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', true, false) + VALUES ('%I', true, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -747,25 +747,25 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + CREATE TABLE IF NOT EXISTS pgmq.a_%I ( msg_id BIGINT, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%s); + ) PARTITION BY RANGE (%I); $QUERY$, queue_name, a_partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.a_%s', '%s', 'native', '%s'); + SELECT public.create_parent('pgmq.a_%I', '%I', 'native', '%I'); $QUERY$, queue_name, a_partition_col, partition_interval ); @@ -774,18 +774,18 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%s', + retention = '%I', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.a_%s'; + WHERE parent_table = 'pgmq.a_%I'; $QUERY$, retention_interval, queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); $QUERY$, queue_name, queue_name ); @@ -820,7 +820,7 @@ BEGIN AND c.relkind = 'p'; IF FOUND THEN - RAISE NOTICE 'Table %s is already partitioned', a_table_name; + RAISE NOTICE 'Table %I is already partitioned', a_table_name; RETURN; END IF; @@ -831,7 +831,7 @@ BEGIN AND c.relkind = 'r'; IF NOT FOUND THEN - RAISE NOTICE 'Table %s doesnot exists', a_table_name; + RAISE NOTICE 'Table %I doesnot exists', a_table_name; RETURN; END IF; From 780b48c6e41f590db3ec5b80a5b093aa2bcd6f72 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 14:48:36 -0500 Subject: [PATCH 02/14] fix formatter --- pgmq-extension/sql/pgmq.sql | 200 ++++++++++++++++++------------------ 1 file changed, 100 insertions(+), 100 deletions(-) diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 6bdb8a72..bf2eea8f 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -55,21 +55,21 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%I m + UPDATE pgmq.%I m SET - vt = clock_timestamp() + interval '%I seconds', + vt = clock_timestamp() + interval '%s seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - queue_name, queue_name, vt + 'q_' || queue_name, 'q_' || queue_name, vt ); RETURN QUERY EXECUTE sql USING qty; END; @@ -90,7 +90,7 @@ DECLARE stop_at TIMESTAMP; sql TEXT; BEGIN - stop_at := clock_timestamp() + FORMAT('%I seconds', max_poll_seconds)::interval; + stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; LOOP IF (SELECT clock_timestamp() >= stop_at) THEN RETURN; @@ -101,21 +101,21 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%I m + UPDATE pgmq.%I m SET - vt = clock_timestamp() + interval '%I seconds', + vt = clock_timestamp() + interval '%s seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - queue_name, queue_name, vt + 'q_' || queue_name, 'q_' || queue_name, vt ); FOR r IN @@ -147,16 +147,16 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = $1 RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'a_' || queue_name ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); @@ -177,16 +177,16 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = ANY($1) RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'a_' || queue_name ); RETURN QUERY EXECUTE sql USING msg_ids; END; @@ -205,11 +205,11 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = $1 RETURNING msg_id $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); @@ -228,11 +228,11 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = ANY($1) RETURNING msg_id $QUERY$, - queue_name + 'q_' || queue_name ); RETURN QUERY EXECUTE sql USING msg_ids; END; @@ -250,11 +250,11 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%I (vt, message) - VALUES ((clock_timestamp() + interval '%I seconds'), $1) + INSERT INTO pgmq.%I (vt, message) + VALUES ((clock_timestamp() + interval '%s seconds'), $1) RETURNING msg_id; $QUERY$, - queue_name, delay + 'q_' || queue_name, delay ); RETURN QUERY EXECUTE sql USING msg; END; @@ -272,11 +272,11 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%I (vt, message) - SELECT clock_timestamp() + interval '%I seconds', unnest($1) + INSERT INTO pgmq.%I (vt, message) + SELECT clock_timestamp() + interval '%s seconds', unnest($1) RETURNING msg_id; $QUERY$, - queue_name, delay + 'q_' || queue_name, delay ); RETURN QUERY EXECUTE sql USING msgs; END; @@ -307,13 +307,13 @@ BEGIN EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, NOW() as scrape_time - FROM pgmq.q_%I + FROM pgmq.%I ), all_metrics AS ( SELECT CASE WHEN is_called THEN last_value ELSE 0 END as total_messages - FROM pgmq.q_%I_msg_id_seq + FROM pgmq.%I ) SELECT '%I' as queue_name, @@ -324,7 +324,7 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - queue_name, queue_name, queue_name + 'q_' || queue_name, 'q_' || queue_name | '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; @@ -359,7 +359,7 @@ RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; BEGIN - EXECUTE format('DELETE FROM pgmq.q_%I', queue_name); + EXECUTE format('DELETE FROM pgmq.%I', 'q_' || queue_name); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END @@ -369,7 +369,7 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I', queue_name); + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', 'a_' || queue_name); END $$ LANGUAGE plpgsql; @@ -385,17 +385,17 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= now() ORDER BY msg_id ASC LIMIT 1 FOR UPDATE SKIP LOCKED ) - DELETE from pgmq.q_%I + DELETE from pgmq.%I WHERE msg_id = (select msg_id from cte) RETURNING *; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'q_' || queue_name ); RETURN QUERY EXECUTE sql; END; @@ -410,12 +410,12 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - UPDATE pgmq.q_%I - SET vt = (now() + interval '%I seconds') - WHERE msg_id = %I + UPDATE pgmq.%I + SET vt = (now() + interval '%s seconds') + WHERE msg_id = %s RETURNING *; $QUERY$, - queue_name, vt, msg_id + 'q_' || queue_name, vt, msg_id ); RETURN QUERY EXECUTE sql; END; @@ -426,30 +426,30 @@ RETURNS BOOLEAN AS $$ BEGIN EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.q_%I + ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I + ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - queue_name + 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.q_%I + DROP TABLE IF EXISTS pgmq.%I $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.a_%I + DROP TABLE IF EXISTS pgmq.%I $QUERY$, - queue_name + 'a_' || queue_name ); IF EXISTS ( @@ -459,7 +459,7 @@ BEGIN ) THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%I' + DELETE FROM pgmq.meta WHERE queue_name = '%L' $QUERY$, queue_name ); @@ -468,7 +468,7 @@ BEGIN IF partitioned THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM public.part_config where parent_table = '%I' + DELETE FROM public.part_config where parent_table = '%L' $QUERY$, queue_name ); @@ -514,7 +514,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -522,12 +522,12 @@ BEGIN message JSONB ) $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -536,35 +536,35 @@ BEGIN message JSONB ); $QUERY$, - queue_name + 'a_' || queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - queue_name, queue_name + 'q_' || queue_name || '_vt_idx', 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', false, false) + VALUES ('%L', false, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -580,7 +580,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -588,12 +588,12 @@ BEGIN message JSONB ) $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -602,35 +602,35 @@ BEGIN message JSONB ); $QUERY$, - queue_name + 'a_' || queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - queue_name, queue_name + 'q_' || queue_name || '_vt_idx', 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', false, true) + VALUES ('%L', false, true) ON CONFLICT DO NOTHING; $QUERY$, @@ -687,52 +687,52 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%I) + ) PARTITION BY RANGE (%L) $QUERY$, - queue_name, partition_col + 'q_' || queue_name, partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.q_%I', '%I', 'native', '%I'); + SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); $QUERY$, - queue_name, partition_col, partition_interval + 'q_' || queue_name, partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_part_idx ON pgmq.q_%I (%I); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (Ls); $QUERY$, - queue_name, queue_name, partition_col + 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col ); EXECUTE FORMAT( $QUERY$ UPDATE public.part_config SET - retention = '%I', + retention = '%L', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' WHERE parent_table = 'pgmq.q_%I'; $QUERY$, - retention_interval, queue_name + retention_interval, 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', true, false) + VALUES ('%L', true, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -747,47 +747,47 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%I); + ) PARTITION BY RANGE (%L); $QUERY$, - queue_name, a_partition_col + 'a_' || queue_name, a_partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.a_%I', '%I', 'native', '%I'); + SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); $QUERY$, - queue_name, a_partition_col, partition_interval + 'a_' || queue_name, a_partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ UPDATE public.part_config SET - retention = '%I', + retention = '%L', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.a_%I'; + WHERE parent_table = 'pgmq.&I'; $QUERY$, - retention_interval, queue_name + retention_interval, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); END; @@ -820,7 +820,7 @@ BEGIN AND c.relkind = 'p'; IF FOUND THEN - RAISE NOTICE 'Table %I is already partitioned', a_table_name; + RAISE NOTICE 'Table %s is already partitioned', a_table_name; RETURN; END IF; @@ -831,7 +831,7 @@ BEGIN AND c.relkind = 'r'; IF NOT FOUND THEN - RAISE NOTICE 'Table %I doesnot exists', a_table_name; + RAISE NOTICE 'Table %s doesnot exists', a_table_name; RETURN; END IF; @@ -852,4 +852,4 @@ BEGIN infinite_time_partitions = true WHERE parent_table = qualified_a_table_name; END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; \ No newline at end of file From 252e96f9ef304dc5b22d03f29acbffc993c63d3b Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 15:03:30 -0500 Subject: [PATCH 03/14] inserts --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 335 +++++++++++++--------- pgmq-extension/sql/pgmq.sql | 6 +- 2 files changed, 204 insertions(+), 137 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 5ff08ba9..53cb5890 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE FUNCTION pgmq.read( +CREATE OR REPLACE pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER @@ -12,28 +12,28 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%I m + UPDATE pgmq.%I m SET - vt = clock_timestamp() + interval '%I seconds', + vt = clock_timestamp() + interval '%s seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - queue_name, queue_name, vt + 'q_' || queue_name, 'q_' || queue_name, vt ); RETURN QUERY EXECUTE sql USING qty; END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.read_with_poll( +CREATE OR REPLACE pgmq.read_with_poll( queue_name TEXT, vt INTEGER, qty INTEGER, @@ -46,7 +46,7 @@ DECLARE stop_at TIMESTAMP; sql TEXT; BEGIN - stop_at := clock_timestamp() + FORMAT('%I seconds', max_poll_seconds)::interval; + stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; LOOP IF (SELECT clock_timestamp() >= stop_at) THEN RETURN; @@ -57,21 +57,21 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= clock_timestamp() ORDER BY msg_id ASC LIMIT $1 FOR UPDATE SKIP LOCKED ) - UPDATE pgmq.q_%I m + UPDATE pgmq.%I m SET - vt = clock_timestamp() + interval '%I seconds', + vt = clock_timestamp() + interval '%s seconds', read_ct = read_ct + 1 FROM cte WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - queue_name, queue_name, vt + 'q_' || queue_name, 'q_' || queue_name, vt ); FOR r IN @@ -88,8 +88,10 @@ BEGIN END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.archive( +---- archive +---- removes a message from the queue, and sends it to the archive, where its +---- saved permanently. +CREATE OR REPLACE pgmq.archive( queue_name TEXT, msg_id BIGINT ) @@ -101,24 +103,26 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = $1 RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'a_' || queue_name ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.archive( +---- archive +---- removes an array of message ids from the queue, and sends it to the archive, +---- where these messages will be saved permanently. +CREATE OR REPLACE pgmq.archive( queue_name TEXT, msg_ids BIGINT[] ) @@ -129,23 +133,24 @@ BEGIN sql := FORMAT( $QUERY$ WITH archived AS ( - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = ANY($1) RETURNING msg_id, vt, read_ct, enqueued_at, message ) - INSERT INTO pgmq.a_%I (msg_id, vt, read_ct, enqueued_at, message) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) SELECT msg_id, vt, read_ct, enqueued_at, message FROM archived RETURNING msg_id; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'a_' || queue_name ); RETURN QUERY EXECUTE sql USING msg_ids; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.delete( +---- delete +---- deletes a message id from the queue permanently +CREATE OR REPLACE pgmq.delete( queue_name TEXT, msg_id BIGINT ) @@ -156,19 +161,20 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = $1 RETURNING msg_id $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.delete( +---- delete +---- deletes an array of message ids from the queue permanently +CREATE OR REPLACE pgmq.delete( queue_name TEXT, msg_ids BIGINT[] ) @@ -178,18 +184,19 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - DELETE FROM pgmq.q_%I + DELETE FROM pgmq.%I WHERE msg_id = ANY($1) RETURNING msg_id $QUERY$, - queue_name + 'q_' || queue_name ); RETURN QUERY EXECUTE sql USING msg_ids; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.send( +-- send +-- sends a message to a queue, optionally with a delay +CREATE OR REPLACE pgmq.send( queue_name TEXT, msg JSONB, delay INTEGER DEFAULT 0 @@ -199,18 +206,19 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%I (vt, message) - VALUES ((clock_timestamp() + interval '%I seconds'), $1) + INSERT INTO pgmq.%I (vt, message) + VALUES ((clock_timestamp() + interval '%s seconds'), $1) RETURNING msg_id; $QUERY$, - queue_name, delay + 'q_' || queue_name, delay ); RETURN QUERY EXECUTE sql USING msg; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.send_batch( +-- send_batch +-- sends an array of list of messages to a queue, optionally with a delay +CREATE OR REPLACE pgmq.send_batch( queue_name TEXT, msgs JSONB[], delay INTEGER DEFAULT 0 @@ -220,18 +228,28 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - INSERT INTO pgmq.q_%I (vt, message) - SELECT clock_timestamp() + interval '%I seconds', unnest($1) + INSERT INTO pgmq.%I (vt, message) + SELECT clock_timestamp() + interval '%s seconds', unnest($1) RETURNING msg_id; $QUERY$, - queue_name, delay + 'q_' || queue_name, delay ); RETURN QUERY EXECUTE sql USING msgs; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT) +-- returned by pgmq.metrics() and pgmq.metrics_all +CREATE TYPE pgmq.metrics_result AS ( + queue_name text, + queue_length bigint, + newest_msg_age_sec int, + oldest_msg_age_sec int, + total_messages bigint, + scrape_time timestamp with time zone +); + +-- get metrics for a single queue +CREATE OR REPLACE pgmq.metrics(queue_name TEXT) RETURNS pgmq.metrics_result AS $$ DECLARE result_row pgmq.metrics_result; @@ -245,13 +263,13 @@ BEGIN EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, NOW() as scrape_time - FROM pgmq.q_%I + FROM pgmq.%I ), all_metrics AS ( SELECT CASE WHEN is_called THEN last_value ELSE 0 END as total_messages - FROM pgmq.q_%I_msg_id_seq + FROM pgmq.%I ) SELECT '%I' as queue_name, @@ -262,35 +280,57 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - queue_name, queue_name, queue_name + 'q_' || queue_name, 'q_' || queue_name | '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; END; $$ LANGUAGE plpgsql; +-- get metrics for all queues +CREATE OR REPLACE pgmq."metrics_all"() +RETURNS SETOF pgmq.metrics_result AS $$ +DECLARE + row_name RECORD; + result_row pgmq.metrics_result; +BEGIN + FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP + result_row := pgmq.metrics(row_name.queue_name); + RETURN NEXT result_row; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +-- list queues +CREATE OR REPLACE pgmq."list_queues"() +RETURNS SETOF pgmq.queue_record AS $$ +BEGIN + RETURN QUERY SELECT * FROM pgmq.meta; +END +$$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) +-- purge queue, deleting all entries in it. +CREATE OR REPLACE pgmq."purge_queue"(queue_name TEXT) RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; BEGIN - EXECUTE format('DELETE FROM pgmq.q_%I', queue_name); + EXECUTE format('DELETE FROM pgmq.%I', 'q_' || queue_name); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq."detach_archive"(queue_name TEXT) +-- unassign archive, so it can be kept when a queue is deleted +CREATE OR REPLACE pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I', queue_name); + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', 'a_' || queue_name); END $$ LANGUAGE plpgsql; -- pop a single message -CREATE OR REPLACE FUNCTION pgmq.pop(queue_name TEXT) +CREATE OR REPLACE pgmq.pop(queue_name TEXT) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -301,24 +341,24 @@ BEGIN WITH cte AS ( SELECT msg_id - FROM pgmq.q_%I + FROM pgmq.%I WHERE vt <= now() ORDER BY msg_id ASC LIMIT 1 FOR UPDATE SKIP LOCKED ) - DELETE from pgmq.q_%I + DELETE from pgmq.%I WHERE msg_id = (select msg_id from cte) RETURNING *; $QUERY$, - queue_name, queue_name + 'q_' || queue_name, 'q_' || queue_name ); RETURN QUERY EXECUTE sql; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +-- Sets vt of a message, returns it +CREATE OR REPLACE pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -326,47 +366,46 @@ DECLARE BEGIN sql := FORMAT( $QUERY$ - UPDATE pgmq.q_%I - SET vt = (now() + interval '%I seconds') - WHERE msg_id = %I + UPDATE pgmq.%I + SET vt = (now() + interval '%s seconds') + WHERE msg_id = %s RETURNING *; $QUERY$, - queue_name, vt, msg_id + 'q_' || queue_name, vt, msg_id ); RETURN QUERY EXECUTE sql; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +CREATE OR REPLACE pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) RETURNS BOOLEAN AS $$ BEGIN EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.q_%I + ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.a_%I + ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - queue_name + 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.q_%I + DROP TABLE IF EXISTS pgmq.%I $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - DROP TABLE IF EXISTS pgmq.a_%I + DROP TABLE IF EXISTS pgmq.%I $QUERY$, - queue_name + 'a_' || queue_name ); IF EXISTS ( @@ -376,7 +415,7 @@ BEGIN ) THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%I' + DELETE FROM pgmq.meta WHERE queue_name = '%L' $QUERY$, queue_name ); @@ -385,7 +424,7 @@ BEGIN IF partitioned THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM public.part_config where parent_table = '%I' + DELETE FROM public.part_config where parent_table = '%L' $QUERY$, queue_name ); @@ -395,8 +434,7 @@ BEGIN END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.validate_queue_name(queue_name TEXT) +CREATE OR REPLACE pgmq.validate_queue_name(queue_name TEXT) RETURNS void AS $$ BEGIN IF length(queue_name) >= 48 THEN @@ -405,7 +443,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) +CREATE OR REPLACE pgmq._belongs_to_pgmq(table_name TEXT) RETURNS BOOLEAN AS $$ DECLARE sql TEXT; @@ -425,15 +463,14 @@ BEGIN END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) +CREATE OR REPLACE pgmq.create_non_partitioned(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.validate_queue_name(queue_name); EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -441,12 +478,12 @@ BEGIN message JSONB ) $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -455,35 +492,35 @@ BEGIN message JSONB ); $QUERY$, - queue_name + 'a_' || queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - queue_name, queue_name + 'q_' || queue_name || '_vt_idx', 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', false, false) + VALUES ('%s', false, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -492,15 +529,14 @@ BEGIN END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.create_unlogged(queue_name TEXT) +CREATE OR REPLACE pgmq.create_unlogged(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.validate_queue_name(queue_name); EXECUTE FORMAT( $QUERY$ - CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -508,12 +544,12 @@ BEGIN message JSONB ) $QUERY$, - queue_name + 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT PRIMARY KEY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, @@ -522,35 +558,35 @@ BEGIN message JSONB ); $QUERY$, - queue_name + 'a_' || queue_name ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_vt_idx ON pgmq.q_%I (vt ASC); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - queue_name, queue_name + 'q_' || queue_name || '_vt_idx', 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', false, true) + VALUES ('%s', false, true) ON CONFLICT DO NOTHING; $QUERY$, @@ -559,8 +595,39 @@ BEGIN END; $$ LANGUAGE plpgsql; +CREATE OR REPLACE pgmq._get_partition_col(partition_interval TEXT) +RETURNS TEXT AS $$ +DECLARE + num INTEGER; +BEGIN + BEGIN + num := partition_interval::INTEGER; + RETURN 'msg_id'; + EXCEPTION + WHEN others THEN + RETURN 'enqueued_at'; + END; +END; +$$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.create_partitioned( +CREATE OR REPLACE pgmq._ensure_pg_partman_installed() +RETURNS void AS $$ +DECLARE + extension_exists BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_extension + WHERE extname = 'pg_partman' + ) INTO extension_exists; + + IF NOT extension_exists THEN + RAISE EXCEPTION 'pg_partman is required for partitioned queues'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE pgmq.create_partitioned( queue_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000' @@ -576,52 +643,52 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT GENERATED ALWAYS AS IDENTITY, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%I) + ) PARTITION BY RANGE (%L) $QUERY$, - queue_name, partition_col + 'q_' || queue_name, partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.q_%I', '%I', 'native', '%I'); + SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); $QUERY$, - queue_name, partition_col, partition_interval + 'q_' || queue_name, partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS q_%I_part_idx ON pgmq.q_%I (%I); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (Ls); $QUERY$, - queue_name, queue_name, partition_col + 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col ); EXECUTE FORMAT( $QUERY$ UPDATE public.part_config SET - retention = '%I', + retention = '%L', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' WHERE parent_table = 'pgmq.q_%I'; $QUERY$, - retention_interval, queue_name + retention_interval, 'q_' || queue_name ); EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%I', true, false) + VALUES ('%s', true, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -636,61 +703,61 @@ BEGIN EXECUTE FORMAT( $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%I ( + CREATE TABLE IF NOT EXISTS pgmq.%I ( msg_id BIGINT, read_ct INT DEFAULT 0 NOT NULL, enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%I); + ) PARTITION BY RANGE (%L); $QUERY$, - queue_name, a_partition_col + 'a_' || queue_name, a_partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%I', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%I', queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.a_%I', '%I', 'native', '%I'); + SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); $QUERY$, - queue_name, a_partition_col, partition_interval + 'a_' || queue_name, a_partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ UPDATE public.part_config SET - retention = '%I', + retention = '%L', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.a_%I'; + WHERE parent_table = 'pgmq.&I'; $QUERY$, - retention_interval, queue_name + retention_interval, 'a_' || queue_name ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%I ON pgmq.a_%I (archived_at); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - queue_name, queue_name + 'archived_at_idx_' || queue_name, 'a_' || queue_name ); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.create(queue_name TEXT) +CREATE OR REPLACE pgmq.create(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.create_non_partitioned(queue_name); END; $$ LANGUAGE plpgsql; -CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, +CREATE OR REPLACE pgmq.convert_archive_partitioned(table_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000', leading_partition INT DEFAULT 10) @@ -709,7 +776,7 @@ BEGIN AND c.relkind = 'p'; IF FOUND THEN - RAISE NOTICE 'Table %I is already partitioned', a_table_name; + RAISE NOTICE 'Table %s is already partitioned', a_table_name; RETURN; END IF; @@ -720,7 +787,7 @@ BEGIN AND c.relkind = 'r'; IF NOT FOUND THEN - RAISE NOTICE 'Table %I doesnot exists', a_table_name; + RAISE NOTICE 'Table %s doesnot exists', a_table_name; RETURN; END IF; @@ -741,4 +808,4 @@ BEGIN infinite_time_partitions = true WHERE parent_table = qualified_a_table_name; END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index bf2eea8f..08b58e62 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -564,7 +564,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%L', false, false) + VALUES ('%s', false, false) ON CONFLICT DO NOTHING; $QUERY$, @@ -630,7 +630,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%L', false, true) + VALUES ('%s', false, true) ON CONFLICT DO NOTHING; $QUERY$, @@ -732,7 +732,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%L', true, false) + VALUES ('%s', true, false) ON CONFLICT DO NOTHING; $QUERY$, From 317f619726afa15fd896de5825aee12e6cc40139 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 15:21:56 -0500 Subject: [PATCH 04/14] handle upgrade sql --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 160 ++++++---------------- pgmq-extension/sql/pgmq.sql | 22 +-- 2 files changed, 54 insertions(+), 128 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 53cb5890..1b25263e 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE pgmq.read( +CREATE OR REPLACE FUNCTION pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER @@ -33,7 +33,7 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.read_with_poll( +CREATE OR REPLACE FUNCTION pgmq.read_with_poll( queue_name TEXT, vt INTEGER, qty INTEGER, @@ -88,10 +88,8 @@ BEGIN END; $$ LANGUAGE plpgsql; ----- archive ----- removes a message from the queue, and sends it to the archive, where its ----- saved permanently. -CREATE OR REPLACE pgmq.archive( + +CREATE OR REPLACE FUNCTION pgmq.archive( queue_name TEXT, msg_id BIGINT ) @@ -119,10 +117,8 @@ BEGIN END; $$ LANGUAGE plpgsql; ----- archive ----- removes an array of message ids from the queue, and sends it to the archive, ----- where these messages will be saved permanently. -CREATE OR REPLACE pgmq.archive( + +CREATE OR REPLACE FUNCTION pgmq.archive( queue_name TEXT, msg_ids BIGINT[] ) @@ -148,9 +144,8 @@ BEGIN END; $$ LANGUAGE plpgsql; ----- delete ----- deletes a message id from the queue permanently -CREATE OR REPLACE pgmq.delete( + +CREATE OR REPLACE FUNCTION pgmq.delete( queue_name TEXT, msg_id BIGINT ) @@ -172,9 +167,8 @@ BEGIN END; $$ LANGUAGE plpgsql; ----- delete ----- deletes an array of message ids from the queue permanently -CREATE OR REPLACE pgmq.delete( + +CREATE OR REPLACE FUNCTION pgmq.delete( queue_name TEXT, msg_ids BIGINT[] ) @@ -194,9 +188,8 @@ BEGIN END; $$ LANGUAGE plpgsql; --- send --- sends a message to a queue, optionally with a delay -CREATE OR REPLACE pgmq.send( + +CREATE OR REPLACE FUNCTION pgmq.send( queue_name TEXT, msg JSONB, delay INTEGER DEFAULT 0 @@ -216,9 +209,8 @@ BEGIN END; $$ LANGUAGE plpgsql; --- send_batch --- sends an array of list of messages to a queue, optionally with a delay -CREATE OR REPLACE pgmq.send_batch( + +CREATE OR REPLACE FUNCTION pgmq.send_batch( queue_name TEXT, msgs JSONB[], delay INTEGER DEFAULT 0 @@ -238,18 +230,8 @@ BEGIN END; $$ LANGUAGE plpgsql; --- returned by pgmq.metrics() and pgmq.metrics_all -CREATE TYPE pgmq.metrics_result AS ( - queue_name text, - queue_length bigint, - newest_msg_age_sec int, - oldest_msg_age_sec int, - total_messages bigint, - scrape_time timestamp with time zone -); - --- get metrics for a single queue -CREATE OR REPLACE pgmq.metrics(queue_name TEXT) + +CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT) RETURNS pgmq.metrics_result AS $$ DECLARE result_row pgmq.metrics_result; @@ -272,7 +254,7 @@ BEGIN FROM pgmq.%I ) SELECT - '%I' as queue_name, + '%s' as queue_name, q_summary.queue_length, q_summary.newest_msg_age_sec, q_summary.oldest_msg_age_sec, @@ -280,37 +262,15 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - 'q_' || queue_name, 'q_' || queue_name | '_msg_id_seq', queue_name + 'q_' || queue_name, 'q_' || queue_name || '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; END; $$ LANGUAGE plpgsql; --- get metrics for all queues -CREATE OR REPLACE pgmq."metrics_all"() -RETURNS SETOF pgmq.metrics_result AS $$ -DECLARE - row_name RECORD; - result_row pgmq.metrics_result; -BEGIN - FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP - result_row := pgmq.metrics(row_name.queue_name); - RETURN NEXT result_row; - END LOOP; -END; -$$ LANGUAGE plpgsql; - --- list queues -CREATE OR REPLACE pgmq."list_queues"() -RETURNS SETOF pgmq.queue_record AS $$ -BEGIN - RETURN QUERY SELECT * FROM pgmq.meta; -END -$$ LANGUAGE plpgsql; --- purge queue, deleting all entries in it. -CREATE OR REPLACE pgmq."purge_queue"(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; @@ -321,16 +281,16 @@ BEGIN END $$ LANGUAGE plpgsql; --- unassign archive, so it can be kept when a queue is deleted -CREATE OR REPLACE pgmq."detach_archive"(queue_name TEXT) + +CREATE OR REPLACE FUNCTION pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ BEGIN EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', 'a_' || queue_name); END $$ LANGUAGE plpgsql; --- pop a single message -CREATE OR REPLACE pgmq.pop(queue_name TEXT) + +CREATE OR REPLACE FUNCTION pgmq.pop(queue_name TEXT) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -357,8 +317,8 @@ BEGIN END; $$ LANGUAGE plpgsql; --- Sets vt of a message, returns it -CREATE OR REPLACE pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) + +CREATE OR REPLACE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -377,7 +337,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +CREATE OR REPLACE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) RETURNS BOOLEAN AS $$ BEGIN EXECUTE FORMAT( @@ -415,7 +375,7 @@ BEGIN ) THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%L' + DELETE FROM pgmq.meta WHERE queue_name = '%s' $QUERY$, queue_name ); @@ -424,7 +384,7 @@ BEGIN IF partitioned THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM public.part_config where parent_table = '%L' + DELETE FROM public.part_config where parent_table = '%s' $QUERY$, queue_name ); @@ -434,7 +394,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.validate_queue_name(queue_name TEXT) + +CREATE OR REPLACE FUNCTION pgmq.validate_queue_name(queue_name TEXT) RETURNS void AS $$ BEGIN IF length(queue_name) >= 48 THEN @@ -443,27 +404,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq._belongs_to_pgmq(table_name TEXT) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_depend - WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') - AND objid = ( - SELECT oid - FROM pg_class - WHERE relname = table_name - ) - ) INTO result; - RETURN result; -END; -$$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_non_partitioned(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.validate_queue_name(queue_name); @@ -529,7 +471,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_unlogged(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create_unlogged(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.validate_queue_name(queue_name); @@ -595,7 +537,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq._get_partition_col(partition_interval TEXT) +CREATE OR REPLACE FUNCTION pgmq._get_partition_col(partition_interval TEXT) RETURNS TEXT AS $$ DECLARE num INTEGER; @@ -610,24 +552,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq._ensure_pg_partman_installed() -RETURNS void AS $$ -DECLARE - extension_exists BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_extension - WHERE extname = 'pg_partman' - ) INTO extension_exists; - - IF NOT extension_exists THEN - RAISE EXCEPTION 'pg_partman is required for partitioned queues'; - END IF; -END; -$$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_partitioned( +CREATE OR REPLACE FUNCTION pgmq.create_partitioned( queue_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000' @@ -649,7 +575,7 @@ BEGIN enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%L) + ) PARTITION BY RANGE (%s) $QUERY$, 'q_' || queue_name, partition_col ); @@ -660,14 +586,14 @@ BEGIN EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); + SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); $QUERY$, 'q_' || queue_name, partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (Ls); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); $QUERY$, 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col ); @@ -676,7 +602,7 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%L', + retention = '%s', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' @@ -710,7 +636,7 @@ BEGIN archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%L); + ) PARTITION BY RANGE (%s); $QUERY$, 'a_' || queue_name, a_partition_col ); @@ -721,7 +647,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); + SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); $QUERY$, 'a_' || queue_name, a_partition_col, partition_interval ); @@ -730,7 +656,7 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%L', + retention = '%s', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' @@ -750,14 +676,14 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.create_non_partitioned(queue_name); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.convert_archive_partitioned(table_name TEXT, +CREATE OR REPLACE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000', leading_partition INT DEFAULT 10) diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 08b58e62..3608197d 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -316,7 +316,7 @@ BEGIN FROM pgmq.%I ) SELECT - '%I' as queue_name, + '%s' as queue_name, q_summary.queue_length, q_summary.newest_msg_age_sec, q_summary.oldest_msg_age_sec, @@ -324,7 +324,7 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - 'q_' || queue_name, 'q_' || queue_name | '_msg_id_seq', queue_name + 'q_' || queue_name, 'q_' || queue_name || '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; @@ -459,7 +459,7 @@ BEGIN ) THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%L' + DELETE FROM pgmq.meta WHERE queue_name = '%s' $QUERY$, queue_name ); @@ -468,7 +468,7 @@ BEGIN IF partitioned THEN EXECUTE FORMAT( $QUERY$ - DELETE FROM public.part_config where parent_table = '%L' + DELETE FROM public.part_config where parent_table = '%s' $QUERY$, queue_name ); @@ -693,7 +693,7 @@ BEGIN enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%L) + ) PARTITION BY RANGE (%s) $QUERY$, 'q_' || queue_name, partition_col ); @@ -704,14 +704,14 @@ BEGIN EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); + SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); $QUERY$, 'q_' || queue_name, partition_col, partition_interval ); EXECUTE FORMAT( $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (Ls); + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); $QUERY$, 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col ); @@ -720,7 +720,7 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%L', + retention = '%s', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' @@ -754,7 +754,7 @@ BEGIN archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, vt TIMESTAMP WITH TIME ZONE NOT NULL, message JSONB - ) PARTITION BY RANGE (%L); + ) PARTITION BY RANGE (%s); $QUERY$, 'a_' || queue_name, a_partition_col ); @@ -765,7 +765,7 @@ BEGIN EXECUTE FORMAT( $QUERY$ - SELECT public.create_parent('pgmq.%I', '%L', 'native', '%L'); + SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); $QUERY$, 'a_' || queue_name, a_partition_col, partition_interval ); @@ -774,7 +774,7 @@ BEGIN $QUERY$ UPDATE public.part_config SET - retention = '%L', + retention = '%s', retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' From 1fc96f37725db8129530de1eb40782782dca8dbb Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 15:41:13 -0500 Subject: [PATCH 05/14] Update pgmq-extension/sql/pgmq.sql Co-authored-by: David E. Wheeler <46604+theory@users.noreply.github.com> --- pgmq-extension/sql/pgmq.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 3608197d..d2dd8b15 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -778,7 +778,7 @@ BEGIN retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.&I'; + WHERE parent_table = 'pgmq.%I'; $QUERY$, retention_interval, 'a_' || queue_name ); From 016587b1b859d414d970f8e14d58a3cdacb3a9d1 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 15:51:09 -0500 Subject: [PATCH 06/14] get pgrx pg_config from info --- .github/workflows/extension_upgrade.yml | 11 ++++------- 1 file changed, 4 insertions(+), 7 deletions(-) diff --git a/.github/workflows/extension_upgrade.yml b/.github/workflows/extension_upgrade.yml index d59db8de..cb52ca33 100644 --- a/.github/workflows/extension_upgrade.yml +++ b/.github/workflows/extension_upgrade.yml @@ -46,15 +46,16 @@ jobs: - uses: ./.github/actions/pgx-init - name: Install dependencies run: sudo apt-get update && sudo apt-get install -y postgresql-server-dev-14 + - name: Set PG_CONFIG environment variable + run: echo "PG_CONFIG=$(cargo pgrx info pg-config pg16)" >> $GITHUB_ENV - name: Install pg_partman run: | git clone https://github.com/pgpartman/pg_partman.git && \ cd pg_partman && \ git checkout v4.7.4 && \ - sed -i 's|PG_CONFIG = pg_config|PG_CONFIG = ~/.pgrx/16.3/pgrx-install/bin/pg_config|' Makefile && \ + sed -i "s|PG_CONFIG = pg_config|PG_CONFIG = ${PG_CONFIG}|" Makefile && \ make && \ - make install && \ - ls -alh /home/runner/.pgrx/16.3/pgrx-install/share/postgresql/extension/pg_partman* + make install - name: Checkout old version (1.0.0) run: | git fetch --tags @@ -71,20 +72,16 @@ jobs: psql $DATABASE_URL -c "CREATE EXTENSION pgmq;" psql $DATABASE_URL -c "select * from pgmq.create('test_queue_1')" psql $DATABASE_URL -c "select * from pgmq.create_partitioned('test_partitioned_queue_1');" - ls -alh /home/runner/.pgrx/16.3/pgrx-install/share/postgresql/extension/pg_partman* - name: Checkout branch's version env: CI_BRANCH: ${{ steps.current-version.outputs.CI_BRANCH }} run: | git checkout $CI_BRANCH - name: Upgrade extension version - env: - PG_CONFIG: ~/.pgrx/16.3/pgrx-install/bin/pg_config run: | make clean make make install - ls -alh /home/runner/.pgrx/16.3/pgrx-install/share/postgresql/extension/pgmq* psql postgres://$USER:postgres@localhost:28816/pgmq -c "ALTER EXTENSION pgmq UPDATE;" - name: Run tests env: From 5aaac9ca5e3a6e8aed1bb450c3aef0e8e411f6ee Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 15:54:35 -0500 Subject: [PATCH 07/14] PERFORM over formatting --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 20 ++++++++------------ pgmq-extension/sql/pgmq.sql | 21 ++++++++------------- 2 files changed, 16 insertions(+), 25 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 1b25263e..9bf88b7c 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -584,12 +584,10 @@ BEGIN EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); - $QUERY$, - 'q_' || queue_name, partition_col, partition_interval - ); + PERFORM public.create_parent( + 'pgmq.' || quote_ident('q_' || queue_name), + partition_col, partition_interval + ); EXECUTE FORMAT( $QUERY$ @@ -645,12 +643,10 @@ BEGIN EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); - $QUERY$, - 'a_' || queue_name, a_partition_col, partition_interval - ); + PERFORM public.create_parent( + 'pgmq.' || quote_ident('a_' || queue_name), + partition_col, partition_interval + ); EXECUTE FORMAT( $QUERY$ diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index d2dd8b15..3fc4b577 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -702,12 +702,10 @@ BEGIN EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); END IF; - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); - $QUERY$, - 'q_' || queue_name, partition_col, partition_interval - ); + PERFORM public.create_parent( + 'pgmq.' || quote_ident('q_' || queue_name), + partition_col, partition_interval + ); EXECUTE FORMAT( $QUERY$ @@ -763,13 +761,10 @@ BEGIN EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); END IF; - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.%I', '%s', 'native', '%s'); - $QUERY$, - 'a_' || queue_name, a_partition_col, partition_interval - ); - + PERFORM public.create_parent( + 'pgmq.' || quote_ident('a_' || queue_name), + partition_col, partition_interval + ); EXECUTE FORMAT( $QUERY$ UPDATE public.part_config From 9bd902dfe4a597c2c698d818157cf8f763431856 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 16:05:55 -0500 Subject: [PATCH 08/14] partition col --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 12 ++++++------ pgmq-extension/sql/pgmq.sql | 13 +++++++------ 2 files changed, 13 insertions(+), 12 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 9bf88b7c..4ba6fe56 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -585,9 +585,9 @@ BEGIN END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('q_' || queue_name), - partition_col, partition_interval - ); + 'pgmq.' || quote_ident('q_' || queue_name), + partition_col, 'native', partition_interval + ); EXECUTE FORMAT( $QUERY$ @@ -644,9 +644,9 @@ BEGIN END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('a_' || queue_name), - partition_col, partition_interval - ); + 'pgmq.' || quote_ident('a_' || queue_name), + a_partition_col, 'native', partition_interval + ); EXECUTE FORMAT( $QUERY$ diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 3fc4b577..7679d43c 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -703,9 +703,9 @@ BEGIN END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('q_' || queue_name), - partition_col, partition_interval - ); + 'pgmq.' || quote_ident('q_' || queue_name), + partition_col, 'native', partition_interval + ); EXECUTE FORMAT( $QUERY$ @@ -762,9 +762,10 @@ BEGIN END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('a_' || queue_name), - partition_col, partition_interval - ); + 'pgmq.' || quote_ident('a_' || queue_name), + a_partition_col, 'native', partition_interval + ); + EXECUTE FORMAT( $QUERY$ UPDATE public.part_config From b961977d75d82c07a979fb929658ca51629556e6 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 16:14:38 -0500 Subject: [PATCH 09/14] fix typo --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 4ba6fe56..346bd2dc 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -656,7 +656,7 @@ BEGIN retention_keep_table = false, retention_keep_index = true, automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.&I'; + WHERE parent_table = 'pgmq.%I'; $QUERY$, retention_interval, 'a_' || queue_name ); From bb11a227ebe960cabdcc6bdbcbde8540b12145f0 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 17:51:06 -0500 Subject: [PATCH 10/14] update test and use helper format fn --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 237 ++++++++++++---------- pgmq-extension/sql/pgmq.sql | 140 ++++++++----- pgmq-extension/test/expected/base.out | 4 +- 3 files changed, 219 insertions(+), 162 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 346bd2dc..6ac94dbb 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -1,4 +1,15 @@ -CREATE OR REPLACE FUNCTION pgmq.read( +-- a helper to format table names to lowercase and in the pgmq schema +CREATE OR REPLACE FUNCTION pgmq.format_table_name(queue_name text, prefix text) + returns text + immutable + language sql +as $$ + select format('%I', lower(prefix || '_' || queue_name)) +$$; + +-- read +-- reads a number of messages from a queue, setting a visibility timeout on them +CREATE OR REPLACE pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER @@ -6,6 +17,7 @@ CREATE OR REPLACE FUNCTION pgmq.read( RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -26,14 +38,15 @@ BEGIN WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name, vt + qtable, qtable, vt ); RETURN QUERY EXECUTE sql USING qty; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.read_with_poll( +---- read_with_poll +---- reads a number of messages from a queue, setting a visibility timeout on them +CREATE OR REPLACE pgmq.read_with_poll( queue_name TEXT, vt INTEGER, qty INTEGER, @@ -45,6 +58,7 @@ DECLARE r pgmq.message_record; stop_at TIMESTAMP; sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; LOOP @@ -71,7 +85,7 @@ BEGIN WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name, vt + qtable, qtable, vt ); FOR r IN @@ -88,8 +102,10 @@ BEGIN END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.archive( +---- archive +---- removes a message from the queue, and sends it to the archive, where its +---- saved permanently. +CREATE OR REPLACE pgmq.archive( queue_name TEXT, msg_id BIGINT ) @@ -97,6 +113,8 @@ RETURNS BOOLEAN AS $$ DECLARE sql TEXT; result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN sql := FORMAT( $QUERY$ @@ -110,21 +128,25 @@ BEGIN FROM archived RETURNING msg_id; $QUERY$, - 'q_' || queue_name, 'a_' || queue_name + qtable, atable ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.archive( +---- archive +---- removes an array of message ids from the queue, and sends it to the archive, +---- where these messages will be saved permanently. +CREATE OR REPLACE pgmq.archive( queue_name TEXT, msg_ids BIGINT[] ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN sql := FORMAT( $QUERY$ @@ -138,14 +160,15 @@ BEGIN FROM archived RETURNING msg_id; $QUERY$, - 'q_' || queue_name, 'a_' || queue_name + qtable, atable ); RETURN QUERY EXECUTE sql USING msg_ids; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.delete( +---- delete +---- deletes a message id from the queue permanently +CREATE OR REPLACE pgmq.delete( queue_name TEXT, msg_id BIGINT ) @@ -153,6 +176,7 @@ RETURNS BOOLEAN AS $$ DECLARE sql TEXT; result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -160,21 +184,23 @@ BEGIN WHERE msg_id = $1 RETURNING msg_id $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.delete( +---- delete +---- deletes an array of message ids from the queue permanently +CREATE OR REPLACE pgmq.delete( queue_name TEXT, msg_ids BIGINT[] ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -182,20 +208,22 @@ BEGIN WHERE msg_id = ANY($1) RETURNING msg_id $QUERY$, - 'q_' || queue_name + qtable ); RETURN QUERY EXECUTE sql USING msg_ids; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.send( +-- send +-- sends a message to a queue, optionally with a delay +CREATE OR REPLACE pgmq.send( queue_name TEXT, msg JSONB, delay INTEGER DEFAULT 0 ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -203,20 +231,22 @@ BEGIN VALUES ((clock_timestamp() + interval '%s seconds'), $1) RETURNING msg_id; $QUERY$, - 'q_' || queue_name, delay + qtable, delay ); RETURN QUERY EXECUTE sql USING msg; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.send_batch( +-- send_batch +-- sends an array of list of messages to a queue, optionally with a delay +CREATE OR REPLACE pgmq.send_batch( queue_name TEXT, msgs JSONB[], delay INTEGER DEFAULT 0 ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -224,18 +254,19 @@ BEGIN SELECT clock_timestamp() + interval '%s seconds', unnest($1) RETURNING msg_id; $QUERY$, - 'q_' || queue_name, delay + qtable, delay ); RETURN QUERY EXECUTE sql USING msgs; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT) +-- get metrics for a single queue +CREATE OR REPLACE pgmq.metrics(queue_name TEXT) RETURNS pgmq.metrics_result AS $$ DECLARE result_row pgmq.metrics_result; query TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN query := FORMAT( $QUERY$ @@ -262,39 +293,43 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - 'q_' || queue_name, 'q_' || queue_name || '_msg_id_seq', queue_name + qtable, qtable || '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) +-- purge queue, deleting all entries in it. +CREATE OR REPLACE pgmq."purge_queue"(queue_name TEXT) RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN - EXECUTE format('DELETE FROM pgmq.%I', 'q_' || queue_name); + EXECUTE format('DELETE FROM pgmq.%I', qtable); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq."detach_archive"(queue_name TEXT) +-- unassign archive, so it can be kept when a queue is deleted +CREATE OR REPLACE pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ +DECLARE + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', 'a_' || queue_name); + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', atable); END $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.pop(queue_name TEXT) +-- pop a single message +CREATE OR REPLACE pgmq.pop(queue_name TEXT) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -311,18 +346,19 @@ BEGIN WHERE msg_id = (select msg_id from cte) RETURNING *; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name + qtable, qtable ); RETURN QUERY EXECUTE sql; END; $$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +-- Sets vt of a message, returns it +CREATE OR REPLACE pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -331,41 +367,44 @@ BEGIN WHERE msg_id = %s RETURNING *; $QUERY$, - 'q_' || queue_name, vt, msg_id + qtable, vt, msg_id ); RETURN QUERY EXECUTE sql; END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +CREATE OR REPLACE pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) RETURNS BOOLEAN AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN EXECUTE FORMAT( $QUERY$ ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( $QUERY$ ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - 'a_' || queue_name + atable ); EXECUTE FORMAT( $QUERY$ DROP TABLE IF EXISTS pgmq.%I $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( $QUERY$ DROP TABLE IF EXISTS pgmq.%I $QUERY$, - 'a_' || queue_name + atable ); IF EXISTS ( @@ -395,18 +434,11 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.validate_queue_name(queue_name TEXT) -RETURNS void AS $$ -BEGIN - IF length(queue_name) >= 48 THEN - RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; - END IF; -END; -$$ LANGUAGE plpgsql; - - -CREATE OR REPLACE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) +CREATE OR REPLACE pgmq.create_non_partitioned(queue_name TEXT) RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); @@ -420,7 +452,7 @@ BEGIN message JSONB ) $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( @@ -434,29 +466,29 @@ BEGIN message JSONB ); $QUERY$, - 'a_' || queue_name + atable ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - 'q_' || queue_name || '_vt_idx', 'q_' || queue_name + qtable || '_vt_idx', qtable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); EXECUTE FORMAT( @@ -471,11 +503,13 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.create_unlogged(queue_name TEXT) +CREATE OR REPLACE pgmq.create_unlogged(queue_name TEXT) RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); - EXECUTE FORMAT( $QUERY$ CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( @@ -486,7 +520,7 @@ BEGIN message JSONB ) $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( @@ -500,29 +534,29 @@ BEGIN message JSONB ); $QUERY$, - 'a_' || queue_name + atable ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - 'q_' || queue_name || '_vt_idx', 'q_' || queue_name + qtable || '_vt_idx', qtable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); EXECUTE FORMAT( @@ -537,23 +571,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq._get_partition_col(partition_interval TEXT) -RETURNS TEXT AS $$ -DECLARE - num INTEGER; -BEGIN - BEGIN - num := partition_interval::INTEGER; - RETURN 'msg_id'; - EXCEPTION - WHEN others THEN - RETURN 'enqueued_at'; - END; -END; -$$ LANGUAGE plpgsql; - -CREATE OR REPLACE FUNCTION pgmq.create_partitioned( +CREATE OR REPLACE pgmq.create_partitioned( queue_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000' @@ -562,6 +581,8 @@ RETURNS void AS $$ DECLARE partition_col TEXT; a_partition_col TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); PERFORM pgmq._ensure_pg_partman_installed(); @@ -577,15 +598,15 @@ BEGIN message JSONB ) PARTITION BY RANGE (%s) $QUERY$, - 'q_' || queue_name, partition_col + qtable, partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('q_' || queue_name), + 'pgmq.' || quote_ident(qtable), partition_col, 'native', partition_interval ); @@ -593,7 +614,7 @@ BEGIN $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); $QUERY$, - 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col + qtable || '_part_idx', qtable, partition_col ); EXECUTE FORMAT( @@ -606,7 +627,7 @@ BEGIN automatic_maintenance = 'on' WHERE parent_table = 'pgmq.q_%I'; $QUERY$, - retention_interval, 'q_' || queue_name + retention_interval, qtable ); EXECUTE FORMAT( @@ -636,15 +657,15 @@ BEGIN message JSONB ) PARTITION BY RANGE (%s); $QUERY$, - 'a_' || queue_name, a_partition_col + atable, a_partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('a_' || queue_name), + 'pgmq.' || quote_ident(atable), a_partition_col, 'native', partition_interval ); @@ -658,37 +679,37 @@ BEGIN automatic_maintenance = 'on' WHERE parent_table = 'pgmq.%I'; $QUERY$, - retention_interval, 'a_' || queue_name + retention_interval, atable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.create(queue_name TEXT) +CREATE OR REPLACE pgmq.create(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.create_non_partitioned(queue_name); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, +CREATE OR REPLACE pgmq.convert_archive_partitioned(table_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000', leading_partition INT DEFAULT 10) RETURNS void AS $$ DECLARE -a_table_name TEXT := 'a_' || table_name; -a_table_name_old TEXT := 'a_'|| table_name || '_old'; -qualified_a_table_name TEXT := format('%I.%I', 'pgmq', 'a_' || table_name); -qualified_a_table_name_old TEXT := format ('%I.%I', 'pgmq', 'a_' || table_name || '_old'); +a_table_name TEXT := pgmq.format_table_name(table_name, 'a'); +a_table_name_old TEXT := pgmq.format_table_name(table_name, 'a') || '_old'; +qualified_a_table_name TEXT := format('pgmq.%I', a_table_name); +qualified_a_table_name_old TEXT := format ('pgmq.%I', a_table_name_old || '_old'); BEGIN PERFORM c.relkind @@ -709,13 +730,13 @@ BEGIN AND c.relkind = 'r'; IF NOT FOUND THEN - RAISE NOTICE 'Table %s doesnot exists', a_table_name; + RAISE NOTICE 'Table %s does not exists', a_table_name; RETURN; END IF; EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; - EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', 'a_' || table_name, 'a_'|| table_name || '_old' ); + EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', a_table_name, a_table_name_old ); EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 7679d43c..b3fc8db6 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -39,6 +39,16 @@ CREATE TYPE pgmq.queue_record AS ( ------------------------------------------------------------ -- Functions ------------------------------------------------------------ + +-- a helper to format table names to lowercase and in the pgmq schema +CREATE FUNCTION pgmq.format_table_name(queue_name text, prefix text) + returns text + immutable + language sql +as $$ + select format('%I', lower(prefix || '_' || queue_name)) +$$; + -- read -- reads a number of messages from a queue, setting a visibility timeout on them CREATE FUNCTION pgmq.read( @@ -49,6 +59,7 @@ CREATE FUNCTION pgmq.read( RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -69,7 +80,7 @@ BEGIN WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name, vt + qtable, qtable, vt ); RETURN QUERY EXECUTE sql USING qty; END; @@ -89,6 +100,7 @@ DECLARE r pgmq.message_record; stop_at TIMESTAMP; sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; LOOP @@ -115,7 +127,7 @@ BEGIN WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name, vt + qtable, qtable, vt ); FOR r IN @@ -143,6 +155,8 @@ RETURNS BOOLEAN AS $$ DECLARE sql TEXT; result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN sql := FORMAT( $QUERY$ @@ -156,7 +170,7 @@ BEGIN FROM archived RETURNING msg_id; $QUERY$, - 'q_' || queue_name, 'a_' || queue_name + qtable, atable ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); @@ -173,6 +187,8 @@ CREATE FUNCTION pgmq.archive( RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN sql := FORMAT( $QUERY$ @@ -186,7 +202,7 @@ BEGIN FROM archived RETURNING msg_id; $QUERY$, - 'q_' || queue_name, 'a_' || queue_name + qtable, atable ); RETURN QUERY EXECUTE sql USING msg_ids; END; @@ -202,6 +218,7 @@ RETURNS BOOLEAN AS $$ DECLARE sql TEXT; result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -209,7 +226,7 @@ BEGIN WHERE msg_id = $1 RETURNING msg_id $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE sql USING msg_id INTO result; RETURN NOT (result IS NULL); @@ -225,6 +242,7 @@ CREATE FUNCTION pgmq.delete( RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -232,7 +250,7 @@ BEGIN WHERE msg_id = ANY($1) RETURNING msg_id $QUERY$, - 'q_' || queue_name + qtable ); RETURN QUERY EXECUTE sql USING msg_ids; END; @@ -247,6 +265,7 @@ CREATE FUNCTION pgmq.send( ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -254,7 +273,7 @@ BEGIN VALUES ((clock_timestamp() + interval '%s seconds'), $1) RETURNING msg_id; $QUERY$, - 'q_' || queue_name, delay + qtable, delay ); RETURN QUERY EXECUTE sql USING msg; END; @@ -269,6 +288,7 @@ CREATE FUNCTION pgmq.send_batch( ) RETURNS SETOF BIGINT AS $$ DECLARE sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -276,7 +296,7 @@ BEGIN SELECT clock_timestamp() + interval '%s seconds', unnest($1) RETURNING msg_id; $QUERY$, - 'q_' || queue_name, delay + qtable, delay ); RETURN QUERY EXECUTE sql USING msgs; END; @@ -298,6 +318,7 @@ RETURNS pgmq.metrics_result AS $$ DECLARE result_row pgmq.metrics_result; query TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN query := FORMAT( $QUERY$ @@ -324,7 +345,7 @@ BEGIN q_summary.scrape_time FROM q_summary, all_metrics $QUERY$, - 'q_' || queue_name, 'q_' || queue_name || '_msg_id_seq', queue_name + qtable, qtable || '_msg_id_seq', queue_name ); EXECUTE query INTO result_row; RETURN result_row; @@ -358,8 +379,9 @@ CREATE FUNCTION pgmq."purge_queue"(queue_name TEXT) RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN - EXECUTE format('DELETE FROM pgmq.%I', 'q_' || queue_name); + EXECUTE format('DELETE FROM pgmq.%I', qtable); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END @@ -368,8 +390,10 @@ $$ LANGUAGE plpgsql; -- unassign archive, so it can be kept when a queue is deleted CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ +DECLARE + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', 'a_' || queue_name); + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', atable); END $$ LANGUAGE plpgsql; @@ -379,6 +403,7 @@ RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -395,7 +420,7 @@ BEGIN WHERE msg_id = (select msg_id from cte) RETURNING *; $QUERY$, - 'q_' || queue_name, 'q_' || queue_name + qtable, qtable ); RETURN QUERY EXECUTE sql; END; @@ -407,6 +432,7 @@ RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); BEGIN sql := FORMAT( $QUERY$ @@ -415,7 +441,7 @@ BEGIN WHERE msg_id = %s RETURNING *; $QUERY$, - 'q_' || queue_name, vt, msg_id + qtable, vt, msg_id ); RETURN QUERY EXECUTE sql; END; @@ -423,33 +449,36 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) RETURNS BOOLEAN AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN EXECUTE FORMAT( $QUERY$ ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( $QUERY$ ALTER EXTENSION pgmq DROP TABLE pgmq.%I $QUERY$, - 'a_' || queue_name + atable ); EXECUTE FORMAT( $QUERY$ DROP TABLE IF EXISTS pgmq.%I $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( $QUERY$ DROP TABLE IF EXISTS pgmq.%I $QUERY$, - 'a_' || queue_name + atable ); IF EXISTS ( @@ -509,6 +538,9 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); @@ -522,7 +554,7 @@ BEGIN message JSONB ) $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( @@ -536,29 +568,29 @@ BEGIN message JSONB ); $QUERY$, - 'a_' || queue_name + atable ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - 'q_' || queue_name || '_vt_idx', 'q_' || queue_name + qtable || '_vt_idx', qtable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); EXECUTE FORMAT( @@ -575,9 +607,11 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION pgmq.create_unlogged(queue_name TEXT) RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); - EXECUTE FORMAT( $QUERY$ CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( @@ -588,7 +622,7 @@ BEGIN message JSONB ) $QUERY$, - 'q_' || queue_name + qtable ); EXECUTE FORMAT( @@ -602,29 +636,29 @@ BEGIN message JSONB ); $QUERY$, - 'a_' || queue_name + atable ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); $QUERY$, - 'q_' || queue_name || '_vt_idx', 'q_' || queue_name + qtable || '_vt_idx', qtable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); EXECUTE FORMAT( @@ -680,6 +714,8 @@ RETURNS void AS $$ DECLARE partition_col TEXT; a_partition_col TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); BEGIN PERFORM pgmq.validate_queue_name(queue_name); PERFORM pgmq._ensure_pg_partman_installed(); @@ -695,15 +731,15 @@ BEGIN message JSONB ) PARTITION BY RANGE (%s) $QUERY$, - 'q_' || queue_name, partition_col + qtable, partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'q_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'q_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('q_' || queue_name), + 'pgmq.' || quote_ident(qtable), partition_col, 'native', partition_interval ); @@ -711,7 +747,7 @@ BEGIN $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); $QUERY$, - 'q_' || queue_name || '_part_idx', 'q_' || queue_name, partition_col + qtable || '_part_idx', qtable, partition_col ); EXECUTE FORMAT( @@ -724,7 +760,7 @@ BEGIN automatic_maintenance = 'on' WHERE parent_table = 'pgmq.q_%I'; $QUERY$, - retention_interval, 'q_' || queue_name + retention_interval, qtable ); EXECUTE FORMAT( @@ -754,15 +790,15 @@ BEGIN message JSONB ) PARTITION BY RANGE (%s); $QUERY$, - 'a_' || queue_name, a_partition_col + atable, a_partition_col ); - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', 'a_' || queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', 'a_' || queue_name); + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); END IF; PERFORM public.create_parent( - 'pgmq.' || quote_ident('a_' || queue_name), + 'pgmq.' || quote_ident(atable), a_partition_col, 'native', partition_interval ); @@ -776,14 +812,14 @@ BEGIN automatic_maintenance = 'on' WHERE parent_table = 'pgmq.%I'; $QUERY$, - retention_interval, 'a_' || queue_name + retention_interval, atable ); EXECUTE FORMAT( $QUERY$ CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); $QUERY$, - 'archived_at_idx_' || queue_name, 'a_' || queue_name + 'archived_at_idx_' || queue_name, atable ); END; @@ -803,10 +839,10 @@ CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, leading_partition INT DEFAULT 10) RETURNS void AS $$ DECLARE -a_table_name TEXT := 'a_' || table_name; -a_table_name_old TEXT := 'a_'|| table_name || '_old'; -qualified_a_table_name TEXT := format('%I.%I', 'pgmq', 'a_' || table_name); -qualified_a_table_name_old TEXT := format ('%I.%I', 'pgmq', 'a_' || table_name || '_old'); +a_table_name TEXT := pgmq.format_table_name(table_name, 'a'); +a_table_name_old TEXT := pgmq.format_table_name(table_name, 'a') || '_old'; +qualified_a_table_name TEXT := format('pgmq.%I', a_table_name); +qualified_a_table_name_old TEXT := format ('pgmq.%I', a_table_name_old || '_old'); BEGIN PERFORM c.relkind @@ -833,7 +869,7 @@ BEGIN EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; - EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', 'a_' || table_name, 'a_'|| table_name || '_old' ); + EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', a_table_name, a_table_name_old ); EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; @@ -848,4 +884,4 @@ BEGIN infinite_time_partitions = true WHERE parent_table = qualified_a_table_name; END; -$$ LANGUAGE plpgsql; \ No newline at end of file +$$ LANGUAGE plpgsql; diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index d02fa564..161e92fe 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -28,7 +28,7 @@ SELECT pgmq.create(repeat('a', 48)); ERROR: queue name is too long, maximum length is 48 characters CONTEXT: PL/pgSQL function pgmq.validate_queue_name(text) line 4 at RAISE SQL statement "SELECT pgmq.validate_queue_name(queue_name)" -PL/pgSQL function pgmq.create_non_partitioned(text) line 3 at PERFORM +PL/pgSQL function pgmq.create_non_partitioned(text) line 6 at PERFORM SQL statement "SELECT pgmq.create_non_partitioned(queue_name)" PL/pgSQL function pgmq."create"(text) line 3 at PERFORM SELECT pgmq.create(repeat('a', 47)); @@ -465,7 +465,7 @@ SELECT * FROM pgmq.create_partitioned( ERROR: pg_partman is required for partitioned queues CONTEXT: PL/pgSQL function pgmq._ensure_pg_partman_installed() line 12 at RAISE SQL statement "SELECT pgmq._ensure_pg_partman_installed()" -PL/pgSQL function pgmq.create_partitioned(text,text,text) line 7 at PERFORM +PL/pgSQL function pgmq.create_partitioned(text,text,text) line 9 at PERFORM -- With the extension existing, the queue is created successfully CREATE EXTENSION pg_partman; SELECT * FROM pgmq.create_partitioned( From 1522edaa53d0d902eedba8359c9a8ab8344e5915 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 18:11:46 -0500 Subject: [PATCH 11/14] simplify fn --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 2 +- pgmq-extension/sql/pgmq.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 6ac94dbb..9b271c7b 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -4,7 +4,7 @@ CREATE OR REPLACE FUNCTION pgmq.format_table_name(queue_name text, prefix text) immutable language sql as $$ - select format('%I', lower(prefix || '_' || queue_name)) + select lower(prefix || '_' || queue_name) $$; -- read diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index b3fc8db6..44dda0b9 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -46,7 +46,7 @@ CREATE FUNCTION pgmq.format_table_name(queue_name text, prefix text) immutable language sql as $$ - select format('%I', lower(prefix || '_' || queue_name)) + select lower(prefix || '_' || queue_name) $$; -- read From e14b0dea3e120db41254a1a8540ea4743f12d271 Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 19:10:40 -0500 Subject: [PATCH 12/14] create or replace --- pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql | 38 +- pgmq-extension/sql/pgmq--1.4.0.sql | 855 +++++++++++++++++++++ pgmq-extension/sql/pgmq--1.4.1.sql | 887 ++++++++++++++++++++++ 3 files changed, 1761 insertions(+), 19 deletions(-) create mode 100644 pgmq-extension/sql/pgmq--1.4.0.sql create mode 100644 pgmq-extension/sql/pgmq--1.4.1.sql diff --git a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql index 9b271c7b..408de9bd 100644 --- a/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql +++ b/pgmq-extension/sql/pgmq--1.4.0--1.4.1.sql @@ -9,7 +9,7 @@ $$; -- read -- reads a number of messages from a queue, setting a visibility timeout on them -CREATE OR REPLACE pgmq.read( +CREATE OR REPLACE FUNCTION pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER @@ -46,7 +46,7 @@ $$ LANGUAGE plpgsql; ---- read_with_poll ---- reads a number of messages from a queue, setting a visibility timeout on them -CREATE OR REPLACE pgmq.read_with_poll( +CREATE OR REPLACE FUNCTION pgmq.read_with_poll( queue_name TEXT, vt INTEGER, qty INTEGER, @@ -105,7 +105,7 @@ $$ LANGUAGE plpgsql; ---- archive ---- removes a message from the queue, and sends it to the archive, where its ---- saved permanently. -CREATE OR REPLACE pgmq.archive( +CREATE OR REPLACE FUNCTION pgmq.archive( queue_name TEXT, msg_id BIGINT ) @@ -138,7 +138,7 @@ $$ LANGUAGE plpgsql; ---- archive ---- removes an array of message ids from the queue, and sends it to the archive, ---- where these messages will be saved permanently. -CREATE OR REPLACE pgmq.archive( +CREATE OR REPLACE FUNCTION pgmq.archive( queue_name TEXT, msg_ids BIGINT[] ) @@ -168,7 +168,7 @@ $$ LANGUAGE plpgsql; ---- delete ---- deletes a message id from the queue permanently -CREATE OR REPLACE pgmq.delete( +CREATE OR REPLACE FUNCTION pgmq.delete( queue_name TEXT, msg_id BIGINT ) @@ -193,7 +193,7 @@ $$ LANGUAGE plpgsql; ---- delete ---- deletes an array of message ids from the queue permanently -CREATE OR REPLACE pgmq.delete( +CREATE OR REPLACE FUNCTION pgmq.delete( queue_name TEXT, msg_ids BIGINT[] ) @@ -216,7 +216,7 @@ $$ LANGUAGE plpgsql; -- send -- sends a message to a queue, optionally with a delay -CREATE OR REPLACE pgmq.send( +CREATE OR REPLACE FUNCTION pgmq.send( queue_name TEXT, msg JSONB, delay INTEGER DEFAULT 0 @@ -239,7 +239,7 @@ $$ LANGUAGE plpgsql; -- send_batch -- sends an array of list of messages to a queue, optionally with a delay -CREATE OR REPLACE pgmq.send_batch( +CREATE OR REPLACE FUNCTION pgmq.send_batch( queue_name TEXT, msgs JSONB[], delay INTEGER DEFAULT 0 @@ -261,7 +261,7 @@ END; $$ LANGUAGE plpgsql; -- get metrics for a single queue -CREATE OR REPLACE pgmq.metrics(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT) RETURNS pgmq.metrics_result AS $$ DECLARE result_row pgmq.metrics_result; @@ -301,7 +301,7 @@ END; $$ LANGUAGE plpgsql; -- purge queue, deleting all entries in it. -CREATE OR REPLACE pgmq."purge_queue"(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) RETURNS BIGINT AS $$ DECLARE deleted_count INTEGER; @@ -314,7 +314,7 @@ END $$ LANGUAGE plpgsql; -- unassign archive, so it can be kept when a queue is deleted -CREATE OR REPLACE pgmq."detach_archive"(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq."detach_archive"(queue_name TEXT) RETURNS VOID AS $$ DECLARE atable TEXT := pgmq.format_table_name(queue_name, 'a'); @@ -324,7 +324,7 @@ END $$ LANGUAGE plpgsql; -- pop a single message -CREATE OR REPLACE pgmq.pop(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.pop(queue_name TEXT) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -353,7 +353,7 @@ END; $$ LANGUAGE plpgsql; -- Sets vt of a message, returns it -CREATE OR REPLACE pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +CREATE OR REPLACE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) RETURNS SETOF pgmq.message_record AS $$ DECLARE sql TEXT; @@ -373,7 +373,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +CREATE OR REPLACE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) RETURNS BOOLEAN AS $$ DECLARE qtable TEXT := pgmq.format_table_name(queue_name, 'q'); @@ -434,7 +434,7 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_non_partitioned(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) RETURNS void AS $$ DECLARE qtable TEXT := pgmq.format_table_name(queue_name, 'q'); @@ -503,7 +503,7 @@ BEGIN END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_unlogged(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create_unlogged(queue_name TEXT) RETURNS void AS $$ DECLARE qtable TEXT := pgmq.format_table_name(queue_name, 'q'); @@ -572,7 +572,7 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create_partitioned( +CREATE OR REPLACE FUNCTION pgmq.create_partitioned( queue_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000' @@ -693,14 +693,14 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.create(queue_name TEXT) +CREATE OR REPLACE FUNCTION pgmq.create(queue_name TEXT) RETURNS void AS $$ BEGIN PERFORM pgmq.create_non_partitioned(queue_name); END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE pgmq.convert_archive_partitioned(table_name TEXT, +CREATE OR REPLACE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, partition_interval TEXT DEFAULT '10000', retention_interval TEXT DEFAULT '100000', leading_partition INT DEFAULT 10) diff --git a/pgmq-extension/sql/pgmq--1.4.0.sql b/pgmq-extension/sql/pgmq--1.4.0.sql new file mode 100644 index 00000000..46d3cd8b --- /dev/null +++ b/pgmq-extension/sql/pgmq--1.4.0.sql @@ -0,0 +1,855 @@ +------------------------------------------------------------ +-- Schema, tables, records, privileges, indexes, etc +------------------------------------------------------------ +-- We don't need to create the `pgmq` schema because it is automatically +-- created by postgres due to being declared in extension control file + +-- Table where queues and metadata about them is stored +CREATE TABLE pgmq.meta ( + queue_name VARCHAR UNIQUE NOT NULL, + is_partitioned BOOLEAN NOT NULL, + is_unlogged BOOLEAN NOT NULL, + created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL +); + +-- Grant permission to pg_monitor to all tables and sequences +GRANT USAGE ON SCHEMA pgmq TO pg_monitor; +GRANT SELECT ON ALL TABLES IN SCHEMA pgmq TO pg_monitor; +GRANT SELECT ON ALL SEQUENCES IN SCHEMA pgmq TO pg_monitor; +ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON TABLES TO pg_monitor; +ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON SEQUENCES TO pg_monitor; + +-- This type has the shape of a message in a queue, and is often returned by +-- pgmq functions that return messages +CREATE TYPE pgmq.message_record AS ( + msg_id BIGINT, + read_ct INTEGER, + enqueued_at TIMESTAMP WITH TIME ZONE, + vt TIMESTAMP WITH TIME ZONE, + message JSONB +); + +CREATE TYPE pgmq.queue_record AS ( + queue_name VARCHAR, + is_partitioned BOOLEAN, + is_unlogged BOOLEAN, + created_at TIMESTAMP WITH TIME ZONE +); + +------------------------------------------------------------ +-- Functions +------------------------------------------------------------ +-- read +-- reads a number of messages from a queue, setting a visibility timeout on them +CREATE FUNCTION pgmq.read( + queue_name TEXT, + vt INTEGER, + qty INTEGER +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%s + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.q_%s m + SET + vt = clock_timestamp() + interval '%s seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + queue_name, queue_name, vt + ); + RETURN QUERY EXECUTE sql USING qty; +END; +$$ LANGUAGE plpgsql; + +---- read_with_poll +---- reads a number of messages from a queue, setting a visibility timeout on them +CREATE FUNCTION pgmq.read_with_poll( + queue_name TEXT, + vt INTEGER, + qty INTEGER, + max_poll_seconds INTEGER DEFAULT 5, + poll_interval_ms INTEGER DEFAULT 100 +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + r pgmq.message_record; + stop_at TIMESTAMP; + sql TEXT; +BEGIN + stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; + LOOP + IF (SELECT clock_timestamp() >= stop_at) THEN + RETURN; + END IF; + + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%s + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.q_%s m + SET + vt = clock_timestamp() + interval '%s seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + queue_name, queue_name, vt + ); + + FOR r IN + EXECUTE sql USING qty + LOOP + RETURN NEXT r; + END LOOP; + IF FOUND THEN + RETURN; + ELSE + PERFORM pg_sleep(poll_interval_ms / 1000); + END IF; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +---- archive +---- removes a message from the queue, and sends it to the archive, where its +---- saved permanently. +CREATE FUNCTION pgmq.archive( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.q_%s + WHERE msg_id = $1 + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + queue_name, queue_name + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + +---- archive +---- removes an array of message ids from the queue, and sends it to the archive, +---- where these messages will be saved permanently. +CREATE FUNCTION pgmq.archive( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.q_%s + WHERE msg_id = ANY($1) + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + queue_name, queue_name + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + +---- delete +---- deletes a message id from the queue permanently +CREATE FUNCTION pgmq.delete( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.q_%s + WHERE msg_id = $1 + RETURNING msg_id + $QUERY$, + queue_name + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + +---- delete +---- deletes an array of message ids from the queue permanently +CREATE FUNCTION pgmq.delete( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.q_%s + WHERE msg_id = ANY($1) + RETURNING msg_id + $QUERY$, + queue_name + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + +-- send +-- sends a message to a queue, optionally with a delay +CREATE FUNCTION pgmq.send( + queue_name TEXT, + msg JSONB, + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.q_%s (vt, message) + VALUES ((clock_timestamp() + interval '%s seconds'), $1) + RETURNING msg_id; + $QUERY$, + queue_name, delay + ); + RETURN QUERY EXECUTE sql USING msg; +END; +$$ LANGUAGE plpgsql; + +-- send_batch +-- sends an array of list of messages to a queue, optionally with a delay +CREATE FUNCTION pgmq.send_batch( + queue_name TEXT, + msgs JSONB[], + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.q_%s (vt, message) + SELECT clock_timestamp() + interval '%s seconds', unnest($1) + RETURNING msg_id; + $QUERY$, + queue_name, delay + ); + RETURN QUERY EXECUTE sql USING msgs; +END; +$$ LANGUAGE plpgsql; + +-- returned by pgmq.metrics() and pgmq.metrics_all +CREATE TYPE pgmq.metrics_result AS ( + queue_name text, + queue_length bigint, + newest_msg_age_sec int, + oldest_msg_age_sec int, + total_messages bigint, + scrape_time timestamp with time zone +); + +-- get metrics for a single queue +CREATE FUNCTION pgmq.metrics(queue_name TEXT) +RETURNS pgmq.metrics_result AS $$ +DECLARE + result_row pgmq.metrics_result; + query TEXT; +BEGIN + query := FORMAT( + $QUERY$ + WITH q_summary AS ( + SELECT + count(*) as queue_length, + EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, + EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, + NOW() as scrape_time + FROM pgmq.q_%s + ), + all_metrics AS ( + SELECT CASE + WHEN is_called THEN last_value ELSE 0 + END as total_messages + FROM pgmq.q_%s_msg_id_seq + ) + SELECT + '%s' as queue_name, + q_summary.queue_length, + q_summary.newest_msg_age_sec, + q_summary.oldest_msg_age_sec, + all_metrics.total_messages, + q_summary.scrape_time + FROM q_summary, all_metrics + $QUERY$, + queue_name, queue_name, queue_name + ); + EXECUTE query INTO result_row; + RETURN result_row; +END; +$$ LANGUAGE plpgsql; + +-- get metrics for all queues +CREATE FUNCTION pgmq."metrics_all"() +RETURNS SETOF pgmq.metrics_result AS $$ +DECLARE + row_name RECORD; + result_row pgmq.metrics_result; +BEGIN + FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP + result_row := pgmq.metrics(row_name.queue_name); + RETURN NEXT result_row; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +-- list queues +CREATE FUNCTION pgmq."list_queues"() +RETURNS SETOF pgmq.queue_record AS $$ +BEGIN + RETURN QUERY SELECT * FROM pgmq.meta; +END +$$ LANGUAGE plpgsql; + +-- purge queue, deleting all entries in it. +CREATE FUNCTION pgmq."purge_queue"(queue_name TEXT) +RETURNS BIGINT AS $$ +DECLARE + deleted_count INTEGER; +BEGIN + EXECUTE format('DELETE FROM pgmq.q_%s', queue_name); + GET DIAGNOSTICS deleted_count = ROW_COUNT; + RETURN deleted_count; +END +$$ LANGUAGE plpgsql; + +-- unassign archive, so it can be kept when a queue is deleted +CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) +RETURNS VOID AS $$ +BEGIN + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s', queue_name); +END +$$ LANGUAGE plpgsql; + +-- pop a single message +CREATE FUNCTION pgmq.pop(queue_name TEXT) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_%s + WHERE vt <= now() + ORDER BY msg_id ASC + LIMIT 1 + FOR UPDATE SKIP LOCKED + ) + DELETE from pgmq.q_%s + WHERE msg_id = (select msg_id from cte) + RETURNING *; + $QUERY$, + queue_name, queue_name + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + +-- Sets vt of a message, returns it +CREATE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; +BEGIN + sql := FORMAT( + $QUERY$ + UPDATE pgmq.q_%s + SET vt = (now() + interval '%s seconds') + WHERE msg_id = %s + RETURNING *; + $QUERY$, + queue_name, vt, msg_id + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +RETURNS BOOLEAN AS $$ +BEGIN + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.q_%s + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.q_%s + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.a_%s + $QUERY$, + queue_name + ); + + IF EXISTS ( + SELECT 1 + FROM information_schema.tables + WHERE table_name = 'meta' and table_schema = 'pgmq' + ) THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM pgmq.meta WHERE queue_name = '%s' + $QUERY$, + queue_name + ); + END IF; + + IF partitioned THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM public.part_config where parent_table = '%s' + $QUERY$, + queue_name + ); + END IF; + + RETURN TRUE; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.validate_queue_name(queue_name TEXT) +RETURNS void AS $$ +BEGIN + IF length(queue_name) >= 48 THEN + RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_depend + WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') + AND objid = ( + SELECT oid + FROM pg_class + WHERE relname = table_name + ) + ) INTO result; + RETURN result; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.q_%s ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + queue_name + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', false, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_unlogged(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + + EXECUTE FORMAT( + $QUERY$ + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%s ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + queue_name + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + $QUERY$, + queue_name, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', false, true) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._get_partition_col(partition_interval TEXT) +RETURNS TEXT AS $$ +DECLARE + num INTEGER; +BEGIN + BEGIN + num := partition_interval::INTEGER; + RETURN 'msg_id'; + EXCEPTION + WHEN others THEN + RETURN 'enqueued_at'; + END; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._ensure_pg_partman_installed() +RETURNS void AS $$ +DECLARE + extension_exists BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_extension + WHERE extname = 'pg_partman' + ) INTO extension_exists; + + IF NOT extension_exists THEN + RAISE EXCEPTION 'pg_partman is required for partitioned queues'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_partitioned( + queue_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000' +) +RETURNS void AS $$ +DECLARE + partition_col TEXT; + a_partition_col TEXT; +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + PERFORM pgmq._ensure_pg_partman_installed(); + SELECT pgmq._get_partition_col(partition_interval) INTO partition_col; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.q_%s ( + msg_id BIGINT GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%s) + $QUERY$, + queue_name, partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + SELECT public.create_parent('pgmq.q_%s', '%s', 'native', '%s'); + $QUERY$, + queue_name, partition_col, partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS q_%s_part_idx ON pgmq.q_%s (%s); + $QUERY$, + queue_name, queue_name, partition_col + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%s', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.q_%s'; + $QUERY$, + retention_interval, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', true, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); + + IF partition_col = 'enqueued_at' THEN + a_partition_col := 'archived_at'; + ELSE + a_partition_col := partition_col; + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.a_%s ( + msg_id BIGINT, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%s); + $QUERY$, + queue_name, a_partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); + END IF; + + EXECUTE FORMAT( + $QUERY$ + SELECT public.create_parent('pgmq.a_%s', '%s', 'native', '%s'); + $QUERY$, + queue_name, a_partition_col, partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%s', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.a_%s'; + $QUERY$, + retention_interval, queue_name + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); + $QUERY$, + queue_name, queue_name + ); + +END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION pgmq.create(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.create_non_partitioned(queue_name); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000', + leading_partition INT DEFAULT 10) +RETURNS void AS $$ +DECLARE +a_table_name TEXT := 'a_' || table_name; +a_table_name_old TEXT := 'a_'|| table_name || '_old'; +qualified_a_table_name TEXT := format('%I.%I', 'pgmq', 'a_' || table_name); +qualified_a_table_name_old TEXT := format ('%I.%I', 'pgmq', 'a_' || table_name || '_old'); +BEGIN + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'p'; + + IF FOUND THEN + RAISE NOTICE 'Table %s is already partitioned', a_table_name; + RETURN; + END IF; + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'r'; + + IF NOT FOUND THEN + RAISE NOTICE 'Table %s doesnot exists', a_table_name; + RETURN; + END IF; + + EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; + + EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', 'a_' || table_name, 'a_'|| table_name || '_old' ); + + EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; + EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; + + PERFORM create_parent(qualified_a_table_name, 'msg_id', 'native', partition_interval, + p_premake := leading_partition); + + UPDATE part_config + SET retention = retention_interval, + retention_keep_table = false, + retention_keep_index = false, + infinite_time_partitions = true + WHERE parent_table = qualified_a_table_name; +END; +$$ LANGUAGE plpgsql; diff --git a/pgmq-extension/sql/pgmq--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.1.sql new file mode 100644 index 00000000..44dda0b9 --- /dev/null +++ b/pgmq-extension/sql/pgmq--1.4.1.sql @@ -0,0 +1,887 @@ +------------------------------------------------------------ +-- Schema, tables, records, privileges, indexes, etc +------------------------------------------------------------ +-- We don't need to create the `pgmq` schema because it is automatically +-- created by postgres due to being declared in extension control file + +-- Table where queues and metadata about them is stored +CREATE TABLE pgmq.meta ( + queue_name VARCHAR UNIQUE NOT NULL, + is_partitioned BOOLEAN NOT NULL, + is_unlogged BOOLEAN NOT NULL, + created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL +); + +-- Grant permission to pg_monitor to all tables and sequences +GRANT USAGE ON SCHEMA pgmq TO pg_monitor; +GRANT SELECT ON ALL TABLES IN SCHEMA pgmq TO pg_monitor; +GRANT SELECT ON ALL SEQUENCES IN SCHEMA pgmq TO pg_monitor; +ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON TABLES TO pg_monitor; +ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON SEQUENCES TO pg_monitor; + +-- This type has the shape of a message in a queue, and is often returned by +-- pgmq functions that return messages +CREATE TYPE pgmq.message_record AS ( + msg_id BIGINT, + read_ct INTEGER, + enqueued_at TIMESTAMP WITH TIME ZONE, + vt TIMESTAMP WITH TIME ZONE, + message JSONB +); + +CREATE TYPE pgmq.queue_record AS ( + queue_name VARCHAR, + is_partitioned BOOLEAN, + is_unlogged BOOLEAN, + created_at TIMESTAMP WITH TIME ZONE +); + +------------------------------------------------------------ +-- Functions +------------------------------------------------------------ + +-- a helper to format table names to lowercase and in the pgmq schema +CREATE FUNCTION pgmq.format_table_name(queue_name text, prefix text) + returns text + immutable + language sql +as $$ + select lower(prefix || '_' || queue_name) +$$; + +-- read +-- reads a number of messages from a queue, setting a visibility timeout on them +CREATE FUNCTION pgmq.read( + queue_name TEXT, + vt INTEGER, + qty INTEGER +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.%I + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.%I m + SET + vt = clock_timestamp() + interval '%s seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + qtable, qtable, vt + ); + RETURN QUERY EXECUTE sql USING qty; +END; +$$ LANGUAGE plpgsql; + +---- read_with_poll +---- reads a number of messages from a queue, setting a visibility timeout on them +CREATE FUNCTION pgmq.read_with_poll( + queue_name TEXT, + vt INTEGER, + qty INTEGER, + max_poll_seconds INTEGER DEFAULT 5, + poll_interval_ms INTEGER DEFAULT 100 +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + r pgmq.message_record; + stop_at TIMESTAMP; + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; + LOOP + IF (SELECT clock_timestamp() >= stop_at) THEN + RETURN; + END IF; + + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.%I + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.%I m + SET + vt = clock_timestamp() + interval '%s seconds', + read_ct = read_ct + 1 + FROM cte + WHERE m.msg_id = cte.msg_id + RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; + $QUERY$, + qtable, qtable, vt + ); + + FOR r IN + EXECUTE sql USING qty + LOOP + RETURN NEXT r; + END LOOP; + IF FOUND THEN + RETURN; + ELSE + PERFORM pg_sleep(poll_interval_ms / 1000); + END IF; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +---- archive +---- removes a message from the queue, and sends it to the archive, where its +---- saved permanently. +CREATE FUNCTION pgmq.archive( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.%I + WHERE msg_id = $1 + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + qtable, atable + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + +---- archive +---- removes an array of message ids from the queue, and sends it to the archive, +---- where these messages will be saved permanently. +CREATE FUNCTION pgmq.archive( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + sql := FORMAT( + $QUERY$ + WITH archived AS ( + DELETE FROM pgmq.%I + WHERE msg_id = ANY($1) + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + $QUERY$, + qtable, atable + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + +---- delete +---- deletes a message id from the queue permanently +CREATE FUNCTION pgmq.delete( + queue_name TEXT, + msg_id BIGINT +) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BIGINT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.%I + WHERE msg_id = $1 + RETURNING msg_id + $QUERY$, + qtable + ); + EXECUTE sql USING msg_id INTO result; + RETURN NOT (result IS NULL); +END; +$$ LANGUAGE plpgsql; + +---- delete +---- deletes an array of message ids from the queue permanently +CREATE FUNCTION pgmq.delete( + queue_name TEXT, + msg_ids BIGINT[] +) +RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + DELETE FROM pgmq.%I + WHERE msg_id = ANY($1) + RETURNING msg_id + $QUERY$, + qtable + ); + RETURN QUERY EXECUTE sql USING msg_ids; +END; +$$ LANGUAGE plpgsql; + +-- send +-- sends a message to a queue, optionally with a delay +CREATE FUNCTION pgmq.send( + queue_name TEXT, + msg JSONB, + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.%I (vt, message) + VALUES ((clock_timestamp() + interval '%s seconds'), $1) + RETURNING msg_id; + $QUERY$, + qtable, delay + ); + RETURN QUERY EXECUTE sql USING msg; +END; +$$ LANGUAGE plpgsql; + +-- send_batch +-- sends an array of list of messages to a queue, optionally with a delay +CREATE FUNCTION pgmq.send_batch( + queue_name TEXT, + msgs JSONB[], + delay INTEGER DEFAULT 0 +) RETURNS SETOF BIGINT AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + INSERT INTO pgmq.%I (vt, message) + SELECT clock_timestamp() + interval '%s seconds', unnest($1) + RETURNING msg_id; + $QUERY$, + qtable, delay + ); + RETURN QUERY EXECUTE sql USING msgs; +END; +$$ LANGUAGE plpgsql; + +-- returned by pgmq.metrics() and pgmq.metrics_all +CREATE TYPE pgmq.metrics_result AS ( + queue_name text, + queue_length bigint, + newest_msg_age_sec int, + oldest_msg_age_sec int, + total_messages bigint, + scrape_time timestamp with time zone +); + +-- get metrics for a single queue +CREATE FUNCTION pgmq.metrics(queue_name TEXT) +RETURNS pgmq.metrics_result AS $$ +DECLARE + result_row pgmq.metrics_result; + query TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + query := FORMAT( + $QUERY$ + WITH q_summary AS ( + SELECT + count(*) as queue_length, + EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, + EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, + NOW() as scrape_time + FROM pgmq.%I + ), + all_metrics AS ( + SELECT CASE + WHEN is_called THEN last_value ELSE 0 + END as total_messages + FROM pgmq.%I + ) + SELECT + '%s' as queue_name, + q_summary.queue_length, + q_summary.newest_msg_age_sec, + q_summary.oldest_msg_age_sec, + all_metrics.total_messages, + q_summary.scrape_time + FROM q_summary, all_metrics + $QUERY$, + qtable, qtable || '_msg_id_seq', queue_name + ); + EXECUTE query INTO result_row; + RETURN result_row; +END; +$$ LANGUAGE plpgsql; + +-- get metrics for all queues +CREATE FUNCTION pgmq."metrics_all"() +RETURNS SETOF pgmq.metrics_result AS $$ +DECLARE + row_name RECORD; + result_row pgmq.metrics_result; +BEGIN + FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP + result_row := pgmq.metrics(row_name.queue_name); + RETURN NEXT result_row; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +-- list queues +CREATE FUNCTION pgmq."list_queues"() +RETURNS SETOF pgmq.queue_record AS $$ +BEGIN + RETURN QUERY SELECT * FROM pgmq.meta; +END +$$ LANGUAGE plpgsql; + +-- purge queue, deleting all entries in it. +CREATE FUNCTION pgmq."purge_queue"(queue_name TEXT) +RETURNS BIGINT AS $$ +DECLARE + deleted_count INTEGER; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + EXECUTE format('DELETE FROM pgmq.%I', qtable); + GET DIAGNOSTICS deleted_count = ROW_COUNT; + RETURN deleted_count; +END +$$ LANGUAGE plpgsql; + +-- unassign archive, so it can be kept when a queue is deleted +CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) +RETURNS VOID AS $$ +DECLARE + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', atable); +END +$$ LANGUAGE plpgsql; + +-- pop a single message +CREATE FUNCTION pgmq.pop(queue_name TEXT) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + WITH cte AS + ( + SELECT msg_id + FROM pgmq.%I + WHERE vt <= now() + ORDER BY msg_id ASC + LIMIT 1 + FOR UPDATE SKIP LOCKED + ) + DELETE from pgmq.%I + WHERE msg_id = (select msg_id from cte) + RETURNING *; + $QUERY$, + qtable, qtable + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + +-- Sets vt of a message, returns it +CREATE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + result pgmq.message_record; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + sql := FORMAT( + $QUERY$ + UPDATE pgmq.%I + SET vt = (now() + interval '%s seconds') + WHERE msg_id = %s + RETURNING *; + $QUERY$, + qtable, vt, msg_id + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) +RETURNS BOOLEAN AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.%I + $QUERY$, + qtable + ); + + EXECUTE FORMAT( + $QUERY$ + ALTER EXTENSION pgmq DROP TABLE pgmq.%I + $QUERY$, + atable + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.%I + $QUERY$, + qtable + ); + + EXECUTE FORMAT( + $QUERY$ + DROP TABLE IF EXISTS pgmq.%I + $QUERY$, + atable + ); + + IF EXISTS ( + SELECT 1 + FROM information_schema.tables + WHERE table_name = 'meta' and table_schema = 'pgmq' + ) THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM pgmq.meta WHERE queue_name = '%s' + $QUERY$, + queue_name + ); + END IF; + + IF partitioned THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM public.part_config where parent_table = '%s' + $QUERY$, + queue_name + ); + END IF; + + RETURN TRUE; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.validate_queue_name(queue_name TEXT) +RETURNS void AS $$ +BEGIN + IF length(queue_name) >= 48 THEN + RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) +RETURNS BOOLEAN AS $$ +DECLARE + sql TEXT; + result BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_depend + WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') + AND objid = ( + SELECT oid + FROM pg_class + WHERE relname = table_name + ) + ) INTO result; + RETURN result; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) +RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + qtable + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + atable + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); + $QUERY$, + qtable || '_vt_idx', qtable + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); + $QUERY$, + 'archived_at_idx_' || queue_name, atable + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', false, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_unlogged(queue_name TEXT) +RETURNS void AS $$ +DECLARE + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + EXECUTE FORMAT( + $QUERY$ + CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) + $QUERY$, + qtable + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT PRIMARY KEY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ); + $QUERY$, + atable + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); + $QUERY$, + qtable || '_vt_idx', qtable + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); + $QUERY$, + 'archived_at_idx_' || queue_name, atable + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', false, true) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._get_partition_col(partition_interval TEXT) +RETURNS TEXT AS $$ +DECLARE + num INTEGER; +BEGIN + BEGIN + num := partition_interval::INTEGER; + RETURN 'msg_id'; + EXCEPTION + WHEN others THEN + RETURN 'enqueued_at'; + END; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._ensure_pg_partman_installed() +RETURNS void AS $$ +DECLARE + extension_exists BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT 1 + FROM pg_extension + WHERE extname = 'pg_partman' + ) INTO extension_exists; + + IF NOT extension_exists THEN + RAISE EXCEPTION 'pg_partman is required for partitioned queues'; + END IF; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.create_partitioned( + queue_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000' +) +RETURNS void AS $$ +DECLARE + partition_col TEXT; + a_partition_col TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); + atable TEXT := pgmq.format_table_name(queue_name, 'a'); +BEGIN + PERFORM pgmq.validate_queue_name(queue_name); + PERFORM pgmq._ensure_pg_partman_installed(); + SELECT pgmq._get_partition_col(partition_interval) INTO partition_col; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT GENERATED ALWAYS AS IDENTITY, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%s) + $QUERY$, + qtable, partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + PERFORM public.create_parent( + 'pgmq.' || quote_ident(qtable), + partition_col, 'native', partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); + $QUERY$, + qtable || '_part_idx', qtable, partition_col + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%s', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.q_%I'; + $QUERY$, + retention_interval, qtable + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES ('%s', true, false) + ON CONFLICT + DO NOTHING; + $QUERY$, + queue_name + ); + + IF partition_col = 'enqueued_at' THEN + a_partition_col := 'archived_at'; + ELSE + a_partition_col := partition_col; + END IF; + + EXECUTE FORMAT( + $QUERY$ + CREATE TABLE IF NOT EXISTS pgmq.%I ( + msg_id BIGINT, + read_ct INT DEFAULT 0 NOT NULL, + enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, + vt TIMESTAMP WITH TIME ZONE NOT NULL, + message JSONB + ) PARTITION BY RANGE (%s); + $QUERY$, + atable, a_partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); + END IF; + + PERFORM public.create_parent( + 'pgmq.' || quote_ident(atable), + a_partition_col, 'native', partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE public.part_config + SET + retention = '%s', + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = 'pgmq.%I'; + $QUERY$, + retention_interval, atable + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); + $QUERY$, + 'archived_at_idx_' || queue_name, atable + ); + +END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION pgmq.create(queue_name TEXT) +RETURNS void AS $$ +BEGIN + PERFORM pgmq.create_non_partitioned(queue_name); +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, + partition_interval TEXT DEFAULT '10000', + retention_interval TEXT DEFAULT '100000', + leading_partition INT DEFAULT 10) +RETURNS void AS $$ +DECLARE +a_table_name TEXT := pgmq.format_table_name(table_name, 'a'); +a_table_name_old TEXT := pgmq.format_table_name(table_name, 'a') || '_old'; +qualified_a_table_name TEXT := format('pgmq.%I', a_table_name); +qualified_a_table_name_old TEXT := format ('pgmq.%I', a_table_name_old || '_old'); +BEGIN + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'p'; + + IF FOUND THEN + RAISE NOTICE 'Table %s is already partitioned', a_table_name; + RETURN; + END IF; + + PERFORM c.relkind + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = a_table_name + AND c.relkind = 'r'; + + IF NOT FOUND THEN + RAISE NOTICE 'Table %s doesnot exists', a_table_name; + RETURN; + END IF; + + EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; + + EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', a_table_name, a_table_name_old ); + + EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; + EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; + + PERFORM create_parent(qualified_a_table_name, 'msg_id', 'native', partition_interval, + p_premake := leading_partition); + + UPDATE part_config + SET retention = retention_interval, + retention_keep_table = false, + retention_keep_index = false, + infinite_time_partitions = true + WHERE parent_table = qualified_a_table_name; +END; +$$ LANGUAGE plpgsql; From 609c475644c74b69ca123bd77fb985312ccd9aac Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 19:10:51 -0500 Subject: [PATCH 13/14] add test case --- pgmq-extension/test/expected/base.out | 31 +++++++++++++++++++++++++++ pgmq-extension/test/sql/base.sql | 11 ++++++++++ 2 files changed, 42 insertions(+) diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index 161e92fe..7db43f15 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -617,4 +617,35 @@ SELECT pgmq.convert_archive_partitioned('long_queue_name_'); (1 row) +--Failed SQL injection attack +SELECT pgmq.create('abc'); + create +-------- + +(1 row) + +SELECT + pgmq.delete( + 'abc where false; + create table public.attack_vector(id int); -- Any SQL can be placed here + delete from pgmq.q_abc', + 1 + ); +NOTICE: identifier "q_abc where false; + create table public.attack_vector(id int); -- any sql can be placed here + delete from pgmq.q_abc" will be truncated to "q_abc where false; + create table public.attack_vector(id in" +ERROR: relation "pgmq.q_abc where false; + create table public.attack_vector(id in" does not exist +LINE 2: DELETE FROM pgmq."q_abc where false; + ^ +QUERY: + DELETE FROM pgmq."q_abc where false; + create table public.attack_vector(id int); -- any sql can be placed here + delete from pgmq.q_abc" + WHERE msg_id = $1 + RETURNING msg_id + +CONTEXT: PL/pgSQL function pgmq.delete(text,bigint) line 15 at EXECUTE +--Cleanup tests DROP EXTENSION pgmq CASCADE; diff --git a/pgmq-extension/test/sql/base.sql b/pgmq-extension/test/sql/base.sql index f5d38398..f6756853 100644 --- a/pgmq-extension/test/sql/base.sql +++ b/pgmq-extension/test/sql/base.sql @@ -253,4 +253,15 @@ SELECT pgmq.convert_archive_partitioned('long_queue_name_12345678901234567890123 SELECT pgmq.create('long_queue_name_'); SELECT pgmq.convert_archive_partitioned('long_queue_name_'); +--Failed SQL injection attack +SELECT pgmq.create('abc'); +SELECT + pgmq.delete( + 'abc where false; + create table public.attack_vector(id int); -- Any SQL can be placed here + delete from pgmq.q_abc', + 1 + ); + +--Cleanup tests DROP EXTENSION pgmq CASCADE; From 4bdfe1b72548a714e940fda63b29ce7e6c3ed2bc Mon Sep 17 00:00:00 2001 From: Adam Hendel Date: Wed, 14 Aug 2024 21:45:31 -0500 Subject: [PATCH 14/14] remove built sql --- pgmq-extension/sql/pgmq--1.4.0.sql | 855 --------------------------- pgmq-extension/sql/pgmq--1.4.1.sql | 887 ----------------------------- 2 files changed, 1742 deletions(-) delete mode 100644 pgmq-extension/sql/pgmq--1.4.0.sql delete mode 100644 pgmq-extension/sql/pgmq--1.4.1.sql diff --git a/pgmq-extension/sql/pgmq--1.4.0.sql b/pgmq-extension/sql/pgmq--1.4.0.sql deleted file mode 100644 index 46d3cd8b..00000000 --- a/pgmq-extension/sql/pgmq--1.4.0.sql +++ /dev/null @@ -1,855 +0,0 @@ ------------------------------------------------------------- --- Schema, tables, records, privileges, indexes, etc ------------------------------------------------------------- --- We don't need to create the `pgmq` schema because it is automatically --- created by postgres due to being declared in extension control file - --- Table where queues and metadata about them is stored -CREATE TABLE pgmq.meta ( - queue_name VARCHAR UNIQUE NOT NULL, - is_partitioned BOOLEAN NOT NULL, - is_unlogged BOOLEAN NOT NULL, - created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL -); - --- Grant permission to pg_monitor to all tables and sequences -GRANT USAGE ON SCHEMA pgmq TO pg_monitor; -GRANT SELECT ON ALL TABLES IN SCHEMA pgmq TO pg_monitor; -GRANT SELECT ON ALL SEQUENCES IN SCHEMA pgmq TO pg_monitor; -ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON TABLES TO pg_monitor; -ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON SEQUENCES TO pg_monitor; - --- This type has the shape of a message in a queue, and is often returned by --- pgmq functions that return messages -CREATE TYPE pgmq.message_record AS ( - msg_id BIGINT, - read_ct INTEGER, - enqueued_at TIMESTAMP WITH TIME ZONE, - vt TIMESTAMP WITH TIME ZONE, - message JSONB -); - -CREATE TYPE pgmq.queue_record AS ( - queue_name VARCHAR, - is_partitioned BOOLEAN, - is_unlogged BOOLEAN, - created_at TIMESTAMP WITH TIME ZONE -); - ------------------------------------------------------------- --- Functions ------------------------------------------------------------- --- read --- reads a number of messages from a queue, setting a visibility timeout on them -CREATE FUNCTION pgmq.read( - queue_name TEXT, - vt INTEGER, - qty INTEGER -) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; -BEGIN - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.q_%s - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq.q_%s m - SET - vt = clock_timestamp() + interval '%s seconds', - read_ct = read_ct + 1 - FROM cte - WHERE m.msg_id = cte.msg_id - RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; - $QUERY$, - queue_name, queue_name, vt - ); - RETURN QUERY EXECUTE sql USING qty; -END; -$$ LANGUAGE plpgsql; - ----- read_with_poll ----- reads a number of messages from a queue, setting a visibility timeout on them -CREATE FUNCTION pgmq.read_with_poll( - queue_name TEXT, - vt INTEGER, - qty INTEGER, - max_poll_seconds INTEGER DEFAULT 5, - poll_interval_ms INTEGER DEFAULT 100 -) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - r pgmq.message_record; - stop_at TIMESTAMP; - sql TEXT; -BEGIN - stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; - LOOP - IF (SELECT clock_timestamp() >= stop_at) THEN - RETURN; - END IF; - - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.q_%s - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq.q_%s m - SET - vt = clock_timestamp() + interval '%s seconds', - read_ct = read_ct + 1 - FROM cte - WHERE m.msg_id = cte.msg_id - RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; - $QUERY$, - queue_name, queue_name, vt - ); - - FOR r IN - EXECUTE sql USING qty - LOOP - RETURN NEXT r; - END LOOP; - IF FOUND THEN - RETURN; - ELSE - PERFORM pg_sleep(poll_interval_ms / 1000); - END IF; - END LOOP; -END; -$$ LANGUAGE plpgsql; - ----- archive ----- removes a message from the queue, and sends it to the archive, where its ----- saved permanently. -CREATE FUNCTION pgmq.archive( - queue_name TEXT, - msg_id BIGINT -) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BIGINT; -BEGIN - sql := FORMAT( - $QUERY$ - WITH archived AS ( - DELETE FROM pgmq.q_%s - WHERE msg_id = $1 - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - $QUERY$, - queue_name, queue_name - ); - EXECUTE sql USING msg_id INTO result; - RETURN NOT (result IS NULL); -END; -$$ LANGUAGE plpgsql; - ----- archive ----- removes an array of message ids from the queue, and sends it to the archive, ----- where these messages will be saved permanently. -CREATE FUNCTION pgmq.archive( - queue_name TEXT, - msg_ids BIGINT[] -) -RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; -BEGIN - sql := FORMAT( - $QUERY$ - WITH archived AS ( - DELETE FROM pgmq.q_%s - WHERE msg_id = ANY($1) - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - $QUERY$, - queue_name, queue_name - ); - RETURN QUERY EXECUTE sql USING msg_ids; -END; -$$ LANGUAGE plpgsql; - ----- delete ----- deletes a message id from the queue permanently -CREATE FUNCTION pgmq.delete( - queue_name TEXT, - msg_id BIGINT -) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BIGINT; -BEGIN - sql := FORMAT( - $QUERY$ - DELETE FROM pgmq.q_%s - WHERE msg_id = $1 - RETURNING msg_id - $QUERY$, - queue_name - ); - EXECUTE sql USING msg_id INTO result; - RETURN NOT (result IS NULL); -END; -$$ LANGUAGE plpgsql; - ----- delete ----- deletes an array of message ids from the queue permanently -CREATE FUNCTION pgmq.delete( - queue_name TEXT, - msg_ids BIGINT[] -) -RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; -BEGIN - sql := FORMAT( - $QUERY$ - DELETE FROM pgmq.q_%s - WHERE msg_id = ANY($1) - RETURNING msg_id - $QUERY$, - queue_name - ); - RETURN QUERY EXECUTE sql USING msg_ids; -END; -$$ LANGUAGE plpgsql; - --- send --- sends a message to a queue, optionally with a delay -CREATE FUNCTION pgmq.send( - queue_name TEXT, - msg JSONB, - delay INTEGER DEFAULT 0 -) RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; -BEGIN - sql := FORMAT( - $QUERY$ - INSERT INTO pgmq.q_%s (vt, message) - VALUES ((clock_timestamp() + interval '%s seconds'), $1) - RETURNING msg_id; - $QUERY$, - queue_name, delay - ); - RETURN QUERY EXECUTE sql USING msg; -END; -$$ LANGUAGE plpgsql; - --- send_batch --- sends an array of list of messages to a queue, optionally with a delay -CREATE FUNCTION pgmq.send_batch( - queue_name TEXT, - msgs JSONB[], - delay INTEGER DEFAULT 0 -) RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; -BEGIN - sql := FORMAT( - $QUERY$ - INSERT INTO pgmq.q_%s (vt, message) - SELECT clock_timestamp() + interval '%s seconds', unnest($1) - RETURNING msg_id; - $QUERY$, - queue_name, delay - ); - RETURN QUERY EXECUTE sql USING msgs; -END; -$$ LANGUAGE plpgsql; - --- returned by pgmq.metrics() and pgmq.metrics_all -CREATE TYPE pgmq.metrics_result AS ( - queue_name text, - queue_length bigint, - newest_msg_age_sec int, - oldest_msg_age_sec int, - total_messages bigint, - scrape_time timestamp with time zone -); - --- get metrics for a single queue -CREATE FUNCTION pgmq.metrics(queue_name TEXT) -RETURNS pgmq.metrics_result AS $$ -DECLARE - result_row pgmq.metrics_result; - query TEXT; -BEGIN - query := FORMAT( - $QUERY$ - WITH q_summary AS ( - SELECT - count(*) as queue_length, - EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, - EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, - NOW() as scrape_time - FROM pgmq.q_%s - ), - all_metrics AS ( - SELECT CASE - WHEN is_called THEN last_value ELSE 0 - END as total_messages - FROM pgmq.q_%s_msg_id_seq - ) - SELECT - '%s' as queue_name, - q_summary.queue_length, - q_summary.newest_msg_age_sec, - q_summary.oldest_msg_age_sec, - all_metrics.total_messages, - q_summary.scrape_time - FROM q_summary, all_metrics - $QUERY$, - queue_name, queue_name, queue_name - ); - EXECUTE query INTO result_row; - RETURN result_row; -END; -$$ LANGUAGE plpgsql; - --- get metrics for all queues -CREATE FUNCTION pgmq."metrics_all"() -RETURNS SETOF pgmq.metrics_result AS $$ -DECLARE - row_name RECORD; - result_row pgmq.metrics_result; -BEGIN - FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP - result_row := pgmq.metrics(row_name.queue_name); - RETURN NEXT result_row; - END LOOP; -END; -$$ LANGUAGE plpgsql; - --- list queues -CREATE FUNCTION pgmq."list_queues"() -RETURNS SETOF pgmq.queue_record AS $$ -BEGIN - RETURN QUERY SELECT * FROM pgmq.meta; -END -$$ LANGUAGE plpgsql; - --- purge queue, deleting all entries in it. -CREATE FUNCTION pgmq."purge_queue"(queue_name TEXT) -RETURNS BIGINT AS $$ -DECLARE - deleted_count INTEGER; -BEGIN - EXECUTE format('DELETE FROM pgmq.q_%s', queue_name); - GET DIAGNOSTICS deleted_count = ROW_COUNT; - RETURN deleted_count; -END -$$ LANGUAGE plpgsql; - --- unassign archive, so it can be kept when a queue is deleted -CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) -RETURNS VOID AS $$ -BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s', queue_name); -END -$$ LANGUAGE plpgsql; - --- pop a single message -CREATE FUNCTION pgmq.pop(queue_name TEXT) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; - result pgmq.message_record; -BEGIN - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.q_%s - WHERE vt <= now() - ORDER BY msg_id ASC - LIMIT 1 - FOR UPDATE SKIP LOCKED - ) - DELETE from pgmq.q_%s - WHERE msg_id = (select msg_id from cte) - RETURNING *; - $QUERY$, - queue_name, queue_name - ); - RETURN QUERY EXECUTE sql; -END; -$$ LANGUAGE plpgsql; - --- Sets vt of a message, returns it -CREATE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; - result pgmq.message_record; -BEGIN - sql := FORMAT( - $QUERY$ - UPDATE pgmq.q_%s - SET vt = (now() + interval '%s seconds') - WHERE msg_id = %s - RETURNING *; - $QUERY$, - queue_name, vt, msg_id - ); - RETURN QUERY EXECUTE sql; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) -RETURNS BOOLEAN AS $$ -BEGIN - EXECUTE FORMAT( - $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.q_%s - $QUERY$, - queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.a_%s - $QUERY$, - queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - DROP TABLE IF EXISTS pgmq.q_%s - $QUERY$, - queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - DROP TABLE IF EXISTS pgmq.a_%s - $QUERY$, - queue_name - ); - - IF EXISTS ( - SELECT 1 - FROM information_schema.tables - WHERE table_name = 'meta' and table_schema = 'pgmq' - ) THEN - EXECUTE FORMAT( - $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%s' - $QUERY$, - queue_name - ); - END IF; - - IF partitioned THEN - EXECUTE FORMAT( - $QUERY$ - DELETE FROM public.part_config where parent_table = '%s' - $QUERY$, - queue_name - ); - END IF; - - RETURN TRUE; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.validate_queue_name(queue_name TEXT) -RETURNS void AS $$ -BEGIN - IF length(queue_name) >= 48 THEN - RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; - END IF; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_depend - WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') - AND objid = ( - SELECT oid - FROM pg_class - WHERE relname = table_name - ) - ) INTO result; - RETURN result; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) -RETURNS void AS $$ -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%s ( - msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) - $QUERY$, - queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( - msg_id BIGINT PRIMARY KEY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ); - $QUERY$, - queue_name - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); - END IF; - - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); - $QUERY$, - queue_name, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); - $QUERY$, - queue_name, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, false) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_unlogged(queue_name TEXT) -RETURNS void AS $$ -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - - EXECUTE FORMAT( - $QUERY$ - CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.q_%s ( - msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) - $QUERY$, - queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( - msg_id BIGINT PRIMARY KEY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ); - $QUERY$, - queue_name - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); - END IF; - - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_vt_idx ON pgmq.q_%s (vt ASC); - $QUERY$, - queue_name, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); - $QUERY$, - queue_name, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, true) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._get_partition_col(partition_interval TEXT) -RETURNS TEXT AS $$ -DECLARE - num INTEGER; -BEGIN - BEGIN - num := partition_interval::INTEGER; - RETURN 'msg_id'; - EXCEPTION - WHEN others THEN - RETURN 'enqueued_at'; - END; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._ensure_pg_partman_installed() -RETURNS void AS $$ -DECLARE - extension_exists BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_extension - WHERE extname = 'pg_partman' - ) INTO extension_exists; - - IF NOT extension_exists THEN - RAISE EXCEPTION 'pg_partman is required for partitioned queues'; - END IF; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_partitioned( - queue_name TEXT, - partition_interval TEXT DEFAULT '10000', - retention_interval TEXT DEFAULT '100000' -) -RETURNS void AS $$ -DECLARE - partition_col TEXT; - a_partition_col TEXT; -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - PERFORM pgmq._ensure_pg_partman_installed(); - SELECT pgmq._get_partition_col(partition_interval) INTO partition_col; - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.q_%s ( - msg_id BIGINT GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) PARTITION BY RANGE (%s) - $QUERY$, - queue_name, partition_col - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('q_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.q_%s', queue_name); - END IF; - - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.q_%s', '%s', 'native', '%s'); - $QUERY$, - queue_name, partition_col, partition_interval - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS q_%s_part_idx ON pgmq.q_%s (%s); - $QUERY$, - queue_name, queue_name, partition_col - ); - - EXECUTE FORMAT( - $QUERY$ - UPDATE public.part_config - SET - retention = '%s', - retention_keep_table = false, - retention_keep_index = true, - automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.q_%s'; - $QUERY$, - retention_interval, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', true, false) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); - - IF partition_col = 'enqueued_at' THEN - a_partition_col := 'archived_at'; - ELSE - a_partition_col := partition_col; - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.a_%s ( - msg_id BIGINT, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) PARTITION BY RANGE (%s); - $QUERY$, - queue_name, a_partition_col - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('a_%s', queue_name)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.a_%s', queue_name); - END IF; - - EXECUTE FORMAT( - $QUERY$ - SELECT public.create_parent('pgmq.a_%s', '%s', 'native', '%s'); - $QUERY$, - queue_name, a_partition_col, partition_interval - ); - - EXECUTE FORMAT( - $QUERY$ - UPDATE public.part_config - SET - retention = '%s', - retention_keep_table = false, - retention_keep_index = true, - automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.a_%s'; - $QUERY$, - retention_interval, queue_name - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS archived_at_idx_%s ON pgmq.a_%s (archived_at); - $QUERY$, - queue_name, queue_name - ); - -END; -$$ LANGUAGE plpgsql; - - -CREATE FUNCTION pgmq.create(queue_name TEXT) -RETURNS void AS $$ -BEGIN - PERFORM pgmq.create_non_partitioned(queue_name); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, - partition_interval TEXT DEFAULT '10000', - retention_interval TEXT DEFAULT '100000', - leading_partition INT DEFAULT 10) -RETURNS void AS $$ -DECLARE -a_table_name TEXT := 'a_' || table_name; -a_table_name_old TEXT := 'a_'|| table_name || '_old'; -qualified_a_table_name TEXT := format('%I.%I', 'pgmq', 'a_' || table_name); -qualified_a_table_name_old TEXT := format ('%I.%I', 'pgmq', 'a_' || table_name || '_old'); -BEGIN - - PERFORM c.relkind - FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - WHERE c.relname = a_table_name - AND c.relkind = 'p'; - - IF FOUND THEN - RAISE NOTICE 'Table %s is already partitioned', a_table_name; - RETURN; - END IF; - - PERFORM c.relkind - FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - WHERE c.relname = a_table_name - AND c.relkind = 'r'; - - IF NOT FOUND THEN - RAISE NOTICE 'Table %s doesnot exists', a_table_name; - RETURN; - END IF; - - EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; - - EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', 'a_' || table_name, 'a_'|| table_name || '_old' ); - - EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; - EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; - - PERFORM create_parent(qualified_a_table_name, 'msg_id', 'native', partition_interval, - p_premake := leading_partition); - - UPDATE part_config - SET retention = retention_interval, - retention_keep_table = false, - retention_keep_index = false, - infinite_time_partitions = true - WHERE parent_table = qualified_a_table_name; -END; -$$ LANGUAGE plpgsql; diff --git a/pgmq-extension/sql/pgmq--1.4.1.sql b/pgmq-extension/sql/pgmq--1.4.1.sql deleted file mode 100644 index 44dda0b9..00000000 --- a/pgmq-extension/sql/pgmq--1.4.1.sql +++ /dev/null @@ -1,887 +0,0 @@ ------------------------------------------------------------- --- Schema, tables, records, privileges, indexes, etc ------------------------------------------------------------- --- We don't need to create the `pgmq` schema because it is automatically --- created by postgres due to being declared in extension control file - --- Table where queues and metadata about them is stored -CREATE TABLE pgmq.meta ( - queue_name VARCHAR UNIQUE NOT NULL, - is_partitioned BOOLEAN NOT NULL, - is_unlogged BOOLEAN NOT NULL, - created_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL -); - --- Grant permission to pg_monitor to all tables and sequences -GRANT USAGE ON SCHEMA pgmq TO pg_monitor; -GRANT SELECT ON ALL TABLES IN SCHEMA pgmq TO pg_monitor; -GRANT SELECT ON ALL SEQUENCES IN SCHEMA pgmq TO pg_monitor; -ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON TABLES TO pg_monitor; -ALTER DEFAULT PRIVILEGES IN SCHEMA pgmq GRANT SELECT ON SEQUENCES TO pg_monitor; - --- This type has the shape of a message in a queue, and is often returned by --- pgmq functions that return messages -CREATE TYPE pgmq.message_record AS ( - msg_id BIGINT, - read_ct INTEGER, - enqueued_at TIMESTAMP WITH TIME ZONE, - vt TIMESTAMP WITH TIME ZONE, - message JSONB -); - -CREATE TYPE pgmq.queue_record AS ( - queue_name VARCHAR, - is_partitioned BOOLEAN, - is_unlogged BOOLEAN, - created_at TIMESTAMP WITH TIME ZONE -); - ------------------------------------------------------------- --- Functions ------------------------------------------------------------- - --- a helper to format table names to lowercase and in the pgmq schema -CREATE FUNCTION pgmq.format_table_name(queue_name text, prefix text) - returns text - immutable - language sql -as $$ - select lower(prefix || '_' || queue_name) -$$; - --- read --- reads a number of messages from a queue, setting a visibility timeout on them -CREATE FUNCTION pgmq.read( - queue_name TEXT, - vt INTEGER, - qty INTEGER -) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.%I - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq.%I m - SET - vt = clock_timestamp() + interval '%s seconds', - read_ct = read_ct + 1 - FROM cte - WHERE m.msg_id = cte.msg_id - RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; - $QUERY$, - qtable, qtable, vt - ); - RETURN QUERY EXECUTE sql USING qty; -END; -$$ LANGUAGE plpgsql; - ----- read_with_poll ----- reads a number of messages from a queue, setting a visibility timeout on them -CREATE FUNCTION pgmq.read_with_poll( - queue_name TEXT, - vt INTEGER, - qty INTEGER, - max_poll_seconds INTEGER DEFAULT 5, - poll_interval_ms INTEGER DEFAULT 100 -) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - r pgmq.message_record; - stop_at TIMESTAMP; - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval; - LOOP - IF (SELECT clock_timestamp() >= stop_at) THEN - RETURN; - END IF; - - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.%I - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq.%I m - SET - vt = clock_timestamp() + interval '%s seconds', - read_ct = read_ct + 1 - FROM cte - WHERE m.msg_id = cte.msg_id - RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message; - $QUERY$, - qtable, qtable, vt - ); - - FOR r IN - EXECUTE sql USING qty - LOOP - RETURN NEXT r; - END LOOP; - IF FOUND THEN - RETURN; - ELSE - PERFORM pg_sleep(poll_interval_ms / 1000); - END IF; - END LOOP; -END; -$$ LANGUAGE plpgsql; - ----- archive ----- removes a message from the queue, and sends it to the archive, where its ----- saved permanently. -CREATE FUNCTION pgmq.archive( - queue_name TEXT, - msg_id BIGINT -) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BIGINT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - sql := FORMAT( - $QUERY$ - WITH archived AS ( - DELETE FROM pgmq.%I - WHERE msg_id = $1 - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - $QUERY$, - qtable, atable - ); - EXECUTE sql USING msg_id INTO result; - RETURN NOT (result IS NULL); -END; -$$ LANGUAGE plpgsql; - ----- archive ----- removes an array of message ids from the queue, and sends it to the archive, ----- where these messages will be saved permanently. -CREATE FUNCTION pgmq.archive( - queue_name TEXT, - msg_ids BIGINT[] -) -RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - sql := FORMAT( - $QUERY$ - WITH archived AS ( - DELETE FROM pgmq.%I - WHERE msg_id = ANY($1) - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.%I (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - $QUERY$, - qtable, atable - ); - RETURN QUERY EXECUTE sql USING msg_ids; -END; -$$ LANGUAGE plpgsql; - ----- delete ----- deletes a message id from the queue permanently -CREATE FUNCTION pgmq.delete( - queue_name TEXT, - msg_id BIGINT -) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BIGINT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - DELETE FROM pgmq.%I - WHERE msg_id = $1 - RETURNING msg_id - $QUERY$, - qtable - ); - EXECUTE sql USING msg_id INTO result; - RETURN NOT (result IS NULL); -END; -$$ LANGUAGE plpgsql; - ----- delete ----- deletes an array of message ids from the queue permanently -CREATE FUNCTION pgmq.delete( - queue_name TEXT, - msg_ids BIGINT[] -) -RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - DELETE FROM pgmq.%I - WHERE msg_id = ANY($1) - RETURNING msg_id - $QUERY$, - qtable - ); - RETURN QUERY EXECUTE sql USING msg_ids; -END; -$$ LANGUAGE plpgsql; - --- send --- sends a message to a queue, optionally with a delay -CREATE FUNCTION pgmq.send( - queue_name TEXT, - msg JSONB, - delay INTEGER DEFAULT 0 -) RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - INSERT INTO pgmq.%I (vt, message) - VALUES ((clock_timestamp() + interval '%s seconds'), $1) - RETURNING msg_id; - $QUERY$, - qtable, delay - ); - RETURN QUERY EXECUTE sql USING msg; -END; -$$ LANGUAGE plpgsql; - --- send_batch --- sends an array of list of messages to a queue, optionally with a delay -CREATE FUNCTION pgmq.send_batch( - queue_name TEXT, - msgs JSONB[], - delay INTEGER DEFAULT 0 -) RETURNS SETOF BIGINT AS $$ -DECLARE - sql TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - INSERT INTO pgmq.%I (vt, message) - SELECT clock_timestamp() + interval '%s seconds', unnest($1) - RETURNING msg_id; - $QUERY$, - qtable, delay - ); - RETURN QUERY EXECUTE sql USING msgs; -END; -$$ LANGUAGE plpgsql; - --- returned by pgmq.metrics() and pgmq.metrics_all -CREATE TYPE pgmq.metrics_result AS ( - queue_name text, - queue_length bigint, - newest_msg_age_sec int, - oldest_msg_age_sec int, - total_messages bigint, - scrape_time timestamp with time zone -); - --- get metrics for a single queue -CREATE FUNCTION pgmq.metrics(queue_name TEXT) -RETURNS pgmq.metrics_result AS $$ -DECLARE - result_row pgmq.metrics_result; - query TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - query := FORMAT( - $QUERY$ - WITH q_summary AS ( - SELECT - count(*) as queue_length, - EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec, - EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec, - NOW() as scrape_time - FROM pgmq.%I - ), - all_metrics AS ( - SELECT CASE - WHEN is_called THEN last_value ELSE 0 - END as total_messages - FROM pgmq.%I - ) - SELECT - '%s' as queue_name, - q_summary.queue_length, - q_summary.newest_msg_age_sec, - q_summary.oldest_msg_age_sec, - all_metrics.total_messages, - q_summary.scrape_time - FROM q_summary, all_metrics - $QUERY$, - qtable, qtable || '_msg_id_seq', queue_name - ); - EXECUTE query INTO result_row; - RETURN result_row; -END; -$$ LANGUAGE plpgsql; - --- get metrics for all queues -CREATE FUNCTION pgmq."metrics_all"() -RETURNS SETOF pgmq.metrics_result AS $$ -DECLARE - row_name RECORD; - result_row pgmq.metrics_result; -BEGIN - FOR row_name IN SELECT queue_name FROM pgmq.meta LOOP - result_row := pgmq.metrics(row_name.queue_name); - RETURN NEXT result_row; - END LOOP; -END; -$$ LANGUAGE plpgsql; - --- list queues -CREATE FUNCTION pgmq."list_queues"() -RETURNS SETOF pgmq.queue_record AS $$ -BEGIN - RETURN QUERY SELECT * FROM pgmq.meta; -END -$$ LANGUAGE plpgsql; - --- purge queue, deleting all entries in it. -CREATE FUNCTION pgmq."purge_queue"(queue_name TEXT) -RETURNS BIGINT AS $$ -DECLARE - deleted_count INTEGER; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - EXECUTE format('DELETE FROM pgmq.%I', qtable); - GET DIAGNOSTICS deleted_count = ROW_COUNT; - RETURN deleted_count; -END -$$ LANGUAGE plpgsql; - --- unassign archive, so it can be kept when a queue is deleted -CREATE FUNCTION pgmq."detach_archive"(queue_name TEXT) -RETURNS VOID AS $$ -DECLARE - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - EXECUTE format('ALTER EXTENSION pgmq DROP TABLE pgmq.%I', atable); -END -$$ LANGUAGE plpgsql; - --- pop a single message -CREATE FUNCTION pgmq.pop(queue_name TEXT) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; - result pgmq.message_record; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - WITH cte AS - ( - SELECT msg_id - FROM pgmq.%I - WHERE vt <= now() - ORDER BY msg_id ASC - LIMIT 1 - FOR UPDATE SKIP LOCKED - ) - DELETE from pgmq.%I - WHERE msg_id = (select msg_id from cte) - RETURNING *; - $QUERY$, - qtable, qtable - ); - RETURN QUERY EXECUTE sql; -END; -$$ LANGUAGE plpgsql; - --- Sets vt of a message, returns it -CREATE FUNCTION pgmq.set_vt(queue_name TEXT, msg_id BIGINT, vt INTEGER) -RETURNS SETOF pgmq.message_record AS $$ -DECLARE - sql TEXT; - result pgmq.message_record; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); -BEGIN - sql := FORMAT( - $QUERY$ - UPDATE pgmq.%I - SET vt = (now() + interval '%s seconds') - WHERE msg_id = %s - RETURNING *; - $QUERY$, - qtable, vt, msg_id - ); - RETURN QUERY EXECUTE sql; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.drop_queue(queue_name TEXT, partitioned BOOLEAN DEFAULT FALSE) -RETURNS BOOLEAN AS $$ -DECLARE - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - EXECUTE FORMAT( - $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.%I - $QUERY$, - qtable - ); - - EXECUTE FORMAT( - $QUERY$ - ALTER EXTENSION pgmq DROP TABLE pgmq.%I - $QUERY$, - atable - ); - - EXECUTE FORMAT( - $QUERY$ - DROP TABLE IF EXISTS pgmq.%I - $QUERY$, - qtable - ); - - EXECUTE FORMAT( - $QUERY$ - DROP TABLE IF EXISTS pgmq.%I - $QUERY$, - atable - ); - - IF EXISTS ( - SELECT 1 - FROM information_schema.tables - WHERE table_name = 'meta' and table_schema = 'pgmq' - ) THEN - EXECUTE FORMAT( - $QUERY$ - DELETE FROM pgmq.meta WHERE queue_name = '%s' - $QUERY$, - queue_name - ); - END IF; - - IF partitioned THEN - EXECUTE FORMAT( - $QUERY$ - DELETE FROM public.part_config where parent_table = '%s' - $QUERY$, - queue_name - ); - END IF; - - RETURN TRUE; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.validate_queue_name(queue_name TEXT) -RETURNS void AS $$ -BEGIN - IF length(queue_name) >= 48 THEN - RAISE EXCEPTION 'queue name is too long, maximum length is 48 characters'; - END IF; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._belongs_to_pgmq(table_name TEXT) -RETURNS BOOLEAN AS $$ -DECLARE - sql TEXT; - result BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_depend - WHERE refobjid = (SELECT oid FROM pg_extension WHERE extname = 'pgmq') - AND objid = ( - SELECT oid - FROM pg_class - WHERE relname = table_name - ) - ) INTO result; - RETURN result; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_non_partitioned(queue_name TEXT) -RETURNS void AS $$ -DECLARE - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) - $QUERY$, - qtable - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT PRIMARY KEY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ); - $QUERY$, - atable - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); - END IF; - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); - $QUERY$, - qtable || '_vt_idx', qtable - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); - $QUERY$, - 'archived_at_idx_' || queue_name, atable - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, false) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_unlogged(queue_name TEXT) -RETURNS void AS $$ -DECLARE - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - EXECUTE FORMAT( - $QUERY$ - CREATE UNLOGGED TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) - $QUERY$, - qtable - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT PRIMARY KEY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ); - $QUERY$, - atable - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); - END IF; - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (vt ASC); - $QUERY$, - qtable || '_vt_idx', qtable - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); - $QUERY$, - 'archived_at_idx_' || queue_name, atable - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', false, true) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._get_partition_col(partition_interval TEXT) -RETURNS TEXT AS $$ -DECLARE - num INTEGER; -BEGIN - BEGIN - num := partition_interval::INTEGER; - RETURN 'msg_id'; - EXCEPTION - WHEN others THEN - RETURN 'enqueued_at'; - END; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq._ensure_pg_partman_installed() -RETURNS void AS $$ -DECLARE - extension_exists BOOLEAN; -BEGIN - SELECT EXISTS ( - SELECT 1 - FROM pg_extension - WHERE extname = 'pg_partman' - ) INTO extension_exists; - - IF NOT extension_exists THEN - RAISE EXCEPTION 'pg_partman is required for partitioned queues'; - END IF; -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.create_partitioned( - queue_name TEXT, - partition_interval TEXT DEFAULT '10000', - retention_interval TEXT DEFAULT '100000' -) -RETURNS void AS $$ -DECLARE - partition_col TEXT; - a_partition_col TEXT; - qtable TEXT := pgmq.format_table_name(queue_name, 'q'); - atable TEXT := pgmq.format_table_name(queue_name, 'a'); -BEGIN - PERFORM pgmq.validate_queue_name(queue_name); - PERFORM pgmq._ensure_pg_partman_installed(); - SELECT pgmq._get_partition_col(partition_interval) INTO partition_col; - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT GENERATED ALWAYS AS IDENTITY, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) PARTITION BY RANGE (%s) - $QUERY$, - qtable, partition_col - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', qtable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); - END IF; - - PERFORM public.create_parent( - 'pgmq.' || quote_ident(qtable), - partition_col, 'native', partition_interval - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%s); - $QUERY$, - qtable || '_part_idx', qtable, partition_col - ); - - EXECUTE FORMAT( - $QUERY$ - UPDATE public.part_config - SET - retention = '%s', - retention_keep_table = false, - retention_keep_index = true, - automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.q_%I'; - $QUERY$, - retention_interval, qtable - ); - - EXECUTE FORMAT( - $QUERY$ - INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) - VALUES ('%s', true, false) - ON CONFLICT - DO NOTHING; - $QUERY$, - queue_name - ); - - IF partition_col = 'enqueued_at' THEN - a_partition_col := 'archived_at'; - ELSE - a_partition_col := partition_col; - END IF; - - EXECUTE FORMAT( - $QUERY$ - CREATE TABLE IF NOT EXISTS pgmq.%I ( - msg_id BIGINT, - read_ct INT DEFAULT 0 NOT NULL, - enqueued_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - archived_at TIMESTAMP WITH TIME ZONE DEFAULT now() NOT NULL, - vt TIMESTAMP WITH TIME ZONE NOT NULL, - message JSONB - ) PARTITION BY RANGE (%s); - $QUERY$, - atable, a_partition_col - ); - - IF NOT pgmq._belongs_to_pgmq(FORMAT('%I', atable)) THEN - EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); - END IF; - - PERFORM public.create_parent( - 'pgmq.' || quote_ident(atable), - a_partition_col, 'native', partition_interval - ); - - EXECUTE FORMAT( - $QUERY$ - UPDATE public.part_config - SET - retention = '%s', - retention_keep_table = false, - retention_keep_index = true, - automatic_maintenance = 'on' - WHERE parent_table = 'pgmq.%I'; - $QUERY$, - retention_interval, atable - ); - - EXECUTE FORMAT( - $QUERY$ - CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (archived_at); - $QUERY$, - 'archived_at_idx_' || queue_name, atable - ); - -END; -$$ LANGUAGE plpgsql; - - -CREATE FUNCTION pgmq.create(queue_name TEXT) -RETURNS void AS $$ -BEGIN - PERFORM pgmq.create_non_partitioned(queue_name); -END; -$$ LANGUAGE plpgsql; - -CREATE FUNCTION pgmq.convert_archive_partitioned(table_name TEXT, - partition_interval TEXT DEFAULT '10000', - retention_interval TEXT DEFAULT '100000', - leading_partition INT DEFAULT 10) -RETURNS void AS $$ -DECLARE -a_table_name TEXT := pgmq.format_table_name(table_name, 'a'); -a_table_name_old TEXT := pgmq.format_table_name(table_name, 'a') || '_old'; -qualified_a_table_name TEXT := format('pgmq.%I', a_table_name); -qualified_a_table_name_old TEXT := format ('pgmq.%I', a_table_name_old || '_old'); -BEGIN - - PERFORM c.relkind - FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - WHERE c.relname = a_table_name - AND c.relkind = 'p'; - - IF FOUND THEN - RAISE NOTICE 'Table %s is already partitioned', a_table_name; - RETURN; - END IF; - - PERFORM c.relkind - FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - WHERE c.relname = a_table_name - AND c.relkind = 'r'; - - IF NOT FOUND THEN - RAISE NOTICE 'Table %s doesnot exists', a_table_name; - RETURN; - END IF; - - EXECUTE 'ALTER TABLE ' || qualified_a_table_name || ' RENAME TO ' || a_table_name_old; - - EXECUTE format( 'CREATE TABLE pgmq.%I (LIKE pgmq.%I including all) PARTITION BY RANGE (msg_id)', a_table_name, a_table_name_old ); - - EXECUTE 'ALTER INDEX pgmq.archived_at_idx_' || table_name || ' RENAME TO archived_at_idx_' || table_name || '_old'; - EXECUTE 'CREATE INDEX archived_at_idx_'|| table_name || ' ON ' || qualified_a_table_name ||'(archived_at)'; - - PERFORM create_parent(qualified_a_table_name, 'msg_id', 'native', partition_interval, - p_premake := leading_partition); - - UPDATE part_config - SET retention = retention_interval, - retention_keep_table = false, - retention_keep_index = false, - infinite_time_partitions = true - WHERE parent_table = qualified_a_table_name; -END; -$$ LANGUAGE plpgsql;