initial work on building schema, related tables

This commit is contained in:
Paul Trowbridge 2020-10-22 01:22:40 -04:00
commit ba3d9e682e
5 changed files with 83 additions and 0 deletions

6
readme.md Normal file
View File

@ -0,0 +1,6 @@
will need to dynamically build sql for whatever layout the target table is in
name of table
read columns
assign meaning
create a pretty name for display?

View File

@ -0,0 +1,27 @@
--if the data is already cleansed is it necessary to even have master data tables? -> yes for adding new scenarios
--it is possible some parts not longer exist in the item master becuase they have since been deleted, so it is not possible to cleanse the data
do
$$
DECLARE
f record;
_sql text;
BEGIN
FOR f IN
SELECT
'DROP TABLE IF EXISTS fc.'||func||'; CREATE TABLE IF NOT EXISTS fc.'||func||' (' ||
string_agg(cname || ' ' || dtype,', ' ORDER BY opos ASC) ||
', PRIMARY KEY ('||string_agg(cname,', ') FILTER (WHERE fkey = func)||'));' AS ddl,
---need to add a clause to exclude where the key is null
'INSERT INTO fc.'||func||' SELECT DISTINCT ' || string_agg(cname,', ' ORDER BY opos ASC) || ' FROM rlarp.osm_dev' AS populate
FROM
fc.target_meta
WHERE
func <> 'doc'
GROUP BY
func
loop
EXECUTE format('%s',f.ddl);
EXECUTE format('%s',f.populate);
END LOOP;
END;
$$

17
sql/schema.sql Normal file
View File

@ -0,0 +1,17 @@
--assumes schema fc already exists
DROP TABLE IF EXISTS fc.target_meta;
CREATE TABLE fc.target_meta (
tname text
,cname text
,opos int
,func text
,fkey text
,pretty text
,dtype 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);
COMMENT ON TABLE fc.target_meta IS 'target table layout info';

22
sql/target_info.sql Normal file
View File

@ -0,0 +1,22 @@
BEGIN;
INSERT INTO
fc.target_meta
SELECT
table_name
,column_name
,ordinal_position
,'doc'::text func
,null::text fkey --foreign key to a master table
,null::text pretty
,data_type::text dtype
FROM
information_schema.columns
WHERE
table_name = 'osm_dev'
AND table_schema = 'rlarp'
ON CONFLICT ON CONSTRAINT target_meta_pk DO UPDATE SET
opos = EXCLUDED.opos
,dtype = EXCLUDED.dtype;
END;

11
sql/temp.sql Normal file
View File

@ -0,0 +1,11 @@
SELECT
'CREATE TABLE IF NOT EXISTS fc.'||func||' (' ||
string_agg(cname || ' ' || dtype,', ' ORDER BY opos ASC) ||
', PRIMARY KEY ('||string_agg(cname,', ') FILTER (WHERE fkey = func)||'))' AS ddl,
'INSERT INTO fc.'||func||' SELECT DISTINCT ' || string_agg(cname,', ' ORDER BY opos ASC) || ' FROM fc.target' AS populate
FROM
fc.target_meta
WHERE
func <> 'doc'
GROUP BY
func;