2017-10-11 00:17:21 -04:00
DO $$
2017-10-15 13:05:20 -04:00
DECLARE _t text;
DECLARE _c text;
2017-10-11 00:17:21 -04:00
2017-10-15 13:05:20 -04:00
BEGIN
2017-10-11 00:17:21 -04:00
2017-10-11 00:29:38 -04:00
----------------------------------------------------build the column list of the temp table----------------------------------------------------------------
2017-10-11 00:17:21 -04:00
SELECT
2017-10-14 01:40:26 -04:00
string_agg(quote_ident(prs.key)||' '||prs.type,','),
string_agg(quote_ident(prs.key),',')
2017-10-11 00:17:21 -04:00
INTO
2017-10-14 01:40:26 -04:00
_t,
_c
2017-10-11 00:17:21 -04:00
FROM
TPS.srce
--unwrap the schema definition array
LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE
2017-10-13 02:40:23 -04:00
WHERE
2017-10-19 00:42:30 -04:00
srce = 'HUNT'
2017-10-11 00:17:21 -04:00
GROUP BY
srce;
2017-10-11 00:29:38 -04:00
----------------------------------------------------add create table verbage in front of column list--------------------------------------------------------
2017-10-14 01:48:13 -04:00
_t := format('CREATE TEMP TABLE csv_i (%s, id SERIAL)', _t);
--RAISE NOTICE '%', _t;
--RAISE NOTICE '%', _c;
2017-10-11 00:29:38 -04:00
2017-10-11 00:17:21 -04:00
DROP TABLE IF EXISTS csv_i;
EXECUTE _t;
2017-10-14 01:48:13 -04:00
----------------------------------------------------do the insert-------------------------------------------------------------------------------------------
2017-10-14 01:40:26 -04:00
--the column list needs to be dynamic forcing this whole line to be dynamic
2017-10-19 00:42:30 -04:00
_t := format('COPY csv_i (%s) FROM ''C:\Users\fleet\downloads\hunt.csv'' WITH (HEADER TRUE,DELIMITER '','', FORMAT CSV, ENCODING ''SQL_ASCII'',QUOTE ''"'');',_c);
2017-10-14 01:48:13 -04:00
--RAISE NOTICE '%', _t;
EXECUTE _t;
2017-10-13 02:40:23 -04:00
2017-10-15 13:05:20 -04:00
END
2017-10-11 00:17:21 -04:00
$$;
2017-10-15 13:05:20 -04:00
--*******************************************
2017-10-14 01:48:13 -04:00
--this needs to aggregate on id sequence
2017-10-15 13:05:20 -04:00
--*******************************************
2017-10-16 00:14:05 -04:00
WITH pending_list AS (
2017-10-18 00:55:00 -04:00
SELECT
---creates a key value pair and then aggregates rows of key value pairs
jsonb_object_agg(
(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
) json_key,
2017-10-18 01:40:09 -04:00
row_to_json(i)::JSONB - 'id' rec,
2017-10-18 00:55:00 -04:00
srce,
--ae.rn,
id
FROM
csv_i i
INNER JOIN tps.srce s ON
2017-10-19 00:42:30 -04:00
s.srce = 'HUNT'
2017-10-18 00:55:00 -04:00
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
id
2017-10-16 00:14:05 -04:00
)
2017-10-18 00:55:00 -04:00
------results of an insert operation--------------
, inserted AS (
INSERT INTO
tps.trans (srce, rec)
SELECT
pl.srce
,pl.rec
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
RETURNING *
2017-10-16 00:14:05 -04:00
)
2017-10-18 02:07:33 -04:00
---------raw list of records not inserted----------
, not_inserted AS (
SELECT
srce
,rec
FROM
pending_list
2017-10-16 00:14:05 -04:00
2017-10-18 02:07:33 -04:00
EXCEPT ALL
SELECT
srce
,rec
FROM
inserted
)
--------summarize records not inserted------------------
2017-10-18 00:55:00 -04:00
SELECT
2017-10-18 02:07:33 -04:00
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)
2017-10-18 00:55:00 -04:00
FROM
2017-10-18 02:07:33 -04:00
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];