Skip to content

Commit

Permalink
POC: delete system also from system_package2
Browse files Browse the repository at this point in the history
  • Loading branch information
psegedy committed Sep 12, 2023
1 parent 6a2474f commit a8cf857
Show file tree
Hide file tree
Showing 3 changed files with 215 additions and 1 deletion.
97 changes: 97 additions & 0 deletions database_admin/migrations/116_delete_system_package2.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,97 @@
CREATE OR REPLACE FUNCTION delete_system(inventory_id_in uuid)
RETURNS TABLE
(
deleted_inventory_id uuid
)
AS
$delete_system$
DECLARE
v_system_id INT;
v_account_id INT;
BEGIN
-- opt out to refresh cache and then delete
SELECT id, rh_account_id
FROM system_platform
WHERE inventory_id = inventory_id_in
LIMIT 1
FOR UPDATE OF system_platform
INTO v_system_id, v_account_id;

IF v_system_id IS NULL OR v_account_id IS NULL THEN
RAISE NOTICE 'Not found';
RETURN;
END IF;

UPDATE system_platform
SET stale = true
WHERE rh_account_id = v_account_id
AND id = v_system_id;

DELETE
FROM system_advisories
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_repo
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_package
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

RETURN QUERY DELETE FROM system_platform
WHERE rh_account_id = v_account_id AND
id = v_system_id
RETURNING inventory_id;
END;
$delete_system$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION delete_systems(inventory_ids UUID[])
RETURNS INTEGER
AS
$$
DECLARE
tmp_cnt INTEGER;
BEGIN

WITH systems as (
SELECT rh_account_id, id
FROM system_platform
WHERE inventory_id = ANY (inventory_ids)
ORDER BY rh_account_id, id FOR UPDATE OF system_platform),
marked as (
UPDATE system_platform sp
SET stale = true
WHERE (rh_account_id, id) in (select rh_account_id, id from systems)
),
advisories as (
DELETE
FROM system_advisories
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
repos as (
DELETE
FROM system_repo
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
packages as (
DELETE
FROM system_package
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
deleted as (
DELETE
FROM system_platform
WHERE (rh_account_id, id) in (select rh_account_id, id from systems)
RETURNING id
)
SELECT count(*)
FROM deleted
INTO tmp_cnt;

RETURN tmp_cnt;
END
$$ LANGUAGE plpgsql;
107 changes: 107 additions & 0 deletions database_admin/migrations/116_delete_system_package2.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,107 @@
CREATE OR REPLACE FUNCTION delete_system(inventory_id_in uuid)
RETURNS TABLE
(
deleted_inventory_id uuid
)
AS
$delete_system$
DECLARE
v_system_id INT;
v_account_id INT;
BEGIN
-- opt out to refresh cache and then delete
SELECT id, rh_account_id
FROM system_platform
WHERE inventory_id = inventory_id_in
LIMIT 1
FOR UPDATE OF system_platform
INTO v_system_id, v_account_id;

IF v_system_id IS NULL OR v_account_id IS NULL THEN
RAISE NOTICE 'Not found';
RETURN;
END IF;

UPDATE system_platform
SET stale = true
WHERE rh_account_id = v_account_id
AND id = v_system_id;

DELETE
FROM system_advisories
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_repo
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_package
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_package2
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

RETURN QUERY DELETE FROM system_platform
WHERE rh_account_id = v_account_id AND
id = v_system_id
RETURNING inventory_id;
END;
$delete_system$ LANGUAGE 'plpgsql';

CREATE OR REPLACE FUNCTION delete_systems(inventory_ids UUID[])
RETURNS INTEGER
AS
$$
DECLARE
tmp_cnt INTEGER;
BEGIN

WITH systems as (
SELECT rh_account_id, id
FROM system_platform
WHERE inventory_id = ANY (inventory_ids)
ORDER BY rh_account_id, id FOR UPDATE OF system_platform),
marked as (
UPDATE system_platform sp
SET stale = true
WHERE (rh_account_id, id) in (select rh_account_id, id from systems)
),
advisories as (
DELETE
FROM system_advisories
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
repos as (
DELETE
FROM system_repo
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
packages as (
DELETE
FROM system_package
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
packages2 as (
DELETE
FROM system_package2
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
deleted as (
DELETE
FROM system_platform
WHERE (rh_account_id, id) in (select rh_account_id, id from systems)
RETURNING id
)
SELECT count(*)
FROM deleted
INTO tmp_cnt;

RETURN tmp_cnt;
END
$$ LANGUAGE plpgsql;
12 changes: 11 additions & 1 deletion database_admin/schema/create_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ CREATE TABLE IF NOT EXISTS schema_migrations


INSERT INTO schema_migrations
VALUES (115, false);
VALUES (116, false);

-- ---------------------------------------------------------------------------
-- Functions
Expand Down Expand Up @@ -387,6 +387,11 @@ BEGIN
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

DELETE
FROM system_package2
WHERE rh_account_id = v_account_id
AND system_id = v_system_id;

RETURN QUERY DELETE FROM system_platform
WHERE rh_account_id = v_account_id AND
id = v_system_id
Expand Down Expand Up @@ -427,6 +432,11 @@ BEGIN
FROM system_package
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
packages2 as (
DELETE
FROM system_package2
WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems)
),
deleted as (
DELETE
FROM system_platform
Expand Down

0 comments on commit a8cf857

Please sign in to comment.