Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

RHINENG-6031: drop old system_package table (POC cleanup) #1356

Merged
merged 2 commits into from
Jan 22, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
153 changes: 153 additions & 0 deletions database_admin/migrations/122_remove_system_package.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,153 @@
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 OR REPLACE FUNCTION update_status(update_data jsonb)
RETURNS TEXT as
$$
DECLARE
len int;
BEGIN
len = jsonb_array_length(update_data);
IF len IS NULL or len = 0 THEN
RETURN 'None';
END IF;
len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status == "Installable")'));
IF len > 0 THEN
RETURN 'Installable';
END IF;
RETURN 'Applicable';
END;
$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE;

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')$$);
102 changes: 102 additions & 0 deletions database_admin/migrations/122_remove_system_package.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,102 @@
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 FUNCTION IF EXISTS update_status(update_data jsonb);

DROP TABLE IF EXISTS system_package;
58 changes: 1 addition & 57 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 (121, false);
VALUES (122, 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 @@ -610,25 +600,6 @@ END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION update_status(update_data jsonb)
RETURNS TEXT as
$$
DECLARE
len int;
BEGIN
len = jsonb_array_length(update_data);
IF len IS NULL or len = 0 THEN
RETURN 'None';
END IF;
len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status == "Installable")'));
IF len > 0 THEN
RETURN 'Installable';
END IF;
RETURN 'Applicable';
END;
$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE;


-- ---------------------------------------------------------------------------
-- Tables
-- ---------------------------------------------------------------------------
Expand Down Expand Up @@ -1015,33 +986,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
1 change: 0 additions & 1 deletion 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
1 change: 0 additions & 1 deletion manager/routes/routes.go
Original file line number Diff line number Diff line change
Expand Up @@ -97,7 +97,6 @@ func InitAdmin(app *gin.Engine) {
api.GET("/check-caches", admin.CheckCaches)
api.PUT("/refresh-packages", admin.RefreshPackagesHandler)
api.PUT("/refresh-packages/:account", admin.RefreshPackagesAccountHandler)
api.PUT("/migrate_system_package", admin.MigrateSystemPackage)
api.GET("/sessions", admin.GetActiveSessionsHandler)
api.GET("/sessions/:search", admin.GetActiveSessionsHandler)
api.DELETE("/sessions/:pid", admin.TerminateSessionHandler)
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
Loading
Loading