From fe761c6975f281a081449fd802f6814df2438110 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 18 Oct 2017 01:06:00 -0400 Subject: [PATCH] include pt branch srce.pgsql changes & transaction range query --- srce.pgsql | 110 ++++++++++++++++++++++++++++------------ transaction_range.pgsql | 14 +++++ 2 files changed, 92 insertions(+), 32 deletions(-) create mode 100644 transaction_range.pgsql diff --git a/srce.pgsql b/srce.pgsql index 2fef279..16209a2 100644 --- a/srce.pgsql +++ b/srce.pgsql @@ -1,61 +1,107 @@ DO $$ -declare _t text; +DECLARE _t text; +DECLARE _c text; -begin +BEGIN ----------------------------------------------------build the column list of the temp table---------------------------------------------------------------- SELECT - string_agg(quote_ident(prs.key)||' '||prs.type,',') + string_agg(quote_ident(prs.key)||' '||prs.type,','), + string_agg(quote_ident(prs.key),',') INTO - _t + _t, + _c FROM TPS.srce --unwrap the schema definition array LEFT JOIN LATERAL jsonb_populate_recordset(null::tps.srce_defn_schema, defn->'schema') prs ON TRUE WHERE - srce = 'PNCL' + srce = 'DCARD' GROUP BY srce; ----------------------------------------------------add create table verbage in front of column list-------------------------------------------------------- - _t := format('CREATE TEMP TABLE csv_i (%s)', _t); - raise notice '%', _t; - - -----------------------------------------------------build the table----------------------------------------------------------------------------------------- + _t := format('CREATE TEMP TABLE csv_i (%s, id SERIAL)', _t); + --RAISE NOTICE '%', _t; + --RAISE NOTICE '%', _c; DROP TABLE IF EXISTS csv_i; EXECUTE _t; - COPY csv_i FROM 'C:\Users\ptrowbridge\Documents\OneDrive - The HC Companies, Inc\Cash\build_hist\pncl.csv' WITH (HEADER TRUE,DELIMITER ',', FORMAT CSV, ENCODING 'SQL_ASCII',QUOTE '"'); +----------------------------------------------------do the insert------------------------------------------------------------------------------------------- -end + --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\dc.csv'' WITH (HEADER TRUE,DELIMITER '','', FORMAT CSV, ENCODING ''SQL_ASCII'',QUOTE ''"'');',_c); + + --RAISE NOTICE '%', _t; + + EXECUTE _t; + + +END $$; ---SELECT row_to_json(csv_i) FROM csv_i; - -/* -INSERT INTO - tps.trans (srce, rec) -SELECT - 'PNCO', row_to_json(csv_i) FROM csv_i; -*/ - +--******************************************* +--this needs to aggregate on id sequence +--******************************************* +WITH pending_list AS ( + 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, + row_to_json(i)::JSONB rec, + srce, + --ae.rn, + id + FROM + csv_i i + INNER JOIN tps.srce s ON + s.srce = 'DCARD' + 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 +) +------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 + ON CONFLICT ON CONSTRAINT uc_rec DO NOTHING + RETURNING * +) +----records not inserted------ SELECT - (row_to_json(i)::jsonb) #> ae.e::text[], - srce, - defn->'unique_constraint'->'type', - defn->'unique_constraint'->'fields', - ae.e, - ae.rn + srce + ,rec FROM - csv_i i - INNER JOIN tps.srce s ON - s.srce = 'PNCL' - LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE -LIMIT 10 \ No newline at end of file + pending_list + +EXCEPT ALL + +SELECT + srce + ,rec +FROM + inserted; \ No newline at end of file diff --git a/transaction_range.pgsql b/transaction_range.pgsql new file mode 100644 index 0000000..b4f469e --- /dev/null +++ b/transaction_range.pgsql @@ -0,0 +1,14 @@ +SELECT + t.srce + ,(ae.e::text[])[1] unq_constr + ,MIN(rec #>> ae.e::text[]) min_text + ,COUNT(*) cnt + ,MAX(rec #>> ae.e::text[]) max_text +FROM + tps.trans 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] \ No newline at end of file