finish out logging the inserts and getting them into the main do block

This commit is contained in:
Paul Trowbridge 2017-10-25 00:47:26 -04:00
parent e2d42467af
commit ed1a903718
2 changed files with 132 additions and 119 deletions

View File

@ -6,8 +6,7 @@
2. get unqiue pending keys 2. get unqiue pending keys
3. see which keys not already in tps.trans 3. see which keys not already in tps.trans
4. insert pending records associated with keys that are not already in trans 4. insert pending records associated with keys that are not already in trans
5. get list of recors not inserted 5. insert summary to log table
6. summarize records not inserted
*/--------------------------------------------------------- */---------------------------------------------------------
@ -15,9 +14,14 @@ DO $$
DECLARE _t text; DECLARE _t text;
DECLARE _c text; DECLARE _c text;
DECLARE _path text;
DECLARE _srce text;
BEGIN BEGIN
_path := 'C:\users\fleet\downloads\dc1024.csv';
_srce := 'DCARD';
----------------------------------------------------build the column list of the temp table---------------------------------------------------------------- ----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
SELECT SELECT
@ -27,11 +31,11 @@ BEGIN
_t, _t,
_c _c
FROM FROM
TPS.srce tps.srce
--unwrap the schema definition array --unwrap the schema definition array
LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE
WHERE WHERE
srce = 'HUNT' srce = _srce
GROUP BY GROUP BY
srce; srce;
@ -48,27 +52,35 @@ BEGIN
----------------------------------------------------do the insert------------------------------------------------------------------------------------------- ----------------------------------------------------do the insert-------------------------------------------------------------------------------------------
--the column list needs to be dynamic forcing this whole line to be dynamic --the column list needs to be dynamic forcing this whole line to be dynamic
_t := format('COPY csv_i (%s) FROM ''C:\Users\fleet\downloads\hunt.csv'' WITH (HEADER TRUE,DELIMITER '','', FORMAT CSV, ENCODING ''SQL_ASCII'',QUOTE ''"'');',_c); _t := format('COPY csv_i (%s) FROM %L WITH (HEADER TRUE,DELIMITER '','', FORMAT CSV, ENCODING ''SQL_ASCII'',QUOTE ''"'');',_c,_path);
--RAISE NOTICE '%', _t; --RAISE NOTICE '%', _t;
EXECUTE _t; EXECUTE _t;
WITH
END -------------extract the limiter fields to one row per source----------------------------------
$$;
ext AS (
WITH
-------------for each imported row in the COPY table, genereate the json rec, and a column for the json key specified in the srce.defn-----------
pending_list AS (
SELECT SELECT
---creates a key value pair and then aggregates rows of key value pairs srce
jsonb_object_agg( ,defn->'unique_constraint'->>'fields'
(ae.e::text[])[1], --the key name ,ARRAY(SELECT ae.e::text[] FROM jsonb_array_elements_text(defn->'unique_constraint'->'fields') ae(e)) text_array
(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 FROM
tps.srce
WHERE
srce = _srce
--add where clause for targeted source
)
-------------for each imported row in the COPY table, genereate the json rec, and a column for the json key specified in the srce.defn-----------
,pending_list AS (
SELECT
jsonb_extract(
row_to_json(i)::jsonb
,ext.text_array
) json_key, ) json_key,
row_to_json(i)::JSONB rec, row_to_json(i)::JSONB rec,
srce, srce,
@ -76,47 +88,52 @@ pending_list AS (
id id
FROM FROM
csv_i i csv_i i
INNER JOIN tps.srce s ON INNER JOIN ext ON
s.srce = 'HUNT' ext.srce = _srce
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE
GROUP BY
i.*,
srce,
id
ORDER BY ORDER BY
id ASC id ASC
) )
-----------create a unique list of keys from staged rows------------------------------------------------------------------------------------------ -----------create a unique list of keys from staged rows------------------------------------------------------------------------------------------
, pending_keys AS ( , pending_keys AS (
SELECT DISTINCT SELECT DISTINCT
json_key json_key
FROM FROM
pending_list pending_list
) )
-----------return unique keys that are not already in tps.trans----------------------------------------------------------------------------------- -----------list of keys already loaded to tps-----------------------------------------------------------------------------------------------------
, unmatched_keys AS ( , matched_keys AS (
SELECT SELECT DISTINCT
json_key
FROM
pending_keys
EXCEPT
SELECT DISTINCT
k.json_key k.json_key
FROM FROM
pending_keys k pending_keys k
INNER JOIN tps.trans t ON INNER JOIN tps.trans t ON
t.rec @> k.json_key t.rec @> k.json_key
) )
-----------insert pending rows that have key with no trans match----------------------------------------------------------------------------------- -----------return unique keys that are not already in tps.trans-----------------------------------------------------------------------------------
, inserted AS ( , unmatched_keys AS (
SELECT
json_key
FROM
pending_keys
EXCEPT
SELECT
json_key
FROM
matched_keys
)
-----------insert pending rows that have key with no trans match-----------------------------------------------------------------------------------
--need to look into mapping the transactions prior to loading
, inserted AS (
INSERT INTO INSERT INTO
tps.trans (srce, rec) tps.trans (srce, rec)
SELECT SELECT
@ -131,39 +148,33 @@ FROM
----this conflict is only if an exact duplicate rec json happens, which will be rejected ----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 ----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
RETURNING * RETURNING *
) )
-----------list of records not inserted-------------------------------------------------------------------------------------------------------------- --------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------
, not_inserted AS ( INSERT INTO
tps.trans_log (info)
SELECT SELECT
srce JSONB_BUILD_OBJECT('time_stamp',CURRENT_TIMESTAMP)
,rec ||JSONB_BUILD_OBJECT('srce',_srce)
FROM ||JSONB_BUILD_OBJECT('path',_path)
pending_list ||JSONB_BUILD_OBJECT('not_inserted',
(
EXCEPT ALL
SELECT SELECT
srce jsonb_agg(json_key)
,rec
FROM FROM
inserted matched_keys
) )
)
||JSONB_BUILD_OBJECT('inserted',
(
SELECT
jsonb_agg(json_key)
FROM
unmatched_keys
)
);
--------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------ END
$$;
SELECT
t.srce
,(ae.e::text[])[1] unq_constr
,MIN(rec #>> ae.e::text[]) min_text
,MAX(rec #>> ae.e::text[]) max_text
,JSONB_PRETTY(JSON_AGG(rec #> ae.e::text[] ORDER BY rec #>> ae.e::text[])::JSONB)
FROM
not_inserted t
INNER JOIN tps.srce s ON
s.srce = t.srce
LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE
GROUP BY
t.srce
,(ae.e::text[])[1];

View File

@ -7,11 +7,13 @@ SELECT
FROM FROM
tps.srce tps.srce
) )
SELECT SELECT
srce t.srce
, ,jsonb_pretty(t.rec)
public.jsonb_extract(rec,txa) ,jsonb_pretty(public.jsonb_extract(rec,txa))
FROM FROM
tps.trans tps.trans t
INNER JOIN ext ON INNER JOIN ext ON
trans.srce = ext.srce t.srce = ext.srce