Skip to content

Commit eaa7646

Browse files
use JSONB of events.extra
IntelMQ's eventdb events.extra switched from type JSON to JSONB: certtools/intelmq#2597 directly use the JSONB type in the functions
1 parent 7f1c316 commit eaa7646

File tree

3 files changed

+187
-7
lines changed

3 files changed

+187
-7
lines changed

NEWS.md

Lines changed: 91 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,97 @@
11
As this component is to be used and released together with others, see
22
(intelmq-cb-mailgen/NEWS)https://github.com/Intevation/intelmq-mailgen-release).
33

4+
## 1.3.7
5+
6+
To use the `JSONB` type of IntelMQ's `extra` field directly without conversion, re-create these adjusted functions:
7+
8+
```sql
9+
CREATE OR REPLACE FUNCTION json_object_as_text_array(obj JSONB)
10+
RETURNS TEXT[][]
11+
AS $$
12+
DECLARE
13+
arr TEXT[][] = '{}'::TEXT[][];
14+
k TEXT;
15+
v TEXT;
16+
BEGIN
17+
FOR k, v IN
18+
SELECT * FROM jsonb_each_text(obj) ORDER BY key
19+
LOOP
20+
arr := arr || ARRAY[ARRAY[k, v]];
21+
END LOOP;
22+
RETURN arr;
23+
END
24+
$$ LANGUAGE plpgsql IMMUTABLE;
25+
26+
CREATE OR REPLACE FUNCTION insert_directive(
27+
event_id BIGINT,
28+
directive JSONB,
29+
endpoint ip_endpoint
30+
) RETURNS VOID
31+
AS $$
32+
DECLARE
33+
medium TEXT := directive ->> 'medium';
34+
recipient_address TEXT := directive ->> 'recipient_address';
35+
template_name TEXT := directive ->> 'template_name';
36+
notification_format TEXT := directive ->> 'notification_format';
37+
event_data_format TEXT := directive ->> 'event_data_format';
38+
aggregate_identifier TEXT[][]
39+
:= json_object_as_text_array(directive -> 'aggregate_identifier');
40+
notification_interval interval
41+
:= coalesce(((directive ->> 'notification_interval') :: INT)
42+
* interval '1 second',
43+
interval '0 second');
44+
BEGIN
45+
IF medium IS NOT NULL
46+
AND recipient_address IS NOT NULL
47+
AND template_name IS NOT NULL
48+
AND notification_format IS NOT NULL
49+
AND event_data_format IS NOT NULL
50+
AND notification_interval IS NOT NULL
51+
AND notification_interval != interval '-1 second'
52+
THEN
53+
INSERT INTO directives (events_id,
54+
medium,
55+
recipient_address,
56+
template_name,
57+
notification_format,
58+
event_data_format,
59+
aggregate_identifier,
60+
notification_interval,
61+
endpoint)
62+
VALUES (event_id,
63+
medium,
64+
recipient_address,
65+
template_name,
66+
notification_format,
67+
event_data_format,
68+
aggregate_identifier,
69+
notification_interval,
70+
endpoint);
71+
END IF;
72+
END
73+
$$ LANGUAGE plpgsql VOLATILE;
74+
75+
76+
CREATE OR REPLACE FUNCTION directives_from_extra(
77+
event_id BIGINT,
78+
extra JSONB
79+
) RETURNS VOID
80+
AS $$
81+
DECLARE
82+
json_directives JSONB := extra -> 'certbund' -> 'source_directives';
83+
directive JSONB;
84+
BEGIN
85+
IF json_directives IS NOT NULL THEN
86+
FOR directive
87+
IN SELECT * FROM jsonb_array_elements(json_directives) LOOP
88+
PERFORM insert_directive(event_id, directive, 'source');
89+
END LOOP;
90+
END IF;
91+
END
92+
$$ LANGUAGE plpgsql VOLATILE;
93+
```
94+
495
## 1.02 to 1.3.0
596

697
* Changed dependency to use the official Python GnuPG bindings

sql/notifications.sql

Lines changed: 7 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -129,7 +129,7 @@ GRANT SELECT, UPDATE ON directives TO eventdb_send_notifications;
129129
-- 16.4 LTS we go with json_each_text because in most cases the values
130130
-- will have come from IntelMQ events where the values have been
131131
-- validated and e.g. ASNs will always be numbers.
132-
CREATE OR REPLACE FUNCTION json_object_as_text_array(obj JSON)
132+
CREATE OR REPLACE FUNCTION json_object_as_text_array(obj JSONB)
133133
RETURNS TEXT[][]
134134
AS $$
135135
DECLARE
@@ -138,7 +138,7 @@ DECLARE
138138
v TEXT;
139139
BEGIN
140140
FOR k, v IN
141-
SELECT * FROM json_each_text(obj) ORDER BY key
141+
SELECT * FROM jsonb_each_text(obj) ORDER BY key
142142
LOOP
143143
arr := arr || ARRAY[ARRAY[k, v]];
144144
END LOOP;
@@ -149,7 +149,7 @@ $$ LANGUAGE plpgsql IMMUTABLE;
149149

150150
CREATE OR REPLACE FUNCTION insert_directive(
151151
event_id BIGINT,
152-
directive JSON,
152+
directive JSONB,
153153
endpoint ip_endpoint
154154
) RETURNS VOID
155155
AS $$
@@ -199,16 +199,16 @@ $$ LANGUAGE plpgsql VOLATILE;
199199

200200
CREATE OR REPLACE FUNCTION directives_from_extra(
201201
event_id BIGINT,
202-
extra JSON
202+
extra JSONB
203203
) RETURNS VOID
204204
AS $$
205205
DECLARE
206-
json_directives JSON := extra -> 'certbund' -> 'source_directives';
207-
directive JSON;
206+
json_directives JSONB := extra -> 'certbund' -> 'source_directives';
207+
directive JSONB;
208208
BEGIN
209209
IF json_directives IS NOT NULL THEN
210210
FOR directive
211-
IN SELECT * FROM json_array_elements(json_directives) LOOP
211+
IN SELECT * FROM jsonb_array_elements(json_directives) LOOP
212212
PERFORM insert_directive(event_id, directive, 'source');
213213
END LOOP;
214214
END IF;

sql/updates.txt

Lines changed: 89 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,94 @@
11
(most recent on top)
22

3+
== Adapt to JSONB type of IntelMQ's `extra` field
4+
5+
```
6+
CREATE OR REPLACE FUNCTION json_object_as_text_array(obj JSONB)
7+
RETURNS TEXT[][]
8+
AS $$
9+
DECLARE
10+
arr TEXT[][] = '{}'::TEXT[][];
11+
k TEXT;
12+
v TEXT;
13+
BEGIN
14+
FOR k, v IN
15+
SELECT * FROM jsonb_each_text(obj) ORDER BY key
16+
LOOP
17+
arr := arr || ARRAY[ARRAY[k, v]];
18+
END LOOP;
19+
RETURN arr;
20+
END
21+
$$ LANGUAGE plpgsql IMMUTABLE;
22+
23+
CREATE OR REPLACE FUNCTION insert_directive(
24+
event_id BIGINT,
25+
directive JSONB,
26+
endpoint ip_endpoint
27+
) RETURNS VOID
28+
AS $$
29+
DECLARE
30+
medium TEXT := directive ->> 'medium';
31+
recipient_address TEXT := directive ->> 'recipient_address';
32+
template_name TEXT := directive ->> 'template_name';
33+
notification_format TEXT := directive ->> 'notification_format';
34+
event_data_format TEXT := directive ->> 'event_data_format';
35+
aggregate_identifier TEXT[][]
36+
:= json_object_as_text_array(directive -> 'aggregate_identifier');
37+
notification_interval interval
38+
:= coalesce(((directive ->> 'notification_interval') :: INT)
39+
* interval '1 second',
40+
interval '0 second');
41+
BEGIN
42+
IF medium IS NOT NULL
43+
AND recipient_address IS NOT NULL
44+
AND template_name IS NOT NULL
45+
AND notification_format IS NOT NULL
46+
AND event_data_format IS NOT NULL
47+
AND notification_interval IS NOT NULL
48+
AND notification_interval != interval '-1 second'
49+
THEN
50+
INSERT INTO directives (events_id,
51+
medium,
52+
recipient_address,
53+
template_name,
54+
notification_format,
55+
event_data_format,
56+
aggregate_identifier,
57+
notification_interval,
58+
endpoint)
59+
VALUES (event_id,
60+
medium,
61+
recipient_address,
62+
template_name,
63+
notification_format,
64+
event_data_format,
65+
aggregate_identifier,
66+
notification_interval,
67+
endpoint);
68+
END IF;
69+
END
70+
$$ LANGUAGE plpgsql VOLATILE;
71+
72+
73+
CREATE OR REPLACE FUNCTION directives_from_extra(
74+
event_id BIGINT,
75+
extra JSONB
76+
) RETURNS VOID
77+
AS $$
78+
DECLARE
79+
json_directives JSONB := extra -> 'certbund' -> 'source_directives';
80+
directive JSONB;
81+
BEGIN
82+
IF json_directives IS NOT NULL THEN
83+
FOR directive
84+
IN SELECT * FROM jsonb_array_elements(json_directives) LOOP
85+
PERFORM insert_directive(event_id, directive, 'source');
86+
END LOOP;
87+
END IF;
88+
END
89+
$$ LANGUAGE plpgsql VOLATILE;
90+
```
91+
392
== Add expression index for recipient_group to directives (2019-10)
493

594
For each tag that is saved in the `aggregate_identifier` in the directives

0 commit comments

Comments
 (0)