update bpr insert trigger
This commit is contained in:
parent
c221a1f7c4
commit
d797592d86
@ -62,4 +62,85 @@ COMMENT ON COLUMN evt.bal.debits IS 'total debits';
|
|||||||
COMMENT ON COLUMN evt.bal.credits IS 'total credits';
|
COMMENT ON COLUMN evt.bal.credits IS 'total credits';
|
||||||
COMMENT ON COLUMN evt.bal.cbal IS 'closing balance';
|
COMMENT ON COLUMN evt.bal.cbal IS 'closing balance';
|
||||||
|
|
||||||
|
-----------------------------------------process bpr insert trigger -----------------------------------
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS
|
||||||
|
$func$
|
||||||
|
BEGIN
|
||||||
|
WITH
|
||||||
|
------------------------------------full extraction-------------------------------------------
|
||||||
|
full_ex AS (
|
||||||
|
SELECT
|
||||||
|
ins.id
|
||||||
|
--th econtents of the gl line
|
||||||
|
,a.i gl_line
|
||||||
|
--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
|
||||||
|
,p.i ref_line
|
||||||
|
--array postition of the reference item
|
||||||
|
,p.rn ref_rownum
|
||||||
|
--follow the path
|
||||||
|
,ins.bpr#>(p.i->>0)::text[] bpr_extract
|
||||||
|
FROM
|
||||||
|
ins
|
||||||
|
--gl array hold each gl line
|
||||||
|
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr->'gl'->'lines') WITH ORDINALITY a(i, rn) ON TRUE
|
||||||
|
--for each
|
||||||
|
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS(ins.bpr#>ARRAY['gl','jpath',(a.rn - 1)::text]) WITH ORDINALITY p(i, rn) ON TRUE
|
||||||
|
)
|
||||||
|
--select * from full_ex
|
||||||
|
--------------------------------re-ggregate extraction to gl line level----------------------
|
||||||
|
,ex_gl_line AS (
|
||||||
|
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
|
||||||
|
)
|
||||||
|
--select * from ex_gl_line
|
||||||
|
,upsert_acct_mast AS (
|
||||||
|
INSERT INTO
|
||||||
|
evt.acct (acct,prop)
|
||||||
|
SELECT DISTINCT
|
||||||
|
account
|
||||||
|
,'{}'::jsonb prop
|
||||||
|
FROM
|
||||||
|
ex_gl_line
|
||||||
|
RETURNING *
|
||||||
|
)
|
||||||
|
INSERT INTO
|
||||||
|
evt.gl (bprid,acct, amount,glline, bprkeys)
|
||||||
|
SELECT
|
||||||
|
id
|
||||||
|
,account
|
||||||
|
,amount
|
||||||
|
,gl_rownum
|
||||||
|
,bprkeys
|
||||||
|
FROM
|
||||||
|
ex_gl_line;
|
||||||
|
RETURN NULL;
|
||||||
|
END;
|
||||||
|
$func$;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TRIGGER log_insert
|
||||||
|
AFTER INSERT ON evt.bpr
|
||||||
|
REFERENCING NEW TABLE AS ins
|
||||||
|
FOR EACH STATEMENT
|
||||||
|
EXECUTE PROCEDURE evt.log_insert();
|
||||||
|
|
||||||
|
|
||||||
COMMIT;
|
COMMIT;
|
@ -1,5 +1,5 @@
|
|||||||
|
|
||||||
CREATE FUNCTION log_insert() RETURNS trigger
|
CREATE OR REPLACE FUNCTION evt.log_insert() RETURNS trigger
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS
|
AS
|
||||||
$func$
|
$func$
|
||||||
@ -75,23 +75,33 @@ CREATE FUNCTION log_insert() RETURNS trigger
|
|||||||
--select * from full_ex
|
--select * from full_ex
|
||||||
--------------------------------re-ggregate extraction to gl line level----------------------
|
--------------------------------re-ggregate extraction to gl line level----------------------
|
||||||
,ex_gl_line AS (
|
,ex_gl_line AS (
|
||||||
SELECT
|
SELECT
|
||||||
id
|
id
|
||||||
,gl_line->>'account' account
|
,gl_line->>'account' account
|
||||||
,(gl_line->>'amount')::numeric amount
|
,(gl_line->>'amount')::numeric amount
|
||||||
,gl_rownum
|
,gl_rownum
|
||||||
--aggregate all the path references back to the gl line
|
--aggregate all the path references back to the gl line
|
||||||
,public.jsonb_concat(bpr_extract) bprkeys
|
,public.jsonb_concat(bpr_extract) bprkeys
|
||||||
FROM
|
FROM
|
||||||
full_ex
|
full_ex
|
||||||
GROUP BY
|
GROUP BY
|
||||||
id
|
id
|
||||||
,gl_line
|
,gl_line
|
||||||
,gl_rownum
|
,gl_rownum
|
||||||
)
|
)
|
||||||
--select * from ex_gl_line
|
--select * from ex_gl_line
|
||||||
|
,upsert_acct_mast AS (
|
||||||
|
INSERT INTO
|
||||||
|
evt.acct (acct,prop)
|
||||||
|
SELECT DISTINCT
|
||||||
|
account
|
||||||
|
,'{}'::jsonb prop
|
||||||
|
FROM
|
||||||
|
ex_gl_line
|
||||||
|
RETURNING *
|
||||||
|
)
|
||||||
INSERT INTO
|
INSERT INTO
|
||||||
evt.gl (bprid,account, amount,glline, bprkeys)
|
evt.gl (bprid,acct, amount,glline, bprkeys)
|
||||||
SELECT
|
SELECT
|
||||||
id
|
id
|
||||||
,account
|
,account
|
||||||
@ -106,7 +116,7 @@ CREATE FUNCTION log_insert() RETURNS trigger
|
|||||||
|
|
||||||
|
|
||||||
CREATE TRIGGER log_insert
|
CREATE TRIGGER log_insert
|
||||||
AFTER INSERT ON evt.log
|
AFTER INSERT ON evt.bpr
|
||||||
REFERENCING NEW TABLE AS ins
|
REFERENCING NEW TABLE AS ins
|
||||||
FOR EACH STATEMENT
|
FOR EACH STATEMENT
|
||||||
EXECUTE PROCEDURE evt.log_insert();
|
EXECUTE PROCEDURE evt.log_insert();
|
Loading…
Reference in New Issue
Block a user