-
Notifications
You must be signed in to change notification settings - Fork 24
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Fixes #RHIROS-1347 - Dynamically create table partitions to optimize …
…DB performance
- Loading branch information
1 parent
cb83d1e
commit d6f0632
Showing
18 changed files
with
136 additions
and
39 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
DROP FUNCTION IF EXISTS create_monthly_patitions; | ||
DROP FUNCTION IF EXISTS create_range_patition; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,58 @@ | ||
CREATE OR REPLACE FUNCTION create_range_patition(partition_table_name TEXT, parent_table Text, partition_start_date Text, partition_end_date Text) | ||
RETURNS void AS | ||
$BODY$ | ||
DECLARE | ||
BEGIN | ||
EXECUTE 'CREATE TABLE ' || partition_table_name | ||
|| ' PARTITION OF '|| parent_table ||' FOR VALUES FROM ' | ||
|| '(''' || partition_start_date || ''')' | ||
|| ' TO ' | ||
|| '(''' || partition_end_date || ''')'; | ||
END; | ||
$BODY$ | ||
LANGUAGE plpgsql; | ||
|
||
CREATE OR REPLACE FUNCTION create_monthly_patitions(max_interval_end TIMESTAMP WITH TIME ZONE, parent_table Text) | ||
RETURNS void AS | ||
$BODY$ | ||
DECLARE | ||
record_day INT; | ||
record_date TEXT; | ||
partition_start_date TEXT; | ||
partition_end_date TEXT; | ||
partition_table_name TEXT; | ||
BEGIN | ||
record_day := TO_NUMBER(TO_CHAR(max_interval_end,'DD'),'99'); | ||
record_date := TO_CHAR(max_interval_end,'YYYY-MM-'); | ||
IF record_day > 15 THEN | ||
partition_start_date = CONCAT(record_date, '16'); | ||
select (date_trunc('month', max_interval_end) + interval '1 month - 1 day')::date INTO partition_end_date; | ||
partition_table_name = replace(parent_table || '_' || partition_start_date, '-', '_'); | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=partition_table_name) THEN | ||
EXECUTE create_range_patition(partition_table_name, parent_table, partition_start_date, partition_end_date); | ||
END IF; | ||
|
||
partition_start_date = CONCAT(record_date, '1'); | ||
partition_end_date = record_date || '16'; | ||
partition_table_name = replace(parent_table || '_' || partition_start_date, '-', '_'); | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=partition_table_name) THEN | ||
EXECUTE create_range_patition(partition_table_name, parent_table, partition_start_date, partition_end_date); | ||
END IF; | ||
ELSE | ||
partition_start_date = CONCAT(record_date, '1'); | ||
partition_end_date = record_date || '16'; | ||
partition_table_name = replace(parent_table || '_' || partition_start_date, '-', '_'); | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=partition_table_name) THEN | ||
EXECUTE create_range_patition(partition_table_name, parent_table, partition_start_date, partition_end_date); | ||
END IF; | ||
|
||
select (date_trunc('month', max_interval_end) - interval '1 month' + interval '15 days' )::date INTO partition_start_date; | ||
select (date_trunc('month', max_interval_end))::date INTO partition_end_date; | ||
partition_table_name = replace(parent_table || '_' || partition_start_date, '-', '_'); | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=partition_table_name) THEN | ||
EXECUTE create_range_patition(partition_table_name, parent_table, partition_start_date, partition_end_date); | ||
END IF; | ||
END IF; | ||
END; | ||
$BODY$ | ||
LANGUAGE plpgsql; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1 +1 @@ | ||
DROP TABLE IF EXISTS workload_metrics; | ||
DROP TABLE IF EXISTS workload_metrics CASCADE; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,15 +1,37 @@ | ||
CREATE TABLE IF NOT EXISTS workload_metrics( | ||
id BIGSERIAL PRIMARY KEY, | ||
id BIGSERIAL NOT NULL, | ||
org_id TEXT NOT NULL, | ||
workload_id BIGINT NOT NULL, | ||
container_name TEXT NOT NULL, | ||
interval_start TIMESTAMP WITH TIME ZONE NOT NULL, | ||
interval_end TIMESTAMP WITH TIME ZONE NOT NULL, | ||
usage_metrics jsonb NOT NULL | ||
); | ||
) PARTITION BY LIST(org_id); | ||
|
||
ALTER TABLE workload_metrics | ||
ADD CONSTRAINT fk_workload_metrics_workload FOREIGN KEY (workload_id) REFERENCES workloads (id) | ||
ON DELETE CASCADE; | ||
|
||
ALTER TABLE workload_metrics | ||
ADD CONSTRAINT UQ_Workload_Metrics UNIQUE (workload_id, container_name, interval_start, interval_end); | ||
ADD CONSTRAINT UQ_Workload_Metrics UNIQUE (org_id, workload_id, container_name, interval_start, interval_end); | ||
|
||
|
||
CREATE OR REPLACE FUNCTION workload_metrics_insert_trigger_func() RETURNS trigger AS | ||
$BODY$ | ||
DECLARE | ||
org_id_partition_table_name TEXT; | ||
BEGIN | ||
org_id_partition_table_name := 'workload_metrics_' || New.org_id; | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=org_id_partition_table_name) THEN | ||
EXECUTE 'CREATE TABLE ' || org_id_partition_table_name | ||
|| ' PARTITION OF workload_metrics FOR VALUES IN' | ||
|| ' (''' || NEW.org_id || ''')' | ||
|| ' PARTITION BY RANGE(interval_end)'; | ||
END IF; | ||
EXECUTE create_monthly_patitions(NEW.metrics_upload_at, org_id_partition_table_name); | ||
return NEW; | ||
END; | ||
$BODY$ | ||
LANGUAGE plpgsql; | ||
|
||
CREATE TRIGGER workload_metrics_insert_trigger BEFORE INSERT ON workloads FOR EACH ROW EXECUTE PROCEDURE workload_metrics_insert_trigger_func(); |
2 changes: 1 addition & 1 deletion
2
migrations/000007_create_historical_recommendation_sets.down.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1 +1 @@ | ||
DROP TABLE IF EXISTS historical_recommendation_sets; | ||
DROP TABLE IF EXISTS historical_recommendation_sets CASCADE; |
43 changes: 31 additions & 12 deletions
43
migrations/000007_create_historical_recommendation_sets.up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,18 +1,37 @@ | ||
CREATE TABLE IF NOT EXISTS historical_recommendation_sets AS TABLE recommendation_sets; | ||
|
||
ALTER TABLE historical_recommendation_sets | ||
ADD PRIMARY KEY (id), | ||
ALTER COLUMN id SET DEFAULT gen_random_uuid(), | ||
ALTER COLUMN id SET NOT NULL, | ||
ALTER COLUMN container_name SET NOT NULL, | ||
ALTER COLUMN monitoring_start_time SET NOT NULL, | ||
ALTER COLUMN monitoring_end_time SET NOT NULL, | ||
ALTER COLUMN recommendations SET NOT NULL, | ||
ALTER COLUMN updated_at SET NOT NULL; | ||
CREATE TABLE IF NOT EXISTS historical_recommendation_sets( | ||
id BIGSERIAL NOT NULL, | ||
org_id TEXT NOT NULL, | ||
workload_id BIGINT NOT NULL, | ||
container_name TEXT NOT NULL, | ||
monitoring_start_time TIMESTAMP WITH TIME ZONE NOT NULL, | ||
monitoring_end_time TIMESTAMP WITH TIME ZONE NOT NULL, | ||
recommendations jsonb NOT NULL, | ||
updated_at TIMESTAMP WITH TIME ZONE NOT NULL | ||
) PARTITION BY LIST(org_id); | ||
|
||
ALTER TABLE historical_recommendation_sets | ||
ADD CONSTRAINT fk_historical_recommendation_sets_workload FOREIGN KEY (workload_id) REFERENCES workloads (id) | ||
ON DELETE CASCADE; | ||
|
||
ALTER TABLE historical_recommendation_sets | ||
ADD CONSTRAINT UQ_historical_recommendation UNIQUE (workload_id, container_name, monitoring_end_time); | ||
ADD CONSTRAINT UQ_historical_recommendation UNIQUE (org_id, workload_id, container_name, monitoring_end_time); | ||
|
||
CREATE OR REPLACE FUNCTION historical_recommendation_sets_insert_trigger_func() RETURNS trigger AS | ||
$BODY$ | ||
DECLARE | ||
org_id_partition_table_name TEXT; | ||
BEGIN | ||
org_id_partition_table_name := 'historical_recommendation_sets_' || New.org_id; | ||
IF NOT EXISTS(SELECT relname FROM pg_class WHERE relname=org_id_partition_table_name) THEN | ||
EXECUTE 'CREATE TABLE ' || org_id_partition_table_name | ||
|| ' PARTITION OF historical_recommendation_sets FOR VALUES IN' | ||
|| ' (''' || NEW.org_id || ''')' | ||
|| ' PARTITION BY RANGE(monitoring_end_time)'; | ||
END IF; | ||
EXECUTE create_monthly_patitions(NEW.metrics_upload_at, org_id_partition_table_name); | ||
return NEW; | ||
END; | ||
$BODY$ | ||
LANGUAGE plpgsql; | ||
|
||
CREATE TRIGGER historical_recommendation_sets_insert_trigger BEFORE INSERT ON workloads FOR EACH ROW EXECUTE PROCEDURE historical_recommendation_sets_insert_trigger_func(); |
Empty file.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.