From dc059a9a8f74f759e8bf155ca5a406a2825712af Mon Sep 17 00:00:00 2001 From: Wenkai Yin Date: Thu, 20 May 2021 11:25:43 +0800 Subject: [PATCH] Improve the performance of artifact related APIs Improve the performance of artifact related APIs by adding indexes and refactoring sql logic Closes #13890 #14813 #14814 Signed-off-by: Wenkai Yin --- .../postgresql/0060_2.3.0_schema.up.sql | 7 +++- src/pkg/artifact/dao/dao.go | 34 +++++++++---------- 2 files changed, 23 insertions(+), 18 deletions(-) diff --git a/make/migrations/postgresql/0060_2.3.0_schema.up.sql b/make/migrations/postgresql/0060_2.3.0_schema.up.sql index 59a2f4173..01132ba9c 100644 --- a/make/migrations/postgresql/0060_2.3.0_schema.up.sql +++ b/make/migrations/postgresql/0060_2.3.0_schema.up.sql @@ -1,2 +1,7 @@ ALTER TABLE replication_policy ADD COLUMN IF NOT EXISTS dest_namespace_replace_count int; -UPDATE replication_policy SET dest_namespace_replace_count=-1 WHERE dest_namespace IS NULL; \ No newline at end of file +UPDATE replication_policy SET dest_namespace_replace_count=-1 WHERE dest_namespace IS NULL; + +CREATE INDEX IF NOT EXISTS idx_artifact_push_time ON artifact (push_time); +CREATE INDEX IF NOT EXISTS idx_tag_push_time ON tag (push_time); +CREATE INDEX IF NOT EXISTS idx_tag_artifact_id ON tag (artifact_id); +CREATE INDEX IF NOT EXISTS idx_artifact_reference_child_id ON artifact_reference (child_id); \ No newline at end of file diff --git a/src/pkg/artifact/dao/dao.go b/src/pkg/artifact/dao/dao.go index 89425a00d..cc9b034e8 100644 --- a/src/pkg/artifact/dao/dao.go +++ b/src/pkg/artifact/dao/dao.go @@ -53,22 +53,22 @@ type DAO interface { } const ( - // both tagged and untagged artifacts - both = `IN ( - SELECT DISTINCT art.id FROM artifact art - LEFT JOIN tag ON art.id=tag.artifact_id - LEFT JOIN artifact_reference ref ON art.id=ref.child_id - WHERE tag.id IS NOT NULL OR ref.id IS NULL)` - // only untagged artifacts - untagged = `IN ( - SELECT DISTINCT art.id FROM artifact art - LEFT JOIN tag ON art.id=tag.artifact_id - WHERE tag.id IS NULL)` - // only tagged artifacts - tagged = `IN ( - SELECT DISTINCT art.id FROM artifact art - JOIN tag ON art.id=tag.artifact_id - WHERE tag.id IS NOT NULL)` + // the QuerySetter of beego doesn't support "EXISTS" directly, use qs.FilterRaw("id", "=id AND xxx") to workaround the limitation + // base filter: both tagged and untagged artifacts + both = `=id AND ( + EXISTS (SELECT 1 FROM tag WHERE tag.artifact_id = T0.id) + OR + NOT EXISTS (SELECT 1 FROM artifact_reference ref WHERE ref.child_id = T0.id) + )` + // tag filter: only untagged artifacts + // the "untagged" filter is based on "base" filter, so we consider the tag only + untagged = `=id AND NOT EXISTS( + SELECT 1 FROM tag WHERE tag.artifact_id = T0.id + )` + // tag filter: only tagged artifacts + tagged = `=id AND EXISTS ( + SELECT 1 FROM tag WHERE tag.artifact_id = T0.id + )` ) // New returns an instance of the default DAO @@ -273,7 +273,7 @@ func querySetter(ctx context.Context, query *q.Query) (beegoorm.QuerySeter, erro // handle q=base=* // when "q=base=*" is specified in the query, the base collection is the all artifacts of database, -// otherwise the base connection is only the tagged artifacts and untagged artifacts that aren't +// otherwise the base collection is only the tagged artifacts and untagged artifacts that aren't // referenced by others func setBaseQuery(qs beegoorm.QuerySeter, query *q.Query) (beegoorm.QuerySeter, error) { if query == nil || len(query.Keywords) == 0 {