diff --git a/pkg/database/migrations/000003_alter_pipelineReports_jsonb.down.sql b/pkg/database/migrations/000003_alter_pipelineReports_jsonb.down.sql new file mode 100644 index 00000000..6ed17cb4 --- /dev/null +++ b/pkg/database/migrations/000003_alter_pipelineReports_jsonb.down.sql @@ -0,0 +1,10 @@ +ALTER TABLE pipelineReports + ALTER COLUMN data + SET DATA TYPE JSON + USING data::JSON; + +DROP INDEX idx_pipelinereports_data_jsonb; +DROP INDEX idx_pipelinereports_updated_at; +DROP INDEX idx_pipelinereports_data_name; +DROP INDEX idx_pipelinereports_data_result; +DROP INDEX idx_pipelinereports_distinct; diff --git a/pkg/database/migrations/000003_alter_pipelineReports_jsonb.up.sql b/pkg/database/migrations/000003_alter_pipelineReports_jsonb.up.sql new file mode 100644 index 00000000..2c0cfe7c --- /dev/null +++ b/pkg/database/migrations/000003_alter_pipelineReports_jsonb.up.sql @@ -0,0 +1,22 @@ +ALTER TABLE pipelineReports + ALTER COLUMN data + SET DATA TYPE JSONB + USING data::JSONB; + +CREATE INDEX idx_pipelinereports_data_jsonb +ON pipelinereports +USING gin (data jsonb_path_ops); + +CREATE INDEX idx_pipelinereports_updated_at +ON pipelinereports (updated_at); + +CREATE INDEX idx_pipelinereports_data_name +ON pipelinereports ((data ->> 'Name')); + +CREATE INDEX idx_pipelinereports_data_result +ON pipelinereports ((data ->> 'Result')); + +CREATE INDEX idx_pipelinereports_distinct +ON pipelinereports ( + (data ->> 'Name'), updated_at DESC +); diff --git a/pkg/server/reportHandler.go b/pkg/server/reportHandler.go index 0d07f9be..2192ce5f 100644 --- a/pkg/server/reportHandler.go +++ b/pkg/server/reportHandler.go @@ -92,24 +92,33 @@ func FindAllPipelineReports(c *gin.Context) { switch scmid { case "": query = ` +WITH filtered_reports AS ( + SELECT id, data,created_at, updated_at + FROM pipelinereports + WHERE + updated_at > current_date - interval '%d day' +) SELECT id, data, created_at, updated_at -FROM pipelineReports -WHERE updated_at > current_date - interval '%d day' +FROM filtered_reports ORDER BY updated_at DESC` query = fmt.Sprintf(query, monitoringDurationDays) case "none", "null", "nil": query = ` -SELECT DISTINCT ON (s.data ->> 'Name') s.id, s.data, s.created_at, s.updated_at - FROM ( - SELECT * - FROM pipelinereports - WHERE - NOT jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL != "" && @.Scm.Branch.Target != "")') AND - updated_at > current_date - interval '%d day' - ORDER BY updated_at DESC - ) s -ORDER BY s.data ->> 'Name', s.updated_at DESC;` +WITH filtered_reports AS ( + SELECT id, data, created_at, updated_at + FROM pipelinereports + WHERE + NOT jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL != "" && @.Scm.Branch.Target != "")') AND + updated_at > current_date - interval '%d day' +) +SELECT DISTINCT ON (data ->> 'Name') + id, + data, + created_at, + updated_at +FROM filtered_reports +ORDER BY (data ->> 'Name'), updated_at DESC;` query = fmt.Sprintf(query, monitoringDurationDays) @@ -126,16 +135,21 @@ ORDER BY s.data ->> 'Name', s.updated_at DESC;` case 1: query = ` -SELECT DISTINCT ON (s.data ->> 'Name') s.id, s.data, s.created_at, s.updated_at -FROM ( - SELECT * - FROM pipelinereports - WHERE - jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL == "%s" && @.Scm.Branch.Target == "%s")') AND - updated_at > current_date - interval '%d day' - ORDER BY updated_at DESC -) s -ORDER BY s.data ->> 'Name', s.updated_at DESC; +WITH filtered_reports AS ( + SELECT id, data, created_at, updated_at + FROM pipelinereports + WHERE + jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL == "%s" && @.Scm.Branch.Target == "%s")') AND + updated_at > current_date - interval '%d day' +) + +SELECT DISTINCT ON (data ->> 'Name') + id, + data, + created_at, + updated_at +FROM filtered_reports +ORDER BY (data ->> 'Name'), updated_at DESC; ` query = fmt.Sprintf(query, scm[0].URL, scm[0].Branch, monitoringDurationDays) diff --git a/pkg/server/scmDBHandler.go b/pkg/server/scmDBHandler.go index 1d9ed55d..57bd4bd2 100644 --- a/pkg/server/scmDBHandler.go +++ b/pkg/server/scmDBHandler.go @@ -69,16 +69,16 @@ func FindSCMSummary(c *gin.Context, scmRows []DatabaseSCMRow) { } query = ` -SELECT DISTINCT ON (s.data ->> 'Name') s.id, ( s.data ->> 'Result') -FROM ( - SELECT * +WITH filtered_reports AS ( + SELECT id, data, updated_at FROM pipelinereports - WHERE - jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL == "%s" && @.Scm.Branch.Target == "%s")') AND - updated_at > current_date - interval '%d day' - ORDER BY updated_at DESC -) s -ORDER BY s.data ->> 'Name', s.updated_at DESC; + WHERE jsonb_path_exists(data::jsonb, '$.Targets[*].* ? (@.Scm.URL == "%s" && @.Scm.Branch.Target == "%s")') AND updated_at > current_date - interval '%d day') +SELECT DISTINCT ON (data ->> 'Name') + id, + (data ->> 'Result') + +FROM filtered_reports +ORDER BY (data ->> 'Name'), updated_at DESC; ` query = fmt.Sprintf(query, scmURL, scmBranch, monitoringDurationDays)