Skip to content

Commit

Permalink
RHINENG-6031: drop old system_package table
Browse files Browse the repository at this point in the history
  • Loading branch information
MichaelMraka committed Jan 8, 2024
1 parent f913e1e commit 81db17b
Show file tree
Hide file tree
Showing 5 changed files with 238 additions and 50 deletions.
135 changes: 135 additions & 0 deletions database_admin/migrations/121_remove_system_package.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,135 @@
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;


CREATE TABLE IF NOT EXISTS system_package
(
rh_account_id INT NOT NULL REFERENCES rh_account,
system_id BIGINT NOT NULL,
package_id BIGINT NOT NULL REFERENCES package,
-- Use null to represent up-to-date packages
update_data JSONB DEFAULT NULL,
latest_evra TEXT GENERATED ALWAYS AS ( ((update_data ->> -1)::jsonb ->> 'evra')::text) STORED
CHECK(NOT empty(latest_evra)),
name_id BIGINT REFERENCES package_name (id) NOT NULL,

PRIMARY KEY (rh_account_id, system_id, package_id) INCLUDE (latest_evra)
) PARTITION BY HASH (rh_account_id);

CREATE INDEX IF NOT EXISTS system_package_name_pkg_system_idx
ON system_package (rh_account_id, name_id, package_id, system_id) INCLUDE (latest_evra);

CREATE INDEX IF NOT EXISTS system_package_package_id_idx on system_package (package_id);

GRANT SELECT, INSERT, UPDATE, DELETE ON system_package TO evaluator;
GRANT SELECT, UPDATE, DELETE ON system_package TO listener;
GRANT SELECT, UPDATE, DELETE ON system_package TO manager;
GRANT SELECT, UPDATE, DELETE ON system_package TO vmaas_sync;

SELECT create_table_partitions('system_package', 128,
$$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$);
100 changes: 100 additions & 0 deletions database_admin/migrations/121_remove_system_package.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,100 @@
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_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)
),
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;


DROP TABLE IF EXISTS system_package;
39 changes: 1 addition & 38 deletions 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 (120, false);
VALUES (121, false);

-- ---------------------------------------------------------------------------
-- Functions
Expand Down Expand Up @@ -382,11 +382,6 @@ BEGIN
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
Expand Down Expand Up @@ -427,11 +422,6 @@ BEGIN
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
Expand Down Expand Up @@ -1014,33 +1004,6 @@ CREATE UNIQUE INDEX IF NOT EXISTS package_evra_idx on package (evra, name_id);
GRANT SELECT, INSERT, UPDATE, DELETE ON TABLE package TO vmaas_sync;
GRANT SELECT, INSERT, UPDATE, DELETE ON TABLE package TO evaluator;

CREATE TABLE IF NOT EXISTS system_package
(
rh_account_id INT NOT NULL REFERENCES rh_account,
system_id BIGINT NOT NULL,
package_id BIGINT NOT NULL REFERENCES package,
-- Use null to represent up-to-date packages
update_data JSONB DEFAULT NULL,
latest_evra TEXT GENERATED ALWAYS AS ( ((update_data ->> -1)::jsonb ->> 'evra')::text) STORED
CHECK(NOT empty(latest_evra)),
name_id BIGINT REFERENCES package_name (id) NOT NULL,

PRIMARY KEY (rh_account_id, system_id, package_id) INCLUDE (latest_evra)
) PARTITION BY HASH (rh_account_id);

CREATE INDEX IF NOT EXISTS system_package_name_pkg_system_idx
ON system_package (rh_account_id, name_id, package_id, system_id) INCLUDE (latest_evra);

CREATE INDEX IF NOT EXISTS system_package_package_id_idx on system_package (package_id);

GRANT SELECT, INSERT, UPDATE, DELETE ON system_package TO evaluator;
GRANT SELECT, UPDATE, DELETE ON system_package TO listener;
GRANT SELECT, UPDATE, DELETE ON system_package TO manager;
GRANT SELECT, UPDATE, DELETE ON system_package TO vmaas_sync;

SELECT create_table_partitions('system_package', 128,
$$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$);

CREATE TABLE IF NOT EXISTS system_package2
(
rh_account_id INT NOT NULL,
Expand Down
10 changes: 0 additions & 10 deletions dev/test_data.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,5 @@
DELETE FROM system_advisories;
DELETE FROM system_repo;
DELETE FROM system_package;
DELETE FROM system_package2;
DELETE FROM system_platform;
DELETE FROM deleted_system;
Expand Down Expand Up @@ -156,15 +155,6 @@ INSERT INTO package(id, name_id, evra, description_hash, summary_hash, advisory_
(12, 102, '76.0.1-2.fc31.x86_64', '22', '2', null, true), -- firefox
(13, 102, '77.0.1-1.fc31.x86_64', '22', '2', null, true); -- firefox

INSERT INTO system_package (rh_account_id, system_id, package_id, name_id, update_data) VALUES
(3, 12, 1, 101, '[{"evra": "5.10.13-201.fc31.x86_64", "advisory": "RH-100", "status": "Installable"}]'),
(3, 12, 2, 102, '[{"evra": "77.0.1-1.fc31.x86_64", "advisory": "RH-1", "status": "Installable"}, {"evra": "76.0.1-2.fc31.x86_64", "advisory": "RH-2", "status": "Installable"}]'),
(3, 13, 1, 101, null),
(3, 13, 2, 102, '[{"evra": "76.0.1-2.fc31.x86_64", "advisory": "RH-2", "status": "Installable"},{"evra": "77.0.1-1.fc31.x86_64", "advisory": "RH-1", "status": "Applicable"}]'),
(3, 13, 3, 103, null),
(3, 13, 4, 104, null),
(3, 16, 1, 101, '[{"evra": "5.10.13-201.fc31.x86_64", "advisory": "RH-100", "status": "Installable"}]');

INSERT INTO system_package2 (rh_account_id, system_id, name_id, package_id, installable_id, applicable_id) VALUES
(3, 12, 101, 1, 11, null),
(3, 12, 102, 2, 12, null),
Expand Down
4 changes: 2 additions & 2 deletions tasks/vmaas_sync/metrics_db_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -17,8 +17,8 @@ func TestTableSizes(t *testing.T) {
for _, item := range tableSizes {
uniqueTables[item.Key] = true
}
assert.Equal(t, 342, len(tableSizes))
assert.Equal(t, 342, len(uniqueTables))
assert.Equal(t, 213, len(tableSizes))
assert.Equal(t, 213, len(uniqueTables))
assert.True(t, uniqueTables["system_platform"]) // check whether table names were loaded
assert.True(t, uniqueTables["package"])
assert.True(t, uniqueTables["repo"])
Expand Down

0 comments on commit 81db17b

Please sign in to comment.