Skip to content

Commit

Permalink
feat: optimize pipelinereports table to improve performances (#127)
Browse files Browse the repository at this point in the history
* feat: rework sql queries

* convert query into subqueries

Signed-off-by: Olivier Vernin <[email protected]>

* Convert json table to jsonb and add variouse indexes

* fix: add missing ; to sql migration

Signed-off-by: Olivier Vernin <[email protected]>

---------

Signed-off-by: Olivier Vernin <[email protected]>
  • Loading branch information
olblak authored Nov 29, 2024
1 parent 1546ad8 commit 5989785
Show file tree
Hide file tree
Showing 4 changed files with 77 additions and 31 deletions.
Original file line number Diff line number Diff line change
@@ -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;
22 changes: 22 additions & 0 deletions pkg/database/migrations/000003_alter_pipelineReports_jsonb.up.sql
Original file line number Diff line number Diff line change
@@ -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
);
58 changes: 36 additions & 22 deletions pkg/server/reportHandler.go
Original file line number Diff line number Diff line change
Expand Up @@ -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)

Expand All @@ -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)
Expand Down
18 changes: 9 additions & 9 deletions pkg/server/scmDBHandler.go
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down

0 comments on commit 5989785

Please sign in to comment.