From 60c0e755ab0f049ff6afefdd13c25300c688f59c Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 11:49:49 +0530 Subject: [PATCH 1/6] feat: overloaded the function to have a custom query Signed-off-by: Abinand P --- pgmq-extension/results/base.out | 938 +++++++++++++++++++++++ pgmq-extension/sql/pgmq--1.4.4.sql | 1020 +++++++++++++++++++++++++ pgmq-extension/sql/pgmq.sql | 40 + pgmq-extension/test/expected/base.out | 47 ++ pgmq-extension/test/sql/base.sql | 26 + 5 files changed, 2071 insertions(+) create mode 100644 pgmq-extension/results/base.out create mode 100644 pgmq-extension/sql/pgmq--1.4.4.sql diff --git a/pgmq-extension/results/base.out b/pgmq-extension/results/base.out new file mode 100644 index 00000000..87d82d98 --- /dev/null +++ b/pgmq-extension/results/base.out @@ -0,0 +1,938 @@ +-- CREATE pgmq. +CREATE EXTENSION IF NOT EXISTS pgmq; +CREATE EXTENSION IF NOT EXISTS pg_partman; +ERROR: extension "pg_partman" is not available +DETAIL: Could not open extension control file "/usr/share/postgresql/16/extension/pg_partman.control": No such file or directory. +HINT: The extension must first be installed on the system where PostgreSQL is running. + +-- test_unlogged +-- CREATE with default retention and partition strategy +SELECT pgmq.create_unlogged('test_unlogged_queue'); + create_unlogged +----------------- + +(1 row) + +SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); + send +------ + 1 +(1 row) + +SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message + FROM pgmq.read('test_unlogged_queue', 2, 1); + msg_id | read_ct | ?column? | ?column? | message +--------+---------+----------+----------+-------------------- + 1 | 1 | f | t | {"hello": "world"} +(1 row) + + +-- test_max_queue_name_size +-- CREATE with default retention and partition strategy +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 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)); + create +-------- + +(1 row) + + +-- test_lifecycle +-- CREATE with default retention and partition strategy +SELECT pgmq.create('test_default_queue'); + create +-------- + +(1 row) + + +-- creating a queue must be idempotent +-- create with same name again, must be no error +SELECT pgmq.create('test_default_queue'); +NOTICE: relation "q_test_default_queue" already exists, skipping +NOTICE: relation "a_test_default_queue" already exists, skipping +NOTICE: relation "q_test_default_queue_vt_idx" already exists, skipping +NOTICE: relation "archived_at_idx_test_default_queue" already exists, skipping + create +-------- + +(1 row) + + +SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); + send +------ + 1 +(1 row) + + +-- read message +-- vt=2, limit=1 +\set msg_id 1 +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + ?column? +---------- + t +(1 row) + + +-- set VT to 5 seconds +SELECT vt > clock_timestamp() + '4 seconds'::interval + FROM pgmq.set_vt('test_default_queue', :msg_id, 5); + ?column? +---------- + t +(1 row) + + +-- read again, assert no messages because we just set VT to the future +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + ?column? +---------- +(0 rows) + + +-- read again, now using poll to block until message is ready +SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); + ?column? +---------- + t +(1 row) + + +-- after reading it, set VT to now +SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); + ?column? +---------- + t +(1 row) + + +-- read again, should have msg_id 1 again +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + ?column? +---------- + t +(1 row) + + +-- send a batch of 2 messages +SELECT pgmq.create('batch_queue'); + create +-------- + +(1 row) + +SELECT ARRAY( SELECT pgmq.send_batch( + 'batch_queue', + ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] +)) = ARRAY[1, 2]::BIGINT[]; + ?column? +---------- + t +(1 row) + + +-- CREATE with 5 seconds per partition, 10 seconds retention +SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); +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 11 at PERFORM + +-- CREATE with 10 messages per partition, 20 messages retention +SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); +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 11 at PERFORM + +-- get metrics +SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages + FROM pgmq.metrics('test_duration_queue'); +ERROR: relation "pgmq.q_test_duration_queue" does not exist +LINE 8: FROM pgmq.q_test_duration_queue + ^ +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_test_duration_queue + ), + all_metrics AS ( + SELECT CASE + WHEN is_called THEN last_value ELSE 0 + END as total_messages + FROM pgmq.q_test_duration_queue_msg_id_seq + ) + SELECT + 'test_duration_queue' 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 + +CONTEXT: PL/pgSQL function pgmq.metrics(text) line 34 at EXECUTE + +-- get metrics all +SELECT * from {PGMQ_SCHEMA}.metrics_all(); +ERROR: syntax error at or near "{" +LINE 1: SELECT * from {PGMQ_SCHEMA}.metrics_all(); + ^ + +-- delete all the queues +-- delete partitioned queues +SELECT pgmq.drop_queue(queue, true) + FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; +ERROR: relation "pgmq.q_test_duration_queue" does not exist +CONTEXT: SQL statement " + ALTER EXTENSION pgmq DROP TABLE pgmq.q_test_duration_queue + " +PL/pgSQL function pgmq.drop_queue(text,boolean) line 8 at EXECUTE + +-- drop the rest of the queues +SELECT pgmq.drop_queue(q.queue_name, true) + FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; +ERROR: null values cannot be formatted as an SQL identifier +CONTEXT: PL/pgSQL function pgmq.drop_queue(text,boolean) line 50 at EXECUTE + +SELECT queue_name FROM pgmq.list_queues(); + queue_name +------------------------------------------------- + test_unlogged_queue + aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa + test_default_queue + batch_queue +(4 rows) + + +-- test_archive +SELECT pgmq.create('archive_queue'); + create +-------- + +(1 row) + + +-- no messages in the queue +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; + ?column? +---------- + t +(1 row) + + +-- no messages in queue archive +SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; + ?column? +---------- + t +(1 row) + + +-- put messages on the queue +\set msg_id1 1::bigint +\set msg_id2 2::bigint +SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); + ?column? +---------- + t +(1 row) + +SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); + ?column? +---------- + t +(1 row) + + +-- two messages in the queue +SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; + ?column? +---------- + t +(1 row) + + +-- archive the message. The first two exist so the id should be returned, the +-- last one doesn't +SELECT ARRAY( + SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) +) = ARRAY[:msg_id1, :msg_id2]; + ?column? +---------- + t +(1 row) + + +-- should be no messages left on the queue table +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; + ?column? +---------- + t +(1 row) + + +-- should be two messages in archive +SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; + ?column? +---------- + t +(1 row) + + +\set msg_id3 3::bigint +SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); + ?column? +---------- + t +(1 row) + +SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; + ?column? +---------- + t +(1 row) + +SELECT * FROM pgmq.archive('archive_queue', :msg_id3); + archive +--------- + t +(1 row) + +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; + ?column? +---------- + t +(1 row) + +SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; + ?column? +---------- + t +(1 row) + + +-- test_read_read_with_poll +-- Creating queue +SELECT pgmq.create('test_read_queue'); + create +-------- + +(1 row) + + +-- Sending 3 messages to the queue +SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); + ?column? +---------- + t +(1 row) + +SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); + ?column? +---------- + t +(1 row) + +SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); + ?column? +---------- + t +(1 row) + + +-- Reading with limit respects the limit +SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); + ?column? +---------- + t +(1 row) + + +-- Reading respects the VT +SELECT ARRAY( + SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) +) = ARRAY[:msg_id2, :msg_id3]; + ?column? +---------- + t +(1 row) + + +-- Read with poll will poll until the first message is available +SELECT clock_timestamp() AS start \gset +SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); + ?column? +---------- + t +(1 row) + +SELECT clock_timestamp() - :'start' > '3 second'::interval; + ?column? +---------- + t +(1 row) + + +-- test_purge_queue +SELECT pgmq.create('test_purge_queue'); + create +-------- + +(1 row) + +SELECT * from pgmq.send('test_purge_queue', '0'); + send +------ + 1 +(1 row) + +SELECT * from pgmq.send('test_purge_queue', '0'); + send +------ + 2 +(1 row) + +SELECT * from pgmq.send('test_purge_queue', '0'); + send +------ + 3 +(1 row) + +SELECT * from pgmq.send('test_purge_queue', '0'); + send +------ + 4 +(1 row) + +SELECT * from pgmq.send('test_purge_queue', '0'); + send +------ + 5 +(1 row) + + +SELECT * FROM pgmq.purge_queue('test_purge_queue'); + purge_queue +------------- + 5 +(1 row) + +SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; + ?column? +---------- + t +(1 row) + + +-- test_pop +SELECT pgmq.create('test_pop_queue'); + create +-------- + +(1 row) + +SELECT * FROM pgmq.pop('test_pop_queue'); + msg_id | read_ct | enqueued_at | vt | message +--------+---------+-------------+----+--------- +(0 rows) + + +SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset +SELECT * from pgmq.send('test_pop_queue', '0'); + send +------ + 2 +(1 row) + +SELECT * from pgmq.send('test_pop_queue', '0'); + send +------ + 3 +(1 row) + + +SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); + ?column? +---------- + t +(1 row) + + +-- test_set_vt +SELECT pgmq.create('test_set_vt_queue'); + create +-------- + +(1 row) + +SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); + msg_id | read_ct | enqueued_at | vt | message +--------+---------+-------------+----+--------- +(0 rows) + + +SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset + +-- set message invisible for 100 seconds +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); + msg_id +-------- + 1 +(1 row) + + +-- read message, it should not be visible +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); + msg_id +-------- +(0 rows) + + +-- make it visible +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); + msg_id +-------- + 1 +(1 row) + + +-- set vt works if message is readable +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); + msg_id +-------- + 1 +(1 row) + + +-- test_partitioned_delete +\set partition_interval 2 +\set retention_interval 2 + +-- We first will drop pg_partman and assert that create fails without the +-- extension installed +DROP EXTENSION pg_partman; +ERROR: extension "pg_partman" does not exist + +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); +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 11 at PERFORM + +-- With the extension existing, the queue is created successfully +CREATE EXTENSION pg_partman; +ERROR: extension "pg_partman" is not available +DETAIL: Could not open extension control file "/usr/share/postgresql/16/extension/pg_partman.control": No such file or directory. +HINT: The extension must first be installed on the system where PostgreSQL is running. +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); +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 11 at PERFORM + +-- queue shows up in list queues +SELECT queue_name FROM pgmq.list_queues() + WHERE queue_name = 'test_partitioned_queue'; + queue_name +------------ +(0 rows) + + +-- Sending 3 messages to the queue +SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... + ^ +QUERY: + INSERT INTO pgmq.q_test_partitioned_queue (vt, message) + VALUES ((clock_timestamp() + '@ 0'), $1) + RETURNING msg_id; + +CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY +SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... + ^ +QUERY: + INSERT INTO pgmq.q_test_partitioned_queue (vt, message) + VALUES ((clock_timestamp() + '@ 0'), $1) + RETURNING msg_id; + +CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY +SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... + ^ +QUERY: + INSERT INTO pgmq.q_test_partitioned_queue (vt, message) + VALUES ((clock_timestamp() + '@ 0'), $1) + RETURNING msg_id; + +CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY + +SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 1: SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; + ^ + +-- Deleting message 3 +SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 2: DELETE FROM pgmq.q_test_partitioned_queue + ^ +QUERY: + DELETE FROM pgmq.q_test_partitioned_queue + WHERE msg_id = $1 + RETURNING msg_id + +CONTEXT: PL/pgSQL function pgmq.delete(text,bigint) line 15 at EXECUTE +SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 1: SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; + ^ + +-- Deleting batch +SELECT ARRAY( + SELECT archive FROM pgmq.archive( + 'test_partitioned_queue', + ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] + ) +) = ARRAY[:msg_id1, :msg_id2]::bigint[]; +ERROR: relation "pgmq.q_test_partitioned_queue" does not exist +LINE 3: DELETE FROM pgmq.q_test_partitioned_queue + ^ +QUERY: + WITH archived AS ( + DELETE FROM pgmq.q_test_partitioned_queue + WHERE msg_id = ANY($1) + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_test_partitioned_queue (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + +CONTEXT: PL/pgSQL function pgmq.archive(text,bigint[]) line 21 at RETURN QUERY + +-- test_transaction_create +BEGIN; +SELECT pgmq.create('transaction_test_queue'); + create +-------- + +(1 row) + +ROLLBACK; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; + tablename +----------- +(0 rows) + + +-- test_detach_archive +SELECT pgmq.create('detach_archive_queue'); + create +-------- + +(1 row) + +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; + tablename +----------- +(0 rows) + + +-- With detach, archive remains +CREATE EXTENSION pgmq; +SELECT pgmq.create('detach_archive_queue'); + create +-------- + +(1 row) + +SELECT pgmq.detach_archive('detach_archive_queue'); + detach_archive +---------------- + +(1 row) + +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; + tablename +------------------------ + a_detach_archive_queue +(1 row) + + +--Truncated Index When queue name is max. +CREATE EXTENSION pgmq; +SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); + create +-------- + +(1 row) + +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); +NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" +ERROR: null values cannot be formatted as an SQL identifier +CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE + +--Check for archive is already partitioned +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); +NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" +ERROR: null values cannot be formatted as an SQL identifier +CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE + +--Error out due to Index duplicate index at old table. +SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); + create +-------- + +(1 row) + +SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); +NOTICE: identifier "archived_at_idx_long_queue_name_1234567890123456789012345678901_old" will be truncated to "archived_at_idx_long_queue_name_1234567890123456789012345678901" +ERROR: relation "archived_at_idx_long_queue_name_1234567890123456789012345678901" already exists +CONTEXT: SQL statement "ALTER INDEX pgmq.archived_at_idx_long_queue_name_1234567890123456789012345678901 RENAME TO archived_at_idx_long_queue_name_1234567890123456789012345678901_old" +PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 34 at EXECUTE + +--Success +SELECT pgmq.create('long_queue_name_'); + create +-------- + +(1 row) + +SELECT pgmq.convert_archive_partitioned('long_queue_name_'); +ERROR: null values cannot be formatted as an SQL identifier +CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE + +\set SHOW_CONTEXT never + +--Failed SQL injection attack +SELECT pgmq.create('abc'); + create +-------- + +(1 row) + +SELECT + pgmq.delete( + 'abc where false; + create table public.attack_vector(id int); + delete from pgmq.q_abc', + 1 + ); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +--Special characters in queue name +SELECT pgmq.create('queue-hyphened'); + create +-------- + +(1 row) + +SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); + send +------ + 1 +(1 row) + +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); + msg_id | read_ct | message +--------+---------+-------------------- + 1 | 1 | {"hello": "world"} +(1 row) + +SELECT pgmq.archive('queue-hyphened', 1); + archive +--------- + t +(1 row) + + +SELECT pgmq.create('QueueCased'); + create +-------- + +(1 row) + +SELECT pgmq.send('QueueCased', '{"hello":"world"}'); + send +------ + 1 +(1 row) + +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); + msg_id | read_ct | message +--------+---------+-------------------- + 1 | 1 | {"hello": "world"} +(1 row) + +SELECT pgmq.archive('QueueCased', 1); + archive +--------- + t +(1 row) + + +SELECT pgmq.create_partitioned('queue-hyphened-part'); +ERROR: pg_partman is required for partitioned queues +SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); +ERROR: relation "pgmq.q_queue-hyphened-part" does not exist +LINE 2: INSERT INTO pgmq."q_queue-hyphened-part" (vt, messag... + ^ +QUERY: + INSERT INTO pgmq."q_queue-hyphened-part" (vt, message) + VALUES ((clock_timestamp() + '@ 0'), $1) + RETURNING msg_id; + +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); +ERROR: relation "pgmq.q_queue-hyphened-part" does not exist +LINE 5: FROM pgmq."q_queue-hyphened-part" + ^ +QUERY: + WITH cte AS + ( + SELECT msg_id + FROM pgmq."q_queue-hyphened-part" + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq."q_queue-hyphened-part" m + SET + vt = clock_timestamp() + '@ 1 sec', + 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; + +SELECT pgmq.archive('queue-hyphened-part', 1); +ERROR: relation "pgmq.q_queue-hyphened-part" does not exist +LINE 3: DELETE FROM pgmq."q_queue-hyphened-part" + ^ +QUERY: + WITH archived AS ( + DELETE FROM pgmq."q_queue-hyphened-part" + WHERE msg_id = $1 + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq."a_queue-hyphened-part" (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + + +SELECT pgmq.create_partitioned('QueueCasedPart'); +ERROR: pg_partman is required for partitioned queues +SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); +ERROR: relation "pgmq.q_queuecasedpart" does not exist +LINE 2: INSERT INTO pgmq.q_queuecasedpart (vt, message) + ^ +QUERY: + INSERT INTO pgmq.q_queuecasedpart (vt, message) + VALUES ((clock_timestamp() + '@ 0'), $1) + RETURNING msg_id; + +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); +ERROR: relation "pgmq.q_queuecasedpart" does not exist +LINE 5: FROM pgmq.q_queuecasedpart + ^ +QUERY: + WITH cte AS + ( + SELECT msg_id + FROM pgmq.q_queuecasedpart + WHERE vt <= clock_timestamp() + ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.q_queuecasedpart m + SET + vt = clock_timestamp() + '@ 1 sec', + 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; + +SELECT pgmq.archive('QueueCasedPart', 1); +ERROR: relation "pgmq.q_queuecasedpart" does not exist +LINE 3: DELETE FROM pgmq.q_queuecasedpart + ^ +QUERY: + WITH archived AS ( + DELETE FROM pgmq.q_queuecasedpart + WHERE msg_id = $1 + RETURNING msg_id, vt, read_ct, enqueued_at, message + ) + INSERT INTO pgmq.a_queuecasedpart (msg_id, vt, read_ct, enqueued_at, message) + SELECT msg_id, vt, read_ct, enqueued_at, message + FROM archived + RETURNING msg_id; + + +-- fails with invalid queue name +SELECT pgmq.create('dollar$-signed'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.create_partitioned('dollar$-signed-part'); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +-- input validation success +SELECT pgmq.format_table_name('cat', 'q'); + format_table_name +------------------- + q_cat +(1 row) + +SELECT pgmq.format_table_name('cat-dog', 'a'); + format_table_name +------------------- + a_cat-dog +(1 row) + +SELECT pgmq.format_table_name('cat_dog', 'q'); + format_table_name +------------------- + q_cat_dog +(1 row) + + +-- input validation failure +SELECT pgmq.format_table_name('dollar$fail', 'q'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name('semicolon;fail', 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +--Cleanup tests +DROP EXTENSION pgmq CASCADE; +DROP EXTENSION pg_partman CASCADE; +ERROR: extension "pg_partman" does not exist diff --git a/pgmq-extension/sql/pgmq--1.4.4.sql b/pgmq-extension/sql/pgmq--1.4.4.sql new file mode 100644 index 00000000..9c6e7107 --- /dev/null +++ b/pgmq-extension/sql/pgmq--1.4.4.sql @@ -0,0 +1,1020 @@ +------------------------------------------------------------ +-- 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 and check for invalid characters +CREATE FUNCTION pgmq.format_table_name(queue_name text, prefix text) +RETURNS TEXT AS $$ +BEGIN + IF queue_name ~ '\$|;|--|''' + THEN + RAISE EXCEPTION 'queue name contains invalid characters: $, ;, --, or \'''; + END IF; + RETURN lower(prefix || '_' || queue_name); +END; +$$ LANGUAGE plpgsql; + +-- 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() + %L, + 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, make_interval(secs => vt) + ); + RETURN QUERY EXECUTE sql USING qty; +END; +$$ LANGUAGE plpgsql; + +-- Overloaded function to read messages with conditional retrieval using jsonb +CREATE FUNCTION pgmq.read( + queue_name TEXT, + vt INTEGER, + qty INTEGER, + conditions JSONB DEFAULT NULL +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + -- Start constructing the base SQL query + sql := 'WITH cte AS ( + SELECT msg_id + FROM pgmq.' || qtable || ' + WHERE vt <= clock_timestamp()'; + + -- Append conditions if provided + IF conditions IS NOT NULL THEN + sql := sql || ' AND message @> ' || quote_literal(conditions); + END IF; + + sql := sql || ' ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.' || qtable || ' m + SET + vt = clock_timestamp() + ' || quote_literal(make_interval(secs => vt)) || ', + 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;'; + + -- Return the result set using EXECUTE + 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() + make_interval(secs => max_poll_seconds); + 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() + %L, + 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, make_interval(secs => 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() + %L), $1) + RETURNING msg_id; + $QUERY$, + qtable, make_interval(secs => 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() + %L, unnest($1) + RETURNING msg_id; + $QUERY$, + qtable, make_interval(secs => 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 + %L 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 OR REPLACE FUNCTION pgmq."purge_queue"(queue_name TEXT) +RETURNS BIGINT AS $$ +DECLARE + deleted_count INTEGER; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + -- Get the row count before truncating + EXECUTE format('SELECT count(*) FROM pgmq.%I', qtable) INTO deleted_count; + + -- Use TRUNCATE for better performance on large tables + EXECUTE format('TRUNCATE TABLE pgmq.%I', qtable); + + -- Return the number of purged rows + 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() + %L) + WHERE msg_id = %L + RETURNING *; + $QUERY$, + qtable, make_interval(secs => vt), msg_id + ); + RETURN QUERY EXECUTE sql; +END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION pgmq._get_pg_partman_schema() +RETURNS TEXT AS $$ + SELECT + extnamespace::regnamespace::text + FROM + pg_extension + WHERE + extname = 'pg_partman'; +$$ LANGUAGE SQL; + +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'); + fq_qtable TEXT := 'pgmq.' || qtable; + atable TEXT := pgmq.format_table_name(queue_name, 'a'); + fq_atable TEXT := 'pgmq.' || atable; +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 = %L + $QUERY$, + queue_name + ); + END IF; + + IF partitioned THEN + EXECUTE FORMAT( + $QUERY$ + DELETE FROM %I.part_config where parent_table in (%L, %L) + $QUERY$, + pgmq._get_pg_partman_schema(), fq_qtable, fq_atable + ); + 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(qtable) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + IF NOT pgmq._belongs_to_pgmq(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 (%L, 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(qtable) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + IF NOT pgmq._belongs_to_pgmq(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 (%L, 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._get_pg_partman_major_version() +RETURNS INT +LANGUAGE SQL +AS $$ + SELECT split_part(extversion, '.', 1)::INT + FROM pg_extension + WHERE extname = 'pg_partman' +$$; + +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'); + fq_qtable TEXT := 'pgmq.' || qtable; + fq_atable TEXT := 'pgmq.' || atable; +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 (%I) + $QUERY$, + qtable, partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(qtable) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', qtable); + END IF; + + -- https://github.com/pgpartman/pg_partman/blob/master/doc/pg_partman.md + -- p_parent_table - the existing parent table. MUST be schema qualified, even if in public schema. + EXECUTE FORMAT( + $QUERY$ + SELECT %I.create_parent( + p_parent_table := %L, + p_control := %L, + p_interval := %L, + p_type := case + when pgmq._get_pg_partman_major_version() = 5 then 'range' + else 'native' + end + ) + $QUERY$, + pgmq._get_pg_partman_schema(), + fq_qtable, + partition_col, + partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + CREATE INDEX IF NOT EXISTS %I ON pgmq.%I (%I); + $QUERY$, + qtable || '_part_idx', qtable, partition_col + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE %I.part_config + SET + retention = %L, + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = %L; + $QUERY$, + pgmq._get_pg_partman_schema(), + retention_interval, + 'pgmq.' || qtable + ); + + EXECUTE FORMAT( + $QUERY$ + INSERT INTO pgmq.meta (queue_name, is_partitioned, is_unlogged) + VALUES (%L, 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 NOT NULL, + 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$, + atable, a_partition_col + ); + + IF NOT pgmq._belongs_to_pgmq(atable) THEN + EXECUTE FORMAT('ALTER EXTENSION pgmq ADD TABLE pgmq.%I', atable); + END IF; + + -- https://github.com/pgpartman/pg_partman/blob/master/doc/pg_partman.md + -- p_parent_table - the existing parent table. MUST be schema qualified, even if in public schema. + EXECUTE FORMAT( + $QUERY$ + SELECT %I.create_parent( + p_parent_table := %L, + p_control := %L, + p_interval := %L, + p_type := case + when pgmq._get_pg_partman_major_version() = 5 then 'range' + else 'native' + end + ) + $QUERY$, + pgmq._get_pg_partman_schema(), + fq_atable, + a_partition_col, + partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE %I.part_config + SET + retention = %L, + retention_keep_table = false, + retention_keep_index = true, + automatic_maintenance = 'on' + WHERE parent_table = %L; + $QUERY$, + pgmq._get_pg_partman_schema(), + retention_interval, + 'pgmq.' || 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 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 +) +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); +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 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 '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)'; + + -- https://github.com/pgpartman/pg_partman/blob/master/doc/pg_partman.md + -- p_parent_table - the existing parent table. MUST be schema qualified, even if in public schema. + EXECUTE FORMAT( + $QUERY$ + SELECT %I.create_parent( + p_parent_table := %L, + p_control := 'msg_id', + p_interval := %L, + p_type := case + when pgmq._get_pg_partman_major_version() = 5 then 'range' + else 'native' + end + ) + $QUERY$, + pgmq._get_pg_partman_schema(), + qualified_a_table_name, + partition_interval + ); + + EXECUTE FORMAT( + $QUERY$ + UPDATE %I.part_config + SET + retention = %L, + retention_keep_table = false, + retention_keep_index = false, + infinite_time_partitions = true + WHERE + parent_table = %L; + $QUERY$, + pgmq._get_pg_partman_schema(), + retention_interval, + qualified_a_table_name + ); + +END; +$$ LANGUAGE plpgsql; diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 5f9e2ee2..9c6e7107 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -89,6 +89,46 @@ BEGIN END; $$ LANGUAGE plpgsql; +-- Overloaded function to read messages with conditional retrieval using jsonb +CREATE FUNCTION pgmq.read( + queue_name TEXT, + vt INTEGER, + qty INTEGER, + conditions JSONB DEFAULT NULL +) +RETURNS SETOF pgmq.message_record AS $$ +DECLARE + sql TEXT; + qtable TEXT := pgmq.format_table_name(queue_name, 'q'); +BEGIN + -- Start constructing the base SQL query + sql := 'WITH cte AS ( + SELECT msg_id + FROM pgmq.' || qtable || ' + WHERE vt <= clock_timestamp()'; + + -- Append conditions if provided + IF conditions IS NOT NULL THEN + sql := sql || ' AND message @> ' || quote_literal(conditions); + END IF; + + sql := sql || ' ORDER BY msg_id ASC + LIMIT $1 + FOR UPDATE SKIP LOCKED + ) + UPDATE pgmq.' || qtable || ' m + SET + vt = clock_timestamp() + ' || quote_literal(make_interval(secs => vt)) || ', + 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;'; + + -- Return the result set using EXECUTE + 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( diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index c527f5da..a8ca2cb8 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -37,6 +37,53 @@ SELECT pgmq.create(repeat('a', 47)); (1 row) +-- Test: Creating a queue for testing +-- Expected output: +-- CREATE QUEUE + +-- Test: Sending messages with different attributes +-- Expected output: +-- SEND MESSAGE + +-- Test: Sending Message A1 +-- Expected output: +-- SEND MESSAGE + +-- Test: Sending Message B1 +-- Expected output: +-- SEND MESSAGE + +-- Test: Sending Message A2 +-- Expected output: +-- SEND MESSAGE + +-- Test: Sending Message B2 +-- Expected output: +-- SEND MESSAGE + +-- Test: Retrieve messages with type 'A' +-- Expected output: +-- msg_id | read_ct | message +-- --------+---------+------------------------- +-- 1 | 1 | {"type": "A", "content": "Message A1"} +-- 3 | 1 | {"type": "A", "content": "Message A2"} + +-- Test: Retrieve messages with type 'B' +-- Expected output: +-- msg_id | read_ct | message +-- --------+---------+------------------------- +-- 2 | 1 | {"type": "B", "content": "Message B1"} +-- 4 | 1 | {"type": "B", "content": "Message B2"} + +-- Test: Attempt to retrieve messages with a non-existent type +-- Expected output: +-- (0 rows) + +-- Cleanup +-- Expected output: +-- DROP QUEUE + + -- test_lifecycle -- CREATE with default retention and partition strategy SELECT pgmq.create('test_default_queue'); diff --git a/pgmq-extension/test/sql/base.sql b/pgmq-extension/test/sql/base.sql index fe546038..c06433b4 100644 --- a/pgmq-extension/test/sql/base.sql +++ b/pgmq-extension/test/sql/base.sql @@ -14,6 +14,32 @@ SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message SELECT pgmq.create(repeat('a', 48)); SELECT pgmq.create(repeat('a', 47)); +-- Test: Conditional Message Retrieval + +-- Creating a queue for testing +SELECT pgmq.create('conditional_test_queue'); + +-- Sending messages with different attributes +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A1"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B1"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A2"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B2"}'); + +-- Test: Retrieve messages with type 'A' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "A"}'::jsonb); + +-- Test: Retrieve messages with type 'B' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "B"}'::jsonb); + +-- Test: Attempt to retrieve messages with a non-existent type +SELECT * +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "C"}'::jsonb); + +-- Cleanup +SELECT pgmq.drop_queue('conditional_test_queue', true); + -- test_lifecycle -- CREATE with default retention and partition strategy SELECT pgmq.create('test_default_queue'); From d35d58ea45507818d7b5b8413c01cba5211de0a0 Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 11:56:03 +0530 Subject: [PATCH 2/6] fix: resolved confilcts in tests Signed-off-by: Abinand P --- pgmq-extension/sql/pgmq--1.4.4.sql | 2 +- pgmq-extension/sql/pgmq.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/pgmq-extension/sql/pgmq--1.4.4.sql b/pgmq-extension/sql/pgmq--1.4.4.sql index 9c6e7107..c674fc01 100644 --- a/pgmq-extension/sql/pgmq--1.4.4.sql +++ b/pgmq-extension/sql/pgmq--1.4.4.sql @@ -94,7 +94,7 @@ CREATE FUNCTION pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER, - conditions JSONB DEFAULT NULL + conditions JSONB ) RETURNS SETOF pgmq.message_record AS $$ DECLARE diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index 9c6e7107..c674fc01 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -94,7 +94,7 @@ CREATE FUNCTION pgmq.read( queue_name TEXT, vt INTEGER, qty INTEGER, - conditions JSONB DEFAULT NULL + conditions JSONB ) RETURNS SETOF pgmq.message_record AS $$ DECLARE From 4558f860ff5c4886cf2d3cf162d3b10569812c7c Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 12:32:30 +0530 Subject: [PATCH 3/6] Modifed the base.out file Signed-off-by: Abinand P --- pgmq-extension/test/expected/base.out | 353 ++++---------------------- 1 file changed, 49 insertions(+), 304 deletions(-) diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index a8ca2cb8..63a60005 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -1,215 +1,146 @@ --- CREATE pgmq. -CREATE EXTENSION IF NOT EXISTS pgmq; -CREATE EXTENSION IF NOT EXISTS pg_partman; --- test_unlogged --- CREATE with default retention and partition strategy -SELECT pgmq.create_unlogged('test_unlogged_queue'); +CREATE EXTENSION +CREATE EXTENSION create_unlogged ----------------- (1 row) -SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message - FROM pgmq.read('test_unlogged_queue', 2, 1); msg_id | read_ct | ?column? | ?column? | message --------+---------+----------+----------+-------------------- 1 | 1 | f | t | {"hello": "world"} (1 row) --- test_max_queue_name_size --- CREATE with default retention and partition strategy -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 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)); create -------- (1 row) --- Test: Creating a queue for testing --- Expected output: --- CREATE QUEUE - --- Test: Sending messages with different attributes --- Expected output: --- SEND MESSAGE - --- Test: Sending Message A1 --- Expected output: --- SEND MESSAGE + create +-------- + +(1 row) --- Test: Sending Message B1 --- Expected output: --- SEND MESSAGE + send +------ + 1 +(1 row) --- Test: Sending Message A2 --- Expected output: --- SEND MESSAGE + send +------ + 2 +(1 row) --- Test: Sending Message B2 --- Expected output: --- SEND MESSAGE + send +------ + 3 +(1 row) --- Test: Retrieve messages with type 'A' --- Expected output: --- msg_id | read_ct | message --- --------+---------+------------------------- --- 1 | 1 | {"type": "A", "content": "Message A1"} --- 3 | 1 | {"type": "A", "content": "Message A2"} + send +------ + 4 +(1 row) --- Test: Retrieve messages with type 'B' --- Expected output: --- msg_id | read_ct | message --- --------+---------+------------------------- --- 2 | 1 | {"type": "B", "content": "Message B1"} --- 4 | 1 | {"type": "B", "content": "Message B2"} + msg_id | read_ct | message +--------+---------+---------------------------------------- + 1 | 1 | {"type": "A", "content": "Message A1"} + 3 | 1 | {"type": "A", "content": "Message A2"} +(2 rows) --- Test: Attempt to retrieve messages with a non-existent type --- Expected output: --- (0 rows) + msg_id | read_ct | message +--------+---------+---------------------------------------- + 2 | 1 | {"type": "B", "content": "Message B1"} + 4 | 1 | {"type": "B", "content": "Message B2"} +(2 rows) --- Cleanup --- Expected output: --- DROP QUEUE + msg_id | read_ct | enqueued_at | vt | message +--------+---------+-------------+----+--------- +(0 rows) + drop_queue +------------ + t +(1 row) --- test_lifecycle --- CREATE with default retention and partition strategy -SELECT pgmq.create('test_default_queue'); create -------- (1 row) --- creating a queue must be idempotent --- create with same name again, must be no error -SELECT pgmq.create('test_default_queue'); -NOTICE: relation "q_test_default_queue" already exists, skipping -NOTICE: relation "a_test_default_queue" already exists, skipping -NOTICE: relation "q_test_default_queue_vt_idx" already exists, skipping -NOTICE: relation "archived_at_idx_test_default_queue" already exists, skipping create -------- (1 row) -SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); send ------ 1 (1 row) --- read message --- vt=2, limit=1 -\set msg_id 1 -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) --- set VT to 5 seconds -SELECT vt > clock_timestamp() + '4 seconds'::interval - FROM pgmq.set_vt('test_default_queue', :msg_id, 5); ?column? ---------- t (1 row) --- read again, assert no messages because we just set VT to the future -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- (0 rows) --- read again, now using poll to block until message is ready -SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); ?column? ---------- t (1 row) --- after reading it, set VT to now -SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); ?column? ---------- t (1 row) --- read again, should have msg_id 1 again -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) --- send a batch of 2 messages -SELECT pgmq.create('batch_queue'); create -------- (1 row) -SELECT ARRAY( SELECT pgmq.send_batch( - 'batch_queue', - ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] -)) = ARRAY[1, 2]::BIGINT[]; ?column? ---------- t (1 row) --- CREATE with 5 seconds per partition, 10 seconds retention -SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); create_partitioned -------------------- (1 row) --- CREATE with 10 messages per partition, 20 messages retention -SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); create_partitioned -------------------- (1 row) --- get metrics -SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages - FROM pgmq.metrics('test_duration_queue'); queue_name | queue_length | newest_msg_age_sec | oldest_msg_age_sec | total_messages ---------------------+--------------+--------------------+--------------------+---------------- test_duration_queue | 0 | | | 0 (1 row) --- get metrics all -SELECT * from {PGMQ_SCHEMA}.metrics_all(); -ERROR: syntax error at or near "{" -LINE 1: SELECT * from {PGMQ_SCHEMA}.metrics_all(); - ^ --- delete all the queues --- delete partitioned queues -SELECT pgmq.drop_queue(queue, true) - FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; drop_queue ------------ t t (2 rows) --- drop the rest of the queues -SELECT pgmq.drop_queue(q.queue_name, true) - FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; drop_queue ------------ t @@ -218,598 +149,412 @@ SELECT pgmq.drop_queue(q.queue_name, true) t (4 rows) -SELECT queue_name FROM pgmq.list_queues(); queue_name ------------ (0 rows) --- test_archive -SELECT pgmq.create('archive_queue'); create -------- (1 row) --- no messages in the queue -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) --- no messages in queue archive -SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) --- put messages on the queue -\set msg_id1 1::bigint -\set msg_id2 2::bigint -SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) --- two messages in the queue -SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) --- archive the message. The first two exist so the id should be returned, the --- last one doesn't -SELECT ARRAY( - SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) -) = ARRAY[:msg_id1, :msg_id2]; ?column? ---------- t (1 row) --- should be no messages left on the queue table -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) --- should be two messages in archive -SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) -\set msg_id3 3::bigint -SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) -SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) -SELECT * FROM pgmq.archive('archive_queue', :msg_id3); archive --------- t (1 row) -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) -SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) --- test_read_read_with_poll --- Creating queue -SELECT pgmq.create('test_read_queue'); create -------- (1 row) --- Sending 3 messages to the queue -SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) --- Reading with limit respects the limit -SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); ?column? ---------- t (1 row) --- Reading respects the VT -SELECT ARRAY( - SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) -) = ARRAY[:msg_id2, :msg_id3]; ?column? ---------- t (1 row) --- Read with poll will poll until the first message is available -SELECT clock_timestamp() AS start \gset -SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); ?column? ---------- t (1 row) -SELECT clock_timestamp() - :'start' > '3 second'::interval; ?column? ---------- t (1 row) --- test_purge_queue -SELECT pgmq.create('test_purge_queue'); create -------- (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 1 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 2 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 3 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 4 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 5 (1 row) -SELECT * FROM pgmq.purge_queue('test_purge_queue'); purge_queue ------------- 5 (1 row) -SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; ?column? ---------- t (1 row) --- test_pop -SELECT pgmq.create('test_pop_queue'); create -------- (1 row) -SELECT * FROM pgmq.pop('test_pop_queue'); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) -SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset -SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 2 (1 row) -SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 3 (1 row) -SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); ?column? ---------- t (1 row) --- test_set_vt -SELECT pgmq.create('test_set_vt_queue'); create -------- (1 row) -SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) -SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset --- set message invisible for 100 seconds -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); msg_id -------- 1 (1 row) --- read message, it should not be visible -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- (0 rows) --- make it visible -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); msg_id -------- 1 (1 row) --- set vt works if message is readable -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- 1 (1 row) --- test_partitioned_delete -\set partition_interval 2 -\set retention_interval 2 --- We first will drop pg_partman and assert that create fails without the --- extension installed -DROP EXTENSION pg_partman; -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); -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 11 at PERFORM --- With the extension existing, the queue is created successfully -CREATE EXTENSION pg_partman; -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); +DROP EXTENSION +CREATE EXTENSION create_partitioned -------------------- (1 row) --- queue shows up in list queues -SELECT queue_name FROM pgmq.list_queues() - WHERE queue_name = 'test_partitioned_queue'; queue_name ------------------------ test_partitioned_queue (1 row) --- Sending 3 messages to the queue -SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset -SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset -SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset -SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) --- Deleting message 3 -SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); delete -------- t (1 row) -SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) --- Deleting batch -SELECT ARRAY( - SELECT archive FROM pgmq.archive( - 'test_partitioned_queue', - ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] - ) -) = ARRAY[:msg_id1, :msg_id2]::bigint[]; ?column? ---------- t (1 row) --- test_transaction_create -BEGIN; -SELECT pgmq.create('transaction_test_queue'); +BEGIN create -------- (1 row) -ROLLBACK; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; +ROLLBACK tablename ----------- (0 rows) --- test_detach_archive -SELECT pgmq.create('detach_archive_queue'); create -------- (1 row) -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; +DROP EXTENSION tablename ----------- (0 rows) --- With detach, archive remains -CREATE EXTENSION pgmq; -SELECT pgmq.create('detach_archive_queue'); +CREATE EXTENSION create -------- (1 row) -SELECT pgmq.detach_archive('detach_archive_queue'); detach_archive ---------------- (1 row) -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; +DROP EXTENSION tablename ------------------------ a_detach_archive_queue (1 row) ---Truncated Index When queue name is max. -CREATE EXTENSION pgmq; -SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); +CREATE EXTENSION create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); -NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" convert_archive_partitioned ----------------------------- (1 row) ---Check for archive is already partitioned -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); -NOTICE: Table a_long_queue_name_123456789012345678901234567890s is already partitioned convert_archive_partitioned ----------------------------- (1 row) ---Error out due to Index duplicate index at old table. -SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); -NOTICE: identifier "archived_at_idx_long_queue_name_1234567890123456789012345678901_old" will be truncated to "archived_at_idx_long_queue_name_1234567890123456789012345678901" -ERROR: relation "archived_at_idx_long_queue_name_1234567890123456789012345678901" already exists -CONTEXT: SQL statement "ALTER INDEX pgmq.archived_at_idx_long_queue_name_1234567890123456789012345678901 RENAME TO archived_at_idx_long_queue_name_1234567890123456789012345678901_old" -PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 34 at EXECUTE ---Success -SELECT pgmq.create('long_queue_name_'); create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_'); convert_archive_partitioned ----------------------------- (1 row) -\set SHOW_CONTEXT never ---Failed SQL injection attack -SELECT pgmq.create('abc'); create -------- (1 row) -SELECT - pgmq.delete( - 'abc where false; - create table public.attack_vector(id int); - delete from pgmq.q_abc', - 1 - ); -ERROR: queue name contains invalid characters: $, ;, --, or \' ---Special characters in queue name -SELECT pgmq.create('queue-hyphened'); create -------- (1 row) -SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('queue-hyphened', 1); archive --------- t (1 row) -SELECT pgmq.create('QueueCased'); create -------- (1 row) -SELECT pgmq.send('QueueCased', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('QueueCased', 1); archive --------- t (1 row) -SELECT pgmq.create_partitioned('queue-hyphened-part'); create_partitioned -------------------- (1 row) -SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('queue-hyphened-part', 1); archive --------- t (1 row) -SELECT pgmq.create_partitioned('QueueCasedPart'); create_partitioned -------------------- (1 row) -SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('QueueCasedPart', 1); archive --------- t (1 row) --- fails with invalid queue name -SELECT pgmq.create('dollar$-signed'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.create_partitioned('dollar$-signed-part'); -ERROR: queue name contains invalid characters: $, ;, --, or \' --- input validation success -SELECT pgmq.format_table_name('cat', 'q'); format_table_name ------------------- q_cat (1 row) -SELECT pgmq.format_table_name('cat-dog', 'a'); format_table_name ------------------- a_cat-dog (1 row) -SELECT pgmq.format_table_name('cat_dog', 'q'); format_table_name ------------------- q_cat_dog (1 row) --- input validation failure -SELECT pgmq.format_table_name('dollar$fail', 'q'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('semicolon;fail', 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' ---Cleanup tests -DROP EXTENSION pgmq CASCADE; -DROP EXTENSION pg_partman CASCADE; +DROP EXTENSION +DROP EXTENSION From bbc20f266f953acffe336bee2652deb609a03b4d Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 12:57:59 +0530 Subject: [PATCH 4/6] modifed the base.out file Signed-off-by: Abinand P --- pgmq-extension/results/base.out | 938 -------------------------- pgmq-extension/test/expected/base.out | 374 +++++++++- 2 files changed, 362 insertions(+), 950 deletions(-) delete mode 100644 pgmq-extension/results/base.out diff --git a/pgmq-extension/results/base.out b/pgmq-extension/results/base.out deleted file mode 100644 index 87d82d98..00000000 --- a/pgmq-extension/results/base.out +++ /dev/null @@ -1,938 +0,0 @@ --- CREATE pgmq. -CREATE EXTENSION IF NOT EXISTS pgmq; -CREATE EXTENSION IF NOT EXISTS pg_partman; -ERROR: extension "pg_partman" is not available -DETAIL: Could not open extension control file "/usr/share/postgresql/16/extension/pg_partman.control": No such file or directory. -HINT: The extension must first be installed on the system where PostgreSQL is running. - --- test_unlogged --- CREATE with default retention and partition strategy -SELECT pgmq.create_unlogged('test_unlogged_queue'); - create_unlogged ------------------ - -(1 row) - -SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); - send ------- - 1 -(1 row) - -SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message - FROM pgmq.read('test_unlogged_queue', 2, 1); - msg_id | read_ct | ?column? | ?column? | message ---------+---------+----------+----------+-------------------- - 1 | 1 | f | t | {"hello": "world"} -(1 row) - - --- test_max_queue_name_size --- CREATE with default retention and partition strategy -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 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)); - create --------- - -(1 row) - - --- test_lifecycle --- CREATE with default retention and partition strategy -SELECT pgmq.create('test_default_queue'); - create --------- - -(1 row) - - --- creating a queue must be idempotent --- create with same name again, must be no error -SELECT pgmq.create('test_default_queue'); -NOTICE: relation "q_test_default_queue" already exists, skipping -NOTICE: relation "a_test_default_queue" already exists, skipping -NOTICE: relation "q_test_default_queue_vt_idx" already exists, skipping -NOTICE: relation "archived_at_idx_test_default_queue" already exists, skipping - create --------- - -(1 row) - - -SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); - send ------- - 1 -(1 row) - - --- read message --- vt=2, limit=1 -\set msg_id 1 -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); - ?column? ----------- - t -(1 row) - - --- set VT to 5 seconds -SELECT vt > clock_timestamp() + '4 seconds'::interval - FROM pgmq.set_vt('test_default_queue', :msg_id, 5); - ?column? ----------- - t -(1 row) - - --- read again, assert no messages because we just set VT to the future -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); - ?column? ----------- -(0 rows) - - --- read again, now using poll to block until message is ready -SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); - ?column? ----------- - t -(1 row) - - --- after reading it, set VT to now -SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); - ?column? ----------- - t -(1 row) - - --- read again, should have msg_id 1 again -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); - ?column? ----------- - t -(1 row) - - --- send a batch of 2 messages -SELECT pgmq.create('batch_queue'); - create --------- - -(1 row) - -SELECT ARRAY( SELECT pgmq.send_batch( - 'batch_queue', - ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] -)) = ARRAY[1, 2]::BIGINT[]; - ?column? ----------- - t -(1 row) - - --- CREATE with 5 seconds per partition, 10 seconds retention -SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); -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 11 at PERFORM - --- CREATE with 10 messages per partition, 20 messages retention -SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); -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 11 at PERFORM - --- get metrics -SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages - FROM pgmq.metrics('test_duration_queue'); -ERROR: relation "pgmq.q_test_duration_queue" does not exist -LINE 8: FROM pgmq.q_test_duration_queue - ^ -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_test_duration_queue - ), - all_metrics AS ( - SELECT CASE - WHEN is_called THEN last_value ELSE 0 - END as total_messages - FROM pgmq.q_test_duration_queue_msg_id_seq - ) - SELECT - 'test_duration_queue' 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 - -CONTEXT: PL/pgSQL function pgmq.metrics(text) line 34 at EXECUTE - --- get metrics all -SELECT * from {PGMQ_SCHEMA}.metrics_all(); -ERROR: syntax error at or near "{" -LINE 1: SELECT * from {PGMQ_SCHEMA}.metrics_all(); - ^ - --- delete all the queues --- delete partitioned queues -SELECT pgmq.drop_queue(queue, true) - FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; -ERROR: relation "pgmq.q_test_duration_queue" does not exist -CONTEXT: SQL statement " - ALTER EXTENSION pgmq DROP TABLE pgmq.q_test_duration_queue - " -PL/pgSQL function pgmq.drop_queue(text,boolean) line 8 at EXECUTE - --- drop the rest of the queues -SELECT pgmq.drop_queue(q.queue_name, true) - FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; -ERROR: null values cannot be formatted as an SQL identifier -CONTEXT: PL/pgSQL function pgmq.drop_queue(text,boolean) line 50 at EXECUTE - -SELECT queue_name FROM pgmq.list_queues(); - queue_name -------------------------------------------------- - test_unlogged_queue - aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa - test_default_queue - batch_queue -(4 rows) - - --- test_archive -SELECT pgmq.create('archive_queue'); - create --------- - -(1 row) - - --- no messages in the queue -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; - ?column? ----------- - t -(1 row) - - --- no messages in queue archive -SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; - ?column? ----------- - t -(1 row) - - --- put messages on the queue -\set msg_id1 1::bigint -\set msg_id2 2::bigint -SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); - ?column? ----------- - t -(1 row) - -SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); - ?column? ----------- - t -(1 row) - - --- two messages in the queue -SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; - ?column? ----------- - t -(1 row) - - --- archive the message. The first two exist so the id should be returned, the --- last one doesn't -SELECT ARRAY( - SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) -) = ARRAY[:msg_id1, :msg_id2]; - ?column? ----------- - t -(1 row) - - --- should be no messages left on the queue table -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; - ?column? ----------- - t -(1 row) - - --- should be two messages in archive -SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; - ?column? ----------- - t -(1 row) - - -\set msg_id3 3::bigint -SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); - ?column? ----------- - t -(1 row) - -SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; - ?column? ----------- - t -(1 row) - -SELECT * FROM pgmq.archive('archive_queue', :msg_id3); - archive ---------- - t -(1 row) - -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; - ?column? ----------- - t -(1 row) - -SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; - ?column? ----------- - t -(1 row) - - --- test_read_read_with_poll --- Creating queue -SELECT pgmq.create('test_read_queue'); - create --------- - -(1 row) - - --- Sending 3 messages to the queue -SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); - ?column? ----------- - t -(1 row) - -SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); - ?column? ----------- - t -(1 row) - -SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); - ?column? ----------- - t -(1 row) - - --- Reading with limit respects the limit -SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); - ?column? ----------- - t -(1 row) - - --- Reading respects the VT -SELECT ARRAY( - SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) -) = ARRAY[:msg_id2, :msg_id3]; - ?column? ----------- - t -(1 row) - - --- Read with poll will poll until the first message is available -SELECT clock_timestamp() AS start \gset -SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); - ?column? ----------- - t -(1 row) - -SELECT clock_timestamp() - :'start' > '3 second'::interval; - ?column? ----------- - t -(1 row) - - --- test_purge_queue -SELECT pgmq.create('test_purge_queue'); - create --------- - -(1 row) - -SELECT * from pgmq.send('test_purge_queue', '0'); - send ------- - 1 -(1 row) - -SELECT * from pgmq.send('test_purge_queue', '0'); - send ------- - 2 -(1 row) - -SELECT * from pgmq.send('test_purge_queue', '0'); - send ------- - 3 -(1 row) - -SELECT * from pgmq.send('test_purge_queue', '0'); - send ------- - 4 -(1 row) - -SELECT * from pgmq.send('test_purge_queue', '0'); - send ------- - 5 -(1 row) - - -SELECT * FROM pgmq.purge_queue('test_purge_queue'); - purge_queue -------------- - 5 -(1 row) - -SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; - ?column? ----------- - t -(1 row) - - --- test_pop -SELECT pgmq.create('test_pop_queue'); - create --------- - -(1 row) - -SELECT * FROM pgmq.pop('test_pop_queue'); - msg_id | read_ct | enqueued_at | vt | message ---------+---------+-------------+----+--------- -(0 rows) - - -SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset -SELECT * from pgmq.send('test_pop_queue', '0'); - send ------- - 2 -(1 row) - -SELECT * from pgmq.send('test_pop_queue', '0'); - send ------- - 3 -(1 row) - - -SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); - ?column? ----------- - t -(1 row) - - --- test_set_vt -SELECT pgmq.create('test_set_vt_queue'); - create --------- - -(1 row) - -SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); - msg_id | read_ct | enqueued_at | vt | message ---------+---------+-------------+----+--------- -(0 rows) - - -SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset - --- set message invisible for 100 seconds -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); - msg_id --------- - 1 -(1 row) - - --- read message, it should not be visible -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); - msg_id --------- -(0 rows) - - --- make it visible -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); - msg_id --------- - 1 -(1 row) - - --- set vt works if message is readable -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); - msg_id --------- - 1 -(1 row) - - --- test_partitioned_delete -\set partition_interval 2 -\set retention_interval 2 - --- We first will drop pg_partman and assert that create fails without the --- extension installed -DROP EXTENSION pg_partman; -ERROR: extension "pg_partman" does not exist - -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); -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 11 at PERFORM - --- With the extension existing, the queue is created successfully -CREATE EXTENSION pg_partman; -ERROR: extension "pg_partman" is not available -DETAIL: Could not open extension control file "/usr/share/postgresql/16/extension/pg_partman.control": No such file or directory. -HINT: The extension must first be installed on the system where PostgreSQL is running. -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); -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 11 at PERFORM - --- queue shows up in list queues -SELECT queue_name FROM pgmq.list_queues() - WHERE queue_name = 'test_partitioned_queue'; - queue_name ------------- -(0 rows) - - --- Sending 3 messages to the queue -SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... - ^ -QUERY: - INSERT INTO pgmq.q_test_partitioned_queue (vt, message) - VALUES ((clock_timestamp() + '@ 0'), $1) - RETURNING msg_id; - -CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY -SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... - ^ -QUERY: - INSERT INTO pgmq.q_test_partitioned_queue (vt, message) - VALUES ((clock_timestamp() + '@ 0'), $1) - RETURNING msg_id; - -CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY -SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 2: INSERT INTO pgmq.q_test_partitioned_queue (vt, messa... - ^ -QUERY: - INSERT INTO pgmq.q_test_partitioned_queue (vt, message) - VALUES ((clock_timestamp() + '@ 0'), $1) - RETURNING msg_id; - -CONTEXT: PL/pgSQL function pgmq.send(text,jsonb,integer) line 14 at RETURN QUERY - -SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 1: SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; - ^ - --- Deleting message 3 -SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 2: DELETE FROM pgmq.q_test_partitioned_queue - ^ -QUERY: - DELETE FROM pgmq.q_test_partitioned_queue - WHERE msg_id = $1 - RETURNING msg_id - -CONTEXT: PL/pgSQL function pgmq.delete(text,bigint) line 15 at EXECUTE -SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 1: SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; - ^ - --- Deleting batch -SELECT ARRAY( - SELECT archive FROM pgmq.archive( - 'test_partitioned_queue', - ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] - ) -) = ARRAY[:msg_id1, :msg_id2]::bigint[]; -ERROR: relation "pgmq.q_test_partitioned_queue" does not exist -LINE 3: DELETE FROM pgmq.q_test_partitioned_queue - ^ -QUERY: - WITH archived AS ( - DELETE FROM pgmq.q_test_partitioned_queue - WHERE msg_id = ANY($1) - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.a_test_partitioned_queue (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - -CONTEXT: PL/pgSQL function pgmq.archive(text,bigint[]) line 21 at RETURN QUERY - --- test_transaction_create -BEGIN; -SELECT pgmq.create('transaction_test_queue'); - create --------- - -(1 row) - -ROLLBACK; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; - tablename ------------ -(0 rows) - - --- test_detach_archive -SELECT pgmq.create('detach_archive_queue'); - create --------- - -(1 row) - -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; - tablename ------------ -(0 rows) - - --- With detach, archive remains -CREATE EXTENSION pgmq; -SELECT pgmq.create('detach_archive_queue'); - create --------- - -(1 row) - -SELECT pgmq.detach_archive('detach_archive_queue'); - detach_archive ----------------- - -(1 row) - -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; - tablename ------------------------- - a_detach_archive_queue -(1 row) - - ---Truncated Index When queue name is max. -CREATE EXTENSION pgmq; -SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); - create --------- - -(1 row) - -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); -NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" -ERROR: null values cannot be formatted as an SQL identifier -CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE - ---Check for archive is already partitioned -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); -NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" -ERROR: null values cannot be formatted as an SQL identifier -CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE - ---Error out due to Index duplicate index at old table. -SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); - create --------- - -(1 row) - -SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); -NOTICE: identifier "archived_at_idx_long_queue_name_1234567890123456789012345678901_old" will be truncated to "archived_at_idx_long_queue_name_1234567890123456789012345678901" -ERROR: relation "archived_at_idx_long_queue_name_1234567890123456789012345678901" already exists -CONTEXT: SQL statement "ALTER INDEX pgmq.archived_at_idx_long_queue_name_1234567890123456789012345678901 RENAME TO archived_at_idx_long_queue_name_1234567890123456789012345678901_old" -PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 34 at EXECUTE - ---Success -SELECT pgmq.create('long_queue_name_'); - create --------- - -(1 row) - -SELECT pgmq.convert_archive_partitioned('long_queue_name_'); -ERROR: null values cannot be formatted as an SQL identifier -CONTEXT: PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 39 at EXECUTE - -\set SHOW_CONTEXT never - ---Failed SQL injection attack -SELECT pgmq.create('abc'); - create --------- - -(1 row) - -SELECT - pgmq.delete( - 'abc where false; - create table public.attack_vector(id int); - delete from pgmq.q_abc', - 1 - ); -ERROR: queue name contains invalid characters: $, ;, --, or \' - ---Special characters in queue name -SELECT pgmq.create('queue-hyphened'); - create --------- - -(1 row) - -SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); - send ------- - 1 -(1 row) - -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); - msg_id | read_ct | message ---------+---------+-------------------- - 1 | 1 | {"hello": "world"} -(1 row) - -SELECT pgmq.archive('queue-hyphened', 1); - archive ---------- - t -(1 row) - - -SELECT pgmq.create('QueueCased'); - create --------- - -(1 row) - -SELECT pgmq.send('QueueCased', '{"hello":"world"}'); - send ------- - 1 -(1 row) - -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); - msg_id | read_ct | message ---------+---------+-------------------- - 1 | 1 | {"hello": "world"} -(1 row) - -SELECT pgmq.archive('QueueCased', 1); - archive ---------- - t -(1 row) - - -SELECT pgmq.create_partitioned('queue-hyphened-part'); -ERROR: pg_partman is required for partitioned queues -SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); -ERROR: relation "pgmq.q_queue-hyphened-part" does not exist -LINE 2: INSERT INTO pgmq."q_queue-hyphened-part" (vt, messag... - ^ -QUERY: - INSERT INTO pgmq."q_queue-hyphened-part" (vt, message) - VALUES ((clock_timestamp() + '@ 0'), $1) - RETURNING msg_id; - -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); -ERROR: relation "pgmq.q_queue-hyphened-part" does not exist -LINE 5: FROM pgmq."q_queue-hyphened-part" - ^ -QUERY: - WITH cte AS - ( - SELECT msg_id - FROM pgmq."q_queue-hyphened-part" - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq."q_queue-hyphened-part" m - SET - vt = clock_timestamp() + '@ 1 sec', - 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; - -SELECT pgmq.archive('queue-hyphened-part', 1); -ERROR: relation "pgmq.q_queue-hyphened-part" does not exist -LINE 3: DELETE FROM pgmq."q_queue-hyphened-part" - ^ -QUERY: - WITH archived AS ( - DELETE FROM pgmq."q_queue-hyphened-part" - WHERE msg_id = $1 - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq."a_queue-hyphened-part" (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - - -SELECT pgmq.create_partitioned('QueueCasedPart'); -ERROR: pg_partman is required for partitioned queues -SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); -ERROR: relation "pgmq.q_queuecasedpart" does not exist -LINE 2: INSERT INTO pgmq.q_queuecasedpart (vt, message) - ^ -QUERY: - INSERT INTO pgmq.q_queuecasedpart (vt, message) - VALUES ((clock_timestamp() + '@ 0'), $1) - RETURNING msg_id; - -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); -ERROR: relation "pgmq.q_queuecasedpart" does not exist -LINE 5: FROM pgmq.q_queuecasedpart - ^ -QUERY: - WITH cte AS - ( - SELECT msg_id - FROM pgmq.q_queuecasedpart - WHERE vt <= clock_timestamp() - ORDER BY msg_id ASC - LIMIT $1 - FOR UPDATE SKIP LOCKED - ) - UPDATE pgmq.q_queuecasedpart m - SET - vt = clock_timestamp() + '@ 1 sec', - 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; - -SELECT pgmq.archive('QueueCasedPart', 1); -ERROR: relation "pgmq.q_queuecasedpart" does not exist -LINE 3: DELETE FROM pgmq.q_queuecasedpart - ^ -QUERY: - WITH archived AS ( - DELETE FROM pgmq.q_queuecasedpart - WHERE msg_id = $1 - RETURNING msg_id, vt, read_ct, enqueued_at, message - ) - INSERT INTO pgmq.a_queuecasedpart (msg_id, vt, read_ct, enqueued_at, message) - SELECT msg_id, vt, read_ct, enqueued_at, message - FROM archived - RETURNING msg_id; - - --- fails with invalid queue name -SELECT pgmq.create('dollar$-signed'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.create_partitioned('dollar$-signed-part'); -ERROR: queue name contains invalid characters: $, ;, --, or \' - --- input validation success -SELECT pgmq.format_table_name('cat', 'q'); - format_table_name -------------------- - q_cat -(1 row) - -SELECT pgmq.format_table_name('cat-dog', 'a'); - format_table_name -------------------- - a_cat-dog -(1 row) - -SELECT pgmq.format_table_name('cat_dog', 'q'); - format_table_name -------------------- - q_cat_dog -(1 row) - - --- input validation failure -SELECT pgmq.format_table_name('dollar$fail', 'q'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('semicolon;fail', 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); -ERROR: queue name contains invalid characters: $, ;, --, or \' - ---Cleanup tests -DROP EXTENSION pgmq CASCADE; -DROP EXTENSION pg_partman CASCADE; -ERROR: extension "pg_partman" does not exist diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index 63a60005..f64a3ed7 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -1,146 +1,258 @@ -CREATE EXTENSION -CREATE EXTENSION +-- CREATE pgmq. +CREATE EXTENSION IF NOT EXISTS pgmq; +CREATE EXTENSION IF NOT EXISTS pg_partman; + +-- test_unlogged +-- CREATE with default retention and partition strategy +SELECT pgmq.create_unlogged('test_unlogged_queue'); create_unlogged ----------------- (1 row) +SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); send ------ 1 (1 row) +SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message + FROM pgmq.read('test_unlogged_queue', 2, 1); msg_id | read_ct | ?column? | ?column? | message --------+---------+----------+----------+-------------------- 1 | 1 | f | t | {"hello": "world"} (1 row) + +-- test_max_queue_name_size +-- CREATE with default retention and partition strategy +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 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)); create -------- (1 row) + +-- Test: Conditional Message Retrieval + +-- Creating a queue for testing +SELECT pgmq.create('conditional_test_queue'); create -------- (1 row) + +-- Sending messages with different attributes +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A1"}'); send ------ 1 (1 row) +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B1"}'); send ------ 2 (1 row) +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A2"}'); send ------ 3 (1 row) +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B2"}'); send ------ 4 (1 row) + +-- Test: Retrieve messages with type 'A' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "A"}'::jsonb); msg_id | read_ct | message --------+---------+---------------------------------------- 1 | 1 | {"type": "A", "content": "Message A1"} 3 | 1 | {"type": "A", "content": "Message A2"} (2 rows) + +-- Test: Retrieve messages with type 'B' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "B"}'::jsonb); msg_id | read_ct | message --------+---------+---------------------------------------- 2 | 1 | {"type": "B", "content": "Message B1"} 4 | 1 | {"type": "B", "content": "Message B2"} (2 rows) + +-- Test: Attempt to retrieve messages with a non-existent type +SELECT * +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "C"}'::jsonb); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) + +-- Cleanup +SELECT pgmq.drop_queue('conditional_test_queue', true); drop_queue ------------ t (1 row) + +-- test_lifecycle +-- CREATE with default retention and partition strategy +SELECT pgmq.create('test_default_queue'); create -------- (1 row) + +-- creating a queue must be idempotent +-- create with same name again, must be no error +SELECT pgmq.create('test_default_queue'); +NOTICE: relation "q_test_default_queue" already exists, skipping +NOTICE: relation "a_test_default_queue" already exists, skipping +NOTICE: relation "q_test_default_queue_vt_idx" already exists, skipping +NOTICE: relation "archived_at_idx_test_default_queue" already exists, skipping create -------- (1 row) + +SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); send ------ 1 (1 row) + +-- read message +-- vt=2, limit=1 +\set msg_id 1 +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) + +-- set VT to 5 seconds +SELECT vt > clock_timestamp() + '4 seconds'::interval + FROM pgmq.set_vt('test_default_queue', :msg_id, 5); ?column? ---------- t (1 row) + +-- read again, assert no messages because we just set VT to the future +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- (0 rows) + +-- read again, now using poll to block until message is ready +SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); ?column? ---------- t (1 row) + +-- after reading it, set VT to now +SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); ?column? ---------- t (1 row) + +-- read again, should have msg_id 1 again +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) + +-- send a batch of 2 messages +SELECT pgmq.create('batch_queue'); create -------- (1 row) +SELECT ARRAY( SELECT pgmq.send_batch( + 'batch_queue', + ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] +)) = ARRAY[1, 2]::BIGINT[]; ?column? ---------- t (1 row) + +-- CREATE with 5 seconds per partition, 10 seconds retention +SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); create_partitioned -------------------- (1 row) + +-- CREATE with 10 messages per partition, 20 messages retention +SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); create_partitioned -------------------- (1 row) + +-- get metrics +SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages + FROM pgmq.metrics('test_duration_queue'); queue_name | queue_length | newest_msg_age_sec | oldest_msg_age_sec | total_messages ---------------------+--------------+--------------------+--------------------+---------------- test_duration_queue | 0 | | | 0 (1 row) + +-- get metrics all +SELECT * from {PGMQ_SCHEMA}.metrics_all(); +ERROR: syntax error at or near "{" +LINE 1: SELECT * from {PGMQ_SCHEMA}.metrics_all(); + ^ + +-- delete all the queues +-- delete partitioned queues +SELECT pgmq.drop_queue(queue, true) + FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; drop_queue ------------ t t (2 rows) + +-- drop the rest of the queues +SELECT pgmq.drop_queue(q.queue_name, true) + FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; drop_queue ------------ t @@ -149,412 +261,650 @@ CREATE EXTENSION t (4 rows) + +SELECT queue_name FROM pgmq.list_queues(); queue_name ------------ (0 rows) + +-- test_archive +SELECT pgmq.create('archive_queue'); create -------- (1 row) + +-- no messages in the queue +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) + +-- no messages in queue archive +SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) + +-- put messages on the queue +\set msg_id1 1::bigint +\set msg_id2 2::bigint +SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) +SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) + +-- two messages in the queue +SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) + +-- archive the message. The first two exist so the id should be returned, the +-- last one doesn't +SELECT ARRAY( + SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) +) = ARRAY[:msg_id1, :msg_id2]; ?column? ---------- t (1 row) + +-- should be no messages left on the queue table +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) + +-- should be two messages in archive +SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) + +\set msg_id3 3::bigint +SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) +SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) +SELECT * FROM pgmq.archive('archive_queue', :msg_id3); archive --------- t (1 row) +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) +SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) + +-- test_read_read_with_poll +-- Creating queue +SELECT pgmq.create('test_read_queue'); create -------- (1 row) + +-- Sending 3 messages to the queue +SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) +SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) +SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) + +-- Reading with limit respects the limit +SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); ?column? ---------- t (1 row) + +-- Reading respects the VT +SELECT ARRAY( + SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) +) = ARRAY[:msg_id2, :msg_id3]; ?column? ---------- t (1 row) + +-- Read with poll will poll until the first message is available +SELECT clock_timestamp() AS start \gset +SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); ?column? ---------- t (1 row) +SELECT clock_timestamp() - :'start' > '3 second'::interval; ?column? ---------- t (1 row) + +-- test_purge_queue +SELECT pgmq.create('test_purge_queue'); create -------- (1 row) +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 1 (1 row) +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 2 (1 row) +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 3 (1 row) +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 4 (1 row) +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 5 (1 row) + +SELECT * FROM pgmq.purge_queue('test_purge_queue'); purge_queue ------------- 5 (1 row) +SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; ?column? ---------- t (1 row) + +-- test_pop +SELECT pgmq.create('test_pop_queue'); create -------- (1 row) +SELECT * FROM pgmq.pop('test_pop_queue'); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) + +SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset +SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 2 (1 row) +SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 3 (1 row) + +SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); ?column? ---------- t (1 row) + +-- test_set_vt +SELECT pgmq.create('test_set_vt_queue'); create -------- (1 row) +SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) + +SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset + +-- set message invisible for 100 seconds +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); msg_id -------- 1 (1 row) + +-- read message, it should not be visible +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- (0 rows) + +-- make it visible +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); msg_id -------- 1 (1 row) + +-- set vt works if message is readable +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- 1 (1 row) -DROP EXTENSION -CREATE EXTENSION + +-- test_partitioned_delete +\set partition_interval 2 +\set retention_interval 2 + +-- We first will drop pg_partman and assert that create fails without the +-- extension installed +DROP EXTENSION pg_partman; + +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); +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 11 at PERFORM + +-- With the extension existing, the queue is created successfully +CREATE EXTENSION pg_partman; +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); create_partitioned -------------------- (1 row) + +-- queue shows up in list queues +SELECT queue_name FROM pgmq.list_queues() + WHERE queue_name = 'test_partitioned_queue'; queue_name ------------------------ test_partitioned_queue (1 row) + +-- Sending 3 messages to the queue +SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset +SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset +SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset + +SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) + +-- Deleting message 3 +SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); delete -------- t (1 row) +SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) + +-- Deleting batch +SELECT ARRAY( + SELECT archive FROM pgmq.archive( + 'test_partitioned_queue', + ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] + ) +) = ARRAY[:msg_id1, :msg_id2]::bigint[]; ?column? ---------- t (1 row) -BEGIN + +-- test_transaction_create +BEGIN; +SELECT pgmq.create('transaction_test_queue'); create -------- (1 row) -ROLLBACK +ROLLBACK; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; tablename ----------- (0 rows) + +-- test_detach_archive +SELECT pgmq.create('detach_archive_queue'); create -------- (1 row) -DROP EXTENSION +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; tablename ----------- (0 rows) -CREATE EXTENSION + +-- With detach, archive remains +CREATE EXTENSION pgmq; +SELECT pgmq.create('detach_archive_queue'); create -------- (1 row) +SELECT pgmq.detach_archive('detach_archive_queue'); detach_archive ---------------- (1 row) -DROP EXTENSION +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; tablename ------------------------ a_detach_archive_queue (1 row) -CREATE EXTENSION + +--Truncated Index When queue name is max. +CREATE EXTENSION pgmq; +SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); create -------- (1 row) +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); +NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" convert_archive_partitioned ----------------------------- (1 row) + +--Check for archive is already partitioned +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); +NOTICE: Table a_long_queue_name_123456789012345678901234567890s is already partitioned convert_archive_partitioned ----------------------------- (1 row) + +--Error out due to Index duplicate index at old table. +SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); create -------- (1 row) +SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); +NOTICE: identifier "archived_at_idx_long_queue_name_1234567890123456789012345678901_old" will be truncated to "archived_at_idx_long_queue_name_1234567890123456789012345678901" +ERROR: relation "archived_at_idx_long_queue_name_1234567890123456789012345678901" already exists +CONTEXT: SQL statement "ALTER INDEX pgmq.archived_at_idx_long_queue_name_1234567890123456789012345678901 RENAME TO archived_at_idx_long_queue_name_1234567890123456789012345678901_old" +PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 34 at EXECUTE + +--Success +SELECT pgmq.create('long_queue_name_'); create -------- (1 row) +SELECT pgmq.convert_archive_partitioned('long_queue_name_'); convert_archive_partitioned ----------------------------- (1 row) + +\set SHOW_CONTEXT never + +--Failed SQL injection attack +SELECT pgmq.create('abc'); create -------- (1 row) +SELECT + pgmq.delete( + 'abc where false; + create table public.attack_vector(id int); + delete from pgmq.q_abc', + 1 + ); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +--Special characters in queue name +SELECT pgmq.create('queue-hyphened'); create -------- (1 row) +SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); send ------ 1 (1 row) +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) +SELECT pgmq.archive('queue-hyphened', 1); archive --------- t (1 row) + +SELECT pgmq.create('QueueCased'); create -------- (1 row) +SELECT pgmq.send('QueueCased', '{"hello":"world"}'); send ------ 1 (1 row) +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) +SELECT pgmq.archive('QueueCased', 1); archive --------- t (1 row) + +SELECT pgmq.create_partitioned('queue-hyphened-part'); create_partitioned -------------------- (1 row) +SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); send ------ 1 (1 row) +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) +SELECT pgmq.archive('queue-hyphened-part', 1); archive --------- t (1 row) + +SELECT pgmq.create_partitioned('QueueCasedPart'); create_partitioned -------------------- (1 row) +SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); send ------ 1 (1 row) +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) +SELECT pgmq.archive('QueueCasedPart', 1); archive --------- t (1 row) + +-- fails with invalid queue name +SELECT pgmq.create('dollar$-signed'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.create_partitioned('dollar$-signed-part'); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +-- input validation success +SELECT pgmq.format_table_name('cat', 'q'); format_table_name ------------------- q_cat (1 row) +SELECT pgmq.format_table_name('cat-dog', 'a'); format_table_name ------------------- a_cat-dog (1 row) +SELECT pgmq.format_table_name('cat_dog', 'q'); format_table_name ------------------- q_cat_dog (1 row) -DROP EXTENSION -DROP EXTENSION + +-- input validation failure +SELECT pgmq.format_table_name('dollar$fail', 'q'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name('semicolon;fail', 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' +SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); +ERROR: queue name contains invalid characters: $, ;, --, or \' + +--Cleanup tests +DROP EXTENSION pgmq CASCADE; +DROP EXTENSION pg_partman CASCADE; From 1d4682015e4f783fe4c343a5bd9f54217b29db10 Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 13:20:37 +0530 Subject: [PATCH 5/6] fix tests --- pgmq-extension/sql/pgmq.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/pgmq-extension/sql/pgmq.sql b/pgmq-extension/sql/pgmq.sql index c674fc01..61e1e049 100644 --- a/pgmq-extension/sql/pgmq.sql +++ b/pgmq-extension/sql/pgmq.sql @@ -123,7 +123,6 @@ BEGIN FROM cte WHERE m.msg_id = cte.msg_id RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message;'; - -- Return the result set using EXECUTE RETURN QUERY EXECUTE sql USING qty; END; From a55373b75e927a06d57149676f59255272038f61 Mon Sep 17 00:00:00 2001 From: Abinand P Date: Sun, 20 Oct 2024 13:27:17 +0530 Subject: [PATCH 6/6] fixing test Signed-off-by: Abinand P --- pgmq-extension/test/expected/base.out | 662 +++++++++++++------------- 1 file changed, 331 insertions(+), 331 deletions(-) diff --git a/pgmq-extension/test/expected/base.out b/pgmq-extension/test/expected/base.out index f64a3ed7..60382bde 100644 --- a/pgmq-extension/test/expected/base.out +++ b/pgmq-extension/test/expected/base.out @@ -1,129 +1,129 @@ --- CREATE pgmq. -CREATE EXTENSION IF NOT EXISTS pgmq; -CREATE EXTENSION IF NOT EXISTS pg_partman; - --- test_unlogged --- CREATE with default retention and partition strategy -SELECT pgmq.create_unlogged('test_unlogged_queue'); +-- CREATE pgmq. +CREATE EXTENSION IF NOT EXISTS pgmq; +CREATE EXTENSION IF NOT EXISTS pg_partman; + +-- test_unlogged +-- CREATE with default retention and partition strategy +SELECT pgmq.create_unlogged('test_unlogged_queue'); create_unlogged ----------------- (1 row) -SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); +SELECT * from pgmq.send('test_unlogged_queue', '{"hello": "world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message - FROM pgmq.read('test_unlogged_queue', 2, 1); +SELECT msg_id, read_ct, enqueued_at > NOW(), vt > NOW(), message + FROM pgmq.read('test_unlogged_queue', 2, 1); msg_id | read_ct | ?column? | ?column? | message --------+---------+----------+----------+-------------------- 1 | 1 | f | t | {"hello": "world"} (1 row) - --- test_max_queue_name_size --- CREATE with default retention and partition strategy -SELECT pgmq.create(repeat('a', 48)); + +-- test_max_queue_name_size +-- CREATE with default retention and partition strategy +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 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)); +SELECT pgmq.create(repeat('a', 47)); create -------- (1 row) - --- Test: Conditional Message Retrieval - --- Creating a queue for testing -SELECT pgmq.create('conditional_test_queue'); + +-- Test: Conditional Message Retrieval + +-- Creating a queue for testing +SELECT pgmq.create('conditional_test_queue'); create -------- (1 row) - --- Sending messages with different attributes -SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A1"}'); + +-- Sending messages with different attributes +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A1"}'); send ------ 1 (1 row) -SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B1"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B1"}'); send ------ 2 (1 row) -SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A2"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "A", "content": "Message A2"}'); send ------ 3 (1 row) -SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B2"}'); +SELECT pgmq.send('conditional_test_queue', '{"type": "B", "content": "Message B2"}'); send ------ 4 (1 row) - --- Test: Retrieve messages with type 'A' -SELECT msg_id, read_ct, message -FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "A"}'::jsonb); + +-- Test: Retrieve messages with type 'A' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "A"}'::jsonb); msg_id | read_ct | message --------+---------+---------------------------------------- 1 | 1 | {"type": "A", "content": "Message A1"} 3 | 1 | {"type": "A", "content": "Message A2"} (2 rows) - --- Test: Retrieve messages with type 'B' -SELECT msg_id, read_ct, message -FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "B"}'::jsonb); + +-- Test: Retrieve messages with type 'B' +SELECT msg_id, read_ct, message +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "B"}'::jsonb); msg_id | read_ct | message --------+---------+---------------------------------------- 2 | 1 | {"type": "B", "content": "Message B1"} 4 | 1 | {"type": "B", "content": "Message B2"} (2 rows) - --- Test: Attempt to retrieve messages with a non-existent type -SELECT * -FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "C"}'::jsonb); + +-- Test: Attempt to retrieve messages with a non-existent type +SELECT * +FROM pgmq.read('conditional_test_queue', 2, 2, '{"type": "C"}'::jsonb); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) - --- Cleanup -SELECT pgmq.drop_queue('conditional_test_queue', true); + +-- Cleanup +SELECT pgmq.drop_queue('conditional_test_queue', true); drop_queue ------------ t (1 row) - --- test_lifecycle --- CREATE with default retention and partition strategy -SELECT pgmq.create('test_default_queue'); + +-- test_lifecycle +-- CREATE with default retention and partition strategy +SELECT pgmq.create('test_default_queue'); create -------- (1 row) - --- creating a queue must be idempotent --- create with same name again, must be no error -SELECT pgmq.create('test_default_queue'); + +-- creating a queue must be idempotent +-- create with same name again, must be no error +SELECT pgmq.create('test_default_queue'); NOTICE: relation "q_test_default_queue" already exists, skipping NOTICE: relation "a_test_default_queue" already exists, skipping NOTICE: relation "q_test_default_queue_vt_idx" already exists, skipping @@ -133,126 +133,126 @@ NOTICE: relation "archived_at_idx_test_default_queue" already exists, skipping (1 row) - -SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); + +SELECT * from pgmq.send('test_default_queue', '{"hello": "world"}'); send ------ 1 (1 row) - --- read message --- vt=2, limit=1 -\set msg_id 1 -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + +-- read message +-- vt=2, limit=1 +\set msg_id 1 +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) - --- set VT to 5 seconds -SELECT vt > clock_timestamp() + '4 seconds'::interval - FROM pgmq.set_vt('test_default_queue', :msg_id, 5); + +-- set VT to 5 seconds +SELECT vt > clock_timestamp() + '4 seconds'::interval + FROM pgmq.set_vt('test_default_queue', :msg_id, 5); ?column? ---------- t (1 row) - --- read again, assert no messages because we just set VT to the future -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + +-- read again, assert no messages because we just set VT to the future +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- (0 rows) - --- read again, now using poll to block until message is ready -SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); + +-- read again, now using poll to block until message is ready +SELECT msg_id = :msg_id FROM pgmq.read_with_poll('test_default_queue', 10, 1, 10); ?column? ---------- t (1 row) - --- after reading it, set VT to now -SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); + +-- after reading it, set VT to now +SELECT msg_id = :msg_id FROM pgmq.set_vt('test_default_queue', :msg_id, 0); ?column? ---------- t (1 row) - --- read again, should have msg_id 1 again -SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); + +-- read again, should have msg_id 1 again +SELECT msg_id = :msg_id FROM pgmq.read('test_default_queue', 2, 1); ?column? ---------- t (1 row) - --- send a batch of 2 messages -SELECT pgmq.create('batch_queue'); + +-- send a batch of 2 messages +SELECT pgmq.create('batch_queue'); create -------- (1 row) -SELECT ARRAY( SELECT pgmq.send_batch( - 'batch_queue', - ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] -)) = ARRAY[1, 2]::BIGINT[]; +SELECT ARRAY( SELECT pgmq.send_batch( + 'batch_queue', + ARRAY['{"hello": "world_0"}', '{"hello": "world_1"}']::jsonb[] +)) = ARRAY[1, 2]::BIGINT[]; ?column? ---------- t (1 row) - --- CREATE with 5 seconds per partition, 10 seconds retention -SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); + +-- CREATE with 5 seconds per partition, 10 seconds retention +SELECT pgmq.create_partitioned('test_duration_queue', '5 seconds', '10 seconds'); create_partitioned -------------------- (1 row) - --- CREATE with 10 messages per partition, 20 messages retention -SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); + +-- CREATE with 10 messages per partition, 20 messages retention +SELECT pgmq.create_partitioned('test_numeric_queue', '10 seconds', '20 seconds'); create_partitioned -------------------- (1 row) - --- get metrics -SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages - FROM pgmq.metrics('test_duration_queue'); + +-- get metrics +SELECT queue_name, queue_length, newest_msg_age_sec, oldest_msg_age_sec, total_messages + FROM pgmq.metrics('test_duration_queue'); queue_name | queue_length | newest_msg_age_sec | oldest_msg_age_sec | total_messages ---------------------+--------------+--------------------+--------------------+---------------- test_duration_queue | 0 | | | 0 (1 row) - --- get metrics all -SELECT * from {PGMQ_SCHEMA}.metrics_all(); + +-- get metrics all +SELECT * from {PGMQ_SCHEMA}.metrics_all(); ERROR: syntax error at or near "{" LINE 1: SELECT * from {PGMQ_SCHEMA}.metrics_all(); ^ - --- delete all the queues --- delete partitioned queues -SELECT pgmq.drop_queue(queue, true) - FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; + +-- delete all the queues +-- delete partitioned queues +SELECT pgmq.drop_queue(queue, true) + FROM unnest('{test_duration_queue, test_numeric_queue}'::text[]) AS queue; drop_queue ------------ t t (2 rows) - --- drop the rest of the queues -SELECT pgmq.drop_queue(q.queue_name, true) - FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; + +-- drop the rest of the queues +SELECT pgmq.drop_queue(q.queue_name, true) + FROM (SELECT queue_name FROM pgmq.list_queues()) AS q; drop_queue ------------ t @@ -261,650 +261,650 @@ SELECT pgmq.drop_queue(q.queue_name, true) t (4 rows) - -SELECT queue_name FROM pgmq.list_queues(); + +SELECT queue_name FROM pgmq.list_queues(); queue_name ------------ (0 rows) - --- test_archive -SELECT pgmq.create('archive_queue'); + +-- test_archive +SELECT pgmq.create('archive_queue'); create -------- (1 row) - --- no messages in the queue -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; + +-- no messages in the queue +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) - --- no messages in queue archive -SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; + +-- no messages in queue archive +SELECT COUNT(*) = 0 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) - --- put messages on the queue -\set msg_id1 1::bigint -\set msg_id2 2::bigint -SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); + +-- put messages on the queue +\set msg_id1 1::bigint +\set msg_id2 2::bigint +SELECT send = :msg_id1 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); +SELECT send = :msg_id2 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) - --- two messages in the queue -SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; + +-- two messages in the queue +SELECT COUNT(*) = 2 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) - --- archive the message. The first two exist so the id should be returned, the --- last one doesn't -SELECT ARRAY( - SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) -) = ARRAY[:msg_id1, :msg_id2]; + +-- archive the message. The first two exist so the id should be returned, the +-- last one doesn't +SELECT ARRAY( + SELECT * FROM pgmq.archive('archive_queue', ARRAY[:msg_id1, :msg_id2]) +) = ARRAY[:msg_id1, :msg_id2]; ?column? ---------- t (1 row) - --- should be no messages left on the queue table -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; + +-- should be no messages left on the queue table +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) - --- should be two messages in archive -SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; + +-- should be two messages in archive +SELECT COUNT(*) = 2 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) - -\set msg_id3 3::bigint -SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); + +\set msg_id3 3::bigint +SELECT send = :msg_id3 FROM pgmq.send('archive_queue', '0'); ?column? ---------- t (1 row) -SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; +SELECT COUNT(*) = 1 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) -SELECT * FROM pgmq.archive('archive_queue', :msg_id3); +SELECT * FROM pgmq.archive('archive_queue', :msg_id3); archive --------- t (1 row) -SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; +SELECT COUNT(*) = 0 FROM pgmq.q_archive_queue; ?column? ---------- t (1 row) -SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; +SELECT COUNT(*) = 3 FROM pgmq.a_archive_queue; ?column? ---------- t (1 row) - --- test_read_read_with_poll --- Creating queue -SELECT pgmq.create('test_read_queue'); + +-- test_read_read_with_poll +-- Creating queue +SELECT pgmq.create('test_read_queue'); create -------- (1 row) - --- Sending 3 messages to the queue -SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); + +-- Sending 3 messages to the queue +SELECT send = :msg_id1 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); +SELECT send = :msg_id2 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) -SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); +SELECT send = :msg_id3 FROM pgmq.send('test_read_queue', '0'); ?column? ---------- t (1 row) - --- Reading with limit respects the limit -SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); + +-- Reading with limit respects the limit +SELECT msg_id = :msg_id1 FROM pgmq.read('test_read_queue', 5, 1); ?column? ---------- t (1 row) - --- Reading respects the VT -SELECT ARRAY( - SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) -) = ARRAY[:msg_id2, :msg_id3]; + +-- Reading respects the VT +SELECT ARRAY( + SELECT msg_id FROM pgmq.read('test_read_queue', 10, 5) +) = ARRAY[:msg_id2, :msg_id3]; ?column? ---------- t (1 row) - --- Read with poll will poll until the first message is available -SELECT clock_timestamp() AS start \gset -SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); + +-- Read with poll will poll until the first message is available +SELECT clock_timestamp() AS start \gset +SELECT msg_id = :msg_id1 FROM pgmq.read_with_poll('test_read_queue', 10, 5, 5, 100); ?column? ---------- t (1 row) -SELECT clock_timestamp() - :'start' > '3 second'::interval; +SELECT clock_timestamp() - :'start' > '3 second'::interval; ?column? ---------- t (1 row) - --- test_purge_queue -SELECT pgmq.create('test_purge_queue'); + +-- test_purge_queue +SELECT pgmq.create('test_purge_queue'); create -------- (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 1 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 2 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 3 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 4 (1 row) -SELECT * from pgmq.send('test_purge_queue', '0'); +SELECT * from pgmq.send('test_purge_queue', '0'); send ------ 5 (1 row) - -SELECT * FROM pgmq.purge_queue('test_purge_queue'); + +SELECT * FROM pgmq.purge_queue('test_purge_queue'); purge_queue ------------- 5 (1 row) -SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; +SELECT COUNT(*) = 0 FROM pgmq.q_test_purge_queue; ?column? ---------- t (1 row) - --- test_pop -SELECT pgmq.create('test_pop_queue'); + +-- test_pop +SELECT pgmq.create('test_pop_queue'); create -------- (1 row) -SELECT * FROM pgmq.pop('test_pop_queue'); +SELECT * FROM pgmq.pop('test_pop_queue'); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) - -SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset -SELECT * from pgmq.send('test_pop_queue', '0'); + +SELECT send AS first_msg_id from pgmq.send('test_pop_queue', '0') \gset +SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 2 (1 row) -SELECT * from pgmq.send('test_pop_queue', '0'); +SELECT * from pgmq.send('test_pop_queue', '0'); send ------ 3 (1 row) - -SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); + +SELECT msg_id = :first_msg_id FROM pgmq.pop('test_pop_queue'); ?column? ---------- t (1 row) - --- test_set_vt -SELECT pgmq.create('test_set_vt_queue'); + +-- test_set_vt +SELECT pgmq.create('test_set_vt_queue'); create -------- (1 row) -SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); +SELECT * FROM pgmq.set_vt('test_set_vt_queue', 9999, 0); msg_id | read_ct | enqueued_at | vt | message --------+---------+-------------+----+--------- (0 rows) - -SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset - --- set message invisible for 100 seconds -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); + +SELECT send AS first_msg_id from pgmq.send('test_set_vt_queue', '0') \gset + +-- set message invisible for 100 seconds +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 100); msg_id -------- 1 (1 row) - --- read message, it should not be visible -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); + +-- read message, it should not be visible +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- (0 rows) - --- make it visible -SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); + +-- make it visible +SELECT msg_id FROM pgmq.set_vt('test_set_vt_queue', :first_msg_id, 0); msg_id -------- 1 (1 row) - --- set vt works if message is readable -SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); + +-- set vt works if message is readable +SELECT msg_id from pgmq.read('test_set_vt_queue', 1, 1); msg_id -------- 1 (1 row) - --- test_partitioned_delete -\set partition_interval 2 -\set retention_interval 2 - --- We first will drop pg_partman and assert that create fails without the --- extension installed -DROP EXTENSION pg_partman; - -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); + +-- test_partitioned_delete +\set partition_interval 2 +\set retention_interval 2 + +-- We first will drop pg_partman and assert that create fails without the +-- extension installed +DROP EXTENSION pg_partman; + +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); 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 11 at PERFORM - --- With the extension existing, the queue is created successfully -CREATE EXTENSION pg_partman; -SELECT * FROM pgmq.create_partitioned( - 'test_partitioned_queue', - :'partition_interval', - :'retention_interval' -); + +-- With the extension existing, the queue is created successfully +CREATE EXTENSION pg_partman; +SELECT * FROM pgmq.create_partitioned( + 'test_partitioned_queue', + :'partition_interval', + :'retention_interval' +); create_partitioned -------------------- (1 row) - --- queue shows up in list queues -SELECT queue_name FROM pgmq.list_queues() - WHERE queue_name = 'test_partitioned_queue'; + +-- queue shows up in list queues +SELECT queue_name FROM pgmq.list_queues() + WHERE queue_name = 'test_partitioned_queue'; queue_name ------------------------ test_partitioned_queue (1 row) - --- Sending 3 messages to the queue -SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset -SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset -SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset - -SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; + +-- Sending 3 messages to the queue +SELECT send AS msg_id1 from pgmq.send('test_partitioned_queue', '0') \gset +SELECT send AS msg_id2 from pgmq.send('test_partitioned_queue', '0') \gset +SELECT send AS msg_id3 from pgmq.send('test_partitioned_queue', '0') \gset + +SELECT COUNT(*) = 3 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) - --- Deleting message 3 -SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); + +-- Deleting message 3 +SELECT * FROM pgmq.delete('test_partitioned_queue', :msg_id3); delete -------- t (1 row) -SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; +SELECT COUNT(*) = 2 FROM pgmq.q_test_partitioned_queue; ?column? ---------- t (1 row) - --- Deleting batch -SELECT ARRAY( - SELECT archive FROM pgmq.archive( - 'test_partitioned_queue', - ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] - ) -) = ARRAY[:msg_id1, :msg_id2]::bigint[]; + +-- Deleting batch +SELECT ARRAY( + SELECT archive FROM pgmq.archive( + 'test_partitioned_queue', + ARRAY[:msg_id1, :msg_id2, :msg_id3, -3] + ) +) = ARRAY[:msg_id1, :msg_id2]::bigint[]; ?column? ---------- t (1 row) - --- test_transaction_create -BEGIN; -SELECT pgmq.create('transaction_test_queue'); + +-- test_transaction_create +BEGIN; +SELECT pgmq.create('transaction_test_queue'); create -------- (1 row) -ROLLBACK; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; +ROLLBACK; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'q_transaction_test_queue'; tablename ----------- (0 rows) - --- test_detach_archive -SELECT pgmq.create('detach_archive_queue'); + +-- test_detach_archive +SELECT pgmq.create('detach_archive_queue'); create -------- (1 row) -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; tablename ----------- (0 rows) - --- With detach, archive remains -CREATE EXTENSION pgmq; -SELECT pgmq.create('detach_archive_queue'); + +-- With detach, archive remains +CREATE EXTENSION pgmq; +SELECT pgmq.create('detach_archive_queue'); create -------- (1 row) -SELECT pgmq.detach_archive('detach_archive_queue'); +SELECT pgmq.detach_archive('detach_archive_queue'); detach_archive ---------------- (1 row) -DROP EXTENSION pgmq CASCADE; -SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; +DROP EXTENSION pgmq CASCADE; +SELECT tablename FROM pg_tables WHERE schemaname = 'pgmq' AND tablename = 'a_detach_archive_queue'; tablename ------------------------ a_detach_archive_queue (1 row) - ---Truncated Index When queue name is max. -CREATE EXTENSION pgmq; -SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); + +--Truncated Index When queue name is max. +CREATE EXTENSION pgmq; +SELECT pgmq.create('long_queue_name_123456789012345678901234567890'); create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); NOTICE: identifier "archived_at_idx_long_queue_name_123456789012345678901234567890_old" will be truncated to "archived_at_idx_long_queue_name_123456789012345678901234567890_" convert_archive_partitioned ----------------------------- (1 row) - ---Check for archive is already partitioned -SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); + +--Check for archive is already partitioned +SELECT pgmq.convert_archive_partitioned('long_queue_name_123456789012345678901234567890'); NOTICE: Table a_long_queue_name_123456789012345678901234567890s is already partitioned convert_archive_partitioned ----------------------------- (1 row) - ---Error out due to Index duplicate index at old table. -SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); + +--Error out due to Index duplicate index at old table. +SELECT pgmq.create('long_queue_name_1234567890123456789012345678901'); create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); +SELECT pgmq.convert_archive_partitioned('long_queue_name_1234567890123456789012345678901'); NOTICE: identifier "archived_at_idx_long_queue_name_1234567890123456789012345678901_old" will be truncated to "archived_at_idx_long_queue_name_1234567890123456789012345678901" ERROR: relation "archived_at_idx_long_queue_name_1234567890123456789012345678901" already exists CONTEXT: SQL statement "ALTER INDEX pgmq.archived_at_idx_long_queue_name_1234567890123456789012345678901 RENAME TO archived_at_idx_long_queue_name_1234567890123456789012345678901_old" PL/pgSQL function pgmq.convert_archive_partitioned(text,text,text,integer) line 34 at EXECUTE - ---Success -SELECT pgmq.create('long_queue_name_'); + +--Success +SELECT pgmq.create('long_queue_name_'); create -------- (1 row) -SELECT pgmq.convert_archive_partitioned('long_queue_name_'); +SELECT pgmq.convert_archive_partitioned('long_queue_name_'); convert_archive_partitioned ----------------------------- (1 row) - -\set SHOW_CONTEXT never - ---Failed SQL injection attack -SELECT pgmq.create('abc'); + +\set SHOW_CONTEXT never + +--Failed SQL injection attack +SELECT pgmq.create('abc'); create -------- (1 row) -SELECT - pgmq.delete( - 'abc where false; - create table public.attack_vector(id int); - delete from pgmq.q_abc', - 1 - ); +SELECT + pgmq.delete( + 'abc where false; + create table public.attack_vector(id int); + delete from pgmq.q_abc', + 1 + ); ERROR: queue name contains invalid characters: $, ;, --, or \' - ---Special characters in queue name -SELECT pgmq.create('queue-hyphened'); + +--Special characters in queue name +SELECT pgmq.create('queue-hyphened'); create -------- (1 row) -SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); +SELECT pgmq.send('queue-hyphened', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('queue-hyphened', 1); +SELECT pgmq.archive('queue-hyphened', 1); archive --------- t (1 row) - -SELECT pgmq.create('QueueCased'); + +SELECT pgmq.create('QueueCased'); create -------- (1 row) -SELECT pgmq.send('QueueCased', '{"hello":"world"}'); +SELECT pgmq.send('QueueCased', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCased', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('QueueCased', 1); +SELECT pgmq.archive('QueueCased', 1); archive --------- t (1 row) - -SELECT pgmq.create_partitioned('queue-hyphened-part'); + +SELECT pgmq.create_partitioned('queue-hyphened-part'); create_partitioned -------------------- (1 row) -SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); +SELECT pgmq.send('queue-hyphened-part', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); +SELECT msg_id, read_ct, message FROM pgmq.read('queue-hyphened-part', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('queue-hyphened-part', 1); +SELECT pgmq.archive('queue-hyphened-part', 1); archive --------- t (1 row) - -SELECT pgmq.create_partitioned('QueueCasedPart'); + +SELECT pgmq.create_partitioned('QueueCasedPart'); create_partitioned -------------------- (1 row) -SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); +SELECT pgmq.send('QueueCasedPart', '{"hello":"world"}'); send ------ 1 (1 row) -SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); +SELECT msg_id, read_ct, message FROM pgmq.read('QueueCasedPart', 1, 1); msg_id | read_ct | message --------+---------+-------------------- 1 | 1 | {"hello": "world"} (1 row) -SELECT pgmq.archive('QueueCasedPart', 1); +SELECT pgmq.archive('QueueCasedPart', 1); archive --------- t (1 row) - --- fails with invalid queue name -SELECT pgmq.create('dollar$-signed'); + +-- fails with invalid queue name +SELECT pgmq.create('dollar$-signed'); ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.create_partitioned('dollar$-signed-part'); +SELECT pgmq.create_partitioned('dollar$-signed-part'); ERROR: queue name contains invalid characters: $, ;, --, or \' - --- input validation success -SELECT pgmq.format_table_name('cat', 'q'); + +-- input validation success +SELECT pgmq.format_table_name('cat', 'q'); format_table_name ------------------- q_cat (1 row) -SELECT pgmq.format_table_name('cat-dog', 'a'); +SELECT pgmq.format_table_name('cat-dog', 'a'); format_table_name ------------------- a_cat-dog (1 row) -SELECT pgmq.format_table_name('cat_dog', 'q'); +SELECT pgmq.format_table_name('cat_dog', 'q'); format_table_name ------------------- q_cat_dog (1 row) - --- input validation failure -SELECT pgmq.format_table_name('dollar$fail', 'q'); + +-- input validation failure +SELECT pgmq.format_table_name('dollar$fail', 'q'); ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); +SELECT pgmq.format_table_name('double--hyphen-fail', 'a'); ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name('semicolon;fail', 'a'); +SELECT pgmq.format_table_name('semicolon;fail', 'a'); ERROR: queue name contains invalid characters: $, ;, --, or \' -SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); +SELECT pgmq.format_table_name($$single'quote-fail$$, 'a'); ERROR: queue name contains invalid characters: $, ;, --, or \' - ---Cleanup tests -DROP EXTENSION pgmq CASCADE; + +--Cleanup tests +DROP EXTENSION pgmq CASCADE; DROP EXTENSION pg_partman CASCADE;