-
Notifications
You must be signed in to change notification settings - Fork 80
/
Copy pathsql_src.sql
339 lines (323 loc) · 8.84 KB
/
sql_src.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
------------------------------------------------------------
-- 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
);
------------------------------------------------------------
-- Functions
------------------------------------------------------------
-- read
-- reads a number of messages from a queue, setting a visibility timeout on them
CREATE FUNCTION pgmq.read(
queue_name TEXT,
vt INTEGER,
qty INTEGER
)
RETURNS SETOF pgmq.message_record AS $$
DECLARE
sql TEXT;
BEGIN
sql := FORMAT(
$QUERY$
WITH cte AS
(
SELECT msg_id
FROM pgmq.q_%s
WHERE vt <= clock_timestamp()
ORDER BY msg_id ASC
LIMIT $1
FOR UPDATE SKIP LOCKED
)
UPDATE pgmq.q_%s m
SET
vt = clock_timestamp() + interval '%s seconds',
read_ct = read_ct + 1
FROM cte
WHERE m.msg_id = cte.msg_id
RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message;
$QUERY$,
queue_name, queue_name, vt
);
RETURN QUERY EXECUTE sql USING qty;
END;
$$ LANGUAGE plpgsql;
---- read_with_poll
---- reads a number of messages from a queue, setting a visibility timeout on them
CREATE FUNCTION pgmq.read_with_poll(
queue_name TEXT,
vt INTEGER,
qty INTEGER,
max_poll_seconds INTEGER DEFAULT 5,
poll_interval_ms INTEGER DEFAULT 100
)
RETURNS SETOF pgmq.message_record AS $$
DECLARE
r pgmq.message_record;
stop_at TIMESTAMP;
sql TEXT;
BEGIN
stop_at := clock_timestamp() + FORMAT('%s seconds', max_poll_seconds)::interval;
LOOP
IF (SELECT clock_timestamp() >= stop_at) THEN
RETURN;
END IF;
sql := FORMAT(
$QUERY$
WITH cte AS
(
SELECT msg_id
FROM pgmq.q_%s
WHERE vt <= clock_timestamp()
ORDER BY msg_id ASC
LIMIT $1
FOR UPDATE SKIP LOCKED
)
UPDATE pgmq.q_%s m
SET
vt = clock_timestamp() + interval '%s seconds',
read_ct = read_ct + 1
FROM cte
WHERE m.msg_id = cte.msg_id
RETURNING m.msg_id, m.read_ct, m.enqueued_at, m.vt, m.message;
$QUERY$,
queue_name, queue_name, vt
);
FOR r IN
EXECUTE sql USING qty
LOOP
RETURN NEXT r;
END LOOP;
IF FOUND THEN
RETURN;
ELSE
PERFORM pg_sleep(poll_interval_ms / 1000);
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;
---- archive
---- removes a message from the queue, and sends it to the archive, where its
---- saved permanently.
CREATE FUNCTION pgmq.archive(
queue_name TEXT,
msg_id BIGINT
)
RETURNS BOOLEAN AS $$
DECLARE
sql TEXT;
result BIGINT;
BEGIN
sql := FORMAT(
$QUERY$
WITH archived AS (
DELETE FROM pgmq.q_%s
WHERE msg_id = $1
RETURNING msg_id, vt, read_ct, enqueued_at, message
)
INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message)
SELECT msg_id, vt, read_ct, enqueued_at, message
FROM archived
RETURNING msg_id;
$QUERY$,
queue_name, queue_name
);
EXECUTE sql USING msg_id INTO result;
RETURN NOT (result IS NULL);
END;
$$ LANGUAGE plpgsql;
---- archive
---- removes an array of message ids from the queue, and sends it to the archive,
---- where these messages will be saved permanently.
CREATE FUNCTION pgmq.archive(
queue_name TEXT,
msg_ids BIGINT[]
)
RETURNS SETOF BIGINT AS $$
DECLARE
sql TEXT;
BEGIN
sql := FORMAT(
$QUERY$
WITH archived AS (
DELETE FROM pgmq.q_%s
WHERE msg_id = ANY($1)
RETURNING msg_id, vt, read_ct, enqueued_at, message
)
INSERT INTO pgmq.a_%s (msg_id, vt, read_ct, enqueued_at, message)
SELECT msg_id, vt, read_ct, enqueued_at, message
FROM archived
RETURNING msg_id;
$QUERY$,
queue_name, queue_name
);
RETURN QUERY EXECUTE sql USING msg_ids;
END;
$$ LANGUAGE plpgsql;
---- delete
---- deletes a message id from the queue permanently
CREATE FUNCTION pgmq.delete(
queue_name TEXT,
msg_id BIGINT
)
RETURNS BOOLEAN AS $$
DECLARE
sql TEXT;
result BIGINT;
BEGIN
sql := FORMAT(
$QUERY$
DELETE FROM pgmq.q_%s
WHERE msg_id = $1
RETURNING msg_id
$QUERY$,
queue_name
);
EXECUTE sql USING msg_id INTO result;
RETURN NOT (result IS NULL);
END;
$$ LANGUAGE plpgsql;
---- delete
---- deletes an array of message ids from the queue permanently
CREATE FUNCTION pgmq.delete(
queue_name TEXT,
msg_ids BIGINT[]
)
RETURNS SETOF BIGINT AS $$
DECLARE
sql TEXT;
BEGIN
sql := FORMAT(
$QUERY$
DELETE FROM pgmq.q_%s
WHERE msg_id = ANY($1)
RETURNING msg_id
$QUERY$,
queue_name
);
RETURN QUERY EXECUTE sql USING msg_ids;
END;
$$ LANGUAGE plpgsql;
-- send
-- sends a message to a queue, optionally with a delay
CREATE FUNCTION pgmq.send(
queue_name TEXT,
msg JSONB,
delay INTEGER DEFAULT 0
) RETURNS SETOF BIGINT AS $$
DECLARE
sql TEXT;
BEGIN
sql := FORMAT(
$QUERY$
INSERT INTO pgmq.q_%s (vt, message)
VALUES ((clock_timestamp() + interval '%s seconds'), $1)
RETURNING msg_id;
$QUERY$,
queue_name, delay
);
RETURN QUERY EXECUTE sql USING msg;
END;
$$ LANGUAGE plpgsql;
-- send_batch
-- sends an array of list of messages to a queue, optionally with a delay
CREATE FUNCTION pgmq.send_batch(
queue_name TEXT,
msgs JSONB[],
delay INTEGER DEFAULT 0
) RETURNS SETOF BIGINT AS $$
DECLARE
sql TEXT;
BEGIN
sql := FORMAT(
$QUERY$
INSERT INTO pgmq.q_%s (vt, message)
SELECT clock_timestamp() + interval '%s seconds', unnest($1)
RETURNING msg_id;
$QUERY$,
queue_name, delay
);
RETURN QUERY EXECUTE sql USING msgs;
END;
$$ LANGUAGE plpgsql;
-- returned by pgmq.metrics() and pgmq.metrics_all
CREATE TYPE pgmq.metrics_result AS (
queue_name text,
queue_length bigint,
newest_msg_age_sec int,
oldest_msg_age_sec int,
total_messages bigint,
scrape_time timestamp with time zone
);
-- get metrics for a single queue
CREATE OR REPLACE FUNCTION pgmq.metrics(queue_name TEXT)
RETURNS pgmq.metrics_result AS $$
DECLARE
result_row pgmq.metrics_result;
query TEXT;
BEGIN
query := FORMAT(
$QUERY$
WITH q_summary AS (
SELECT
count(*) as queue_length,
EXTRACT(epoch FROM (NOW() - max(enqueued_at)))::int as newest_msg_age_sec,
EXTRACT(epoch FROM (NOW() - min(enqueued_at)))::int as oldest_msg_age_sec,
NOW() as scrape_time
FROM pgmq.q_%I
),
all_metrics AS (
SELECT CASE
WHEN is_called THEN last_value ELSE 0
END as total_messages
FROM pgmq.q_%I_msg_id_seq
)
SELECT
'%s' as queue_name,
q_summary.queue_length,
q_summary.newest_msg_age_sec,
q_summary.oldest_msg_age_sec,
all_metrics.total_messages,
q_summary.scrape_time
FROM q_summary, all_metrics
$QUERY$,
queue_name, queue_name, queue_name
);
EXECUTE query INTO result_row;
RETURN result_row;
END;
$$ LANGUAGE plpgsql;
-- get metrics for all queues
CREATE OR REPLACE 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;