include pt branch srce.pgsql changes & transaction range query
This commit is contained in:
		
							parent
							
								
									c81a7c7dc4
								
							
						
					
					
						commit
						fe761c6975
					
				
							
								
								
									
										110
									
								
								srce.pgsql
									
									
									
									
									
								
							
							
						
						
									
										110
									
								
								srce.pgsql
									
									
									
									
									
								
							| @ -1,61 +1,107 @@ | |||||||
| DO $$ | DO $$ | ||||||
| 
 | 
 | ||||||
| declare _t text; | DECLARE _t text; | ||||||
|  | DECLARE _c text; | ||||||
| 
 | 
 | ||||||
| begin | BEGIN | ||||||
| 	 | 	 | ||||||
| ----------------------------------------------------build the column list of the temp table---------------------------------------------------------------- | ----------------------------------------------------build the column list of the temp table---------------------------------------------------------------- | ||||||
| 
 | 
 | ||||||
| 	SELECT | 	SELECT | ||||||
|         string_agg(quote_ident(prs.key)||' '||prs.type,',') |         string_agg(quote_ident(prs.key)||' '||prs.type,','), | ||||||
|  |         string_agg(quote_ident(prs.key),',') | ||||||
|     INTO |     INTO | ||||||
|     	_t |     	_t,  | ||||||
|  |         _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 = 'PNCL' |         srce = 'DCARD' | ||||||
|     GROUP BY |     GROUP BY | ||||||
|         srce; |         srce; | ||||||
|          |          | ||||||
| ----------------------------------------------------add create table verbage in front of column list-------------------------------------------------------- | ----------------------------------------------------add create table verbage in front of column list-------------------------------------------------------- | ||||||
| 
 | 
 | ||||||
|     _t := format('CREATE TEMP TABLE csv_i (%s)', _t); |     _t := format('CREATE TEMP TABLE csv_i (%s, id SERIAL)', _t); | ||||||
|     raise notice '%', _t; |     --RAISE NOTICE '%', _t; | ||||||
|      |     --RAISE NOTICE '%', _c; | ||||||
| 
 |  | ||||||
| ----------------------------------------------------build the table----------------------------------------------------------------------------------------- |  | ||||||
| 
 | 
 | ||||||
|     DROP TABLE IF EXISTS csv_i; |     DROP TABLE IF EXISTS csv_i; | ||||||
|      |      | ||||||
|     EXECUTE _t; |     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; | --******************************************* | ||||||
| 
 | --this needs to aggregate on id sequence | ||||||
| /* | --******************************************* | ||||||
| INSERT INTO | WITH pending_list AS ( | ||||||
|     tps.trans (srce, rec) |     SELECT | ||||||
| SELECT  |         ---creates a key value pair and then aggregates rows of key value pairs | ||||||
|     'PNCO', row_to_json(csv_i) FROM csv_i; |         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 | SELECT | ||||||
|     (row_to_json(i)::jsonb) #> ae.e::text[], |     srce | ||||||
|     srce, |     ,rec | ||||||
|     defn->'unique_constraint'->'type', |  | ||||||
|     defn->'unique_constraint'->'fields', |  | ||||||
|     ae.e, |  | ||||||
|     ae.rn |  | ||||||
| FROM | FROM | ||||||
|     csv_i i |     pending_list | ||||||
|     INNER JOIN tps.srce s ON | 
 | ||||||
|         s.srce = 'PNCL' | EXCEPT ALL | ||||||
|     LEFT JOIN LATERAL JSONB_ARRAY_ELEMENTS_TEXT(defn->'unique_constraint'->'fields') WITH ORDINALITY ae(e, rn) ON TRUE | 
 | ||||||
| LIMIT 10 | SELECT  | ||||||
|  |     srce | ||||||
|  |     ,rec | ||||||
|  | FROM  | ||||||
|  |     inserted; | ||||||
							
								
								
									
										14
									
								
								transaction_range.pgsql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										14
									
								
								transaction_range.pgsql
									
									
									
									
									
										Normal file
									
								
							| @ -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] | ||||||
		Loading…
	
		Reference in New Issue
	
	Block a user