From 75cb7b8554f82a41fac02b63488270ffd0764def Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sat, 1 Dec 2018 21:58:00 -0500 Subject: [PATCH 1/5] swaps & logs untrack --- .gitignore | 2 ++ 1 file changed, 2 insertions(+) diff --git a/.gitignore b/.gitignore index c6114bc..692065f 100644 --- a/.gitignore +++ b/.gitignore @@ -2,3 +2,5 @@ .dbeaver-data-sources.xml .project Scripts/ +*.log +*.swp From 69dbc7742b7cc617a8f1cade5f478cf851b85e45 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sun, 2 Dec 2018 00:59:00 -0500 Subject: [PATCH 2/5] work on upgrade query to adjust schema and leave sources in place --- .../upgrade_scripts/001.extract_schemas.sql | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) create mode 100644 database/upgrade_scripts/001.extract_schemas.sql diff --git a/database/upgrade_scripts/001.extract_schemas.sql b/database/upgrade_scripts/001.extract_schemas.sql new file mode 100644 index 0000000..39a01a7 --- /dev/null +++ b/database/upgrade_scripts/001.extract_schemas.sql @@ -0,0 +1,19 @@ +SELECT + srce + ,jsonb_pretty(defn) + ,jsonb_pretty((defn - 'schemas')|| + --rebuild the schemas key value from below + jsonb_build_object( + 'schemas' + --aggregate all the new key values for a single soure + ,jsonb_agg( + --combine a new key 'name' with the columns for that name + jsonb_build_object('name',k)||jsonb_build_object('columns',v) + ) + )) +FROM + tps.srce + LEFT JOIN LATERAL jsonb_each(defn->'schemas') WITH ORDINALITY je(k,v, rn) ON TRUE +GROUP BY + srce + ,defn \ No newline at end of file From cf06d241d7da404b93ebce7368e79517833cce85 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sun, 2 Dec 2018 01:01:19 -0500 Subject: [PATCH 3/5] build update --- .../upgrade_scripts/001.extract_schemas.sql | 22 ++++++++++++++++++- 1 file changed, 21 insertions(+), 1 deletion(-) diff --git a/database/upgrade_scripts/001.extract_schemas.sql b/database/upgrade_scripts/001.extract_schemas.sql index 39a01a7..dba329e 100644 --- a/database/upgrade_scripts/001.extract_schemas.sql +++ b/database/upgrade_scripts/001.extract_schemas.sql @@ -1,3 +1,22 @@ +UPDATE + tps.srce +SET + defn = + --delete "schemas" from existing json and tack on revamped layout + jsonb_pretty((defn - 'schemas')|| + --rebuild the schemas key value from below + jsonb_build_object( + 'schemas' + --aggregate all the new key values for a single soure + ,jsonb_agg( + --combine a new key 'name' with the columns for that name + jsonb_build_object('name',k)||jsonb_build_object('columns',v) + ) + )) + + +---------------select statement test----------------------- +/* SELECT srce ,jsonb_pretty(defn) @@ -16,4 +35,5 @@ FROM LEFT JOIN LATERAL jsonb_each(defn->'schemas') WITH ORDINALITY je(k,v, rn) ON TRUE GROUP BY srce - ,defn \ No newline at end of file + ,defn +*/ \ No newline at end of file From 43f9bb2d10f6ecc955e42dba143bfac5a7e35896 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sun, 2 Dec 2018 01:10:34 -0500 Subject: [PATCH 4/5] update target source schema sample --- database/templates/srce.json | 138 ++++++++++++++++++----------------- 1 file changed, 72 insertions(+), 66 deletions(-) diff --git a/database/templates/srce.json b/database/templates/srce.json index bea9cbd..daaf1e4 100644 --- a/database/templates/srce.json +++ b/database/templates/srce.json @@ -7,70 +7,76 @@ "{Post Date}", "{Description}" ], - "schemas": { - "default": [ - { - "path": "{Trans. Date}", - "type": "date", - "column_name": "Trans. Date" - }, - { - "path": "{Post Date}", - "type": "date", - "column_name": "Post Date" - }, - { - "path": "{Description}", - "type": "text", - "column_name": "Description" - }, - { - "path": "{Amount}", - "type": "numeric", - "column_name": "Amount" - }, - { - "path": "{Category}", - "type": "text", - "column_name": "Category" - } - ], - "mapped": [ - { - "path": "{Trans. Date}", - "type": "date", - "column_name": "Trans. Date" - }, - { - "path": "{Post Date}", - "type": "date", - "column_name": "Post Date" - }, - { - "path": "{Description}", - "type": "text", - "column_name": "Description" - }, - { - "path": "{Amount}", - "type": "numeric", - "column_name": "Amount" - }, - { - "path": "{Category}", - "type": "text", - "column_name": "Category" - }, - { - "path": "{party}", - "type": "text", - "column_name": "Party" - }, - { - "path": "{reason}", - "type": "text", - "column_name": "Reason" - } - ] - } + "schemas": [ + { + "name": "default", + "columns": [ + { + "path": "{Trans. Date}", + "type": "date", + "column_name": "Trans. Date" + }, + { + "path": "{Post Date}", + "type": "date", + "column_name": "Post Date" + }, + { + "path": "{Description}", + "type": "text", + "column_name": "Description" + }, + { + "path": "{Amount}", + "type": "numeric", + "column_name": "Amount" + }, + { + "path": "{Category}", + "type": "text", + "column_name": "Category" + } + ] + }, + { + "name": "mapped", + "columns": [ + { + "path": "{Trans. Date}", + "type": "date", + "column_name": "Trans. Date" + }, + { + "path": "{Post Date}", + "type": "date", + "column_name": "Post Date" + }, + { + "path": "{Description}", + "type": "text", + "column_name": "Description" + }, + { + "path": "{Amount}", + "type": "numeric", + "column_name": "Amount" + }, + { + "path": "{Category}", + "type": "text", + "column_name": "Category" + }, + { + "path": "{party}", + "type": "text", + "column_name": "Party" + }, + { + "path": "{reason}", + "type": "text", + "column_name": "Reason" + } + ] + } + ] } \ No newline at end of file From 87407e36fcfd4ec8d8dec2c13116fc3f9ff46230 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Sun, 2 Dec 2018 01:18:29 -0500 Subject: [PATCH 5/5] use select in with block and update with join back in order to retain lateral joins in the update --- .../upgrade_scripts/001.extract_schemas.sql | 37 +++++++------------ 1 file changed, 14 insertions(+), 23 deletions(-) diff --git a/database/upgrade_scripts/001.extract_schemas.sql b/database/upgrade_scripts/001.extract_schemas.sql index dba329e..1f5c1d4 100644 --- a/database/upgrade_scripts/001.extract_schemas.sql +++ b/database/upgrade_scripts/001.extract_schemas.sql @@ -1,26 +1,9 @@ -UPDATE - tps.srce -SET - defn = - --delete "schemas" from existing json and tack on revamped layout - jsonb_pretty((defn - 'schemas')|| - --rebuild the schemas key value from below - jsonb_build_object( - 'schemas' - --aggregate all the new key values for a single soure - ,jsonb_agg( - --combine a new key 'name' with the columns for that name - jsonb_build_object('name',k)||jsonb_build_object('columns',v) - ) - )) - - ----------------select statement test----------------------- -/* +WITH +mod AS ( SELECT srce - ,jsonb_pretty(defn) - ,jsonb_pretty((defn - 'schemas')|| + ,jsonb_pretty(defn) orig + ,(defn - 'schemas')|| --rebuild the schemas key value from below jsonb_build_object( 'schemas' @@ -29,11 +12,19 @@ SELECT --combine a new key 'name' with the columns for that name jsonb_build_object('name',k)||jsonb_build_object('columns',v) ) - )) + ) rebuild FROM tps.srce LEFT JOIN LATERAL jsonb_each(defn->'schemas') WITH ORDINALITY je(k,v, rn) ON TRUE GROUP BY srce ,defn -*/ \ No newline at end of file +) +UPDATE + tps.srce s +SET + defn = rebuild +FROM + mod +WHERE + mod.srce = s.srce \ No newline at end of file