From 8af87825300c32ae6111381002ab35b748761294 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 15 Oct 2025 13:59:17 +0200 Subject: [PATCH 01/27] RHINENG-21214: create system_inventory table --- .../142_split_system_platform.up.sql | 85 +++++++++++++++++++ 1 file changed, 85 insertions(+) create mode 100644 database_admin/migrations/142_split_system_platform.up.sql diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql new file mode 100644 index 000000000..26f525c4f --- /dev/null +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -0,0 +1,85 @@ +-- system_inventory +CREATE TABLE IF NOT EXISTS system_inventory +( + id BIGINT GENERATED BY DEFAULT AS IDENTITY, + inventory_id UUID NOT NULL, + rh_account_id INT NOT NULL, + vmaas_json TEXT CHECK (NOT empty(vmaas_json)), + json_checksum TEXT CHECK (NOT empty(json_checksum)), + last_updated TIMESTAMPTZ NOT NULL, + unchanged_since TIMESTAMPTZ NOT NULL, + last_upload TIMESTAMPTZ, + stale BOOLEAN NOT NULL DEFAULT false, + display_name TEXT NOT NULL CHECK (NOT empty(display_name)), + reporter_id INT, + yum_updates JSONB, + yum_checksum TEXT CHECK (NOT empty(yum_checksum)), + satellite_managed BOOLEAN NOT NULL DEFAULT false, + built_pkgcache BOOLEAN NOT NULL DEFAULT false, + arch TEXT CHECK (NOT empty(arch)), + bootc BOOLEAN NOT NULL DEFAULT false, + tags JSONB NOT NULL, + created TIMESTAMPTZ NOT NULL, + workspaces TEXT ARRAY CHECK (array_length(workspaces,1) > 0 or workspaces is null), -- group IDs from system_platform.groups + stale_timestamp TIMESTAMPTZ NOT NULL, + stale_warning_timestamp TIMESTAMPTZ NOT NULL, + culled_timestamp TIMESTAMPTZ NOT NULL, + os_name TEXT CHECK (NOT empty(os_name)), + os_major SMALLINT, + os_minor SMALLINT, + rhsm_version TEXT CHECK (NOT empty(rhsm_version)), + subscription_manager_id UUID, + sap_workload BOOLEAN NOT NULL DEFAULT false, + sap_workload_sids TEXT ARRAY CHECK (array_length(sap_workload_sids,1) > 0 or sap_workload_sids is null), + ansible_workload BOOLEAN NOT NULL DEFAULT false, + ansible_workload_controller_version TEXT CHECK (NOT empty(ansible_workload_controller_version)), + mssql_workload BOOLEAN NOT NULL DEFAULT false, + mssql_workload_version TEXT CHECK (NOT empty(mssql_workload_version)) +) PARTITION BY HASH (rh_account_id); + +-- PARTITIONING +SELECT create_table_partitions('system_inventory', 16, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05') + TABLESPACE pg_default$$); + +-- PRIVILEGES (listener has write access) +GRANT SELECT, INSERT, UPDATE ON system_inventory TO listener; +GRANT SELECT, UPDATE, DELETE ON system_inventory TO vmaas_sync; -- vmaas_sync performs system culling +GRANT SELECT, UPDATE (stale) ON system_inventory TO manager; -- manager needs to be able to update opt_out column +GRANT SELECT ON system_inventory TO evaluator; +SELECT grant_table_partitions('SELECT', 'system_inventory', 'evaluator'); +SELECT grant_table_partitions('SELECT', 'system_inventory', 'listener'); +SELECT grant_table_partitions('SELECT', 'system_inventory', 'manager'); +SELECT grant_table_partitions('SELECT', 'system_inventory', 'vmaas_sync'); +GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO evaluator; +GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO listener; +GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO vmaas_sync; + +-- TRIGGERS +SELECT create_table_partition_triggers('system_inventory_set_last_updated', + $$BEFORE INSERT OR UPDATE$$, + 'system_inventory', + $$FOR EACH ROW EXECUTE PROCEDURE set_last_updated()$$); + +SELECT create_table_partition_triggers('system_inventory_check_unchanged', + $$BEFORE INSERT OR UPDATE$$, + 'system_inventory', + $$FOR EACH ROW EXECUTE PROCEDURE check_unchanged()$$); + +SELECT create_table_partition_triggers('system_inventory_on_update', + $$AFTER UPDATE$$, + 'system_inventory', + $$FOR EACH ROW EXECUTE PROCEDURE on_system_update()$$); + +-- CONSTRAINTS +ALTER TABLE IF EXISTS system_inventory +ADD PRIMARY KEY (rh_account_id, id), +ADD FOREIGN KEY (rh_account_id) REFERENCES rh_account (id), +ADD FOREIGN KEY (reporter_id) REFERENCES reporter (id), +ADD UNIQUE (rh_account_id, inventory_id); + +-- INDEXES +CREATE INDEX IF NOT EXISTS system_inventory_inventory_id_idx ON system_inventory (inventory_id); +CREATE INDEX IF NOT EXISTS system_inventory_tags_index ON system_inventory USING GIN (tags JSONB_PATH_OPS); +CREATE INDEX IF NOT EXISTS system_inventory_stale_timestamp_index ON system_inventory (stale_timestamp); +CREATE INDEX IF NOT EXISTS system_inventory_workspaces_index ON system_inventory USING GIN (workspaces); From b73f9fb2c99779f5026de07402f3f71c3f1aeed7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 15 Oct 2025 13:59:17 +0200 Subject: [PATCH 02/27] RHINENG-21214: create system_patch table --- .../142_split_system_platform.up.sql | 50 +++++++++++++++++++ 1 file changed, 50 insertions(+) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index 26f525c4f..7311770e3 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -83,3 +83,53 @@ CREATE INDEX IF NOT EXISTS system_inventory_inventory_id_idx ON system_inventory CREATE INDEX IF NOT EXISTS system_inventory_tags_index ON system_inventory USING GIN (tags JSONB_PATH_OPS); CREATE INDEX IF NOT EXISTS system_inventory_stale_timestamp_index ON system_inventory (stale_timestamp); CREATE INDEX IF NOT EXISTS system_inventory_workspaces_index ON system_inventory USING GIN (workspaces); + + + +-- system_patch +CREATE TABLE IF NOT EXISTS system_patch +( + system_id BIGINT NOT NULL, + rh_account_id INT NOT NULL, + last_evaluation TIMESTAMPTZ, + installable_advisory_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + packages_installed INT NOT NULL DEFAULT 0, + packages_installable INT NOT NULL DEFAULT 0, + packages_applicable INT NOT NULL DEFAULT 0, + third_party BOOLEAN NOT NULL DEFAULT false, + applicable_advisory_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + template_id BIGINT +) PARTITION BY HASH (rh_account_id); + +-- PARTITIONING +SELECT create_table_partitions('system_patch', 16, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05') + TABLESPACE pg_default$$); + +-- PRIVILEGES (evaluator has write access) +GRANT SELECT, UPDATE ON system_patch TO evaluator; +GRANT SELECT, UPDATE (installable_advisory_count_cache, + installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache, + applicable_advisory_count_cache, + applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache) ON system_patch TO manager; +GRANT SELECT, UPDATE, DELETE ON system_patch to vmaas_sync; -- vmaas_sync performs system culling +SELECT grant_table_partitions('SELECT', 'system_patch', 'evaluator'); +SELECT grant_table_partitions('SELECT', 'system_patch', 'listener'); +SELECT grant_table_partitions('SELECT', 'system_patch', 'manager'); +SELECT grant_table_partitions('SELECT', 'system_patch', 'vmaas_sync'); + +-- CONSTRAINTS +ALTER TABLE IF EXISTS system_patch +ADD PRIMARY KEY (rh_account_id, system_id), +ADD FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), +ADD FOREIGN KEY (system_id, rh_account_id) REFERENCES system_inventory (id, rh_account_id); From 89952bf4abcbe9b4b0eca3649367c7fd89801f76 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 15 Oct 2025 13:59:17 +0200 Subject: [PATCH 03/27] RHINENG-21214: load data into the new tables --- .../142_split_system_platform.up.sql | 82 +++++++++++++++++++ 1 file changed, 82 insertions(+) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index 7311770e3..9fb9f98d8 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -55,6 +55,68 @@ GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO evaluator; GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO listener; GRANT SELECT, USAGE ON SEQUENCE system_inventory_id_seq TO vmaas_sync; +-- LOAD DATA +CREATE OR REPLACE FUNCTION safe_to_int(input_text TEXT) +RETURNS SMALLINT AS $$ +BEGIN + RETURN input_text::SMALLINT; +EXCEPTION WHEN OTHERS THEN + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION safe_to_uuid(input_text TEXT) +RETURNS UUID AS $$ +BEGIN + RETURN input_text::UUID; +EXCEPTION WHEN OTHERS THEN + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +INSERT INTO system_inventory SELECT + sp.id, + sp.inventory_id, + sp.rh_account_id, + sp.vmaas_json, + sp.json_checksum, + sp.last_updated, + sp.unchanged_since, + sp.last_upload, + sp.stale, + COALESCE(sp.display_name, ih.display_name), + sp.reporter_id, + sp.yum_updates, + sp.yum_checksum, + sp.satellite_managed, + sp.built_pkgcache, + sp.arch, + sp.bootc, + ih.tags, + ih.created, + ARRAY(SELECT jsonb_array_elements(ih.groups)->>'id') AS workspaces, + COALESCE(ih.stale_timestamp, sp.stale_timestamp), + COALESCE(ih.stale_warning_timestamp, sp.stale_warning_timestamp), + COALESCE(ih.culled_timestamp, sp.culled_timestamp), + ih.system_profile->'operating_system'->>'name' AS os_name, + safe_to_int(ih.system_profile->'operating_system'->>'major') AS os_major, + safe_to_int(ih.system_profile->'operating_system'->>'minor') AS os_minor, + ih.system_profile->'rhsm'->>'version' AS rhsm_version, + safe_to_uuid(ih.system_profile->>'owner_id') AS subscription_manager_id, + COALESCE((ih.system_profile->'workloads'->'sap'->>'sap_system')::BOOLEAN, false) AS sap_workload, + ARRAY(SELECT jsonb_array_elements_text(ih.system_profile->'workloads'->'sap'->'sids')) AS sap_workload_sids, + COALESCE(LENGTH(ih.system_profile->'workloads'->>'ansible') > 2, false) AS ansible_workload, + ih.system_profile->'workloads'->'ansible'->>'controller_version' AS ansible_workload_controller_version, + COALESCE(LENGTH(ih.system_profile->'workloads'->>'mssql') > 2, false) AS mssql_workload, + ih.system_profile->'workloads'->'mssql'->>'version' AS mssql_workload_version +FROM inventory.hosts ih JOIN system_platform sp ON ih.id = sp.inventory_id +WHERE sp.stale = false; + +SELECT setval('system_inventory_id_seq', (SELECT MAX(id) FROM system_inventory)); + +DROP FUNCTION safe_to_int; +DROP FUNCTION safe_to_uuid; + -- TRIGGERS SELECT create_table_partition_triggers('system_inventory_set_last_updated', $$BEFORE INSERT OR UPDATE$$, @@ -128,6 +190,26 @@ SELECT grant_table_partitions('SELECT', 'system_patch', 'listener'); SELECT grant_table_partitions('SELECT', 'system_patch', 'manager'); SELECT grant_table_partitions('SELECT', 'system_patch', 'vmaas_sync'); +INSERT INTO system_patch SELECT + id, + rh_account_id, + last_evaluation, + installable_advisory_count_cache, + installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache, + packages_installed, + packages_installable, + packages_applicable, + third_party, + applicable_advisory_count_cache, + applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache, + template_id +FROM system_platform sp +WHERE sp.stale = false; + -- CONSTRAINTS ALTER TABLE IF EXISTS system_patch ADD PRIMARY KEY (rh_account_id, system_id), From e1fd07b7b151940ac9c27badf59261a458e11fdf Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 17 Dec 2025 16:13:51 +0100 Subject: [PATCH 04/27] RHINENG-21214: update fkeys to refer to system_inventory Update tables that refered to system_platform to use system_inventory instead. --- .../142_split_system_platform.up.sql | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index 9fb9f98d8..4c9a70435 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -146,6 +146,25 @@ CREATE INDEX IF NOT EXISTS system_inventory_tags_index ON system_inventory USING CREATE INDEX IF NOT EXISTS system_inventory_stale_timestamp_index ON system_inventory (stale_timestamp); CREATE INDEX IF NOT EXISTS system_inventory_workspaces_index ON system_inventory USING GIN (workspaces); +-- UPDATE FKEYS +ALTER TABLE IF EXISTS system_repo +DROP CONSTRAINT system_platform_id, +ADD CONSTRAINT system_inventory_id + FOREIGN KEY (rh_account_id, system_id) + REFERENCES system_inventory (rh_account_id, id); + +ALTER TABLE IF EXISTS system_advisories +DROP CONSTRAINT system_platform_id, +ADD CONSTRAINT system_inventory_id + FOREIGN KEY (rh_account_id, system_id) + REFERENCES system_inventory (rh_account_id, id); + +ALTER TABLE IF EXISTS system_package2 +DROP CONSTRAINT system_package2_rh_account_id_system_id_fkey, +ADD CONSTRAINT system_inventory_id + FOREIGN KEY (rh_account_id, system_id) + REFERENCES system_inventory (rh_account_id, id); + -- system_patch From 12bfcf852e290e04f90110c17e6e316b99e9c494 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 15 Oct 2025 13:59:17 +0200 Subject: [PATCH 05/27] RHINENG-21214: update sql functions that use system_platform --- .../142_split_system_platform.up.sql | 303 ++++++++++++++++++ 1 file changed, 303 insertions(+) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index 4c9a70435..ea8ec30bb 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -165,6 +165,309 @@ ADD CONSTRAINT system_inventory_id FOREIGN KEY (rh_account_id, system_id) REFERENCES system_inventory (rh_account_id, id); +-- UPDATE FUNCTIONS +CREATE OR REPLACE FUNCTION on_system_update() +-- this trigger updates advisory_account_data when server changes its stale flag + RETURNS TRIGGER +AS +$system_update$ +DECLARE + was_counted BOOLEAN; + should_count BOOLEAN; + change INT; +BEGIN + -- Ignore not yet evaluated systems + IF TG_OP != 'UPDATE' OR NOT EXISTS ( + SELECT 1 + FROM system_patch + WHERE system_id = NEW.id + AND rh_account_id = NEW.rh_account_id + AND last_evaluation IS NOT NULL + ) THEN + RETURN NEW; + END IF; + + was_counted := OLD.stale = FALSE; + should_count := NEW.stale = FALSE; + + -- Determine what change we are performing + IF was_counted and NOT should_count THEN + change := -1; + ELSIF NOT was_counted AND should_count THEN + change := 1; + ELSE + -- No change + RETURN NEW; + END IF; + + -- insert/update advisories linked to the server + INSERT + INTO advisory_account_data (advisory_id, rh_account_id, systems_installable, systems_applicable) + SELECT sa.advisory_id, NEW.rh_account_id, + case when sa.status_id = 0 then change else 0 end as systems_installable, + change as systems_applicable + FROM system_advisories sa + WHERE sa.system_id = NEW.id AND sa.rh_account_id = NEW.rh_account_id + ORDER BY sa.advisory_id + ON CONFLICT (advisory_id, rh_account_id) DO UPDATE + SET systems_installable = advisory_account_data.systems_installable + EXCLUDED.systems_installable, + systems_applicable = advisory_account_data.systems_applicable + EXCLUDED.systems_applicable; + RETURN NEW; +END; +$system_update$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION refresh_advisory_caches_multi(advisory_ids_in INTEGER[] DEFAULT NULL, + rh_account_id_in INTEGER DEFAULT NULL) + RETURNS VOID AS +$refresh_advisory$ +BEGIN + -- Lock rows + PERFORM aad.rh_account_id, aad.advisory_id + FROM advisory_account_data aad + WHERE (aad.advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (aad.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + FOR UPDATE OF aad; + + WITH current_counts AS ( + SELECT sa.advisory_id, sa.rh_account_id, + count(sa.*) filter (where sa.status_id = 0) as systems_installable, + count(sa.*) as systems_applicable + FROM system_advisories sa + JOIN system_inventory si + ON sa.rh_account_id = si.rh_account_id AND sa.system_id = si.id + JOIN system_patch sp + ON si.id = sp.system_id AND sp.rh_account_id = si.rh_account_id + WHERE sp.last_evaluation IS NOT NULL + AND si.stale = FALSE + AND (sa.advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (si.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + GROUP BY sa.advisory_id, sa.rh_account_id + ), + upserted AS ( + INSERT INTO advisory_account_data (advisory_id, rh_account_id, systems_installable, systems_applicable) + SELECT advisory_id, rh_account_id, systems_installable, systems_applicable + FROM current_counts + ON CONFLICT (advisory_id, rh_account_id) DO UPDATE SET + systems_installable = EXCLUDED.systems_installable, + systems_applicable = EXCLUDED.systems_applicable + ) + DELETE FROM advisory_account_data + WHERE (advisory_id, rh_account_id) NOT IN (SELECT advisory_id, rh_account_id FROM current_counts) + AND (advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL); +END; +$refresh_advisory$ language plpgsql; + +CREATE OR REPLACE FUNCTION refresh_system_caches(system_id_in BIGINT DEFAULT NULL, + rh_account_id_in INTEGER DEFAULT NULL) + RETURNS INTEGER AS +$refresh_system$ +DECLARE + COUNT INTEGER; +BEGIN + WITH system_advisories_count AS ( + SELECT si.rh_account_id, si.id, + COUNT(advisory_id) FILTER (WHERE sa.status_id = 0) as installable_total, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1 AND sa.status_id = 0) AS installable_enhancement, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2 AND sa.status_id = 0) AS installable_bugfix, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 3 AND sa.status_id = 0) as installable_security, + COUNT(advisory_id) as applicable_total, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1) AS applicable_enhancement, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2) AS applicable_bugfix, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 3) as applicable_security + FROM system_inventory si -- this table ensures even systems without any system_advisories are in results + LEFT JOIN system_advisories sa + ON si.rh_account_id = sa.rh_account_id AND si.id = sa.system_id + LEFT JOIN advisory_metadata am + ON sa.advisory_id = am.id + WHERE (si.id = system_id_in OR system_id_in IS NULL) + AND (si.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + GROUP BY si.rh_account_id, si.id + ORDER BY si.rh_account_id, si.id + ) + UPDATE system_patch sp + SET installable_advisory_count_cache = sc.installable_total, + installable_advisory_enh_count_cache = sc.installable_enhancement, + installable_advisory_bug_count_cache = sc.installable_bugfix, + installable_advisory_sec_count_cache = sc.installable_security, + applicable_advisory_count_cache = sc.applicable_total, + applicable_advisory_enh_count_cache = sc.applicable_enhancement, + applicable_advisory_bug_count_cache = sc.applicable_bugfix, + applicable_advisory_sec_count_cache = sc.applicable_security + FROM system_advisories_count sc + WHERE sp.rh_account_id = sc.rh_account_id AND sp.system_id = sc.id + AND (sp.system_id = system_id_in OR system_id_in IS NULL) + AND (sp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL); + + GET DIAGNOSTICS COUNT = ROW_COUNT; + RETURN COUNT; +END; +$refresh_system$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION refresh_system_cached_counts(inventory_id_in varchar) + RETURNS void AS +$refresh_system_cached_counts$ +DECLARE + system_id int; +BEGIN + + SELECT id FROM system_inventory WHERE inventory_id = inventory_id_in INTO system_id; + + PERFORM refresh_system_caches(system_id, NULL); +END; +$refresh_system_cached_counts$ + LANGUAGE 'plpgsql'; + +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_inventory + WHERE inventory_id = inventory_id_in + LIMIT 1 + FOR UPDATE OF system_inventory + 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_inventory + 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; + + DELETE + FROM system_patch + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + RETURN QUERY DELETE FROM system_inventory + 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_inventory + WHERE inventory_id = ANY (inventory_ids) + ORDER BY rh_account_id, id FOR UPDATE OF system_inventory), + marked as ( + UPDATE system_inventory 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) + ), + patch_systems as ( + DELETE + FROM system_patch + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + deleted as ( + DELETE + FROM system_inventory + 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 delete_culled_systems(delete_limit INTEGER) + RETURNS INTEGER +AS +$fun$ +DECLARE + ids UUID[]; +BEGIN + ids := ARRAY( + SELECT inventory_id + FROM system_inventory + WHERE culled_timestamp < now() + ORDER BY id + LIMIT delete_limit + ); + return delete_systems(ids); +END; +$fun$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION mark_stale_systems(mark_limit integer) + RETURNS INTEGER +AS +$fun$ +DECLARE + marked integer; +BEGIN + WITH ids AS ( + SELECT rh_account_id, id, stale_warning_timestamp < now() as expired + FROM system_inventory + WHERE stale != (stale_warning_timestamp < now()) + ORDER BY rh_account_id, id FOR UPDATE OF system_inventory + LIMIT mark_limit + ) + UPDATE system_inventory si + SET stale = ids.expired + FROM ids + WHERE si.rh_account_id = ids.rh_account_id + AND si.id = ids.id; + GET DIAGNOSTICS marked = ROW_COUNT; + RETURN marked; +END; +$fun$ LANGUAGE plpgsql; + -- system_patch From b6c9d25ad6e766ee4da1d08e7eac83405ffed03f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 15 Oct 2025 13:59:17 +0200 Subject: [PATCH 06/27] RHINENG-21214: replace old tables with views --- .../142_split_system_platform.up.sql | 50 +++++++++++++++++++ 1 file changed, 50 insertions(+) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index ea8ec30bb..d94660f46 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -537,3 +537,53 @@ ALTER TABLE IF EXISTS system_patch ADD PRIMARY KEY (rh_account_id, system_id), ADD FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), ADD FOREIGN KEY (system_id, rh_account_id) REFERENCES system_inventory (id, rh_account_id); + + + +-- system_platform +DROP TABLE IF EXISTS system_platform; +CREATE OR REPLACE VIEW system_platform AS SELECT + si.id, + si.inventory_id, + si.rh_account_id, + si.vmaas_json, + si.json_checksum, + si.last_updated, + si.unchanged_since, + sp.last_evaluation, + sp.installable_advisory_count_cache, + sp.installable_advisory_enh_count_cache, + sp.installable_advisory_bug_count_cache, + sp.installable_advisory_sec_count_cache, + si.last_upload, + si.stale_timestamp, + si.stale_warning_timestamp, + si.culled_timestamp, + si.stale, + si.display_name, + sp.packages_installed, + sp.packages_installable, + si.reporter_id, + sp.third_party, + si.yum_updates, + sp.applicable_advisory_count_cache, + sp.applicable_advisory_enh_count_cache, + sp.applicable_advisory_bug_count_cache, + sp.applicable_advisory_sec_count_cache, + si.satellite_managed, + si.built_pkgcache, + sp.packages_applicable, + sp.template_id, + si.yum_checksum, + si.arch, + si.bootc +FROM system_inventory si JOIN system_patch sp + ON si.id = sp.system_id AND si.rh_account_id = sp.rh_account_id; + +GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; +-- evaluator needs to update last_evaluation +GRANT SELECT, UPDATE ON system_platform TO evaluator; +-- manager needs to update cache and delete systems +GRANT SELECT, UPDATE, DELETE ON system_platform TO manager; +-- VMaaS sync needs to be able to perform system culling tasks +GRANT SELECT, UPDATE, DELETE ON system_platform to vmaas_sync; From fe135b5b8a19e9869b8a1547d0aa058a10a8cf1d Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Thu, 11 Dec 2025 11:42:06 +0100 Subject: [PATCH 07/27] RHINENG-21214: add down migration --- .../142_split_system_platform.down.sql | 443 ++++++++++++++++++ 1 file changed, 443 insertions(+) create mode 100644 database_admin/migrations/142_split_system_platform.down.sql diff --git a/database_admin/migrations/142_split_system_platform.down.sql b/database_admin/migrations/142_split_system_platform.down.sql new file mode 100644 index 000000000..548cd6cd6 --- /dev/null +++ b/database_admin/migrations/142_split_system_platform.down.sql @@ -0,0 +1,443 @@ +-- system_platform +CREATE TABLE IF NOT EXISTS system_platform +( + id BIGINT GENERATED BY DEFAULT AS IDENTITY, + inventory_id UUID NOT NULL, + rh_account_id INT NOT NULL, + vmaas_json TEXT CHECK (NOT empty(vmaas_json)), + json_checksum TEXT CHECK (NOT empty(json_checksum)), + last_updated TIMESTAMP WITH TIME ZONE NOT NULL, + unchanged_since TIMESTAMP WITH TIME ZONE NOT NULL, + last_evaluation TIMESTAMP WITH TIME ZONE, + installable_advisory_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + last_upload TIMESTAMP WITH TIME ZONE, + stale_timestamp TIMESTAMP WITH TIME ZONE, + stale_warning_timestamp TIMESTAMP WITH TIME ZONE, + culled_timestamp TIMESTAMP WITH TIME ZONE, + stale BOOLEAN NOT NULL DEFAULT false, + display_name TEXT NOT NULL CHECK (NOT empty(display_name)), + packages_installed INT NOT NULL DEFAULT 0, + packages_installable INT NOT NULL DEFAULT 0, + reporter_id INT, + third_party BOOLEAN NOT NULL DEFAULT false, + yum_updates JSONB, + applicable_advisory_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + satellite_managed BOOLEAN NOT NULL DEFAULT FALSE, + built_pkgcache BOOLEAN NOT NULL DEFAULT FALSE, + packages_applicable INT NOT NULL DEFAULT 0, + template_id BIGINT, + yum_checksum TEXT CHECK (NOT empty(yum_checksum)), + arch TEXT CHECK (NOT empty(arch)), + bootc BOOLEAN NOT NULL DEFAULT false +) PARTITION BY HASH (rh_account_id); + +-- PARTITIONING +SELECT create_table_partitions('system_platform', 16, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05') + TABLESPACE pg_default$$); + +-- PRIVILEGES +GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; +-- evaluator needs to update last_evaluation +GRANT UPDATE ON system_platform TO evaluator; +-- manager needs to update cache and delete systems +GRANT SELECT, UPDATE, DELETE ON system_platform TO manager; +-- VMaaS sync needs to be able to perform system culling tasks +GRANT SELECT, UPDATE, DELETE ON system_platform to vmaas_sync; + +-- INSERT +INSERT INTO system_platform SELECT + si.id + si.inventory_id, + si.rh_account_id, + si.vmaas_json, + si.json_checksum, + si.last_updated, + si.unchanged_since, + sp.last_evaluation, + sp.installable_advisory_count_cache, + sp.installable_advisory_enh_count_cache, + sp.installable_advisory_bug_count_cache, + sp.installable_advisory_sec_count_cache, + si.last_upload, + si.stale_timestamp, + si.stale_warning_timestamp, + si.culled_timestamp, + si.stale, + si.display_name, + sp.packages_installed, + sp.packages_installable, + si.reporter_id, + sp.third_party, + si.yum_updates, + sp.applicable_advisory_count_cache, + sp.applicable_advisory_enh_count_cache, + sp.applicable_advisory_bug_count_cache, + sp.applicable_advisory_sec_count_cache, + si.satellite_managed, + si.built_pkgcache, + sp.packages_applicable, + sp.template_id, + si.yum_checksum, + si.arch, + si.bootc +FROM system_inventory si JOIN system_patch sp + ON si.rh_account_id = sp.rh_account_id AND si.inventory_id = sp.inventory_id; + +SELECT setval('system_platform_id_seq', (SELECT MAX(id) FROM system_platform)); + +-- TRIGGERS +SELECT create_table_partition_triggers('system_platform_set_last_updated', + $$BEFORE INSERT OR UPDATE$$, + 'system_platform', + $$FOR EACH ROW EXECUTE PROCEDURE set_last_updated()$$); + +SELECT create_table_partition_triggers('system_platform_check_unchanged', + $$BEFORE INSERT OR UPDATE$$, + 'system_platform', + $$FOR EACH ROW EXECUTE PROCEDURE check_unchanged()$$); + +SELECT create_table_partition_triggers('system_platform_on_update', + $$AFTER UPDATE$$, + 'system_platform', + $$FOR EACH ROW EXECUTE PROCEDURE on_system_update()$$); + +-- CONSTRAINTS +ALTER TABLE system_platform +ADD PRIMARY KEY (rh_account_id, id), +ADD FOREIGN KEY (reporter_id) REFERENCES reporter (id), +ADD FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), +ADD FOREIGN KEY (rh_account_id) REFERENCES rh_account (id), +ADD UNIQUE (rh_account_id, inventory_id); + +-- INDEXES +CREATE INDEX IF NOT EXISTS system_platform_inventory_id_idx + ON system_platform (inventory_id); + +-- UPDATE FUNCTIONS +CREATE OR REPLACE FUNCTION on_system_update() +-- this trigger updates advisory_account_data when server changes its stale flag + RETURNS TRIGGER +AS +$system_update$ +DECLARE + was_counted BOOLEAN; + should_count BOOLEAN; + change INT; +BEGIN + -- Ignore not yet evaluated systems + IF TG_OP != 'UPDATE' OR NEW.last_evaluation IS NULL THEN + RETURN NEW; + END IF; + + was_counted := OLD.stale = FALSE; + should_count := NEW.stale = FALSE; + + -- Determine what change we are performing + IF was_counted and NOT should_count THEN + change := -1; + ELSIF NOT was_counted AND should_count THEN + change := 1; + ELSE + -- No change + RETURN NEW; + END IF; + + -- insert/update advisories linked to the server + INSERT + INTO advisory_account_data (advisory_id, rh_account_id, systems_installable, systems_applicable) + SELECT sa.advisory_id, NEW.rh_account_id, + case when sa.status_id = 0 then change else 0 end as systems_installable, + change as systems_applicable + FROM system_advisories sa + WHERE sa.system_id = NEW.id AND sa.rh_account_id = NEW.rh_account_id + ORDER BY sa.advisory_id + ON CONFLICT (advisory_id, rh_account_id) DO UPDATE + SET systems_installable = advisory_account_data.systems_installable + EXCLUDED.systems_installable, + systems_applicable = advisory_account_data.systems_applicable + EXCLUDED.systems_applicable; + RETURN NEW; +END; +$system_update$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION refresh_advisory_caches_multi(advisory_ids_in INTEGER[] DEFAULT NULL, + rh_account_id_in INTEGER DEFAULT NULL) + RETURNS VOID AS +$refresh_advisory$ +BEGIN + -- Lock rows + PERFORM aad.rh_account_id, aad.advisory_id + FROM advisory_account_data aad + WHERE (aad.advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (aad.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + FOR UPDATE OF aad; + + WITH current_counts AS ( + SELECT sa.advisory_id, sa.rh_account_id, + count(sa.*) filter (where sa.status_id = 0) as systems_installable, + count(sa.*) as systems_applicable + FROM system_advisories sa + JOIN system_platform sp + ON sa.rh_account_id = sp.rh_account_id AND sa.system_id = sp.id + WHERE sp.last_evaluation IS NOT NULL + AND sp.stale = FALSE + AND (sa.advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (sp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + GROUP BY sa.advisory_id, sa.rh_account_id + ), + upserted AS ( + INSERT INTO advisory_account_data (advisory_id, rh_account_id, systems_installable, systems_applicable) + SELECT advisory_id, rh_account_id, systems_installable, systems_applicable + FROM current_counts + ON CONFLICT (advisory_id, rh_account_id) DO UPDATE SET + systems_installable = EXCLUDED.systems_installable, + systems_applicable = EXCLUDED.systems_applicable + ) + DELETE FROM advisory_account_data + WHERE (advisory_id, rh_account_id) NOT IN (SELECT advisory_id, rh_account_id FROM current_counts) + AND (advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) + AND (rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL); +END; +$refresh_advisory$ language plpgsql; + +CREATE OR REPLACE FUNCTION refresh_system_caches(system_id_in BIGINT DEFAULT NULL, + rh_account_id_in INTEGER DEFAULT NULL) + RETURNS INTEGER AS +$refresh_system$ +DECLARE + COUNT INTEGER; +BEGIN + WITH system_advisories_count AS ( + SELECT asp.rh_account_id, asp.id, + COUNT(advisory_id) FILTER (WHERE sa.status_id = 0) as installable_total, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1 AND sa.status_id = 0) AS installable_enhancement, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2 AND sa.status_id = 0) AS installable_bugfix, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 3 AND sa.status_id = 0) as installable_security, + COUNT(advisory_id) as applicable_total, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1) AS applicable_enhancement, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2) AS applicable_bugfix, + COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 3) as applicable_security + FROM system_platform asp -- this table ensures even systems without any system_advisories are in results + LEFT JOIN system_advisories sa + ON asp.rh_account_id = sa.rh_account_id AND asp.id = sa.system_id + LEFT JOIN advisory_metadata am + ON sa.advisory_id = am.id + WHERE (asp.id = system_id_in OR system_id_in IS NULL) + AND (asp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + GROUP BY asp.rh_account_id, asp.id + ORDER BY asp.rh_account_id, asp.id + ) + UPDATE system_platform sp + SET installable_advisory_count_cache = sc.installable_total, + installable_advisory_enh_count_cache = sc.installable_enhancement, + installable_advisory_bug_count_cache = sc.installable_bugfix, + installable_advisory_sec_count_cache = sc.installable_security, + applicable_advisory_count_cache = sc.applicable_total, + applicable_advisory_enh_count_cache = sc.applicable_enhancement, + applicable_advisory_bug_count_cache = sc.applicable_bugfix, + applicable_advisory_sec_count_cache = sc.applicable_security + FROM system_advisories_count sc + WHERE sp.rh_account_id = sc.rh_account_id AND sp.id = sc.id + AND (sp.id = system_id_in OR system_id_in IS NULL) + AND (sp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL); + + GET DIAGNOSTICS COUNT = ROW_COUNT; + RETURN COUNT; +END; +$refresh_system$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION update_system_caches(system_id_in BIGINT) + RETURNS VOID AS +$update_system_caches$ +BEGIN + PERFORM refresh_system_caches(system_id_in, NULL); +END; +$update_system_caches$ + LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION refresh_all_cached_counts() + RETURNS void AS +$refresh_all_cached_counts$ +BEGIN + PERFORM refresh_system_caches(NULL, NULL); + PERFORM refresh_advisory_caches(NULL, NULL); +END; +$refresh_all_cached_counts$ + LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION refresh_account_cached_counts(rh_account_in varchar) + RETURNS void AS +$refresh_account_cached_counts$ +DECLARE + rh_account_id_in INT; +BEGIN + -- update advisory count for ordered systems + SELECT id FROM rh_account WHERE name = rh_account_in INTO rh_account_id_in; + + PERFORM refresh_system_caches(NULL, rh_account_id_in); + PERFORM refresh_advisory_caches(NULL, rh_account_id_in); +END; +$refresh_account_cached_counts$ + LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION refresh_system_cached_counts(inventory_id_in varchar) + RETURNS void AS +$refresh_system_cached_counts$ +DECLARE + system_id int; +BEGIN + + SELECT id FROM system_platform WHERE inventory_id = inventory_id_in INTO system_id; + + PERFORM refresh_system_caches(system_id, NULL); +END; +$refresh_system_cached_counts$ + LANGUAGE 'plpgsql'; + +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; + +CREATE OR REPLACE FUNCTION delete_culled_systems(delete_limit INTEGER) + RETURNS INTEGER +AS +$$ +DECLARE + ids UUID[]; +BEGIN + ids := ARRAY( + SELECT inventory_id + FROM system_platform + WHERE culled_timestamp < now() + ORDER BY id + LIMIT delete_limit + ); + return delete_systems(ids); +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION mark_stale_systems(mark_limit integer) + RETURNS INTEGER +AS +$$ +DECLARE + marked integer; +BEGIN + WITH ids AS ( + SELECT rh_account_id, id + FROM system_platform + WHERE stale_warning_timestamp < now() + AND stale = false + ORDER BY rh_account_id, id FOR UPDATE OF system_platform + LIMIT mark_limit + ) + UPDATE system_platform sp + SET stale = true + FROM ids + WHERE sp.rh_account_id = ids.rh_account_id + AND sp.id = ids.id; + GET DIAGNOSTICS marked = ROW_COUNT; + RETURN marked; +END; +$$ LANGUAGE plpgsql; + +-- inventory.hosts gets created by cyndi From b091f2cae64e19d8dbc107f519f9fb19518bc30e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Fri, 14 Nov 2025 11:15:21 +0100 Subject: [PATCH 08/27] RHINENG-21214: update test data --- dev/test_data.sql | 90 +++++++++++++++++++++++++++---------------- platform/candlepin.go | 7 ++-- 2 files changed, 61 insertions(+), 36 deletions(-) diff --git a/dev/test_data.sql b/dev/test_data.sql index 10e44916e..434180a6b 100644 --- a/dev/test_data.sql +++ b/dev/test_data.sql @@ -1,7 +1,8 @@ DELETE FROM system_advisories; DELETE FROM system_repo; DELETE FROM system_package2; -DELETE FROM system_platform; +DELETE FROM system_patch; +DELETE FROM system_inventory; DELETE FROM deleted_system; DELETE FROM repo; DELETE FROM timestamp_kv; @@ -24,36 +25,59 @@ INSERT INTO template (id, rh_account_id, uuid, environment_id, name, description (3, 1, '99900000-0000-0000-0000-000000000003', '99900000000000000000000000000003', 'temp3-1', NULL, '{"to_time": "2000-01-01T00:00:00+00:00"}', 'x86_64', '8', 'user3'), (4, 3, '99900000-0000-0000-0000-000000000004', '99900000000000000000000000000004', 'temp4-3', 'desc4', '{"to_time": "2000-01-01T00:00:00+00:00"}', 'x86_64', '8', 'user4'); -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, reporter_id, vmaas_json, json_checksum, last_evaluation, last_upload, packages_installed, packages_installable, packages_applicable, third_party, template_id, arch) VALUES -(1, '00000000-0000-0000-0000-000000000001','00000000-0000-0000-0000-000000000001', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2020-09-22 12:00:00-04',0,0,0, true, 1, 'x86_64'), -(2, '00000000-0000-0000-0000-000000000002','00000000-0000-0000-0000-000000000002', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-09-22 12:00:00-04',0,0,0, false, 1, 'x86_64'), -(3, '00000000-0000-0000-0000-000000000003','00000000-0000-0000-0000-000000000003', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-09-18 12:00:00-04',0,0,0, false, 2, 'x86_64'), -(4, '00000000-0000-0000-0000-000000000004','00000000-0000-0000-0000-000000000004', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-09-18 12:00:00-04',0,0,0, false, NULL, 'x86_64'), -(5, '00000000-0000-0000-0000-000000000005','00000000-0000-0000-0000-000000000005', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-09-18 12:00:00-04',0,0,0, false, NULL, 'x86_64'), -(6, '00000000-0000-0000-0000-000000000006','00000000-0000-0000-0000-000000000006', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04',0,0,0, false, NULL, 'x86_64'); - -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, vmaas_json, json_checksum, last_updated, unchanged_since, last_upload, packages_installed, packages_installable, packages_applicable, arch) VALUES -(7, '00000000-0000-0000-0000-000000000007','00000000-0000-0000-0000-000000000007', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-10-04 14:13:12-04', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04',0,0,0, 'x86_64'); - -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, vmaas_json, json_checksum, last_evaluation, last_upload, packages_installed, packages_installable, packages_applicable, arch) VALUES -(8, '00000000-0000-0000-0000-000000000008','00000000-0000-0000-0000-000000000008', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04',0,0,0, 'x86_64'), -(9, '00000000-0000-0000-0000-000000000009','00000000-0000-0000-0000-000000000009', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04',0,0,0, 'x86_64'), -(10, '00000000-0000-0000-0000-000000000010','00000000-0000-0000-0000-000000000010', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04',0,0,0, 'x86_64'), -(11, '00000000-0000-0000-0000-000000000011','00000000-0000-0000-0000-000000000011', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04',0,0,0, 'x86_64'), -(12, '00000000-0000-0000-0000-000000000012','00000000-0000-0000-0000-000000000012', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04',2,2,2, 'x86_64'); - -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, vmaas_json, json_checksum, last_evaluation, last_upload, packages_installed, packages_installable, packages_applicable, yum_updates) VALUES -(13, '00000000-0000-0000-0000-000000000013','00000000-0000-0000-0000-000000000013', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04', 1,0,0, NULL), -(14, '00000000-0000-0000-0000-000000000014','00000000-0000-0000-0000-000000000014', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04', 0,0,0, NULL), -(15, '00000000-0000-0000-0000-000000000015','00000000-0000-0000-0000-000000000015', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04', 0,0,0, - '{"update_list": {"suricata-0:6.0.3-2.fc35.i686": {"available_updates": [{"erratum": "RHSA-2021:3801", "basearch": "i686", "releasever": "ser1", "repository": "group_oisf:suricata-6.0", "package": "suricata-0:6.0.4-2.fc35.i686"}]}}, "basearch": "i686", "releasever": "ser1"}'); - -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, vmaas_json, json_checksum, last_evaluation, last_upload, packages_installed, packages_installable, packages_applicable, yum_updates, template_id) VALUES -(16, '00000000-0000-0000-0000-000000000016','00000000-0000-0000-0000-000000000016', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04', 1,1,1, NULL, 4), -(17, '00000000-0000-0000-0000-000000000017','00000000-0000-0000-0000-000000000017', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2018-01-22 12:00:00-04',2,2,2, NULL, NULL); - -INSERT INTO system_platform (id, inventory_id, display_name, rh_account_id, reporter_id, vmaas_json, json_checksum, last_evaluation, last_upload, packages_installed, packages_installable, packages_applicable, third_party, template_id, arch) VALUES -(18, '00000000-0000-0000-0000-000000000018','00000000-0000-0000-0000-000000000018', 1, 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '2020-09-22 12:00:00-04',0,0,0, true, NULL, 'x86_64'); +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, reporter_id, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload, sap_workload_sids, mssql_workload, mssql_workload_version) VALUES +(1, '00000000-0000-0000-0000-000000000001', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000001', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 10, '8.10', NULL, true, ARRAY['ABC', 'DEF', 'GHI'], false, NULL), +(2, '00000000-0000-0000-0000-000000000002', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000002', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"},{"key": "k3", "value": "val3", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true, ARRAY['ABC'], false, NULL), +(3, '00000000-0000-0000-0000-000000000003', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000003', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}, {"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.0', NULL, true, NULL, false, NULL), +(4, '00000000-0000-0000-0000-000000000004', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000004', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.3', 'cccccccc-0000-0000-0001-000000000004', true, NULL, false, NULL), +(5, '00000000-0000-0000-0000-000000000005', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000005', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000005', true, NULL, false, NULL), +(6, '00000000-0000-0000-0000-000000000006', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000006', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 7, 3, '7.3', NULL, true, NULL, true, '15.3.0'); +INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, third_party, template_id) VALUES +(1, 1, '2018-09-22 12:00:00-04', true , 1), +(2, 1, '2018-09-22 12:00:00-04', false, 1), +(3, 1, '2018-09-22 12:00:00-04', false, 2), +(4, 1, '2018-09-22 12:00:00-04', false, NULL), +(5, 1, '2018-09-22 12:00:00-04', false, NULL), +(6, 1, '2018-09-22 12:00:00-04', false, NULL); + +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_updated, unchanged_since, last_upload, display_name, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, rhsm_version, subscription_manager_id, sap_workload, ansible_workload, ansible_workload_controller_version) VALUES +(7, '00000000-0000-0000-0000-000000000007', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-10-04 14:13:12-04', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000007', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, '8.x', 'cccccccc-0000-0000-0001-000000000007', true, true, '1.0'); +INSERT INTO system_patch (system_id, rh_account_id) VALUES +(7, 1); + +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload) VALUES +( 8, '00000000-0000-0000-0000-000000000008', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000008', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000008', true), +( 9, '00000000-0000-0000-0000-000000000009', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000009', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true), +(10, '00000000-0000-0000-0000-000000000010', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000010', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', NULL, true), +(11, '00000000-0000-0000-0000-000000000011', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000011', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', NULL, true), +(12, '00000000-0000-0000-0000-000000000012', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000012', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true); +INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed, packages_installable, packages_applicable) VALUES +( 8, 1, '2018-09-22 12:00:00-04', 0, 0, 0), +( 9, 2, '2018-09-22 12:00:00-04', 0, 0, 0), +(10, 2, '2018-09-22 12:00:00-04', 0, 0, 0), +(11, 2, '2018-09-22 12:00:00-04', 0, 0, 0), +(12, 3, '2018-09-22 12:00:00-04', 2, 2, 2); + +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, yum_updates, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, sap_workload) VALUES +(13, '00000000-0000-0000-0000-000000000013', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000013', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', true), +(14, '00000000-0000-0000-0000-000000000014', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000014', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, NULL, true), +(15, '00000000-0000-0000-0000-000000000015', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000015', '{"update_list": {"suricata-0:6.0.3-2.fc35.i686": {"available_updates": [{"erratum": "RHSA-2021:3801", "basearch": "i686", "releasever": "ser1", "repository": "group_oisf:suricata-6.0", "package": "suricata-0:6.0.4-2.fc35.i686"}]}}, "basearch": "i686", "releasever": "ser1"}', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', false); +INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed) VALUES +(13, 3, '2018-09-22 12:00:00-04', 1), +(14, 3, '2018-09-22 12:00:00-04', 0), +(15, 3, '2018-09-22 12:00:00-04', 0); + +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, ansible_workload, ansible_workload_controller_version, mssql_workload, mssql_workload_version) VALUES +(16, '00000000-0000-0000-0000-000000000016', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000016', '[]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', false, NULL, false, NULL), +(17, '00000000-0000-0000-0000-000000000017', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000017', '[]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', true, '1.0', true, '15.3.0'); +INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed, packages_installable, packages_applicable, template_id) VALUES +(16, 3, '2018-09-22 12:00:00-04', 1, 1, 1, 4), +(17, 1, '2018-09-22 12:00:00-04', 2, 2, 2, NULL); + +INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, reporter_id, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload) VALUES +(18, '00000000-0000-0000-0000-000000000018', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000018', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.3', '99999999-9999-9999-9999-999999999404', true); +INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, third_party) VALUES +(18, 1, '2018-09-22 12:00:00-04', true); INSERT INTO advisory_metadata (id, name, description, synopsis, summary, solution, advisory_type_id, public_date, modified_date, url, severity_id, cve_list, release_versions) VALUES @@ -233,13 +257,13 @@ INSERT INTO inventory.hosts_v1_0 (id, insights_id, account, display_name, tags, '{"rhsm": {"version": "8.1"}, "operating_system": {"name": "RHEL", "major": 8, "minor": 1}, "workloads": {"ansible": {"controller_version": "1.0", "hub_version": "3.4.1", "catalog_worker_version": "100.387.9846.12", "sso_version": "1.28.3.52641.10000513168495123"}, "mssql": { "version": "15.3.0"}}}', 'puptoo', '{}', 'org_3', '[]'), ('00000000000000000000000000000018', '00000000-0000-0000-0018-000000000001', '1', '00000000-0000-0000-0000-000000000018', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', - '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04', '2018-08-26 12:00:00-04', '{"workloads": {"sap": {"sap_system": true}}, "operating_system": {"name": "RHEL", "major": 8, "minor": 2}, "rhsm": {"version": "8.3"}, "owner_id": "return_404"}', + '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04', '2018-08-26 12:00:00-04', '{"workloads": {"sap": {"sap_system": true}}, "operating_system": {"name": "RHEL", "major": 8, "minor": 2}, "rhsm": {"version": "8.3"}, "owner_id": "99999999-9999-9999-9999-999999999404"}', 'puptoo', '{}', 'org_1', '[{"id": "inventory-group-1", "name": "group1"}]'); SELECT refresh_all_cached_counts(); ALTER TABLE advisory_metadata ALTER COLUMN id RESTART WITH 100; -ALTER TABLE system_platform ALTER COLUMN id RESTART WITH 100; +ALTER TABLE system_inventory ALTER COLUMN id RESTART WITH 100; ALTER TABLE rh_account ALTER COLUMN id RESTART WITH 100; ALTER TABLE repo ALTER COLUMN id RESTART WITH 100; ALTER TABLE package ALTER COLUMN id RESTART WITH 100; diff --git a/platform/candlepin.go b/platform/candlepin.go index 290183493..2ccf538e8 100644 --- a/platform/candlepin.go +++ b/platform/candlepin.go @@ -16,7 +16,7 @@ func candlepinConsumersPutHandler(c *gin.Context) { consumer := c.Param("consumer") jsonData, _ := io.ReadAll(c.Request.Body) utils.LogInfo("PUT consumer", consumer, "body", string(jsonData)) - if consumer == "return_404" { + if consumer == "return_404" || consumer == "99999999-9999-9999-9999-999999999404" { c.Data(http.StatusNotFound, gin.MIMEJSON, []byte{}) return } @@ -26,7 +26,7 @@ func candlepinConsumersPutHandler(c *gin.Context) { func candlepinConsumersGetHandler(c *gin.Context) { consumer := c.Param("consumer") utils.LogInfo("GET consumer", consumer, "body") - if consumer == "return_404" { + if consumer == "return_404" || consumer == "99999999-9999-9999-9999-999999999404" { c.Data(http.StatusNotFound, gin.MIMEJSON, []byte{}) return } @@ -51,7 +51,8 @@ func candlepinConsumersEnvironmentsHandler(c *gin.Context) { return } utils.LogInfo("ConsumerUuids", req.ConsumerUuids) - if slices.Contains(req.ConsumerUuids, "return_404") { + if slices.Contains(req.ConsumerUuids, "return_404") || + slices.Contains(req.ConsumerUuids, "99999999-9999-9999-9999-999999999404") { c.Data(http.StatusNotFound, gin.MIMEJSON, []byte{}) return } From 59c1629f07f0052e0d76ffc9282caea96986ce4e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 17 Dec 2025 16:45:53 +0100 Subject: [PATCH 09/27] RHINENG-21214: update create_schema.sql --- database_admin/schema/create_schema.sql | 304 +++++++++++++++--------- 1 file changed, 196 insertions(+), 108 deletions(-) diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index 8dfc150b9..487dacdfd 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 (141, false); +VALUES (142, false); -- --------------------------------------------------------------------------- -- Functions @@ -77,7 +77,13 @@ DECLARE change INT; BEGIN -- Ignore not yet evaluated systems - IF TG_OP != 'UPDATE' OR NEW.last_evaluation IS NULL THEN + IF TG_OP != 'UPDATE' OR NOT EXISTS ( + SELECT 1 + FROM system_patch + WHERE system_id = NEW.id + AND rh_account_id = NEW.rh_account_id + AND last_evaluation IS NOT NULL + ) THEN RETURN NEW; END IF; @@ -127,12 +133,14 @@ BEGIN count(sa.*) filter (where sa.status_id = 0) as systems_installable, count(sa.*) as systems_applicable FROM system_advisories sa - JOIN system_platform sp - ON sa.rh_account_id = sp.rh_account_id AND sa.system_id = sp.id + JOIN system_inventory si + ON sa.rh_account_id = si.rh_account_id AND sa.system_id = si.id + JOIN system_patch sp + ON si.id = sp.system_id AND sp.rh_account_id = si.rh_account_id WHERE sp.last_evaluation IS NOT NULL - AND sp.stale = FALSE + AND si.stale = FALSE AND (sa.advisory_id = ANY (advisory_ids_in) OR advisory_ids_in IS NULL) - AND (sp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + AND (si.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) GROUP BY sa.advisory_id, sa.rh_account_id ), upserted AS ( @@ -171,7 +179,7 @@ DECLARE COUNT INTEGER; BEGIN WITH system_advisories_count AS ( - SELECT asp.rh_account_id, asp.id, + SELECT si.rh_account_id, si.id, COUNT(advisory_id) FILTER (WHERE sa.status_id = 0) as installable_total, COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1 AND sa.status_id = 0) AS installable_enhancement, COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2 AND sa.status_id = 0) AS installable_bugfix, @@ -180,17 +188,17 @@ BEGIN COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 1) AS applicable_enhancement, COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 2) AS applicable_bugfix, COUNT(advisory_id) FILTER (WHERE am.advisory_type_id = 3) as applicable_security - FROM system_platform asp -- this table ensures even systems without any system_advisories are in results + FROM system_inventory si -- this table ensures even systems without any system_advisories are in results LEFT JOIN system_advisories sa - ON asp.rh_account_id = sa.rh_account_id AND asp.id = sa.system_id + ON si.rh_account_id = sa.rh_account_id AND si.id = sa.system_id LEFT JOIN advisory_metadata am ON sa.advisory_id = am.id - WHERE (asp.id = system_id_in OR system_id_in IS NULL) - AND (asp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) - GROUP BY asp.rh_account_id, asp.id - ORDER BY asp.rh_account_id, asp.id + WHERE (si.id = system_id_in OR system_id_in IS NULL) + AND (si.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL) + GROUP BY si.rh_account_id, si.id + ORDER BY si.rh_account_id, si.id ) - UPDATE system_platform sp + UPDATE system_patch sp SET installable_advisory_count_cache = sc.installable_total, installable_advisory_enh_count_cache = sc.installable_enhancement, installable_advisory_bug_count_cache = sc.installable_bugfix, @@ -200,8 +208,8 @@ BEGIN applicable_advisory_bug_count_cache = sc.applicable_bugfix, applicable_advisory_sec_count_cache = sc.applicable_security FROM system_advisories_count sc - WHERE sp.rh_account_id = sc.rh_account_id AND sp.id = sc.id - AND (sp.id = system_id_in OR system_id_in IS NULL) + WHERE sp.rh_account_id = sc.rh_account_id AND sp.system_id = sc.id + AND (sp.system_id = system_id_in OR system_id_in IS NULL) AND (sp.rh_account_id = rh_account_id_in OR rh_account_id_in IS NULL); GET DIAGNOSTICS COUNT = ROW_COUNT; @@ -284,7 +292,7 @@ DECLARE system_id int; BEGIN - SELECT id FROM system_platform WHERE inventory_id = inventory_id_in INTO system_id; + SELECT id FROM system_inventory WHERE inventory_id = inventory_id_in INTO system_id; PERFORM refresh_system_caches(system_id, NULL); END; @@ -305,10 +313,10 @@ DECLARE BEGIN -- opt out to refresh cache and then delete SELECT id, rh_account_id - FROM system_platform + FROM system_inventory WHERE inventory_id = inventory_id_in LIMIT 1 - FOR UPDATE OF system_platform + FOR UPDATE OF system_inventory INTO v_system_id, v_account_id; IF v_system_id IS NULL OR v_account_id IS NULL THEN @@ -316,7 +324,7 @@ BEGIN RETURN; END IF; - UPDATE system_platform + UPDATE system_inventory SET stale = true WHERE rh_account_id = v_account_id AND id = v_system_id; @@ -336,7 +344,12 @@ BEGIN WHERE rh_account_id = v_account_id AND system_id = v_system_id; - RETURN QUERY DELETE FROM system_platform + DELETE + FROM system_patch + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + RETURN QUERY DELETE FROM system_inventory WHERE rh_account_id = v_account_id AND id = v_system_id RETURNING inventory_id; @@ -353,11 +366,11 @@ BEGIN WITH systems as ( SELECT rh_account_id, id - FROM system_platform + FROM system_inventory WHERE inventory_id = ANY (inventory_ids) - ORDER BY rh_account_id, id FOR UPDATE OF system_platform), + ORDER BY rh_account_id, id FOR UPDATE OF system_inventory), marked as ( - UPDATE system_platform sp + UPDATE system_inventory sp SET stale = true WHERE (rh_account_id, id) in (select rh_account_id, id from systems) ), @@ -376,9 +389,14 @@ BEGIN FROM system_package2 WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) ), + patch_systems as ( + DELETE + FROM system_patch + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), deleted as ( DELETE - FROM system_platform + FROM system_inventory WHERE (rh_account_id, id) in (select rh_account_id, id from systems) RETURNING id ) @@ -399,7 +417,7 @@ DECLARE BEGIN ids := ARRAY( SELECT inventory_id - FROM system_platform + FROM system_inventory WHERE culled_timestamp < now() ORDER BY id LIMIT delete_limit @@ -417,16 +435,16 @@ DECLARE BEGIN WITH ids AS ( SELECT rh_account_id, id, stale_warning_timestamp < now() as expired - FROM system_platform + FROM system_inventory WHERE stale != (stale_warning_timestamp < now()) - ORDER BY rh_account_id, id FOR UPDATE OF system_platform + ORDER BY rh_account_id, id FOR UPDATE OF system_inventory LIMIT mark_limit ) - UPDATE system_platform sp + UPDATE system_inventory si SET stale = ids.expired FROM ids - WHERE sp.rh_account_id = ids.rh_account_id - AND sp.id = ids.id; + WHERE si.rh_account_id = ids.rh_account_id + AND si.id = ids.id; GET DIAGNOSTICS marked = ROW_COUNT; RETURN marked; END; @@ -632,88 +650,75 @@ SELECT grant_table_partitions('SELECT, INSERT, UPDATE, DELETE', 'template', 'lis SELECT grant_table_partitions('SELECT', 'template', 'evaluator'); SELECT grant_table_partitions('SELECT', 'template', 'vmaas_sync'); --- system_platform -CREATE TABLE IF NOT EXISTS system_platform +-- system_inventory +CREATE TABLE IF NOT EXISTS system_inventory ( - id BIGINT GENERATED BY DEFAULT AS IDENTITY, - inventory_id UUID NOT NULL, - rh_account_id INT NOT NULL, - vmaas_json TEXT CHECK (NOT empty(vmaas_json)), - json_checksum TEXT CHECK (NOT empty(json_checksum)), - last_updated TIMESTAMP WITH TIME ZONE NOT NULL, - unchanged_since TIMESTAMP WITH TIME ZONE NOT NULL, - last_evaluation TIMESTAMP WITH TIME ZONE, - installable_advisory_count_cache INT NOT NULL DEFAULT 0, - installable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, - installable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, - installable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, - last_upload TIMESTAMP WITH TIME ZONE, - stale_timestamp TIMESTAMP WITH TIME ZONE, - stale_warning_timestamp TIMESTAMP WITH TIME ZONE, - culled_timestamp TIMESTAMP WITH TIME ZONE, - stale BOOLEAN NOT NULL DEFAULT false, - display_name TEXT NOT NULL CHECK (NOT empty(display_name)), - packages_installed INT NOT NULL DEFAULT 0, - packages_installable INT NOT NULL DEFAULT 0, - reporter_id INT, - third_party BOOLEAN NOT NULL DEFAULT false, - yum_updates JSONB, - applicable_advisory_count_cache INT NOT NULL DEFAULT 0, - applicable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, - applicable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, - applicable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, - satellite_managed BOOLEAN NOT NULL DEFAULT FALSE, - built_pkgcache BOOLEAN NOT NULL DEFAULT FALSE, - packages_applicable INT NOT NULL DEFAULT 0, - template_id BIGINT, - yum_checksum TEXT CHECK (NOT empty(yum_checksum)), - arch TEXT CHECK (NOT empty(arch)), - bootc BOOLEAN NOT NULL DEFAULT false, + id BIGINT GENERATED BY DEFAULT AS IDENTITY, + inventory_id UUID NOT NULL, + rh_account_id INT NOT NULL REFERENCES rh_account (id), + vmaas_json TEXT CHECK (NOT empty(vmaas_json)), + json_checksum TEXT CHECK (NOT empty(json_checksum)), + last_updated TIMESTAMPTZ NOT NULL, + unchanged_since TIMESTAMPTZ NOT NULL, + last_upload TIMESTAMPTZ, + stale BOOLEAN NOT NULL DEFAULT false, + display_name TEXT NOT NULL CHECK (NOT empty(display_name)), + reporter_id INT REFERENCES reporter (id), + yum_updates JSONB, + yum_checksum TEXT CHECK (NOT empty(yum_checksum)), + satellite_managed BOOLEAN NOT NULL DEFAULT false, + built_pkgcache BOOLEAN NOT NULL DEFAULT false, + arch TEXT CHECK (NOT empty(arch)), + bootc BOOLEAN NOT NULL DEFAULT false, + tags JSONB NOT NULL, + created TIMESTAMPTZ NOT NULL, + workspaces TEXT ARRAY CHECK (array_length(workspaces,1) > 0 or workspaces is null), -- group IDs from system_platform.groups + stale_timestamp TIMESTAMPTZ NOT NULL, + stale_warning_timestamp TIMESTAMPTZ NOT NULL, + culled_timestamp TIMESTAMPTZ NOT NULL, + os_name TEXT CHECK (NOT empty(os_name)), + os_major SMALLINT, + os_minor SMALLINT, + rhsm_version TEXT CHECK (NOT empty(rhsm_version)), + subscription_manager_id UUID, + sap_workload BOOLEAN NOT NULL DEFAULT false, + sap_workload_sids TEXT ARRAY CHECK (array_length(sap_workload_sids,1) > 0 or sap_workload_sids is null), + ansible_workload BOOLEAN NOT NULL DEFAULT false, + ansible_workload_controller_version TEXT CHECK (NOT empty(ansible_workload_controller_version)), + mssql_workload BOOLEAN NOT NULL DEFAULT false, + mssql_workload_version TEXT CHECK (NOT empty(mssql_workload_version)), PRIMARY KEY (rh_account_id, id), - UNIQUE (rh_account_id, inventory_id), - CONSTRAINT reporter_id FOREIGN KEY (reporter_id) REFERENCES reporter (id), - CONSTRAINT template_id FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id) + UNIQUE (rh_account_id, inventory_id) ) PARTITION BY HASH (rh_account_id); -SELECT create_table_partitions('system_platform', 16, +SELECT create_table_partitions('system_inventory', 16, $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05') TABLESPACE pg_default$$); -SELECT create_table_partition_triggers('system_platform_set_last_updated', +GRANT SELECT, INSERT, UPDATE ON system_inventory TO listener; +GRANT SELECT, UPDATE, DELETE ON system_inventory TO vmaas_sync; -- vmaas_sync performs system culling +GRANT SELECT, UPDATE (stale) ON system_inventory TO manager; -- manager needs to be able to update opt_out column +GRANT SELECT ON system_inventory TO evaluator; + +SELECT create_table_partition_triggers('system_inventory_set_last_updated', $$BEFORE INSERT OR UPDATE$$, - 'system_platform', + 'system_inventory', $$FOR EACH ROW EXECUTE PROCEDURE set_last_updated()$$); -SELECT create_table_partition_triggers('system_platform_check_unchanged', +SELECT create_table_partition_triggers('system_inventory_check_unchanged', $$BEFORE INSERT OR UPDATE$$, - 'system_platform', + 'system_inventory', $$FOR EACH ROW EXECUTE PROCEDURE check_unchanged()$$); -SELECT create_table_partition_triggers('system_platform_on_update', +SELECT create_table_partition_triggers('system_inventory_on_update', $$AFTER UPDATE$$, - 'system_platform', + 'system_inventory', $$FOR EACH ROW EXECUTE PROCEDURE on_system_update()$$); -CREATE INDEX IF NOT EXISTS system_platform_inventory_id_idx - ON system_platform (inventory_id); - -GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; --- evaluator needs to update last_evaluation -GRANT UPDATE ON system_platform TO evaluator; --- manager needs to update cache and delete systems -GRANT UPDATE (installable_advisory_count_cache, - installable_advisory_enh_count_cache, - installable_advisory_bug_count_cache, - installable_advisory_sec_count_cache), DELETE ON system_platform TO manager; -GRANT UPDATE (applicable_advisory_count_cache, - applicable_advisory_enh_count_cache, - applicable_advisory_bug_count_cache, - applicable_advisory_sec_count_cache), DELETE ON system_platform TO manager; - -GRANT SELECT, UPDATE, DELETE ON system_platform TO manager; - --- VMaaS sync needs to be able to perform system culling tasks -GRANT SELECT, UPDATE, DELETE ON system_platform to vmaas_sync; +CREATE INDEX IF NOT EXISTS system_inventory_inventory_id_idx ON system_inventory (inventory_id); +CREATE INDEX IF NOT EXISTS system_inventory_tags_index ON system_inventory USING GIN (tags JSONB_PATH_OPS); +CREATE INDEX IF NOT EXISTS system_inventory_stale_timestamp_index ON system_inventory (stale_timestamp); +CREATE INDEX IF NOT EXISTS system_inventory_workspaces_index ON system_inventory USING GIN (workspaces); CREATE TABLE IF NOT EXISTS deleted_system ( @@ -833,8 +838,6 @@ SELECT create_table_partitions('system_advisories', 32, GRANT SELECT, INSERT, UPDATE, DELETE ON system_advisories TO evaluator; -- manager needs to be able to update things like 'status' on a sysid/advisory combination, also needs to delete GRANT UPDATE, DELETE ON system_advisories TO manager; --- manager needs to be able to update opt_out column -GRANT UPDATE (stale) ON system_platform TO manager; -- listener deletes systems, TODO: temporary added evaluator permissions to listener GRANT SELECT, INSERT, UPDATE, DELETE ON system_advisories TO listener; -- vmaas_sync needs to delete culled systems, which cascades to system_advisories @@ -893,9 +896,9 @@ CREATE TABLE IF NOT EXISTS system_repo repo_id BIGINT NOT NULL, rh_account_id INT NOT NULL, UNIQUE (rh_account_id, system_id, repo_id), - CONSTRAINT system_platform_id + CONSTRAINT system_inventory_id FOREIGN KEY (rh_account_id, system_id) - REFERENCES system_platform (rh_account_id, id), + REFERENCES system_inventory (rh_account_id, id), CONSTRAINT repo_id FOREIGN KEY (repo_id) REFERENCES repo (id) @@ -911,16 +914,12 @@ GRANT SELECT, DELETE on system_repo to vmaas_sync; -- the following constraints are enabled here not directly in the table definitions -- to make new schema equal to the migrated schema ALTER TABLE system_advisories - ADD CONSTRAINT system_platform_id + ADD CONSTRAINT system_inventory_id FOREIGN KEY (rh_account_id, system_id) - REFERENCES system_platform (rh_account_id, id), + REFERENCES system_inventory (rh_account_id, id), ADD CONSTRAINT status_id FOREIGN KEY (status_id) REFERENCES status (id); -ALTER TABLE system_platform - ADD CONSTRAINT rh_account_id - FOREIGN KEY (rh_account_id) - REFERENCES rh_account (id); CREATE TABLE IF NOT EXISTS package_name ( @@ -971,7 +970,9 @@ CREATE TABLE IF NOT EXISTS system_package2 applicable_id BIGINT REFERENCES package (id), PRIMARY KEY (rh_account_id, system_id, package_id), - FOREIGN KEY (rh_account_id, system_id) REFERENCES system_platform (rh_account_id, id) + CONSTRAINT system_inventory_id + FOREIGN KEY (rh_account_id, system_id) + REFERENCES system_inventory (rh_account_id, id) ) PARTITION BY HASH (rh_account_id); CREATE INDEX IF NOT EXISTS system_package2_account_pkg_name_idx @@ -1023,6 +1024,93 @@ GRANT SELECT, INSERT, UPDATE, DELETE ON timestamp_kv TO vmaas_sync; GRANT DELETE ON system_advisories TO vmaas_sync; GRANT DELETE ON advisory_account_data TO vmaas_sync; +-- system_patch +CREATE TABLE IF NOT EXISTS system_patch +( + system_id BIGINT NOT NULL, + rh_account_id INT NOT NULL, + last_evaluation TIMESTAMPTZ, + installable_advisory_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + installable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + packages_installed INT NOT NULL DEFAULT 0, + packages_installable INT NOT NULL DEFAULT 0, + packages_applicable INT NOT NULL DEFAULT 0, + third_party BOOLEAN NOT NULL DEFAULT false, + applicable_advisory_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_enh_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_bug_count_cache INT NOT NULL DEFAULT 0, + applicable_advisory_sec_count_cache INT NOT NULL DEFAULT 0, + template_id BIGINT, + PRIMARY KEY (rh_account_id, system_id), + FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), + FOREIGN KEY (system_id, rh_account_id) REFERENCES system_inventory (id, rh_account_id) +) PARTITION BY HASH (rh_account_id); + +SELECT create_table_partitions('system_patch', 16, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05') + TABLESPACE pg_default$$); + +GRANT SELECT, UPDATE ON system_patch TO evaluator; +GRANT SELECT, UPDATE (installable_advisory_count_cache, + installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache, + applicable_advisory_count_cache, + applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache) ON system_patch TO manager; +GRANT SELECT, UPDATE, DELETE ON system_patch to vmaas_sync; -- vmaas_sync performs system culling + +-- system_platform +DROP TABLE IF EXISTS system_platform; +CREATE OR REPLACE VIEW system_platform AS SELECT + si.id, + si.inventory_id, + si.rh_account_id, + si.vmaas_json, + si.json_checksum, + si.last_updated, + si.unchanged_since, + sp.last_evaluation, + sp.installable_advisory_count_cache, + sp.installable_advisory_enh_count_cache, + sp.installable_advisory_bug_count_cache, + sp.installable_advisory_sec_count_cache, + si.last_upload, + si.stale_timestamp, + si.stale_warning_timestamp, + si.culled_timestamp, + si.stale, + si.display_name, + sp.packages_installed, + sp.packages_installable, + si.reporter_id, + sp.third_party, + si.yum_updates, + sp.applicable_advisory_count_cache, + sp.applicable_advisory_enh_count_cache, + sp.applicable_advisory_bug_count_cache, + sp.applicable_advisory_sec_count_cache, + si.satellite_managed, + si.built_pkgcache, + sp.packages_applicable, + sp.template_id, + si.yum_checksum, + si.arch, + si.bootc +FROM system_inventory si JOIN system_patch sp + ON si.id = sp.system_id AND si.rh_account_id = sp.rh_account_id; + +GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; +-- evaluator needs to update last_evaluation +GRANT UPDATE ON system_platform TO evaluator; +-- manager needs to update cache and delete systems +GRANT SELECT, UPDATE, DELETE ON system_platform TO manager; +-- VMaaS sync needs to be able to perform system culling tasks +GRANT SELECT, UPDATE, DELETE ON system_platform to vmaas_sync; + -- ---------------------------------------------------------------------------- -- Read access for all users -- ---------------------------------------------------------------------------- From d113c5cdf53b164013e3bae588bb7e38b2a40e60 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Mon, 19 Jan 2026 16:57:04 +0100 Subject: [PATCH 10/27] RHINENG-21214: remove unused insights_id --- docs/v3/openapi.json | 11 ----------- manager/controllers/advisory_systems.go | 1 - manager/controllers/systems.go | 5 ++--- 3 files changed, 2 insertions(+), 15 deletions(-) diff --git a/docs/v3/openapi.json b/docs/v3/openapi.json index 3628c34fb..e7c20d346 100644 --- a/docs/v3/openapi.json +++ b/docs/v3/openapi.json @@ -2446,14 +2446,6 @@ "type": "string" } }, - { - "name": "filter[insights_id]", - "in": "query", - "description": "Filter", - "schema": { - "type": "string" - } - }, { "name": "filter[display_name]", "in": "query", @@ -7182,9 +7174,6 @@ "$ref": "#/components/schemas/controllers.SystemGroup" } }, - "insights_id": { - "type": "string" - }, "installable_other_count": { "type": "integer" }, diff --git a/manager/controllers/advisory_systems.go b/manager/controllers/advisory_systems.go index 7323bb86f..1c2e51919 100644 --- a/manager/controllers/advisory_systems.go +++ b/manager/controllers/advisory_systems.go @@ -218,7 +218,6 @@ func systemsIDsStatus(c *gin.Context, systems []SystemsStatusID, meta *ListMeta) // @Param sort query string false "Sort field" Enums(id,display_name,last_evaluation,last_upload,rhsa_count,rhba_count,rhea_count,other_count,satellite_managed,stale,built_pkgcache) // @Param search query string false "Find matching text" // @Param filter[id] query string false "Filter" -// @Param filter[insights_id] query string false "Filter" // @Param filter[display_name] query string false "Filter" // @Param filter[last_evaluation] query string false "Filter" // @Param filter[last_upload] query string false "Filter" diff --git a/manager/controllers/systems.go b/manager/controllers/systems.go index f5090c05b..06cbfd12e 100644 --- a/manager/controllers/systems.go +++ b/manager/controllers/systems.go @@ -101,9 +101,8 @@ type SystemItemAttributes struct { // nolint: lll type SystemItemAttributesExtended struct { SystemItemAttributes - ThirdParty bool `json:"third_party" csv:"third_party" query:"sp.third_party" gorm:"column:third_party"` - InsightsID string `json:"insights_id" csv:"insights_id" query:"ih.insights_id" gorm:"column:insights_id"` - PackagesUpdatable int `json:"packages_updatable" csv:"packages_updatable" query:"sp.packages_installable" gorm:"column:packages_updatable"` + ThirdParty bool `json:"third_party" csv:"third_party" query:"sp.third_party" gorm:"column:third_party"` + PackagesUpdatable int `json:"packages_updatable" csv:"packages_updatable" query:"sp.packages_installable" gorm:"column:packages_updatable"` OSName string `json:"os_name" csv:"os_name" query:"ih.system_profile->'operating_system'->>'name'" gorm:"column:osname"` OSMajor string `json:"os_major" csv:"os_major" query:"ih.system_profile->'operating_system'->>'major'" gorm:"column:osmajor"` From 3decb1c240ce15ba9898d572fcaabbc02f411fdc Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Wed, 7 Jan 2026 16:03:49 +0100 Subject: [PATCH 11/27] RHINENG-21214: add models for the new tables --- base/models/models.go | 69 +++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 69 insertions(+) diff --git a/base/models/models.go b/base/models/models.go index a287026d9..7ce72d9cd 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -2,6 +2,8 @@ package models import ( "time" + + "github.com/lib/pq" ) type RhAccount struct { @@ -96,6 +98,73 @@ func (s *SystemPlatform) GetInventoryID() string { return s.InventoryID } +type SystemInventory struct { + ID int64 `gorm:"primaryKey"` + InventoryID string `gorm:"unique"` + RhAccountID int `gorm:"primaryKey"` + VmaasJSON *string + JSONChecksum *string + LastUpdated *time.Time `gorm:"default:null"` + UnchangedSince *time.Time `gorm:"default:null"` + LastUpload *time.Time `gorm:"default:null"` + Stale bool + DisplayName string + ReporterID *int + YumUpdates []byte `gorm:"column:yum_updates"` + YumChecksum *string `gorm:"column:yum_checksum"` + SatelliteManaged bool `gorm:"column:satellite_managed"` + BuiltPkgcache bool `gorm:"column:built_pkgcache"` + Arch *string + Bootc bool + Tags []byte `gorm:"column:tags"` + Created time.Time + Workspaces pq.StringArray `gorm:"type:text[]"` + StaleTimestamp time.Time + StaleWarningTimestamp time.Time + CulledTimestamp time.Time + OSName *string + OSMajor *int16 + OSMinor *int16 + RhsmVersion *string + SubscriptionManagerID *string + SapWorkload bool + SapWorkloadSIDs pq.StringArray `gorm:"type:text[];column:sap_workload_sids"` + AnsibleWorkload bool + AnsibleWorkloadControllerVersion *string + MssqlWorkload bool + MssqlWorkloadVersion *string +} + +func (SystemInventory) TableName() string { + return "system_inventory" +} + +func (s *SystemInventory) GetInventoryID() string { + if s == nil { + return "" + } + return s.InventoryID +} + +type SystemPatch struct { + SystemID int64 `gorm:"primaryKey"` + RhAccountID int `gorm:"primaryKey"` + LastEvaluation *time.Time `gorm:"default:null"` // TODO: trigger sets it to current time? + InstallableAdvisoryCountCache int + InstallableAdvisoryEnhCountCache int + InstallableAdvisoryBugCountCache int + InstallableAdvisorySecCountCache int + PackagesInstalled int + PackagesInstallable int + PackagesApplicable int + ThirdParty bool + ApplicableAdvisoryCountCache int + ApplicableAdvisoryEnhCountCache int + ApplicableAdvisoryBugCountCache int + ApplicableAdvisorySecCountCache int + TemplateID *int64 `gorm:"column:template_id"` +} + type String struct { ID []byte `gorm:"primaryKey"` Value string From 267557d488c730bc866e49b008cb76a3c2c902ef Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Tue, 20 Jan 2026 16:36:56 +0100 Subject: [PATCH 12/27] wip: fix TestInitDelete --- turnpike/controllers/admin_test.go | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/turnpike/controllers/admin_test.go b/turnpike/controllers/admin_test.go index 426f46bbe..d36fb9dfc 100644 --- a/turnpike/controllers/admin_test.go +++ b/turnpike/controllers/admin_test.go @@ -18,10 +18,11 @@ func TestInitDelete(t *testing.T) { utils.TestLoadEnv("conf/test.env") core.SetupTest(t) - assert.NoError(t, database.DB.Create(&models.SystemPlatform{ + assert.NoError(t, database.DB.Create(&models.SystemInventory{ InventoryID: del, RhAccountID: 1, DisplayName: del, + Tags: []byte("[]"), }).Error) utils.TestLoadEnv("conf/manager.env") } From 4d1cdcce0d679e7e130e6414df5fed91b88f0a7f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jakub=20Dugovi=C4=8D?= Date: Tue, 20 Jan 2026 16:55:04 +0100 Subject: [PATCH 13/27] wip: fix TestSystemDelete --- turnpike/controllers/admin.go | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/turnpike/controllers/admin.go b/turnpike/controllers/admin.go index 444c0e866..74ddc8c61 100644 --- a/turnpike/controllers/admin.go +++ b/turnpike/controllers/admin.go @@ -229,8 +229,8 @@ func SystemDeleteHandler(c *gin.Context) { defer tx.Rollback() - err := tx.Set("gorm:query_option", "FOR UPDATE OF system_platform"). - Table("system_platform"). + err := tx.Set("gorm:query_option", "FOR UPDATE OF system_inventory"). + Table("system_inventory"). Where("inventory_id = ?::uuid", inventoryID). Pluck("inventory_id", &systemInventoryID).Error From be01b5bedb869ccc80f51b8fd97bb416455bf3f9 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 15:58:30 +0100 Subject: [PATCH 14/27] RHINENG-21214: handle inserts/updates to system_platform view --- ...stem_platform_instead_of_triggers.down.sql | 5 + ...system_platform_instead_of_triggers.up.sql | 154 +++++++++++++++++ database_admin/schema/create_schema.sql | 155 +++++++++++++++++- 3 files changed, 313 insertions(+), 1 deletion(-) create mode 100644 database_admin/migrations/143_system_platform_instead_of_triggers.down.sql create mode 100644 database_admin/migrations/143_system_platform_instead_of_triggers.up.sql diff --git a/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql b/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql new file mode 100644 index 000000000..3040e0550 --- /dev/null +++ b/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql @@ -0,0 +1,5 @@ +DROP TRIGGER IF EXISTS system_platform_update_trigger ON system_platform; +DROP TRIGGER IF EXISTS system_platform_insert_trigger ON system_platform; + +DROP FUNCTION IF EXISTS system_platform_update(); +DROP FUNCTION IF EXISTS system_platform_insert(); diff --git a/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql b/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql new file mode 100644 index 000000000..8f5490fe9 --- /dev/null +++ b/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql @@ -0,0 +1,154 @@ +-- INSTEAD OF triggers for system_platform view to handle INSERT and UPDATE + +CREATE OR REPLACE FUNCTION system_platform_insert() + RETURNS TRIGGER AS +$system_platform_insert$ +DECLARE + new_system_id BIGINT; + created TIMESTAMPTZ := CURRENT_TIMESTAMP; +BEGIN + INSERT INTO system_inventory ( + inventory_id, + rh_account_id, + vmaas_json, + json_checksum, + last_updated, + unchanged_since, + last_upload, + stale_timestamp, + stale_warning_timestamp, + culled_timestamp, + stale, + display_name, + reporter_id, + yum_updates, + satellite_managed, + built_pkgcache, + yum_checksum, + arch, + bootc, + tags, + created + ) VALUES ( + NEW.inventory_id, + NEW.rh_account_id, + NEW.vmaas_json, + NEW.json_checksum, + NEW.last_updated, + NEW.unchanged_since, + NEW.last_upload, + NEW.stale_timestamp, + NEW.stale_warning_timestamp, + NEW.culled_timestamp, + COALESCE(NEW.stale, false), + NEW.display_name, + NEW.reporter_id, + NEW.yum_updates, + COALESCE(NEW.satellite_managed, false), + COALESCE(NEW.built_pkgcache, false), + NEW.yum_checksum, + NEW.arch, + COALESCE(NEW.bootc, false), + '[]'::JSONB, + created + ) + RETURNING id INTO new_system_id; + + INSERT INTO system_patch ( + system_id, + rh_account_id, + last_evaluation, + installable_advisory_count_cache, + installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache, + packages_installed, + packages_installable, + packages_applicable, + third_party, + applicable_advisory_count_cache, + applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache, + template_id + ) VALUES ( + new_system_id, + NEW.rh_account_id, + NEW.last_evaluation, + COALESCE(NEW.installable_advisory_count_cache, 0), + COALESCE(NEW.installable_advisory_enh_count_cache, 0), + COALESCE(NEW.installable_advisory_bug_count_cache, 0), + COALESCE(NEW.installable_advisory_sec_count_cache, 0), + COALESCE(NEW.packages_installed, 0), + COALESCE(NEW.packages_installable, 0), + COALESCE(NEW.packages_applicable, 0), + COALESCE(NEW.third_party, false), + COALESCE(NEW.applicable_advisory_count_cache, 0), + COALESCE(NEW.applicable_advisory_enh_count_cache, 0), + COALESCE(NEW.applicable_advisory_bug_count_cache, 0), + COALESCE(NEW.applicable_advisory_sec_count_cache, 0), + NEW.template_id + ); + + NEW.id := new_system_id; + RETURN NEW; +END; +$system_platform_insert$ + LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION system_platform_update() + RETURNS TRIGGER AS +$system_platform_update$ +BEGIN + UPDATE system_inventory SET + inventory_id = NEW.inventory_id, + vmaas_json = NEW.vmaas_json, + json_checksum = NEW.json_checksum, + last_updated = NEW.last_updated, + unchanged_since = NEW.unchanged_since, + last_upload = NEW.last_upload, + stale_timestamp = NEW.stale_timestamp, + stale_warning_timestamp = NEW.stale_warning_timestamp, + culled_timestamp = NEW.culled_timestamp, + stale = NEW.stale, + display_name = NEW.display_name, + reporter_id = NEW.reporter_id, + yum_updates = NEW.yum_updates, + satellite_managed = NEW.satellite_managed, + built_pkgcache = NEW.built_pkgcache, + yum_checksum = NEW.yum_checksum, + arch = NEW.arch, + bootc = NEW.bootc + WHERE id = OLD.id AND rh_account_id = OLD.rh_account_id; + + UPDATE system_patch SET + last_evaluation = NEW.last_evaluation, + installable_advisory_count_cache = NEW.installable_advisory_count_cache, + installable_advisory_enh_count_cache = NEW.installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache = NEW.installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache = NEW.installable_advisory_sec_count_cache, + packages_installed = NEW.packages_installed, + packages_installable = NEW.packages_installable, + packages_applicable = NEW.packages_applicable, + third_party = NEW.third_party, + applicable_advisory_count_cache = NEW.applicable_advisory_count_cache, + applicable_advisory_enh_count_cache = NEW.applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache = NEW.applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache = NEW.applicable_advisory_sec_count_cache, + template_id = NEW.template_id + WHERE system_id = OLD.id AND rh_account_id = OLD.rh_account_id; + + RETURN NEW; +END; +$system_platform_update$ + LANGUAGE 'plpgsql'; + +CREATE TRIGGER system_platform_insert_trigger + INSTEAD OF INSERT ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_insert(); + +CREATE TRIGGER system_platform_update_trigger + INSTEAD OF UPDATE ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_update(); diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index 487dacdfd..27a96e614 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 (142, false); +VALUES (143, false); -- --------------------------------------------------------------------------- -- Functions @@ -1103,6 +1103,159 @@ CREATE OR REPLACE VIEW system_platform AS SELECT FROM system_inventory si JOIN system_patch sp ON si.id = sp.system_id AND si.rh_account_id = sp.rh_account_id; +CREATE OR REPLACE FUNCTION system_platform_insert() + RETURNS TRIGGER AS +$system_platform_insert$ +DECLARE + new_system_id BIGINT; + created TIMESTAMPTZ := CURRENT_TIMESTAMP; +BEGIN + INSERT INTO system_inventory ( + inventory_id, + rh_account_id, + vmaas_json, + json_checksum, + last_updated, + unchanged_since, + last_upload, + stale_timestamp, + stale_warning_timestamp, + culled_timestamp, + stale, + display_name, + reporter_id, + yum_updates, + satellite_managed, + built_pkgcache, + yum_checksum, + arch, + bootc, + tags, + created + ) VALUES ( + NEW.inventory_id, + NEW.rh_account_id, + NEW.vmaas_json, + NEW.json_checksum, + NEW.last_updated, + NEW.unchanged_since, + NEW.last_upload, + NEW.stale_timestamp, + NEW.stale_warning_timestamp, + NEW.culled_timestamp, + COALESCE(NEW.stale, false), + NEW.display_name, + NEW.reporter_id, + NEW.yum_updates, + COALESCE(NEW.satellite_managed, false), + COALESCE(NEW.built_pkgcache, false), + NEW.yum_checksum, + NEW.arch, + COALESCE(NEW.bootc, false), + '[]'::JSONB, + created + ) + RETURNING id INTO new_system_id; + + INSERT INTO system_patch ( + system_id, + rh_account_id, + last_evaluation, + installable_advisory_count_cache, + installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache, + packages_installed, + packages_installable, + packages_applicable, + third_party, + applicable_advisory_count_cache, + applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache, + template_id + ) VALUES ( + new_system_id, + NEW.rh_account_id, + NEW.last_evaluation, + COALESCE(NEW.installable_advisory_count_cache, 0), + COALESCE(NEW.installable_advisory_enh_count_cache, 0), + COALESCE(NEW.installable_advisory_bug_count_cache, 0), + COALESCE(NEW.installable_advisory_sec_count_cache, 0), + COALESCE(NEW.packages_installed, 0), + COALESCE(NEW.packages_installable, 0), + COALESCE(NEW.packages_applicable, 0), + COALESCE(NEW.third_party, false), + COALESCE(NEW.applicable_advisory_count_cache, 0), + COALESCE(NEW.applicable_advisory_enh_count_cache, 0), + COALESCE(NEW.applicable_advisory_bug_count_cache, 0), + COALESCE(NEW.applicable_advisory_sec_count_cache, 0), + NEW.template_id + ); + + NEW.id := new_system_id; + RETURN NEW; +END; +$system_platform_insert$ + LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION system_platform_update() + RETURNS TRIGGER AS +$system_platform_update$ +BEGIN + UPDATE system_inventory SET + inventory_id = NEW.inventory_id, + vmaas_json = NEW.vmaas_json, + json_checksum = NEW.json_checksum, + last_updated = NEW.last_updated, + unchanged_since = NEW.unchanged_since, + last_upload = NEW.last_upload, + stale_timestamp = NEW.stale_timestamp, + stale_warning_timestamp = NEW.stale_warning_timestamp, + culled_timestamp = NEW.culled_timestamp, + stale = NEW.stale, + display_name = NEW.display_name, + reporter_id = NEW.reporter_id, + yum_updates = NEW.yum_updates, + satellite_managed = NEW.satellite_managed, + built_pkgcache = NEW.built_pkgcache, + yum_checksum = NEW.yum_checksum, + arch = NEW.arch, + bootc = NEW.bootc + WHERE id = OLD.id AND rh_account_id = OLD.rh_account_id; + + UPDATE system_patch SET + last_evaluation = NEW.last_evaluation, + installable_advisory_count_cache = NEW.installable_advisory_count_cache, + installable_advisory_enh_count_cache = NEW.installable_advisory_enh_count_cache, + installable_advisory_bug_count_cache = NEW.installable_advisory_bug_count_cache, + installable_advisory_sec_count_cache = NEW.installable_advisory_sec_count_cache, + packages_installed = NEW.packages_installed, + packages_installable = NEW.packages_installable, + packages_applicable = NEW.packages_applicable, + third_party = NEW.third_party, + applicable_advisory_count_cache = NEW.applicable_advisory_count_cache, + applicable_advisory_enh_count_cache = NEW.applicable_advisory_enh_count_cache, + applicable_advisory_bug_count_cache = NEW.applicable_advisory_bug_count_cache, + applicable_advisory_sec_count_cache = NEW.applicable_advisory_sec_count_cache, + template_id = NEW.template_id + WHERE system_id = OLD.id AND rh_account_id = OLD.rh_account_id; + + RETURN NEW; +END; +$system_platform_update$ + LANGUAGE 'plpgsql'; + +CREATE TRIGGER system_platform_insert_trigger + INSTEAD OF INSERT ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_insert(); + +CREATE TRIGGER system_platform_update_trigger + INSTEAD OF UPDATE ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_update(); + GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; -- evaluator needs to update last_evaluation GRANT UPDATE ON system_platform TO evaluator; From aa33bf3caf0b798a07cbfe306dd02c4ca1872edf Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 16:24:17 +0100 Subject: [PATCH 15/27] fixup! RHINENG-21214: update create_schema.sql --- database_admin/migrations/142_split_system_platform.up.sql | 6 +++--- database_admin/schema/create_schema.sql | 6 +++--- 2 files changed, 6 insertions(+), 6 deletions(-) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index d94660f46..9b95412d0 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -21,9 +21,9 @@ CREATE TABLE IF NOT EXISTS system_inventory tags JSONB NOT NULL, created TIMESTAMPTZ NOT NULL, workspaces TEXT ARRAY CHECK (array_length(workspaces,1) > 0 or workspaces is null), -- group IDs from system_platform.groups - stale_timestamp TIMESTAMPTZ NOT NULL, - stale_warning_timestamp TIMESTAMPTZ NOT NULL, - culled_timestamp TIMESTAMPTZ NOT NULL, + stale_timestamp TIMESTAMPTZ, + stale_warning_timestamp TIMESTAMPTZ, + culled_timestamp TIMESTAMPTZ, os_name TEXT CHECK (NOT empty(os_name)), os_major SMALLINT, os_minor SMALLINT, diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index 27a96e614..e3577c4a8 100644 --- a/database_admin/schema/create_schema.sql +++ b/database_admin/schema/create_schema.sql @@ -673,9 +673,9 @@ CREATE TABLE IF NOT EXISTS system_inventory tags JSONB NOT NULL, created TIMESTAMPTZ NOT NULL, workspaces TEXT ARRAY CHECK (array_length(workspaces,1) > 0 or workspaces is null), -- group IDs from system_platform.groups - stale_timestamp TIMESTAMPTZ NOT NULL, - stale_warning_timestamp TIMESTAMPTZ NOT NULL, - culled_timestamp TIMESTAMPTZ NOT NULL, + stale_timestamp TIMESTAMPTZ, + stale_warning_timestamp TIMESTAMPTZ, + culled_timestamp TIMESTAMPTZ, os_name TEXT CHECK (NOT empty(os_name)), os_major SMALLINT, os_minor SMALLINT, From b2114424ef9b478bb0ebcc8c893f1dc05df32e31 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 16:36:49 +0100 Subject: [PATCH 16/27] fixup! RHINENG-21214: handle inserts/updates to system_platform view --- ...stem_platform_instead_of_triggers.down.sql | 2 ++ ...system_platform_instead_of_triggers.up.sql | 20 +++++++++++++++++++ database_admin/schema/create_schema.sql | 20 +++++++++++++++++++ 3 files changed, 42 insertions(+) diff --git a/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql b/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql index 3040e0550..6f65c81b1 100644 --- a/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql +++ b/database_admin/migrations/143_system_platform_instead_of_triggers.down.sql @@ -1,5 +1,7 @@ +DROP TRIGGER IF EXISTS system_platform_delete_trigger ON system_platform; DROP TRIGGER IF EXISTS system_platform_update_trigger ON system_platform; DROP TRIGGER IF EXISTS system_platform_insert_trigger ON system_platform; +DROP FUNCTION IF EXISTS system_platform_delete(); DROP FUNCTION IF EXISTS system_platform_update(); DROP FUNCTION IF EXISTS system_platform_insert(); diff --git a/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql b/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql index 8f5490fe9..406c70941 100644 --- a/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql +++ b/database_admin/migrations/143_system_platform_instead_of_triggers.up.sql @@ -143,6 +143,21 @@ END; $system_platform_update$ LANGUAGE 'plpgsql'; +CREATE OR REPLACE FUNCTION system_platform_delete() + RETURNS TRIGGER AS +$system_platform_delete$ +BEGIN + DELETE FROM system_patch + WHERE system_id = OLD.id AND rh_account_id = OLD.rh_account_id; + + DELETE FROM system_inventory + WHERE id = OLD.id AND rh_account_id = OLD.rh_account_id; + + RETURN OLD; +END; +$system_platform_delete$ + LANGUAGE 'plpgsql'; + CREATE TRIGGER system_platform_insert_trigger INSTEAD OF INSERT ON system_platform FOR EACH ROW @@ -152,3 +167,8 @@ CREATE TRIGGER system_platform_update_trigger INSTEAD OF UPDATE ON system_platform FOR EACH ROW EXECUTE FUNCTION system_platform_update(); + +CREATE TRIGGER system_platform_delete_trigger + INSTEAD OF DELETE ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_delete(); diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index e3577c4a8..22bc401ff 100644 --- a/database_admin/schema/create_schema.sql +++ b/database_admin/schema/create_schema.sql @@ -1246,6 +1246,21 @@ END; $system_platform_update$ LANGUAGE 'plpgsql'; +CREATE OR REPLACE FUNCTION system_platform_delete() + RETURNS TRIGGER AS +$system_platform_delete$ +BEGIN + DELETE FROM system_patch + WHERE system_id = OLD.id AND rh_account_id = OLD.rh_account_id; + + DELETE FROM system_inventory + WHERE id = OLD.id AND rh_account_id = OLD.rh_account_id; + + RETURN OLD; +END; +$system_platform_delete$ + LANGUAGE 'plpgsql'; + CREATE TRIGGER system_platform_insert_trigger INSTEAD OF INSERT ON system_platform FOR EACH ROW @@ -1256,6 +1271,11 @@ CREATE TRIGGER system_platform_update_trigger FOR EACH ROW EXECUTE FUNCTION system_platform_update(); +CREATE TRIGGER system_platform_delete_trigger + INSTEAD OF DELETE ON system_platform + FOR EACH ROW + EXECUTE FUNCTION system_platform_delete(); + GRANT SELECT, INSERT, UPDATE, DELETE ON system_platform TO listener; -- evaluator needs to update last_evaluation GRANT UPDATE ON system_platform TO evaluator; From 4d1710051235355550ebbac27b55cf4bc2c1f570 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 17:23:21 +0100 Subject: [PATCH 17/27] fixup! RHINENG-21214: update test data --- dev/test_data.sql | 36 ++++++++++++++++++------------------ 1 file changed, 18 insertions(+), 18 deletions(-) diff --git a/dev/test_data.sql b/dev/test_data.sql index 434180a6b..1311bfbbe 100644 --- a/dev/test_data.sql +++ b/dev/test_data.sql @@ -26,12 +26,12 @@ INSERT INTO template (id, rh_account_id, uuid, environment_id, name, description (4, 3, '99900000-0000-0000-0000-000000000004', '99900000000000000000000000000004', 'temp4-3', 'desc4', '{"to_time": "2000-01-01T00:00:00+00:00"}', 'x86_64', '8', 'user4'); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, reporter_id, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload, sap_workload_sids, mssql_workload, mssql_workload_version) VALUES -(1, '00000000-0000-0000-0000-000000000001', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000001', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 10, '8.10', NULL, true, ARRAY['ABC', 'DEF', 'GHI'], false, NULL), -(2, '00000000-0000-0000-0000-000000000002', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000002', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"},{"key": "k3", "value": "val3", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true, ARRAY['ABC'], false, NULL), -(3, '00000000-0000-0000-0000-000000000003', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000003', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}, {"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.0', NULL, true, NULL, false, NULL), -(4, '00000000-0000-0000-0000-000000000004', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000004', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.3', 'cccccccc-0000-0000-0001-000000000004', true, NULL, false, NULL), -(5, '00000000-0000-0000-0000-000000000005', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000005', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000005', true, NULL, false, NULL), -(6, '00000000-0000-0000-0000-000000000006', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000006', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 7, 3, '7.3', NULL, true, NULL, true, '15.3.0'); +(1, '00000000-0000-0000-0000-000000000001', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000001', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 10, '8.10', NULL, true, ARRAY['ABC', 'DEF', 'GHI'], false, NULL), +(2, '00000000-0000-0000-0000-000000000002', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000002', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"},{"key": "k2", "value": "val2", "namespace": "ns1"},{"key": "k3", "value": "val3", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 1, '8.1', NULL, true, ARRAY['ABC'], false, NULL), +(3, '00000000-0000-0000-0000-000000000003', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000003', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}, {"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 1, '8.0', NULL, true, NULL, false, NULL), +(4, '00000000-0000-0000-0000-000000000004', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000004', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 2, '8.3', 'cccccccc-0000-0000-0001-000000000004', true, NULL, false, NULL), +(5, '00000000-0000-0000-0000-000000000005', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-09-18 12:00:00-04', '00000000-0000-0000-0000-000000000005', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000005', true, NULL, false, NULL), +(6, '00000000-0000-0000-0000-000000000006', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000006', 1, 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 7, 3, '7.3', NULL, true, NULL, true, '15.3.0'); INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, third_party, template_id) VALUES (1, 1, '2018-09-22 12:00:00-04', true , 1), (2, 1, '2018-09-22 12:00:00-04', false, 1), @@ -41,16 +41,16 @@ INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, third_party (6, 1, '2018-09-22 12:00:00-04', false, NULL); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_updated, unchanged_since, last_upload, display_name, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, rhsm_version, subscription_manager_id, sap_workload, ansible_workload, ansible_workload_controller_version) VALUES -(7, '00000000-0000-0000-0000-000000000007', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-10-04 14:13:12-04', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000007', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, '8.x', 'cccccccc-0000-0000-0001-000000000007', true, true, '1.0'); +(7, '00000000-0000-0000-0000-000000000007', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-10-04 14:13:12-04', '2018-09-22 12:00:00-04', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000007', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], NULL, NULL, NULL, 'RHEL', 8, '8.x', 'cccccccc-0000-0000-0001-000000000007', true, true, '1.0'); INSERT INTO system_patch (system_id, rh_account_id) VALUES (7, 1); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload) VALUES -( 8, '00000000-0000-0000-0000-000000000008', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000008', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000008', true), -( 9, '00000000-0000-0000-0000-000000000009', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000009', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true), -(10, '00000000-0000-0000-0000-000000000010', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000010', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', NULL, true), -(11, '00000000-0000-0000-0000-000000000011', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000011', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, '8.3', NULL, true), -(12, '00000000-0000-0000-0000-000000000012', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000012', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', NULL, true); +( 8, '00000000-0000-0000-0000-000000000008', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-08-26 12:00:00-04', '00000000-0000-0000-0000-000000000008', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-2'], NULL, NULL, NULL, 'RHEL', 8, 3, '8.3', 'cccccccc-0000-0000-0001-000000000008', true), +( 9, '00000000-0000-0000-0000-000000000009', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000009', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 1, '8.1', NULL, true), +(10, '00000000-0000-0000-0000-000000000010', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000010', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 2, '8.2', NULL, true), +(11, '00000000-0000-0000-0000-000000000011', 2, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000011', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 3, '8.3', NULL, true), +(12, '00000000-0000-0000-0000-000000000012', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000012', 'x86_64', '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 1, '8.1', NULL, true); INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed, packages_installable, packages_applicable) VALUES ( 8, 1, '2018-09-22 12:00:00-04', 0, 0, 0), ( 9, 2, '2018-09-22 12:00:00-04', 0, 0, 0), @@ -59,23 +59,23 @@ INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_in (12, 3, '2018-09-22 12:00:00-04', 2, 2, 2); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, yum_updates, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, sap_workload) VALUES -(13, '00000000-0000-0000-0000-000000000013', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000013', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', true), -(14, '00000000-0000-0000-0000-000000000014', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000014', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 3, NULL, true), -(15, '00000000-0000-0000-0000-000000000015', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000015', '{"update_list": {"suricata-0:6.0.3-2.fc35.i686": {"available_updates": [{"erratum": "RHSA-2021:3801", "basearch": "i686", "releasever": "ser1", "repository": "group_oisf:suricata-6.0", "package": "suricata-0:6.0.4-2.fc35.i686"}]}}, "basearch": "i686", "releasever": "ser1"}', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', false); +(13, '00000000-0000-0000-0000-000000000013', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000013', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 2, '8.2', true), +(14, '00000000-0000-0000-0000-000000000014', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000014', NULL, '[{"key": "k1", "value": "val1", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 3, NULL, true), +(15, '00000000-0000-0000-0000-000000000015', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000015', '{"update_list": {"suricata-0:6.0.3-2.fc35.i686": {"available_updates": [{"erratum": "RHSA-2021:3801", "basearch": "i686", "releasever": "ser1", "repository": "group_oisf:suricata-6.0", "package": "suricata-0:6.0.4-2.fc35.i686"}]}}, "basearch": "i686", "releasever": "ser1"}', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 1, '8.1', false); INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed) VALUES (13, 3, '2018-09-22 12:00:00-04', 1), (14, 3, '2018-09-22 12:00:00-04', 0), (15, 3, '2018-09-22 12:00:00-04', 0); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, ansible_workload, ansible_workload_controller_version, mssql_workload, mssql_workload_version) VALUES -(16, '00000000-0000-0000-0000-000000000016', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000016', '[]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.2', false, NULL, false, NULL), -(17, '00000000-0000-0000-0000-000000000017', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000017', '[]', '2018-08-26 12:00:00-04', NULL, '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 1, '8.1', true, '1.0', true, '15.3.0'); +(16, '00000000-0000-0000-0000-000000000016', 3, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000016', '[]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 2, '8.2', false, NULL, false, NULL), +(17, '00000000-0000-0000-0000-000000000017', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2018-01-22 12:00:00-04', '00000000-0000-0000-0000-000000000017', '[]', '2018-08-26 12:00:00-04', NULL, NULL, NULL, NULL, 'RHEL', 8, 1, '8.1', true, '1.0', true, '15.3.0'); INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, packages_installed, packages_installable, packages_applicable, template_id) VALUES (16, 3, '2018-09-22 12:00:00-04', 1, 1, 1, 4), (17, 1, '2018-09-22 12:00:00-04', 2, 2, 2, NULL); INSERT INTO system_inventory (id, inventory_id, rh_account_id, vmaas_json, json_checksum, last_upload, display_name, reporter_id, arch, tags, created, workspaces, stale_timestamp, stale_warning_timestamp, culled_timestamp, os_name, os_major, os_minor, rhsm_version, subscription_manager_id, sap_workload) VALUES -(18, '00000000-0000-0000-0000-000000000018', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000018', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], '2018-08-26 12:00:00-04', '2018-09-02 12:00:00-04', '2018-09-09 12:00:00-04', 'RHEL', 8, 2, '8.3', '99999999-9999-9999-9999-999999999404', true); +(18, '00000000-0000-0000-0000-000000000018', 1, '{ "package_list": [ "kernel-2.6.32-696.20.1.el6.x86_64" ], "repository_list": [ "rhel-6-server-rpms" ] }', '1', '2020-09-22 12:00:00-04', '00000000-0000-0000-0000-000000000018', 1, 'x86_64', '[{"key": "k3", "value": "val4", "namespace": "ns1"}]', '2018-08-26 12:00:00-04', ARRAY['inventory-group-1'], NULL, NULL, NULL, 'RHEL', 8, 2, '8.3', '99999999-9999-9999-9999-999999999404', true); INSERT INTO system_patch (system_id, rh_account_id, last_evaluation, third_party) VALUES (18, 1, '2018-09-22 12:00:00-04', true); From d3cf89120978be0602d3e0ec5299dda4b8270d4f Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 17:30:48 +0100 Subject: [PATCH 18/27] RHINENG-21214: fix TestTableSizes system_patch table with 16 partitions has been added --- tasks/vmaas_sync/metrics_db_test.go | 7 ++++--- 1 file changed, 4 insertions(+), 3 deletions(-) diff --git a/tasks/vmaas_sync/metrics_db_test.go b/tasks/vmaas_sync/metrics_db_test.go index 8383a69fd..e8769c06d 100644 --- a/tasks/vmaas_sync/metrics_db_test.go +++ b/tasks/vmaas_sync/metrics_db_test.go @@ -17,9 +17,10 @@ func TestTableSizes(t *testing.T) { for _, item := range tableSizes { uniqueTables[item.Key] = true } - assert.Equal(t, 214, len(tableSizes)) - assert.Equal(t, 214, len(uniqueTables)) - assert.True(t, uniqueTables["public.system_platform"]) // check whether table names were loaded + assert.Equal(t, 231, len(tableSizes)) + assert.Equal(t, 231, len(uniqueTables)) + assert.True(t, uniqueTables["public.system_inventory"]) // check whether table names were loaded + assert.True(t, uniqueTables["public.system_patch"]) // check whether table names were loaded assert.True(t, uniqueTables["public.package"]) assert.True(t, uniqueTables["public.repo"]) assert.True(t, uniqueTables["inventory.hosts_v1_0"]) From a2f3daa7dc8aa2f7fa197e89c5d62214b0c29f00 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 17:52:08 +0100 Subject: [PATCH 19/27] fixup! RHINENG-21214: load data into the new tables --- database_admin/migrations/142_split_system_platform.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database_admin/migrations/142_split_system_platform.up.sql b/database_admin/migrations/142_split_system_platform.up.sql index 9b95412d0..32faccd28 100644 --- a/database_admin/migrations/142_split_system_platform.up.sql +++ b/database_admin/migrations/142_split_system_platform.up.sql @@ -536,7 +536,7 @@ WHERE sp.stale = false; ALTER TABLE IF EXISTS system_patch ADD PRIMARY KEY (rh_account_id, system_id), ADD FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), -ADD FOREIGN KEY (system_id, rh_account_id) REFERENCES system_inventory (id, rh_account_id); +ADD FOREIGN KEY (rh_account_id, system_id) REFERENCES system_inventory (rh_account_id, id); From 26bdb4659f07570f95db736347f0d0bc2eb940c2 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 17:53:13 +0100 Subject: [PATCH 20/27] fixup! RHINENG-21214: update create_schema.sql --- database_admin/schema/create_schema.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index 22bc401ff..ad5b4fc0b 100644 --- a/database_admin/schema/create_schema.sql +++ b/database_admin/schema/create_schema.sql @@ -1045,7 +1045,7 @@ CREATE TABLE IF NOT EXISTS system_patch template_id BIGINT, PRIMARY KEY (rh_account_id, system_id), FOREIGN KEY (rh_account_id, template_id) REFERENCES template (rh_account_id, id), - FOREIGN KEY (system_id, rh_account_id) REFERENCES system_inventory (id, rh_account_id) + FOREIGN KEY (rh_account_id, system_id) REFERENCES system_inventory (rh_account_id, id) ) PARTITION BY HASH (rh_account_id); SELECT create_table_partitions('system_patch', 16, From d231db07bf7e8ee9ff9244f7608ebe714abe15af Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 21 Jan 2026 23:17:51 +0100 Subject: [PATCH 21/27] fixup! RHINENG-21214: add models for the new tables --- base/models/models.go | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/base/models/models.go b/base/models/models.go index 7ce72d9cd..222b4c97b 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -119,9 +119,9 @@ type SystemInventory struct { Tags []byte `gorm:"column:tags"` Created time.Time Workspaces pq.StringArray `gorm:"type:text[]"` - StaleTimestamp time.Time - StaleWarningTimestamp time.Time - CulledTimestamp time.Time + StaleTimestamp *time.Time + StaleWarningTimestamp *time.Time + CulledTimestamp *time.Time OSName *string OSMajor *int16 OSMinor *int16 From eb0fe486536b4a33acab3e98bb6bc34b27fe38fc Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 10:15:08 +0100 Subject: [PATCH 22/27] wip: replace save into system_platform with system_{inventory,patch} --- listener/upload.go | 55 ++++++++++++++++++++++++++++++++++++++++++---- 1 file changed, 51 insertions(+), 4 deletions(-) diff --git a/listener/upload.go b/listener/upload.go index 575bc4894..f237e1868 100644 --- a/listener/upload.go +++ b/listener/upload.go @@ -19,6 +19,7 @@ import ( "net/http" "net/url" "regexp" + "slices" "strings" "sync" "time" @@ -469,6 +470,7 @@ func updateSystemPlatform(tx *gorm.DB, accountID int, host *Host, return &systemPlatform, nil } +// nolint: funlen func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsToUpdate []string) error { if err := tx.Where("rh_account_id = ? AND inventory_id = ?", system.RhAccountID, system.InventoryID). Select("id").Find(system).Error; err != nil { @@ -479,7 +481,7 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo tx = tx.Clauses(clause.Returning{ Columns: []clause.Column{ {Name: "id"}, {Name: "inventory_id"}, {Name: "rh_account_id"}, - {Name: "unchanged_since"}, {Name: "last_evaluation"}, + {Name: "unchanged_since"}, }, }) @@ -488,9 +490,54 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo err := tx.Select(colsToUpdate).Updates(system).Error return base.WrapFatalDBError(err, "unable to update system_platform") } - // insert system - err := database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "inventory_id"}, colsToUpdate...). - Save(system).Error + inventoryRecord := models.SystemInventory{ + ID: system.ID, + InventoryID: system.InventoryID, + RhAccountID: system.RhAccountID, + DisplayName: system.DisplayName, + LastUpload: system.LastUpload, + SatelliteManaged: system.SatelliteManaged, + BuiltPkgcache: system.BuiltPkgcache, + Arch: system.Arch, + Bootc: system.Bootc, + VmaasJSON: system.VmaasJSON, + JSONChecksum: system.JSONChecksum, + ReporterID: system.ReporterID, + YumUpdates: system.YumUpdates, + YumChecksum: system.YumChecksum, + StaleTimestamp: system.StaleTimestamp, + StaleWarningTimestamp: system.StaleWarningTimestamp, + CulledTimestamp: system.CulledTimestamp, + Tags: []byte("[]"), + } + inventoryColsToUpdate := slices.DeleteFunc(colsToUpdate, func(col string) bool { + return col == "template_id" + }) + err := database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "inventory_id"}, inventoryColsToUpdate...). + Save(&inventoryRecord).Error + if err != nil { + return base.WrapFatalDBError(err, "unable to insert to system_inventory") + } + + system.ID = inventoryRecord.ID + system.InventoryID = inventoryRecord.InventoryID + system.RhAccountID = inventoryRecord.RhAccountID + system.UnchangedSince = inventoryRecord.UnchangedSince + + var patchColsToUpdate []string + if slices.Contains(colsToUpdate, "template_id") { + patchColsToUpdate = []string{"template_id"} + } + patchRecord := models.SystemPatch{ + SystemID: inventoryRecord.ID, + RhAccountID: system.RhAccountID, + LastEvaluation: system.LastEvaluation, + TemplateID: system.TemplateID, + } + tx = tx.Clauses(clause.Returning{Columns: []clause.Column{{Name: "last_evaluation"}}}) + err = database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "system_id"}, patchColsToUpdate...). + Save(patchRecord).Error + system.LastEvaluation = patchRecord.LastEvaluation return base.WrapFatalDBError(err, "unable to insert to system_platform") } From 3250fc1861e5f0561d0f6b05339df4687b02af38 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 10:55:05 +0100 Subject: [PATCH 23/27] fixup! RHINENG-21214: add models for the new tables --- base/models/models.go | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/base/models/models.go b/base/models/models.go index 222b4c97b..c49952004 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -165,6 +165,10 @@ type SystemPatch struct { TemplateID *int64 `gorm:"column:template_id"` } +func (SystemPatch) TableName() string { + return "system_patch" +} + type String struct { ID []byte `gorm:"primaryKey"` Value string From d2d03c13f2d31894ba4870d48aed2ca196d9cccf Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 10:59:15 +0100 Subject: [PATCH 24/27] fixup! wip: replace save into system_platform with system_{inventory,patch} --- listener/upload.go | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/listener/upload.go b/listener/upload.go index f237e1868..e1e567326 100644 --- a/listener/upload.go +++ b/listener/upload.go @@ -478,7 +478,7 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo } // return system_platform record after update - tx = tx.Clauses(clause.Returning{ + txi := tx.Clauses(clause.Returning{ Columns: []clause.Column{ {Name: "id"}, {Name: "inventory_id"}, {Name: "rh_account_id"}, {Name: "unchanged_since"}, @@ -487,7 +487,7 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo if system.ID != 0 { // update system - err := tx.Select(colsToUpdate).Updates(system).Error + err := txi.Select(colsToUpdate).Updates(system).Error return base.WrapFatalDBError(err, "unable to update system_platform") } inventoryRecord := models.SystemInventory{ @@ -513,7 +513,7 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo inventoryColsToUpdate := slices.DeleteFunc(colsToUpdate, func(col string) bool { return col == "template_id" }) - err := database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "inventory_id"}, inventoryColsToUpdate...). + err := database.OnConflictUpdateMulti(txi, []string{"rh_account_id", "inventory_id"}, inventoryColsToUpdate...). Save(&inventoryRecord).Error if err != nil { return base.WrapFatalDBError(err, "unable to insert to system_inventory") @@ -534,9 +534,9 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo LastEvaluation: system.LastEvaluation, TemplateID: system.TemplateID, } - tx = tx.Clauses(clause.Returning{Columns: []clause.Column{{Name: "last_evaluation"}}}) - err = database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "system_id"}, patchColsToUpdate...). - Save(patchRecord).Error + txp := tx.Clauses(clause.Returning{Columns: []clause.Column{{Name: "last_evaluation"}}}) + err = database.OnConflictUpdateMulti(txp, []string{"rh_account_id", "system_id"}, patchColsToUpdate...). + Create(&patchRecord).Error system.LastEvaluation = patchRecord.LastEvaluation return base.WrapFatalDBError(err, "unable to insert to system_platform") } From fc19cca7b3f9196751ce81f8c0442ad0b5d85bcb Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 13:34:07 +0100 Subject: [PATCH 25/27] RHINENG-21214: DoNothing the there are no clumns to update --- base/database/database.go | 11 +++++++---- 1 file changed, 7 insertions(+), 4 deletions(-) diff --git a/base/database/database.go b/base/database/database.go index ffecf5bbb..338da4649 100644 --- a/base/database/database.go +++ b/base/database/database.go @@ -16,10 +16,13 @@ func OnConflictUpdateMulti(db *gorm.DB, keys []string, updateCols ...string) *go for _, key := range keys { confilctColumns = append(confilctColumns, clause.Column{Name: key}) } - return db.Clauses(clause.OnConflict{ - Columns: confilctColumns, - DoUpdates: clause.AssignmentColumns(updateCols), - }) + onConflict := clause.OnConflict{Columns: confilctColumns} + if len(updateCols) > 0 { + onConflict.DoUpdates = clause.AssignmentColumns(updateCols) + } else { + onConflict.DoNothing = true + } + return db.Clauses(onConflict) } type UpExpr struct { From 943ebe78b04900ea2393073cbeeecd0508ac0506 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 15:10:20 +0100 Subject: [PATCH 26/27] fixup! wip: replace save into system_platform with system_{inventory,patch} --- listener/upload.go | 27 +++++++++++++++------------ 1 file changed, 15 insertions(+), 12 deletions(-) diff --git a/listener/upload.go b/listener/upload.go index e1e567326..c6b7555b7 100644 --- a/listener/upload.go +++ b/listener/upload.go @@ -485,11 +485,13 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo }, }) - if system.ID != 0 { - // update system - err := txi.Select(colsToUpdate).Updates(system).Error - return base.WrapFatalDBError(err, "unable to update system_platform") - } + /* + if system.ID != 0 { + // update system + err := txi.Select(colsToUpdate).Updates(system).Error + return base.WrapFatalDBError(err, "unable to update system_platform") + } + */ inventoryRecord := models.SystemInventory{ ID: system.ID, InventoryID: system.InventoryID, @@ -514,7 +516,7 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo return col == "template_id" }) err := database.OnConflictUpdateMulti(txi, []string{"rh_account_id", "inventory_id"}, inventoryColsToUpdate...). - Save(&inventoryRecord).Error + Create(&inventoryRecord).Error if err != nil { return base.WrapFatalDBError(err, "unable to insert to system_inventory") } @@ -524,15 +526,16 @@ func storeOrUpdateSysPlatform(tx *gorm.DB, system *models.SystemPlatform, colsTo system.RhAccountID = inventoryRecord.RhAccountID system.UnchangedSince = inventoryRecord.UnchangedSince - var patchColsToUpdate []string + // var patchColsToUpdate = []string{"last_evaluation"} + var patchColsToUpdate = []string{} if slices.Contains(colsToUpdate, "template_id") { - patchColsToUpdate = []string{"template_id"} + patchColsToUpdate = append(patchColsToUpdate, "template_id") } patchRecord := models.SystemPatch{ - SystemID: inventoryRecord.ID, - RhAccountID: system.RhAccountID, - LastEvaluation: system.LastEvaluation, - TemplateID: system.TemplateID, + SystemID: inventoryRecord.ID, + RhAccountID: system.RhAccountID, + // LastEvaluation: system.LastEvaluation, + TemplateID: system.TemplateID, } txp := tx.Clauses(clause.Returning{Columns: []clause.Column{{Name: "last_evaluation"}}}) err = database.OnConflictUpdateMulti(txp, []string{"rh_account_id", "system_id"}, patchColsToUpdate...). From c56c378be2d6203bfeafd11799286f5461f1a9d4 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 22 Jan 2026 15:10:42 +0100 Subject: [PATCH 27/27] wip: save evaluated data --- evaluator/evaluate.go | 28 +++++++++++++++++++++++++++- listener/upload_test.go | 2 +- 2 files changed, 28 insertions(+), 2 deletions(-) diff --git a/evaluator/evaluate.go b/evaluator/evaluate.go index 9c36c7f49..c457ea469 100644 --- a/evaluator/evaluate.go +++ b/evaluator/evaluate.go @@ -608,7 +608,33 @@ func updateSystemPlatform(tx *gorm.DB, system *models.SystemPlatform, data["third_party"] = system.ThirdParty } - err := tx.Model(system).Updates(data).Error + systemPatch := models.SystemPatch{ + SystemID: system.ID, + RhAccountID: system.RhAccountID, + } + // err := tx.Model(system).Updates(data).Error + err := tx.Model(&systemPatch).Updates(data).Error + if enableAdvisoryAnalysis { + system.InstallableAdvisoryCountCache = systemPatch.InstallableAdvisoryCountCache + system.InstallableAdvisoryEnhCountCache = systemPatch.InstallableAdvisoryEnhCountCache + system.InstallableAdvisoryBugCountCache = systemPatch.InstallableAdvisoryBugCountCache + system.InstallableAdvisorySecCountCache = systemPatch.InstallableAdvisorySecCountCache + + system.ApplicableAdvisoryCountCache = systemPatch.ApplicableAdvisoryCountCache + system.ApplicableAdvisoryEnhCountCache = systemPatch.ApplicableAdvisoryEnhCountCache + system.ApplicableAdvisoryBugCountCache = systemPatch.ApplicableAdvisoryBugCountCache + system.ApplicableAdvisorySecCountCache = systemPatch.ApplicableAdvisorySecCountCache + } + + if enablePackageAnalysis { + system.PackagesInstalled = systemPatch.PackagesInstalled + system.PackagesInstallable = systemPatch.PackagesInstallable + system.PackagesApplicable = systemPatch.PackagesApplicable + } + + if enableRepoAnalysis { + system.ThirdParty = systemPatch.ThirdParty + } now := time.Now() if system.LastUpload != nil && system.LastUpload.Sub(now) > time.Hour { diff --git a/listener/upload_test.go b/listener/upload_test.go index 8b9194923..1aff9ed9d 100644 --- a/listener/upload_test.go +++ b/listener/upload_test.go @@ -400,7 +400,7 @@ func TestStoreOrUpdateSysPlatform(t *testing.T) { // make sure we are not creating gaps in id sequences database.DB.Model(&models.SystemPlatform{}).Select("count(*)").Find(&newCount) - database.DB.Raw("select currval('system_platform_id_seq')").Find(&currval) + database.DB.Raw("select currval('system_inventory_id_seq')").Find(&currval) countInc := newCount - oldCount maxInc := currval - nextval assert.Equal(t, countInc, maxInc)