merge srce changes from pt branch
This commit is contained in:
parent
937cf38af1
commit
6056491ace
130
srce.pgsql
130
srce.pgsql
@ -1,6 +1,3 @@
|
|||||||
SET auto_explain.log_min_duration = 0;
|
|
||||||
SHOW ALL;
|
|
||||||
|
|
||||||
\timing
|
\timing
|
||||||
|
|
||||||
/*--------------------------------------------------------
|
/*--------------------------------------------------------
|
||||||
@ -9,8 +6,7 @@ SHOW ALL;
|
|||||||
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
|
|
||||||
*/---------------------------------------------------------
|
*/---------------------------------------------------------
|
||||||
|
|
||||||
|
|
||||||
@ -23,8 +19,8 @@ DECLARE _srce text;
|
|||||||
|
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
_path := 'C:\users\ptrowbridge\downloads\lon_loan_ledgerbal.csv';
|
_path := 'C:\users\fleet\downloads\dc1024.csv';
|
||||||
_srce := 'PNCO';
|
_srce := 'DCARD';
|
||||||
|
|
||||||
----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
|
----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
|
||||||
|
|
||||||
@ -35,7 +31,7 @@ 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
|
||||||
@ -62,22 +58,29 @@ BEGIN
|
|||||||
|
|
||||||
EXECUTE _t;
|
EXECUTE _t;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
END
|
|
||||||
$$;
|
|
||||||
|
|
||||||
|
|
||||||
WITH
|
WITH
|
||||||
|
|
||||||
|
-------------extract the limiter fields to one row per source----------------------------------
|
||||||
|
|
||||||
|
ext AS (
|
||||||
|
SELECT
|
||||||
|
srce
|
||||||
|
,defn->'unique_constraint'->>'fields'
|
||||||
|
,ARRAY(SELECT ae.e::text[] FROM jsonb_array_elements_text(defn->'unique_constraint'->'fields') ae(e)) text_array
|
||||||
|
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-----------
|
-------------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 (
|
,pending_list AS (
|
||||||
SELECT
|
SELECT
|
||||||
---creates a key value pair and then aggregates rows of key value pairs
|
jsonb_extract(
|
||||||
jsonb_object_agg(
|
row_to_json(i)::jsonb
|
||||||
(ae.e::text[])[1], --the key name
|
,ext.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
|
|
||||||
) json_key,
|
) json_key,
|
||||||
row_to_json(i)::JSONB rec,
|
row_to_json(i)::JSONB rec,
|
||||||
srce,
|
srce,
|
||||||
@ -85,13 +88,8 @@ $$;
|
|||||||
id
|
id
|
||||||
FROM
|
FROM
|
||||||
csv_i i
|
csv_i i
|
||||||
INNER JOIN tps.srce s ON
|
INNER JOIN ext ON
|
||||||
s.srce = 'PNCO'
|
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
|
||||||
)
|
)
|
||||||
@ -105,6 +103,17 @@ $$;
|
|||||||
pending_list
|
pending_list
|
||||||
)
|
)
|
||||||
|
|
||||||
|
-----------list of keys already loaded to tps-----------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
, matched_keys AS (
|
||||||
|
SELECT DISTINCT
|
||||||
|
k.json_key
|
||||||
|
FROM
|
||||||
|
pending_keys k
|
||||||
|
INNER JOIN tps.trans t ON
|
||||||
|
t.rec @> k.json_key
|
||||||
|
)
|
||||||
|
|
||||||
-----------return unique keys that are not already in tps.trans-----------------------------------------------------------------------------------
|
-----------return unique keys that are not already in tps.trans-----------------------------------------------------------------------------------
|
||||||
|
|
||||||
, unmatched_keys AS (
|
, unmatched_keys AS (
|
||||||
@ -115,12 +124,10 @@ $$;
|
|||||||
|
|
||||||
EXCEPT
|
EXCEPT
|
||||||
|
|
||||||
SELECT DISTINCT
|
SELECT
|
||||||
k.json_key
|
json_key
|
||||||
FROM
|
FROM
|
||||||
pending_keys k
|
matched_keys
|
||||||
INNER JOIN tps.trans t ON
|
|
||||||
t.rec @> k.json_key
|
|
||||||
)
|
)
|
||||||
|
|
||||||
-----------insert pending rows that have key with no trans match-----------------------------------------------------------------------------------
|
-----------insert pending rows that have key with no trans match-----------------------------------------------------------------------------------
|
||||||
@ -143,44 +150,31 @@ $$;
|
|||||||
RETURNING *
|
RETURNING *
|
||||||
)
|
)
|
||||||
|
|
||||||
-----------list of records not inserted--------------------------------------------------------------------------------------------------------------
|
|
||||||
|
|
||||||
, not_inserted AS (
|
|
||||||
SELECT
|
|
||||||
srce
|
|
||||||
,rec
|
|
||||||
FROM
|
|
||||||
pending_list
|
|
||||||
|
|
||||||
EXCEPT ALL
|
|
||||||
|
|
||||||
SELECT
|
|
||||||
srce
|
|
||||||
,rec
|
|
||||||
FROM
|
|
||||||
inserted
|
|
||||||
)
|
|
||||||
|
|
||||||
--------insert to log-------------------------------------------------------------------------------------------------------------------------------------
|
|
||||||
--below select should be loaded to the log table
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
--------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------
|
--------summarize records not inserted-------------------+------------------------------------------------------------------------------------------------
|
||||||
|
|
||||||
|
INSERT INTO
|
||||||
|
tps.trans_log (info)
|
||||||
SELECT
|
SELECT
|
||||||
jsonb_build_object('srce', t.srce) srce,
|
JSONB_BUILD_OBJECT('time_stamp',CURRENT_TIMESTAMP)
|
||||||
,(ae.e::text[])[1] unq_constr
|
||JSONB_BUILD_OBJECT('srce',_srce)
|
||||||
,MIN(rec #>> ae.e::text[]) min_text
|
||JSONB_BUILD_OBJECT('path',_path)
|
||||||
,MAX(rec #>> ae.e::text[]) max_text
|
||JSONB_BUILD_OBJECT('not_inserted',
|
||||||
,JSONB_PRETTY(JSON_AGG(rec #> ae.e::text[] ORDER BY rec #>> ae.e::text[])::JSONB)
|
(
|
||||||
|
SELECT
|
||||||
|
jsonb_agg(json_key)
|
||||||
FROM
|
FROM
|
||||||
not_inserted t
|
matched_keys
|
||||||
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
|
||JSONB_BUILD_OBJECT('inserted',
|
||||||
GROUP BY
|
(
|
||||||
t.srce
|
SELECT
|
||||||
,(ae.e::text[])[1];
|
jsonb_agg(json_key)
|
||||||
*/
|
FROM
|
||||||
|
unmatched_keys
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
END
|
||||||
|
$$;
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user