Skip to content

Commit

Permalink
Remove hardcoded dependency between artifacts and projects (#2991)
Browse files Browse the repository at this point in the history
* Remove hardcoded dependency between artifacts and projects

This makes repos nullable in artifacts. As of today, this is not really
a case that actually happens... so this should effectively be a no-op.
However, the idea is that soon we'll start getting artifacts that that
come from other providers that are not the same as the repository they
are linked to.

Signed-off-by: Juan Antonio Osorio <[email protected]>

* Update database/migrations/000050_artifact_projects.up.sql

Co-authored-by: Jakub Hrozek <[email protected]>

* Update database/migrations/000050_artifact_projects.up.sql

Co-authored-by: Jakub Hrozek <[email protected]>

* More changes due to recent changes

Signed-off-by: Juan Antonio Osorio <[email protected]>

* Fix down-migration

Signed-off-by: Juan Antonio Osorio <[email protected]>

---------

Signed-off-by: Juan Antonio Osorio <[email protected]>
Co-authored-by: Jakub Hrozek <[email protected]>
  • Loading branch information
JAORMX and jhrozek authored Apr 10, 2024
1 parent af5fcf3 commit 5abbaa3
Show file tree
Hide file tree
Showing 29 changed files with 2,819 additions and 2,442 deletions.
75 changes: 75 additions & 0 deletions database/migrations/000050_artifact_projects.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,75 @@
-- Copyright 2024 Stacklok, Inc
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.

BEGIN;

-- Artifact changes

-- make repository_id not nullable in artifacts
ALTER TABLE artifacts ALTER COLUMN repository_id SET NOT NULL;

-- remove foreign key constraints
ALTER TABLE artifacts DROP CONSTRAINT fk_artifacts_project_id;
ALTER TABLE artifacts DROP CONSTRAINT fk_artifacts_provider_id_and_name;

-- remove project_id, provider_id and provider_name columns from artifacts table
ALTER TABLE artifacts DROP COLUMN project_id;
ALTER TABLE artifacts DROP COLUMN provider_id;
ALTER TABLE artifacts DROP COLUMN provider_name;

-- recreate index artifact_name_lower_idx on artifacts but without project_id
DROP INDEX IF EXISTS artifact_name_lower_idx;

CREATE INDEX artifact_name_lower_idx ON artifacts (repository_id, LOWER(artifact_name));

COMMIT;

BEGIN;

-- Entity Execution lock changes

-- make repository_id not nullable in entity_execution_lock and flush_cache
ALTER TABLE entity_execution_lock ALTER COLUMN repository_id SET NOT NULL;
ALTER TABLE flush_cache ALTER COLUMN repository_id SET NOT NULL;

-- remove foreign key constraints
ALTER TABLE entity_execution_lock DROP CONSTRAINT fk_entity_execution_lock_project_id;

-- remove project_id column from entity_execution_lock
ALTER TABLE entity_execution_lock DROP COLUMN project_id;

-- remove project_id column from flush_cache
ALTER TABLE flush_cache DROP COLUMN project_id;

COMMIT;

BEGIN;

DROP INDEX IF EXISTS entity_execution_lock_idx;
DROP INDEX IF EXISTS flush_cache_idx;

-- recreate entity_execution_lock_idx and flush_cache_idx indexes with nullable repository_id
CREATE UNIQUE INDEX IF NOT EXISTS entity_execution_lock_idx ON entity_execution_lock(
entity,
repository_id,
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID));

CREATE UNIQUE INDEX IF NOT EXISTS flush_cache_idx ON flush_cache(
entity,
repository_id,
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID));

COMMIT;
107 changes: 107 additions & 0 deletions database/migrations/000050_artifact_projects.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,107 @@
-- Copyright 2024 Stacklok, Inc
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.

-- Artifact changes

BEGIN;

-- Add project_id column to artifacts table
ALTER TABLE artifacts ADD COLUMN project_id UUID;

-- make it a foreign key to projects
ALTER TABLE artifacts ADD CONSTRAINT fk_artifacts_project_id FOREIGN KEY (project_id) REFERENCES projects (id);

-- Add provider_id and provider_name columns to artifacts table
ALTER TABLE artifacts ADD COLUMN provider_id UUID;
ALTER TABLE artifacts ADD COLUMN provider_name TEXT;

-- make provider_id a foreign key to providers
ALTER TABLE artifacts ADD CONSTRAINT fk_artifacts_provider_id_and_name FOREIGN KEY (provider_id, provider_name) REFERENCES providers (id, name);

-- remove index artifact_name_lower_idx from artifacts
DROP INDEX artifact_name_lower_idx;

-- recreate index artifact_name_lower_idx on artifacts but with project_id
CREATE UNIQUE INDEX artifact_name_lower_idx ON artifacts (project_id, LOWER(artifact_name));

COMMIT;

BEGIN;

-- populate project_id, provider_id and provider_name in artifacts
UPDATE artifacts
SET project_id = repositories.project_id,
provider_id = repositories.provider_id,
provider_name = repositories.provider
FROM repositories
WHERE artifacts.repository_id = repositories.id;

COMMIT;

BEGIN;

-- make repository_id nullable in artifacts
ALTER TABLE artifacts ALTER COLUMN repository_id DROP NOT NULL;

-- make project_id not nullable in artifacts
ALTER TABLE artifacts ALTER COLUMN project_id SET NOT NULL;

ALTER TABLE artifacts ALTER COLUMN provider_id SET NOT NULL;

ALTER TABLE artifacts ALTER COLUMN provider_name SET NOT NULL;

-- Now that repository_id's are nullable, let's index artifacts by repository_id where the repository_id is not null
CREATE UNIQUE INDEX artifacts_repository_id_idx ON artifacts (repository_id) WHERE repository_id IS NOT NULL;

COMMIT;

-- Entity Execution lock needs the project ID now that not everything depends
-- on repositories.

BEGIN;

-- make repository_id nullable in entity_execution_lock and flush_cache
ALTER TABLE entity_execution_lock ALTER COLUMN repository_id DROP NOT NULL;
ALTER TABLE flush_cache ALTER COLUMN repository_id DROP NOT NULL;

-- Add project_id column to entity_execution_lock table and make it a foreign key to projects
ALTER TABLE entity_execution_lock ADD COLUMN project_id UUID;
ALTER TABLE entity_execution_lock ADD CONSTRAINT fk_entity_execution_lock_project_id FOREIGN KEY (project_id) REFERENCES projects (id);

-- Add project_id column to flush_cache table and make it a foreign key to projects
ALTER TABLE flush_cache ADD COLUMN project_id UUID;
ALTER TABLE flush_cache ADD CONSTRAINT fk_flush_cache_project_id FOREIGN KEY (project_id) REFERENCES projects (id);

COMMIT;

BEGIN;

-- delete entity_execution_lock_idx and flush_cache_idx indexes.
DROP INDEX entity_execution_lock_idx;
DROP INDEX flush_cache_idx;

-- recreate entity_execution_lock_idx and flush_cache_idx indexes with nullable repository_id
CREATE UNIQUE INDEX IF NOT EXISTS entity_execution_lock_idx ON entity_execution_lock(
entity,
COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID));

CREATE UNIQUE INDEX IF NOT EXISTS flush_cache_idx ON flush_cache(
entity,
COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID),
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID));

COMMIT;
25 changes: 5 additions & 20 deletions database/mock/store.go

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

31 changes: 11 additions & 20 deletions database/query/artifacts.sql
Original file line number Diff line number Diff line change
@@ -1,37 +1,28 @@
-- name: CreateArtifact :one
INSERT INTO artifacts (
repository_id,
artifact_name,
artifact_type,
artifact_visibility) VALUES ($1, $2, $3, $4) RETURNING *;

-- name: UpsertArtifact :one
INSERT INTO artifacts (
repository_id,
artifact_name,
artifact_type,
artifact_visibility
) VALUES ($1, $2, $3, $4)
ON CONFLICT (repository_id, LOWER(artifact_name))
artifact_visibility,
project_id,
provider_id,
provider_name
) VALUES ($1, $2, $3, $4, sqlc.arg(project_id), sqlc.arg(provider_id), sqlc.arg(provider_name))
ON CONFLICT (project_id, LOWER(artifact_name))
DO UPDATE SET
artifact_type = $3,
artifact_visibility = $4
WHERE artifacts.repository_id = $1 AND artifacts.artifact_name = $2
RETURNING *;

-- name: GetArtifactByID :one
SELECT artifacts.id, artifacts.repository_id, artifacts.artifact_name, artifacts.artifact_type,
artifacts.artifact_visibility, artifacts.created_at,
repositories.provider, repositories.project_id, repositories.repo_owner, repositories.repo_name
FROM artifacts INNER JOIN repositories ON repositories.id = artifacts.repository_id
WHERE artifacts.id = $1;
SELECT * FROM artifacts
WHERE artifacts.id = $1 AND artifacts.project_id = $2;

-- name: GetArtifactByName :one
SELECT artifacts.id, artifacts.repository_id, artifacts.artifact_name, artifacts.artifact_type,
artifacts.artifact_visibility, artifacts.created_at,
repositories.provider, repositories.project_id, repositories.repo_owner, repositories.repo_name
FROM artifacts INNER JOIN repositories ON repositories.id = artifacts.repository_id
WHERE lower(artifacts.artifact_name) = lower(sqlc.arg(artifact_name)) AND artifacts.repository_id = $1;
SELECT * FROM artifacts
WHERE lower(artifacts.artifact_name) = lower(sqlc.arg(artifact_name))
AND artifacts.repository_id = $1 AND artifacts.project_id = $2;

-- name: ListArtifactsByRepoID :many
SELECT * FROM artifacts
Expand Down
29 changes: 18 additions & 11 deletions database/query/entity_execution_lock.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,15 +11,17 @@ INSERT INTO entity_execution_lock(
last_lock_time,
repository_id,
artifact_id,
pull_request_id
pull_request_id,
project_id
) VALUES(
sqlc.arg(entity)::entities,
gen_random_uuid(),
NOW(),
sqlc.arg(repository_id)::UUID,
sqlc.narg(repository_id)::UUID,
sqlc.narg(artifact_id)::UUID,
sqlc.narg(pull_request_id)::UUID
) ON CONFLICT(entity, repository_id, COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID))
sqlc.narg(pull_request_id)::UUID,
sqlc.arg(project_id)::UUID
) ON CONFLICT(entity, COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID))
DO UPDATE SET
locked_by = gen_random_uuid(),
last_lock_time = NOW()
Expand All @@ -32,14 +34,16 @@ RETURNING *;

-- name: ReleaseLock :exec
DELETE FROM entity_execution_lock
WHERE entity = sqlc.arg(entity)::entities AND repository_id = sqlc.arg(repository_id)::UUID AND
WHERE entity = sqlc.arg(entity)::entities AND
COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(repository_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(artifact_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(pull_request_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
locked_by = sqlc.arg(locked_by)::UUID;

-- name: UpdateLease :exec
UPDATE entity_execution_lock SET last_lock_time = NOW()
WHERE entity = $1 AND repository_id = $2 AND
WHERE entity = $1 AND
COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(repository_id), '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(artifact_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(pull_request_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
locked_by = sqlc.arg(locked_by)::UUID;
Expand All @@ -49,19 +53,22 @@ INSERT INTO flush_cache(
entity,
repository_id,
artifact_id,
pull_request_id
pull_request_id,
project_id
) VALUES(
sqlc.arg(entity)::entities,
sqlc.arg(repository_id)::UUID,
sqlc.narg(repository_id)::UUID,
sqlc.narg(artifact_id)::UUID,
sqlc.narg(pull_request_id)::UUID
) ON CONFLICT(entity, repository_id, COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID))
sqlc.narg(pull_request_id)::UUID,
sqlc.arg(project_id)::UUID
) ON CONFLICT(entity, COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID), COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID))
DO NOTHING
RETURNING *;

-- name: FlushCache :one
DELETE FROM flush_cache
WHERE entity = $1 AND repository_id = $2 AND
WHERE entity = $1 AND
COALESCE(repository_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(repository_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(artifact_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(artifact_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID) AND
COALESCE(pull_request_id, '00000000-0000-0000-0000-000000000000'::UUID) = COALESCE(sqlc.narg(pull_request_id)::UUID, '00000000-0000-0000-0000-000000000000'::UUID)
RETURNING *;
Expand Down
2 changes: 2 additions & 0 deletions docs/docs/ref/proto.md

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

Loading

0 comments on commit 5abbaa3

Please sign in to comment.