diff --git a/database_admin/migrations/121_remove_system_package.down.sql b/database_admin/migrations/121_remove_system_package.down.sql new file mode 100644 index 000000000..13d1a0df4 --- /dev/null +++ b/database_admin/migrations/121_remove_system_package.down.sql @@ -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')$$); diff --git a/database_admin/migrations/121_remove_system_package.up.sql b/database_admin/migrations/121_remove_system_package.up.sql new file mode 100644 index 000000000..0a855569d --- /dev/null +++ b/database_admin/migrations/121_remove_system_package.up.sql @@ -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; diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index 2cf7e57a1..6669e889d 100644 --- a/database_admin/schema/create_schema.sql +++ b/database_admin/schema/create_schema.sql @@ -7,7 +7,7 @@ CREATE TABLE IF NOT EXISTS schema_migrations INSERT INTO schema_migrations -VALUES (120, false); +VALUES (121, false); -- --------------------------------------------------------------------------- -- Functions @@ -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 @@ -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 @@ -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 -- --------------------------------------------------------------------------- @@ -1014,33 +985,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, diff --git a/dev/test_data.sql b/dev/test_data.sql index 16d39deaf..ea8f5c7ec 100644 --- a/dev/test_data.sql +++ b/dev/test_data.sql @@ -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; @@ -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), diff --git a/tasks/vmaas_sync/metrics_db_test.go b/tasks/vmaas_sync/metrics_db_test.go index 633adc14d..51a8efbc4 100644 --- a/tasks/vmaas_sync/metrics_db_test.go +++ b/tasks/vmaas_sync/metrics_db_test.go @@ -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"])