Skip to content

Commit a7a0651

Browse files
authored
Added missing scripts for current version (#516)
1 parent f85f017 commit a7a0651

File tree

1 file changed

+392
-1
lines changed

1 file changed

+392
-1
lines changed
Lines changed: 392 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1 +1,392 @@
1-
-- This script is autogenerated from the tool DbTools. Do not edit manually.
1+
-- This script is autogenerated from the tool DbTools. Do not edit manually.
2+
3+
-- getemailrecipients.sql:
4+
CREATE OR REPLACE FUNCTION notifications.getemailrecipients_v2(_alternateid uuid)
5+
RETURNS TABLE(
6+
recipientorgno text,
7+
recipientnin text,
8+
toaddress text
9+
)
10+
LANGUAGE 'plpgsql'
11+
AS $BODY$
12+
DECLARE
13+
__orderid BIGINT := (SELECT _id from notifications.orders
14+
where alternateid = _alternateid);
15+
BEGIN
16+
RETURN query
17+
SELECT e.recipientorgno, e.recipientnin, e.toaddress
18+
FROM notifications.emailnotifications e
19+
WHERE e._orderid = __orderid;
20+
END;
21+
$BODY$;
22+
23+
-- getemailsstatusnewupdatestatus.sql:
24+
CREATE OR REPLACE FUNCTION notifications.getemails_statusnew_updatestatus()
25+
RETURNS TABLE(alternateid uuid, subject text, body text, fromaddress text, toaddress text, contenttype text)
26+
LANGUAGE 'plpgsql'
27+
AS $BODY$
28+
DECLARE
29+
latest_email_timeout TIMESTAMP WITH TIME ZONE;
30+
BEGIN
31+
SELECT emaillimittimeout INTO latest_email_timeout FROM notifications.resourcelimitlog WHERE id = (SELECT MAX(id) FROM notifications.resourcelimitlog);
32+
IF latest_email_timeout IS NOT NULL THEN
33+
IF latest_email_timeout >= NOW() THEN
34+
RETURN QUERY SELECT NULL::uuid AS alternateid, NULL::text AS subject, NULL::text AS body, NULL::text AS fromaddress, NULL::text AS toaddress, NULL::text AS contenttype WHERE FALSE;
35+
RETURN;
36+
ELSE
37+
UPDATE notifications.resourcelimitlog SET emaillimittimeout = NULL WHERE id = (SELECT MAX(id) FROM notifications.resourcelimitlog);
38+
END IF;
39+
END IF;
40+
41+
RETURN query
42+
WITH updated AS (
43+
UPDATE notifications.emailnotifications
44+
SET result = 'Sending', resulttime = now()
45+
WHERE result = 'New'
46+
RETURNING notifications.emailnotifications.alternateid, _orderid, notifications.emailnotifications.toaddress)
47+
SELECT u.alternateid, et.subject, et.body, et.fromaddress, u.toaddress, et.contenttype
48+
FROM updated u, notifications.emailtexts et
49+
WHERE u._orderid = et._orderid;
50+
END;
51+
$BODY$;
52+
53+
-- getemailsummary.sql:
54+
CREATE OR REPLACE FUNCTION notifications.getemailsummary_v2(
55+
_alternateorderid uuid,
56+
_creatorname text)
57+
RETURNS TABLE(
58+
sendersreference text,
59+
alternateid uuid,
60+
recipientorgno text,
61+
recipientnin text,
62+
toaddress text,
63+
result emailnotificationresulttype,
64+
resulttime timestamptz)
65+
LANGUAGE 'plpgsql'
66+
AS $BODY$
67+
68+
BEGIN
69+
RETURN QUERY
70+
SELECT o.sendersreference, n.alternateid, n.recipientorgno, n.recipientnin, n.toaddress, n.result, n.resulttime
71+
FROM notifications.emailnotifications n
72+
LEFT JOIN notifications.orders o ON n._orderid = o._id
73+
WHERE o.alternateid = _alternateorderid
74+
and o.creatorname = _creatorname;
75+
IF NOT FOUND THEN
76+
RETURN QUERY
77+
SELECT o.sendersreference, NULL::uuid, NULL::text, NULL::text, NULL::text, NULL::emailnotificationresulttype, NULL::timestamptz
78+
FROM notifications.orders o
79+
WHERE o.alternateid = _alternateorderid
80+
and o.creatorname = _creatorname;
81+
END IF;
82+
END;
83+
$BODY$;
84+
85+
-- getmetrics.sql:
86+
CREATE OR REPLACE FUNCTION notifications.getmetrics(
87+
month_input int,
88+
year_input int
89+
)
90+
RETURNS TABLE (
91+
org text,
92+
placed_orders bigint,
93+
sent_emails bigint,
94+
succeeded_emails bigint,
95+
sent_sms bigint,
96+
succeeded_sms bigint
97+
)
98+
AS $$
99+
BEGIN
100+
RETURN QUERY
101+
SELECT
102+
o.creatorname,
103+
COUNT(DISTINCT o._id) AS placed_orders,
104+
SUM(CASE WHEN e._id IS NOT NULL THEN 1 ELSE 0 END) AS sent_emails,
105+
SUM(CASE WHEN e.result = 'Succeeded' THEN 1 ELSE 0 END) AS succeeded_emails,
106+
SUM(CASE WHEN s._id IS NOT NULL THEN s.smscount ELSE 0 END) AS sent_sms,
107+
SUM(CASE WHEN s.result = 'Accepted' THEN 1 ELSE 0 END) AS succeeded_sms
108+
FROM notifications.orders o
109+
LEFT JOIN notifications.emailnotifications e ON o._id = e._orderid
110+
LEFT JOIN notifications.smsnotifications s ON o._id = s._orderid
111+
WHERE EXTRACT(MONTH FROM o.requestedsendtime) = month_input
112+
AND EXTRACT(YEAR FROM o.requestedsendtime) = year_input
113+
GROUP BY o.creatorname;
114+
END;
115+
$$ LANGUAGE plpgsql;
116+
117+
118+
-- getorderincludestatus.sql:
119+
CREATE OR REPLACE FUNCTION notifications.getorder_includestatus_v2(
120+
_alternateid uuid,
121+
_creatorname text
122+
)
123+
RETURNS TABLE(
124+
alternateid uuid,
125+
creatorname text,
126+
sendersreference text,
127+
created timestamp with time zone,
128+
requestedsendtime timestamp with time zone,
129+
processed timestamp with time zone,
130+
processedstatus orderprocessingstate,
131+
notificationchannel text,
132+
generatedemailcount bigint,
133+
succeededemailcount bigint,
134+
generatedsmscount bigint,
135+
succeededsmscount bigint
136+
)
137+
LANGUAGE 'plpgsql'
138+
AS $BODY$
139+
DECLARE
140+
_target_orderid INTEGER;
141+
_succeededEmailCount BIGINT;
142+
_generatedEmailCount BIGINT;
143+
_succeededSmsCount BIGINT;
144+
_generatedSmsCount BIGINT;
145+
BEGIN
146+
SELECT _id INTO _target_orderid
147+
FROM notifications.orders
148+
WHERE orders.alternateid = _alternateid
149+
AND orders.creatorname = _creatorname;
150+
151+
SELECT
152+
SUM(CASE WHEN result = 'Succeeded' THEN 1 ELSE 0 END),
153+
COUNT(1) AS generatedEmailCount
154+
INTO _succeededEmailCount, _generatedEmailCount
155+
FROM notifications.emailnotifications
156+
WHERE _orderid = _target_orderid;
157+
158+
SELECT
159+
SUM(CASE WHEN result = 'Accepted' THEN 1 ELSE 0 END),
160+
COUNT(1) AS generatedSmsCount
161+
INTO _succeededSmsCount, _generatedSmsCount
162+
FROM notifications.smsnotifications
163+
WHERE _orderid = _target_orderid;
164+
165+
RETURN QUERY
166+
SELECT
167+
orders.alternateid,
168+
orders.creatorname,
169+
orders.sendersreference,
170+
orders.created,
171+
orders.requestedsendtime,
172+
orders.processed,
173+
orders.processedstatus,
174+
orders.notificationorder->>'NotificationChannel',
175+
_generatedEmailCount,
176+
_succeededEmailCount,
177+
_generatedSmsCount,
178+
_succeededSmsCount
179+
FROM
180+
notifications.orders AS orders
181+
WHERE
182+
orders.alternateid = _alternateid;
183+
END;
184+
$BODY$;
185+
186+
187+
-- getorderspastsendtimeupdatestatus.sql:
188+
CREATE OR REPLACE FUNCTION notifications.getorders_pastsendtime_updatestatus()
189+
RETURNS TABLE(notificationorders jsonb)
190+
LANGUAGE 'plpgsql'
191+
AS $BODY$
192+
BEGIN
193+
RETURN QUERY
194+
UPDATE notifications.orders
195+
SET processedstatus = 'Processing'
196+
WHERE _id IN (select _id
197+
from notifications.orders
198+
where processedstatus = 'Registered'
199+
and requestedsendtime <= now() + INTERVAL '1 minute'
200+
limit 50)
201+
RETURNING notificationorder AS notificationorders;
202+
END;
203+
$BODY$;
204+
205+
-- getsmsrecipients.sql:
206+
CREATE OR REPLACE FUNCTION notifications.getsmsrecipients_v2(_orderid uuid)
207+
RETURNS TABLE(
208+
recipientorgno text,
209+
recipientnin text,
210+
mobilenumber text
211+
)
212+
LANGUAGE 'plpgsql'
213+
AS $BODY$
214+
DECLARE
215+
__orderid BIGINT := (SELECT _id from notifications.orders
216+
where alternateid = _orderid);
217+
BEGIN
218+
RETURN query
219+
SELECT s.recipientorgno, s.recipientnin, s.mobilenumber
220+
FROM notifications.smsnotifications s
221+
WHERE s._orderid = __orderid;
222+
END;
223+
$BODY$;
224+
225+
-- getsmsstatusnewupdatestatus.sql:
226+
CREATE OR REPLACE FUNCTION notifications.getsms_statusnew_updatestatus()
227+
RETURNS TABLE(alternateid uuid, sendernumber text, mobilenumber text, body text)
228+
LANGUAGE 'plpgsql'
229+
AS $BODY$
230+
BEGIN
231+
232+
RETURN query
233+
WITH updated AS (
234+
UPDATE notifications.smsnotifications
235+
SET result = 'Sending', resulttime = now()
236+
WHERE result = 'New'
237+
RETURNING notifications.smsnotifications.alternateid, _orderid, notifications.smsnotifications.mobilenumber)
238+
SELECT u.alternateid, st.sendernumber, u.mobilenumber, st.body
239+
FROM updated u, notifications.smstexts st
240+
WHERE u._orderid = st._orderid;
241+
END;
242+
$BODY$;
243+
244+
-- getsmssummary.sql:
245+
CREATE OR REPLACE FUNCTION notifications.getsmssummary_v2(
246+
_alternateorderid uuid,
247+
_creatorname text)
248+
RETURNS TABLE(
249+
sendersreference text,
250+
alternateid uuid,
251+
recipientorgno text,
252+
recipientnin text,
253+
mobilenumber text,
254+
result smsnotificationresulttype,
255+
resulttime timestamptz)
256+
LANGUAGE 'plpgsql'
257+
AS $BODY$
258+
259+
BEGIN
260+
RETURN QUERY
261+
SELECT o.sendersreference, n.alternateid, n.recipientorgno, n.recipientnin, n.mobilenumber, n.result, n.resulttime
262+
FROM notifications.smsnotifications n
263+
LEFT JOIN notifications.orders o ON n._orderid = o._id
264+
WHERE o.alternateid = _alternateorderid
265+
and o.creatorname = _creatorname;
266+
IF NOT FOUND THEN
267+
RETURN QUERY
268+
SELECT o.sendersreference, NULL::uuid, NULL::text, NULL::text, NULL::text, NULL::smsnotificationresulttype, NULL::timestamptz
269+
FROM notifications.orders o
270+
WHERE o.alternateid = _alternateorderid
271+
and o.creatorname = _creatorname;
272+
END IF;
273+
END;
274+
$BODY$;
275+
276+
-- insertemailnotification.sql:
277+
CREATE OR REPLACE PROCEDURE notifications.insertemailnotification(
278+
_orderid uuid,
279+
_alternateid uuid,
280+
_recipientorgno TEXT,
281+
_recipientnin TEXT,
282+
_toaddress TEXT,
283+
_result text,
284+
_resulttime timestamptz,
285+
_expirytime timestamptz)
286+
LANGUAGE 'plpgsql'
287+
AS $BODY$
288+
DECLARE
289+
__orderid BIGINT := (SELECT _id from notifications.orders
290+
where alternateid = _orderid);
291+
BEGIN
292+
293+
INSERT INTO notifications.emailnotifications(
294+
_orderid,
295+
alternateid,
296+
recipientorgno,
297+
recipientnin,
298+
toaddress, result,
299+
resulttime,
300+
expirytime)
301+
VALUES (
302+
__orderid,
303+
_alternateid,
304+
_recipientorgno,
305+
_recipientnin,
306+
_toaddress,
307+
_result::emailnotificationresulttype,
308+
_resulttime,
309+
_expirytime);
310+
END;
311+
$BODY$;
312+
313+
-- insertemailtext.sql:
314+
CREATE OR REPLACE PROCEDURE notifications.insertemailtext(__orderid BIGINT, _fromaddress TEXT, _subject TEXT, _body TEXT, _contenttype TEXT)
315+
LANGUAGE 'plpgsql'
316+
AS $BODY$
317+
BEGIN
318+
INSERT INTO notifications.emailtexts(_orderid, fromaddress, subject, body, contenttype)
319+
VALUES (__orderid, _fromaddress, _subject, _body, _contenttype);
320+
END;
321+
$BODY$;
322+
323+
324+
-- insertorder.sql:
325+
CREATE OR REPLACE FUNCTION notifications.insertorder(_alternateid UUID, _creatorname TEXT, _sendersreference TEXT, _created TIMESTAMPTZ, _requestedsendtime TIMESTAMPTZ, _notificationorder JSONB)
326+
RETURNS BIGINT
327+
LANGUAGE 'plpgsql'
328+
AS $BODY$
329+
DECLARE
330+
_orderid BIGINT;
331+
BEGIN
332+
INSERT INTO notifications.orders(alternateid, creatorname, sendersreference, created, requestedsendtime, processed, notificationorder)
333+
VALUES (_alternateid, _creatorname, _sendersreference, _created, _requestedsendtime, _created, _notificationorder)
334+
RETURNING _id INTO _orderid;
335+
336+
RETURN _orderid;
337+
END;
338+
$BODY$;
339+
340+
-- insertsmsnotification.sql:
341+
CREATE OR REPLACE PROCEDURE notifications.insertsmsnotification(
342+
_orderid uuid,
343+
_alternateid uuid,
344+
_recipientorgno TEXT,
345+
_recipientnin TEXT,
346+
_mobilenumber TEXT,
347+
_result text,
348+
_smscount integer,
349+
_resulttime timestamptz,
350+
_expirytime timestamptz
351+
)
352+
LANGUAGE 'plpgsql'
353+
AS $BODY$
354+
DECLARE
355+
__orderid BIGINT := (SELECT _id from notifications.orders
356+
where alternateid = _orderid);
357+
BEGIN
358+
359+
INSERT INTO notifications.smsnotifications(
360+
_orderid,
361+
alternateid,
362+
recipientorgno,
363+
recipientnin,
364+
mobilenumber,
365+
result,
366+
smscount,
367+
resulttime,
368+
expirytime)
369+
VALUES (
370+
__orderid,
371+
_alternateid,
372+
_recipientorgno,
373+
_recipientnin,
374+
_mobilenumber,
375+
_result::smsnotificationresulttype,
376+
_smscount,
377+
_resulttime,
378+
_expirytime);
379+
END;
380+
$BODY$;
381+
382+
-- updateemailstatus.sql:
383+
CREATE OR REPLACE PROCEDURE notifications.updateemailstatus(_alternateid UUID, _result text, _operationid text)
384+
LANGUAGE 'plpgsql'
385+
AS $BODY$
386+
BEGIN
387+
UPDATE notifications.emailnotifications
388+
SET result = _result::emailnotificationresulttype, resulttime = now(), operationid = _operationid
389+
WHERE alternateid = _alternateid;
390+
END;
391+
$BODY$;
392+

0 commit comments

Comments
 (0)