-
Notifications
You must be signed in to change notification settings - Fork 4
/
supa_queue--1.0.3.sql
296 lines (270 loc) · 8.16 KB
/
supa_queue--1.0.3.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
CREATE TABLE job_queue (
job_id BIGINT GENERATED BY DEFAULT AS IDENTITY,
http_verb TEXT NOT NULL CHECK (http_verb IN ('GET', 'POST', 'DELETE')),
payload jsonb,
status TEXT NOT NULL DEFAULT '',
retry_count INTEGER DEFAULT 0,
retry_limit INTEGER DEFAULT 10,
url_path TEXT DEFAULT '',
content TEXT DEFAULT '',
created_at TIMESTAMPTZ DEFAULT NOW(),
CONSTRAINT job_id_pkey PRIMARY KEY (job_id)
);
CREATE TABLE current_jobs (
request_id BIGINT NOT NULL,
job_id BIGINT NOT NULL
);
CREATE TABLE workers (
id BIGINT GENERATED BY DEFAULT AS IDENTITY,
locked BOOLEAN NOT NULL DEFAULT FALSE,
CONSTRAINT workers_pkey PRIMARY KEY (id)
);
do $$
begin
execute (
select string_agg('INSERT INTO workers DEFAULT VALUES',';')
from generate_series(1,5)
);
end;
$$;
--
-- Execute current jobs function if there are available workers
--
CREATE OR REPLACE FUNCTION process_current_jobs_if_unlocked()
RETURNS VOID AS $$
DECLARE
worker RECORD;
BEGIN
-- Find an unlocked worker
SELECT * INTO worker FROM workers FOR UPDATE SKIP LOCKED LIMIT 1;
IF worker IS NOT NULL THEN
RAISE NOTICE 'Using worker_id: %', worker.id;
-- Lock the worker (this is already done by the SELECT ... FOR UPDATE)
-- Process current jobs
PERFORM process_current_jobs();
-- Unlock the worker
UPDATE workers SET locked = FALSE WHERE id = worker.id;
ELSE
RAISE NOTICE 'No unlocked workers available';
END IF;
END;
$$ LANGUAGE plpgsql;
--
-- Loop through records in current_jobs and get response from pg_net
--
CREATE OR REPLACE FUNCTION process_current_jobs()
RETURNS VOID
SECURITY DEFINER
SET search_path = public, extensions, net, vault
AS $$
DECLARE
current_job RECORD;
response_result RECORD;
BEGIN
FOR current_job IN SELECT * FROM current_jobs
FOR UPDATE SKIP LOCKED
LOOP
RAISE NOTICE 'Processing job_id: %, request_id: %', current_job.job_id, current_job.request_id;
SELECT
status,
(response).status_code AS status_code,
(response).body AS body
INTO response_result
FROM net._http_collect_response(current_job.request_id);
IF response_result.status = 'SUCCESS' AND response_result.status_code BETWEEN 200 AND 299 THEN
RAISE NOTICE 'Job completed (job_id: %)', current_job.job_id;
UPDATE job_queue
SET status = 'complete',
content = response_result.body::TEXT
WHERE job_id = current_job.job_id;
DELETE FROM current_jobs
WHERE request_id = current_job.request_id;
ELSIF response_result.status = 'ERROR' THEN
RAISE NOTICE 'Job failed (job_id: %)', current_job.job_id;
UPDATE job_queue
SET status = 'failed',
retry_count = retry_count + 1
WHERE job_id = current_job.job_id;
DELETE FROM current_jobs
WHERE request_id = current_job.request_id;
ELSE
RAISE NOTICE 'Job still in progress or not found (job_id: %)', current_job.job_id;
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Called after a record is insert in the queue
--
CREATE OR REPLACE FUNCTION process_job()
RETURNS TRIGGER
SECURITY DEFINER
SET search_path = public, extensions, net, vault
AS $$
DECLARE
request_id BIGINT;
api_key TEXT;
base_url TEXT;
did_timeout BOOLEAN;
response_message TEXT;
response_status_code INTEGER;
BEGIN
RAISE NOTICE 'Processing job_id: %', NEW.job_id;
UPDATE job_queue
SET status = 'processing'
WHERE job_id = NEW.job_id;
-- Get the API key
SELECT decrypted_secret
INTO api_key
FROM vault.decrypted_secrets
WHERE name = 'service_role';
-- Get the consumer function URL
SELECT decrypted_secret
INTO base_url
FROM vault.decrypted_secrets
WHERE name = 'consumer_function';
-- Call the request_wrapper to process the job
request_id := request_wrapper(
method := NEW.http_verb,
url := base_url || COALESCE(NEW.url_path, ''),
body := COALESCE(NEW.payload::jsonb, '{}'::jsonb),
headers := jsonb_build_object('Authorization', 'Bearer ' || api_key, 'Content-Type', 'application/json')
);
INSERT INTO current_jobs (request_id, job_id)
VALUES (request_id, NEW.job_id);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
--
-- Convenience function around pg_net:
--
CREATE OR REPLACE FUNCTION request_wrapper(
method TEXT,
url TEXT,
params JSONB DEFAULT '{}'::JSONB,
body JSONB DEFAULT '{}'::JSONB,
headers JSONB DEFAULT '{}'::JSONB
)
RETURNS BIGINT
SECURITY DEFINER
SET search_path = public, extensions, net
LANGUAGE plpgsql
AS $$
DECLARE
request_id BIGINT;
timeout INT;
BEGIN
timeout := 6000;
IF method = 'DELETE' THEN
SELECT net.http_delete(
url:=url,
params:=params,
headers:=headers,
timeout_milliseconds:=timeout
) INTO request_id;
ELSIF method = 'POST' THEN
SELECT net.http_post(
url:=url,
body:=body,
params:=params,
headers:=headers,
timeout_milliseconds:=timeout
) INTO request_id;
ELSIF method = 'GET' THEN
SELECT net.http_get(
url:=url,
params:=params,
headers:=headers,
timeout_milliseconds:=timeout
) INTO request_id;
ELSE
RAISE EXCEPTION 'Method must be DELETE, POST, or GET';
END IF;
RETURN request_id;
END;
$$;
--
-- Retrying jobs flagged as failures to increase reliability
--
CREATE OR REPLACE FUNCTION public.retry_failed_jobs()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public', 'extensions', 'net', 'vault'
AS $function$
DECLARE
r RECORD;
request_id BIGINT;
api_key TEXT;
base_url TEXT;
response_result net._http_response_result;
BEGIN
RAISE NOTICE 'Retrying failed jobs';
-- Get the API key
SELECT decrypted_secret
INTO api_key
FROM vault.decrypted_secrets
WHERE name = 'service_role';
FOR r IN (
SELECT * FROM job_queue
WHERE (status = 'failed' AND retry_count < retry_limit)
OR (status = 'processing' AND created_at < current_timestamp - INTERVAL '10 minutes')
FOR UPDATE SKIP LOCKED
) LOOP
RAISE NOTICE 'Retrying job_id: %', r.job_id;
UPDATE job_queue
SET retry_count = retry_count + 1
WHERE job_id = r.job_id;
SELECT decrypted_secret
INTO base_url
FROM vault.decrypted_secrets
WHERE name = 'consumer_function';
-- Call the request_wrapper to process the job
request_id := request_wrapper(
method := r.http_verb,
-- Edge function call (like AWS lambda)
url := base_url || COALESCE(r.url_path, ''),
body := COALESCE(r.payload::jsonb, '{}'::jsonb),
headers := jsonb_build_object('Authorization', 'Bearer ' || api_key, 'Content-Type', 'application/json')
);
INSERT INTO current_jobs (request_id, job_id)
VALUES (request_id, r.job_id);
END LOOP;
END;
$function$;
-- Adding the trigger to the queue table:
CREATE TRIGGER process_job_trigger
AFTER INSERT ON job_queue
FOR EACH ROW
EXECUTE FUNCTION process_job();
CREATE OR REPLACE FUNCTION public.process_tasks_subminute()
RETURNS text
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO 'public', 'extensions', 'secrets', 'net'
AS $function$
BEGIN
-- Call process_tasks() with 20 seconds between each call
PERFORM process_current_jobs_if_unlocked();
PERFORM pg_sleep(20);
PERFORM process_current_jobs_if_unlocked();
PERFORM pg_sleep(20);
PERFORM process_current_jobs_if_unlocked();
return 'Done';
END;
$function$;
-- Retry jobs each 10 minutes
SELECT cron.schedule(
'retry_failed_jobs',
'*/10 * * * *',
$$ SELECT retry_failed_jobs(); $$
);
-- Schedule process jobs 3 times per minute:
SELECT cron.schedule(
'process_tasks_subminute',
'* * * * *',
$$ SELECT process_tasks_subminute(); $$
);
ALTER TABLE current_jobs ENABLE ROW LEVEL SECURITY;
ALTER TABLE job_queue ENABLE ROW LEVEL SECURITY;
ALTER TABLE workers ENABLE ROW LEVEL SECURITY;