From 57051675b3b4ac416630d031c5ee5854a008d6b9 Mon Sep 17 00:00:00 2001 From: Paul Trowbridge Date: Wed, 6 Apr 2022 01:52:18 -0400 Subject: [PATCH] add dynamic target table; dynamically create additional columns if application columns were not defined --- routes/baseline/gen_baseline.sql | 14 +++--- setup_sql/build_master_tables.sql | 72 +++++++++++++++++++++++++++---- setup_sql/mapping.md | 34 ++++++++------- setup_sql/schema.sql | 18 ++++---- setup_sql/target_info.sql | 12 +++--- 5 files changed, 106 insertions(+), 44 deletions(-) diff --git a/routes/baseline/gen_baseline.sql b/routes/baseline/gen_baseline.sql index 1b3054b..3fdff1e 100644 --- a/routes/baseline/gen_baseline.sql +++ b/routes/baseline/gen_baseline.sql @@ -13,6 +13,8 @@ DECLARE _date_funcs jsonb; _perd_joins text; _interval interval; + _target_table text; + _version_col text; /*----------------parameters listing-------------- app_baseline_from_date @@ -30,8 +32,10 @@ BEGIN SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'order_date') INTO _order_date; SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'ship_date') INTO _ship_date; SELECT (SELECT cname FROM fc.target_meta WHERE appcol = 'order_status') INTO _order_status; +SELECT format('%I',max(schema))||'.'||format('%I',max(tname)) INTO _target_table FROM fc.target_meta; --the target interval SELECT interval '1 year' INTO _interval; +SELECT cname INTO _version_col FROM fc.target_meta WHERE appcol = 'version'; SELECT jsonb_agg(func) INTO _date_funcs FROM fc.target_meta WHERE dtype = 'date' AND fkey is NOT null; --create table join for each date based func in target_meta joining to fc.perd static table --the join, though, should be based on the target date, which is needs an interval added to get to the target @@ -70,7 +74,7 @@ SELECT --...but it's not the date itself... WHEN fkey IS NULL THEN --...pull the associated date field from perd table - func||'.'||m.dateref + func||'.'||m.fcol --...and it's the primary key date... ELSE --use the date key but increment by the target interval @@ -101,7 +105,7 @@ $$SELECT ,'forecast_name' "version" ,'actuals' iter FROM - fc.live o + $$||_target_table||$$ o WHERE ( --base period orders booked.... @@ -128,7 +132,7 @@ $$ ,'forecast_name' "version" ,'plug' iter FROM - fc.live o$$||E'\n'||_perd_joins||$$ + $$||_target_table||' o'||E'\n'||_perd_joins||$$ WHERE $$||format('%I',_order_date)||$$ BETWEEN 'app_plug_fromdate'::date AND 'app_plug_todate'::date --be sure to pre-exclude unwanted items, like canceled orders, non-gross sales, and short-ships @@ -152,7 +156,7 @@ FROM ) ,ins AS ( INSERT INTO - fc.live + $$||_target_table||$$ SELECT * FROM @@ -171,7 +175,7 @@ INTO ------------------------------stack the sql into the final format------------------------------------------------ SELECT -$$DELETE FROM fc.live WHERE version = 'forecast_name'; +$$DELETE FROM $$||_target_table||$$ WHERE $$||_version_col||$$ = 'forecast_name'; WITH baseline AS ( $$||_ytdbody|| diff --git a/setup_sql/build_master_tables.sql b/setup_sql/build_master_tables.sql index 1717d2e..ab8cceb 100644 --- a/setup_sql/build_master_tables.sql +++ b/setup_sql/build_master_tables.sql @@ -5,31 +5,85 @@ $$ DECLARE f record; _sql text; + _target_table text; + BEGIN + SELECT format('%I',max(schema))||'.'||format('%I',max(tname)) INTO _target_table FROM fc.target_meta; FOR f IN SELECT + tname, + func, -------------------------------------------create table--------------------------------------------------------------------------------------------------------- 'DROP TABLE IF EXISTS fc.'||func||' CASCADE; CREATE TABLE IF NOT EXISTS fc.'||func||' (' || string_agg(format('%I',cname) || ' ' || dtype,', ' ORDER BY CASE WHEN fkey IS NOT NULL THEN 0 ELSE opos END ASC) || - ', PRIMARY KEY ('||string_agg(format('%I',cname),', ') FILTER (WHERE fkey = func)||'));' AS ddl, + ', PRIMARY KEY ('||string_agg(format('%I',cname),', ') FILTER (WHERE COALESCE(fkey,'') <> '')||'));' AS ddl, -------------------------------------------populate table------------------------------------------------------------------------------------------------------- ---need to add a clause to exclude where the key is null - 'INSERT INTO fc.'||func||' SELECT DISTINCT ' || string_agg(format('%I',cname),', ' ORDER BY CASE WHEN fkey IS NOT NULL THEN 0 ELSE opos END ASC) || ' FROM '||tname||' WHERE '|| - string_agg(format('%I',cname)||' IS NOT NULL ',' AND ') FILTER (WHERE fkey = func)||' ON CONFLICT DO NOTHING' AS pop, + 'INSERT INTO fc.'||func||' SELECT DISTINCT ' || string_agg(format('%I',cname),', ' ORDER BY CASE WHEN fkey IS NOT NULL THEN 0 ELSE opos END ASC) || ' FROM '||schema||'.'||tname||' WHERE '|| + string_agg(format('%I',cname)||' IS NOT NULL ',' AND ') FILTER (WHERE COALESCE(fkey,'') <> '')||' ON CONFLICT DO NOTHING' AS pop, -------------------------------------------setup foreign keys--------------------------------------------------------------------------------------------------- - 'ALTER TABLE fc.live ADD CONSTRAINT fk_'||func||' FOREIGN KEY ('||string_agg(format('%I',cname),', ') FILTER (WHERE fkey = func)||') REFERENCES fc.'||func||' ('|| - string_agg(format('%I',cname),', ') FILTER (WHERE fkey = func)||')' AS fk + 'ALTER TABLE '||tm.schema||'.'||tm.tname||' ADD CONSTRAINT fk_'||func||' FOREIGN KEY ('||string_agg(format('%I',cname),', ') FILTER (WHERE COALESCE(fkey,'') <> '')||') REFERENCES fc.'||func||' ('|| + string_agg(format('%I',cname),', ') FILTER (WHERE COALESCE(fkey,'') <>'')||')' AS fk FROM - fc.target_meta + fc.target_meta tm + WHERE + func IS NOT NULL GROUP BY - tname + schema + ,tname ,func - HAVING - string_agg(cname,', ') FILTER (WHERE fkey = func) <> '' + --HAVING + -- string_agg(cname,', ') FILTER (WHERE fkey = func) <> '' loop + INSERT INTO fc.sql SELECT f.func, f.ddl; EXECUTE format('%s',f.ddl); EXECUTE format('%s',f.pop); EXECUTE format('%s',f.fk); END LOOP; + -------add a version column if one doesn't exist-------------------------------- + IF (SELECT COUNT(*) FROM fc.target_meta WHERE appcol = 'version') = 0 THEN + SELECT 'ALTER TABLE '||_target_table||' ADD COLUMN app_version text' INTO _sql; + EXECUTE format('%s',_sql); + --insert the newly created row meta into target_meta + INSERT INTO + fc.target_meta + SELECT + table_schema, table_name, column_name, ordinal_position, null::text, null::text, null::text, data_type, 'version', null::text + FROM + information_schema.columns + WHERE + format('%I',table_schema)||'.'||format('%I',table_name) = _target_table + AND column_name = 'app_version'; + END IF; + -------add a iter column if one doesn't exist-------------------------------- + IF (SELECT COUNT(*) FROM fc.target_meta WHERE appcol = 'iter') = 0 THEN + SELECT 'ALTER TABLE '||_target_table||' ADD COLUMN app_iter text' INTO _sql; + EXECUTE format('%s',_sql); + --insert the newly created row meta into target_meta + INSERT INTO + fc.target_meta + SELECT + table_schema, table_name, column_name, ordinal_position, null::text, null::text, null::text, data_type, 'iter', null::text + FROM + information_schema.columns + WHERE + format('%I',table_schema)||'.'||format('%I',table_name) = _target_table + AND column_name = 'app_iter'; + END IF; + -------add a logid column if one doesn't exist-------------------------------- + IF (SELECT COUNT(*) FROM fc.target_meta WHERE appcol = 'logid') = 0 THEN + SELECT 'ALTER TABLE '||_target_table||' ADD COLUMN app_logid text' INTO _sql; + EXECUTE format('%s',_sql); + --insert the newly created row meta into target_meta + INSERT INTO + fc.target_meta + SELECT + table_schema, table_name, column_name, ordinal_position, null::text, null::text, null::text, data_type, 'logid', null::text + FROM + information_schema.columns + WHERE + format('%I',table_schema)||'.'||format('%I',table_name) = _target_table + AND column_name = 'app_logid'; + END IF; END; $$ diff --git a/setup_sql/mapping.md b/setup_sql/mapping.md index befc8a0..98e05ee 100644 --- a/setup_sql/mapping.md +++ b/setup_sql/mapping.md @@ -1,21 +1,23 @@ -| tname | cname | opos | func | fkey | pretty | dtype | mastcol | appcol | dateref | -| ------- | -------------- | ---- | ------------ | ------------ | ------ | ------- | -------------- | ------------ | ------- | -| fc.live | fb_cst_loc | 91 | cost | | | numeric | fb_cst_loc | | | -| fc.live | ship_cust | 36 | scust | scust | | text | ship_cust | | | -| fc.live | rdate | 98 | rdate | rdate | | date | drange | | | -| fc.live | geo | 42 | scust | | | text | geo | customer | | -| fc.live | part | 54 | item | item | | text | part | item | | -| fc.live | odate | 96 | odate | odate | | date | drange | order_date | | -| fc.live | sdate | 100 | sdate | sdate | | date | sdate | ship_date | | -| fc.live | oseas | 97 | odate | | | integer | ssyr | | ssyr | -| fc.live | calc_status | 94 | order_status | order_status | | text | calc_status | order_status | | -| fc.live | rseas | 99 | rdate | | | integer | ssyr | | ssyr | -| fc.live | sseas | 101 | sdate | | | integer | ssyr | | ssyr | - +| schema | tname | cname | opos | func | fkey | fcol | dtype | appcol | pretty | +| ------- | ------- | -------------- | ---- | ------------ | ------------ | -------------- | ------- | ------------ | ------ | +| fc | live | fb_cst_loc | 91 | cost | | fb_cst_loc | numeric | | | +| fc | live | ship_cust | 36 | scust | scust | ship_cust | text | | | +| fc | live | rdate | 98 | rdate | rdate | drange | date | | | +| fc | live | geo | 42 | scust | | geo | text | customer | | +| fc | live | part | 54 | item | item | part | text | item | | +| fc | live | odate | 96 | odate | odate | drange | date | order_date | | +| fc | live | sdate | 100 | sdate | sdate | sdate | date | ship_date | | +| fc | live | oseas | 97 | odate | | ssyr | integer | | | +| fc | live | calc_status | 94 | order_status | order_status | calc_status | text | order_status | | +| fc | live | rseas | 99 | rdate | | ssyr | integer | | | +| fc | live | sseas | 101 | sdate | | ssyr | integer | | | +| | | | | | | | | version | | +| | | | | | | | | iter | | +| | | | | | | | | logid | | * func: table name of associated data * fkey: primary key of assoicated dat -* pretty: display column name -* mastcol: associated table column reference (whats the point of this?) +* fcol: associated field from the master data table if it is different (oseas would refer to ssyr in fc.perd) +* pretty: display column name (user friendly) * appcol: parameters that will have to be supplied but the application * dateref: diff --git a/setup_sql/schema.sql b/setup_sql/schema.sql index c0f7b9e..172a5f6 100644 --- a/setup_sql/schema.sql +++ b/setup_sql/schema.sql @@ -2,32 +2,32 @@ CREATE SCHEMA IF NOT EXISTS fc; --DROP TABLE IF EXISTS fc.target_meta; CREATE TABLE IF NOT EXISTS fc.target_meta ( - tname text + schema text + ,tname text ,cname text ,opos int ,func text ,fkey text - ,pretty text + ,fcol text ,dtype text - ,mastcol text ,appcol text - ,dateref text + ,pretty text ); --ALTER TABLE fc.target_meta DROP CONSTRAINT IF EXISTS target_meta_pk; -ALTER TABLE fc.target_meta ADD CONSTRAINT target_meta_pk PRIMARY KEY (tname, cname); +ALTER TABLE fc.target_meta ADD CONSTRAINT target_meta_pk PRIMARY KEY (schema, tname, cname); COMMENT ON TABLE fc.target_meta IS 'target table layout info'; -COMMENT ON COLUMN fc.target_meta.tname IS 'schema.table_name of target sales data table'; +COMMENT ON COLUMN fc.target_meta.schema IS 'schema of target sales data table'; +COMMENT ON COLUMN fc.target_meta.tname IS 'table_name of target sales data table'; COMMENT ON COLUMN fc.target_meta.cname IS 'column name'; COMMENT ON COLUMN fc.target_meta.opos IS 'ordinal position of column'; COMMENT ON COLUMN fc.target_meta.func IS 'a functional entity (like customer, part number) that master tables will be build from'; +COMMENT ON COLUMN fc.target_meta.fcol IS 'associated field from the master data table if it is different (oseas would refer to ssyr in fc.perd)'; COMMENT ON COLUMN fc.target_meta.fkey IS 'primary key for functional entity'; -COMMENT ON COLUMN fc.target_meta.pretty IS 'the presentation name of the column'; COMMENT ON COLUMN fc.target_meta.dtype IS 'data type of the sales table column'; -COMMENT ON COLUMN fc.target_meta.mastcol IS 'associated field from the master data table if it is different (oseas would refer to ssyr in fc.perd)'; COMMENT ON COLUMN fc.target_meta.appcol IS 'supply column name to be used for application variables - (specifcy the order date column)'; -COMMENT ON COLUMN fc.target_meta.dateref IS 'reference to the relevant hard coded perd table column for dates'; +COMMENT ON COLUMN fc.target_meta.pretty IS 'the presentation name of the column'; CREATE TABLE IF NOT EXISTS fc.log ( id int GENERATED ALWAYS AS IDENTITY diff --git a/setup_sql/target_info.sql b/setup_sql/target_info.sql index 5a7310e..5a5af46 100644 --- a/setup_sql/target_info.sql +++ b/setup_sql/target_info.sql @@ -3,18 +3,20 @@ BEGIN; INSERT INTO fc.target_meta SELECT - table_schema||'.'||table_name + table_schema + ,table_name ,column_name ,ordinal_position - ,'doc'::text func + ,null::text func ,null::text fkey --foreign key to a master table - ,null::text pretty + ,column_name fcol ,data_type::text dtype - ,column_name mastcol + ,null::text appcol + ,null::text pretty FROM information_schema.columns WHERE - table_name = 'live' + table_name = 'dcard_mapped' AND table_schema = 'fc' ON CONFLICT ON CONSTRAINT target_meta_pk DO UPDATE SET opos = EXCLUDED.opos