snap to pt branch on srce.pgsql
This commit is contained in:
parent
fe3a9c4bed
commit
63a3bd3b97
86
srce.pgsql
86
srce.pgsql
@ -1,4 +1,3 @@
|
|||||||
|
|
||||||
DO $$
|
DO $$
|
||||||
|
|
||||||
DECLARE _t text;
|
DECLARE _t text;
|
||||||
@ -50,38 +49,59 @@ $$;
|
|||||||
--this needs to aggregate on id sequence
|
--this needs to aggregate on id sequence
|
||||||
--*******************************************
|
--*******************************************
|
||||||
WITH pending_list AS (
|
WITH pending_list AS (
|
||||||
SELECT
|
SELECT
|
||||||
---creates a key value pair and then aggregates rows of key value pairs
|
---creates a key value pair and then aggregates rows of key value pairs
|
||||||
jsonb_object_agg(
|
jsonb_object_agg(
|
||||||
(ae.e::text[])[1], --the key name
|
(ae.e::text[])[1], --the key name
|
||||||
(row_to_json(i)::jsonb) #> ae.e::text[] --get the target value from the key from the csv row that has been converted to json
|
(row_to_json(i)::jsonb) #> ae.e::text[] --get the target value from the key from the csv row that has been converted to json
|
||||||
) json_key,
|
) json_key,
|
||||||
row_to_json(i) rec,
|
row_to_json(i)::JSONB rec,
|
||||||
srce,
|
srce,
|
||||||
--ae.rn,
|
--ae.rn,
|
||||||
id
|
id
|
||||||
FROM
|
FROM
|
||||||
csv_i i
|
csv_i i
|
||||||
INNER JOIN tps.srce s ON
|
INNER JOIN tps.srce s ON
|
||||||
s.srce = 'DCARD'
|
s.srce = 'DCARD'
|
||||||
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE
|
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE
|
||||||
GROUP BY
|
GROUP BY
|
||||||
i.*,
|
i.*,
|
||||||
srce,
|
srce,
|
||||||
id
|
id
|
||||||
ORDER BY
|
ORDER BY
|
||||||
id
|
id
|
||||||
)
|
)
|
||||||
, matched_tps AS (
|
------results of an insert operation--------------
|
||||||
SELECT
|
, inserted AS (
|
||||||
*
|
INSERT INTO
|
||||||
FROM
|
tps.trans (srce, rec)
|
||||||
pending_list pl
|
SELECT
|
||||||
INNER JOIN tps.trans t ON
|
pl.srce
|
||||||
t.srce = pl.srce
|
,pl.rec
|
||||||
AND t.rec @> pl.json_key
|
FROM
|
||||||
|
pending_list pl
|
||||||
|
LEFT JOIN tps.trans t ON
|
||||||
|
t.srce = pl.srce
|
||||||
|
AND t.rec @> pl.json_key
|
||||||
|
WHERE
|
||||||
|
t IS NULL
|
||||||
|
----this conflict is only if an exact duplicate rec json happens, which will be rejected
|
||||||
|
----therefore, records may not be inserted due to ay matches with certain json fields, or if the entire json is a duplicate, reason is not specified
|
||||||
|
ON CONFLICT ON CONSTRAINT uc_rec DO NOTHING
|
||||||
|
RETURNING *
|
||||||
)
|
)
|
||||||
SELECT * FROM matched_tps;
|
|
||||||
|
|
||||||
-- need to compare against and tps matches
|
----records not inserted------
|
||||||
-- therefore need to apply keyset to tps rows
|
SELECT
|
||||||
|
srce
|
||||||
|
,rec
|
||||||
|
FROM
|
||||||
|
pending_list
|
||||||
|
|
||||||
|
EXCEPT ALL
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,rec
|
||||||
|
FROM
|
||||||
|
inserted;
|
Loading…
Reference in New Issue
Block a user