From aff4ea58b1730fc148e0d29e588a62553cab8cd1 Mon Sep 17 00:00:00 2001 From: chmnata Date: Tue, 11 Oct 2022 17:24:55 -0400 Subject: [PATCH] #66 Add parent table structure for monthly centreline table --- ...create_yearly_monthly_centreline_table.sql | 35 +++++++++++++++++++ 1 file changed, 35 insertions(+) create mode 100644 data_aggregation/sql/function_create_yearly_monthly_centreline_table.sql diff --git a/data_aggregation/sql/function_create_yearly_monthly_centreline_table.sql b/data_aggregation/sql/function_create_yearly_monthly_centreline_table.sql new file mode 100644 index 0000000..f9d56ef --- /dev/null +++ b/data_aggregation/sql/function_create_yearly_monthly_centreline_table.sql @@ -0,0 +1,35 @@ +CREATE OR REPLACE FUNCTION congestion.create_yearly_monthly_centreline_table(yyyy text) + RETURNS void + LANGUAGE 'plpgsql' + COST 100 + VOLATILE STRICT SECURITY DEFINER PARALLEL UNSAFE +AS $BODY$ + +DECLARE + startdate DATE; + enddate DATE; + basetablename TEXT := 'centreline_monthly_'; + tablename TEXT; +BEGIN + + startdate:= to_date(yyyy||'-01-01', 'YYYY-MM-DD'); + enddate:= startdate + INTERVAL '1 year'; + tablename:= basetablename||yyyy; + EXECUTE format($$CREATE TABLE congestion.%I + PARTITION OF congestion.centreline_monthly + FOR VALUES FROM (%L) TO (%L); + CREATE INDEX ON congestion.%I (uid); + CREATE INDEX ON congestion.%I (hr); + CREATE INDEX ON congestion.%I (mth); + ALTER TABLE congestion.%I ADD UNIQUE(uid, hr, mth, day_type); + ALTER TABLE congestion.%I OWNER TO congestion_admins; + $$ + , tablename, startdate, enddate, tablename, tablename, tablename, tablename, tablename); +END; +$BODY$; + +ALTER FUNCTION congestion.create_yearly_monthly_centreline_table(text) + OWNER TO congestion_admins; + +COMMENT ON FUNCTION congestion.create_yearly_monthly_centreline_table(text) + IS 'Function to create yearly partitioned table for centreline_monthly. Scheduled to execute at the end of the year with EOY maintanence airflow DAG.';