jl/schema/triggers/log_insert.sql

123 lines
3.2 KiB
MySQL
Raw Normal View History

2018-09-17 23:38:53 -04:00
2018-09-18 00:11:59 -04:00
CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger
2018-09-14 01:11:48 -04:00
LANGUAGE plpgsql
AS
$func$
BEGIN
WITH
2018-09-17 23:38:53 -04:00
/*
ins AS (
SELECT
1 id
,$${
"gl": {
"lines": [
{
"amount": 2.19,
"account": "h.food"
},
{
"amount": -2.19,
"account": "h.dcard"
}
],
"jpath": [
[
"{item,0}",
"{header}"
],
[
"{item,0}",
"{header}"
]
]
},
"item": [
{
"item": "green olives",
"amount": 2.19,
"reason": "food",
"account": "h.food"
}
],
"header": {
"entity": "home",
"module": "MHI",
"offset": "h.dcard",
"transaction": "purchase"
}
}$$::jsonb bpr
),
*/
2018-09-14 01:11:48 -04:00
------------------------------------full extraction-------------------------------------------
full_ex AS (
SELECT
ins.id
2018-09-17 23:38:53 -04:00
--th econtents of the gl line
2018-09-14 01:11:48 -04:00
,a.i gl_line
2018-09-17 23:38:53 -04:00
--the array position of the gl line
,a.rn gl_rownum
--array of references
,ins.bpr#>ARRAY['gl','jpath',(a.rn - 1)::text] gl_ref
--each item in the reference array
2018-09-14 01:11:48 -04:00
,p.i ref_line
2018-09-17 23:38:53 -04:00
--array postition of the reference item
,p.rn ref_rownum
--follow the path
,ins.bpr#>(p.i->>0)::text[] bpr_extract
2018-09-14 01:11:48 -04:00
FROM
ins
--gl array hold each gl line
2018-09-17 23:38:53 -04:00
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr->'gl'->'lines') WITH ORDINALITY a(i, rn) ON TRUE
2018-09-14 01:11:48 -04:00
--for each
2018-09-17 23:38:53 -04:00
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr#>ARRAY['gl','jpath',(a.rn - 1)::text]) WITH ORDINALITY p(i, rn) ON TRUE
2018-09-14 00:16:19 -04:00
)
2018-09-17 23:38:53 -04:00
--select * from full_ex
2018-09-14 01:11:48 -04:00
--------------------------------re-ggregate extraction to gl line level----------------------
2018-09-17 23:38:53 -04:00
,ex_gl_line AS (
2018-09-18 00:11:59 -04:00
SELECT
id
,gl_line->>'account' account
,(gl_line->>'amount')::numeric amount
,gl_rownum
--aggregate all the path references back to the gl line
,public.jsonb_concat(bpr_extract) bprkeys
FROM
full_ex
GROUP BY
id
,gl_line
,gl_rownum
2018-09-17 23:38:53 -04:00
)
--select * from ex_gl_line
2018-09-18 00:11:59 -04:00
,upsert_acct_mast AS (
INSERT INTO
evt.acct (acct,prop)
SELECT DISTINCT
account
,'{}'::jsonb prop
FROM
ex_gl_line
2018-09-18 23:07:10 -04:00
ON CONFLICT DO NOTHING
2018-09-18 00:11:59 -04:00
RETURNING *
)
2018-09-17 23:38:53 -04:00
INSERT INTO
2018-09-18 00:11:59 -04:00
evt.gl (bprid,acct, amount,glline, bprkeys)
2018-09-17 23:38:53 -04:00
SELECT
id
,account
,amount
,gl_rownum
,bprkeys
FROM
ex_gl_line;
2018-09-14 01:11:48 -04:00
RETURN NULL;
END;
$func$
CREATE TRIGGER log_insert
2018-09-18 00:11:59 -04:00
AFTER INSERT ON evt.bpr
2018-09-14 01:11:48 -04:00
REFERENCING NEW TABLE AS ins
FOR EACH STATEMENT
2018-09-17 23:38:53 -04:00
EXECUTE PROCEDURE evt.log_insert();