From d58b31b6ad3538ea17ba87cc30ac72e120c3c03a Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Fri, 22 Sep 2023 11:58:11 +0200 Subject: [PATCH 01/15] RHINENG-2281: new tables for package data --- .../119_package_data_tables.down.sql | 20 ++++++ .../migrations/119_package_data_tables.up.sql | 64 +++++++++++++++++++ database_admin/schema/create_schema.sql | 41 +++++++++++- tasks/vmaas_sync/metrics_db_test.go | 4 +- 4 files changed, 125 insertions(+), 4 deletions(-) create mode 100644 database_admin/migrations/119_package_data_tables.down.sql create mode 100644 database_admin/migrations/119_package_data_tables.up.sql diff --git a/database_admin/migrations/119_package_data_tables.down.sql b/database_admin/migrations/119_package_data_tables.down.sql new file mode 100644 index 000000000..a629880e7 --- /dev/null +++ b/database_admin/migrations/119_package_data_tables.down.sql @@ -0,0 +1,20 @@ +DROP TABLE IF EXISTS system_package_data; +DROP TABLE IF EXISTS package_system_data; + +CREATE OR REPLACE FUNCTION update_status(update_data jsonb) + RETURNS TEXT as +$$ +DECLARE + len int; +BEGIN + len = jsonb_array_length(update_data); + IF len IS NULL or len = 0 THEN + RETURN 'None'; + END IF; + len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status == "Installable")')); + IF len > 0 THEN + RETURN 'Installable'; + END IF; + RETURN 'Applicable'; +END; +$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE; diff --git a/database_admin/migrations/119_package_data_tables.up.sql b/database_admin/migrations/119_package_data_tables.up.sql new file mode 100644 index 000000000..33b6f2954 --- /dev/null +++ b/database_admin/migrations/119_package_data_tables.up.sql @@ -0,0 +1,64 @@ +CREATE TABLE IF NOT EXISTS system_package_data +( + rh_account_id INT NOT NULL, + system_id BIGINT NOT NULL, + update_data JSONB DEFAULT NULL, + + PRIMARY KEY (rh_account_id, system_id), + FOREIGN KEY (rh_account_id, system_id) REFERENCES system_platform (rh_account_id, id) +) PARTITION BY HASH (rh_account_id); + +GRANT SELECT, INSERT, UPDATE, DELETE ON system_package_data TO evaluator; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO listener; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO manager; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO vmaas_sync; + +SELECT create_table_partitions('system_package_data', 32, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$); + +CREATE TABLE IF NOT EXISTS package_system_data +( + rh_account_id INT NOT NULL, + package_name_id BIGINT NOT NULL, + update_data JSONB DEFAULT NULL, + + PRIMARY KEY (rh_account_id, package_name_id), + FOREIGN KEY (rh_account_id) REFERENCES rh_account (id) +) PARTITION BY HASH (rh_account_id); + +GRANT SELECT, INSERT, UPDATE, DELETE ON package_system_data TO evaluator; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO listener; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO manager; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO vmaas_sync; + +SELECT create_table_partitions('package_system_data', 32, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$); + +GRANT SELECT ON ALL TABLES IN SCHEMA public TO evaluator; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO evaluator; + +GRANT SELECT ON ALL TABLES IN SCHEMA public TO listener; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO listener; + +GRANT SELECT ON ALL TABLES IN SCHEMA public TO manager; + +GRANT SELECT ON ALL TABLES IN SCHEMA public TO vmaas_sync; +GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO vmaas_sync; + +CREATE OR REPLACE FUNCTION update_status(update_data jsonb) + RETURNS TEXT as +$$ +DECLARE + len int; +BEGIN + len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status != "Installed")')); + IF len IS NULL or len = 0 THEN + RETURN 'None'; + END IF; + len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status == "Installable")')); + IF len > 0 THEN + RETURN 'Installable'; + END IF; + RETURN 'Applicable'; +END; +$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE; diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index ea22af09c..dc2139c48 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 (118, false); +VALUES (119, false); -- --------------------------------------------------------------------------- -- Functions @@ -616,7 +616,7 @@ $$ DECLARE len int; BEGIN - len = jsonb_array_length(update_data); + len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status != "Installed")')); IF len IS NULL or len = 0 THEN RETURN 'None'; END IF; @@ -1066,6 +1066,43 @@ GRANT SELECT, UPDATE, DELETE ON system_package2 TO vmaas_sync; SELECT create_table_partitions('system_package2', 128, $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$); + +CREATE TABLE IF NOT EXISTS system_package_data +( + rh_account_id INT NOT NULL, + system_id BIGINT NOT NULL, + update_data JSONB DEFAULT NULL, + + PRIMARY KEY (rh_account_id, system_id), + FOREIGN KEY (rh_account_id, system_id) REFERENCES system_platform (rh_account_id, id) +) PARTITION BY HASH (rh_account_id); + +GRANT SELECT, INSERT, UPDATE, DELETE ON system_package_data TO evaluator; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO listener; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO manager; +GRANT SELECT, UPDATE, DELETE ON system_package_data TO vmaas_sync; + +SELECT create_table_partitions('system_package_data', 32, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$); + +CREATE TABLE IF NOT EXISTS package_system_data +( + rh_account_id INT NOT NULL, + package_name_id BIGINT NOT NULL, + update_data JSONB DEFAULT NULL, + + PRIMARY KEY (rh_account_id, package_name_id), + FOREIGN KEY (rh_account_id) REFERENCES rh_account (id) +) PARTITION BY HASH (rh_account_id); + +GRANT SELECT, INSERT, UPDATE, DELETE ON package_system_data TO evaluator; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO listener; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO manager; +GRANT SELECT, UPDATE, DELETE ON package_system_data TO vmaas_sync; + +SELECT create_table_partitions('package_system_data', 32, + $$WITH (fillfactor = '70', autovacuum_vacuum_scale_factor = '0.05')$$); + -- package_account_data CREATE TABLE IF NOT EXISTS package_account_data ( diff --git a/tasks/vmaas_sync/metrics_db_test.go b/tasks/vmaas_sync/metrics_db_test.go index 633adc14d..b1028f960 100644 --- a/tasks/vmaas_sync/metrics_db_test.go +++ b/tasks/vmaas_sync/metrics_db_test.go @@ -17,8 +17,8 @@ func TestTableSizes(t *testing.T) { for _, item := range tableSizes { uniqueTables[item.Key] = true } - assert.Equal(t, 342, len(tableSizes)) - assert.Equal(t, 342, len(uniqueTables)) + assert.Equal(t, 408, len(tableSizes)) + assert.Equal(t, 408, len(uniqueTables)) assert.True(t, uniqueTables["system_platform"]) // check whether table names were loaded assert.True(t, uniqueTables["package"]) assert.True(t, uniqueTables["repo"]) From 50caa2d6680daa4111c20cc2fb613d06e654d4c2 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Fri, 22 Sep 2023 15:35:06 +0200 Subject: [PATCH 02/15] RHINENG-2281: migrate data into {system_package,package_system}_data tables --- ..._package_data_tables_data_migration.up.sql | 53 +++++++++++++++++++ database_admin/schema/create_schema.sql | 2 +- 2 files changed, 54 insertions(+), 1 deletion(-) create mode 100644 database_admin/migrations/120_package_data_tables_data_migration.up.sql diff --git a/database_admin/migrations/120_package_data_tables_data_migration.up.sql b/database_admin/migrations/120_package_data_tables_data_migration.up.sql new file mode 100644 index 000000000..44b15ea87 --- /dev/null +++ b/database_admin/migrations/120_package_data_tables_data_migration.up.sql @@ -0,0 +1,53 @@ +DO $$ + DECLARE + rownum INT; + total INT; + account_id INT; + sys_id BIGINT; + update_list TEXT[] := NULL; + json TEXT := ''; + pkgname_id BIGINT; + BEGIN + -- order accounts so that we read from system_package by partitions + FOR rownum, total, account_id IN + SELECT row_number() over (), count(*) over (), id FROM + ( SELECT id FROM rh_account order by hash_partition_id(id, 128), id) as o + LOOP + RAISE NOTICE 'Migrating account % (%/%)', account_id, rownum, total; + FOR sys_id, update_list IN + SELECT system_id, + array_agg(CONCAT('"', package_id, '":[', '{"evra":"' || i.evra || '","status":"Installable"}', + CASE WHEN i.evra IS NOT NULL AND a.evra IS NOT NULL THEN ',' ELSE '' END, + '{"evra":"' || a.evra || '","status":"Applicable"}', ']')) as update_list + FROM system_package2 sp + LEFT JOIN package i ON sp.installable_id = i.id + LEFT JOIN package a ON sp.applicable_id = a.id + WHERE sp.rh_account_id = account_id + GROUP BY system_id + LOOP + json := '{' || array_to_string(update_list, ',') || '}'; + -- RAISE NOTICE 'system_package_data (%, %, %)', account_id, sys_id, json; + INSERT INTO system_package_data VALUES (account_id, sys_id, json::jsonb); + END LOOP; + + FOR pkgname_id, update_list IN + SELECT sp.name_id, + array_agg(CONCAT('"', sp.system_id, '":[{"evra":"', p.evra,'", "status": "Installed"}', + ',{"evra":"' || i.evra || '","status":"Installable"}', + ',{"evra":"' || a.evra || '","status":"Applicable"}', ']')) as update_list + FROM system_package2 sp + JOIN package p ON p.id = sp.package_id + LEFT JOIN package i ON sp.installable_id = i.id + LEFT JOIN package a ON sp.applicable_id = a.id + WHERE sp.rh_account_id = account_id + GROUP BY sp.name_id + LOOP + json := '{' || array_to_string(update_list, ',') || '}'; + -- RAISE NOTICE 'package_system_data (%, %, %)', account_id, pkgname_id, json; + INSERT INTO package_system_data VALUES (account_id, pkgname_id, json::jsonb); + END LOOP; + END LOOP; + END; +$$ +; + diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index dc2139c48..dec0a978b 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 (119, false); +VALUES (120, false); -- --------------------------------------------------------------------------- -- Functions From b14a405d100cb4b5a361175e90ba944b153798ae Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Tue, 26 Sep 2023 14:19:31 +0200 Subject: [PATCH 03/15] RHINENG-2282: use system_package_data in /system/packages API --- base/database/utils.go | 12 ++++++++++++ manager/controllers/system_packages.go | 4 +--- 2 files changed, 13 insertions(+), 3 deletions(-) diff --git a/base/database/utils.go b/base/database/utils.go index 9708afcaa..022b73265 100644 --- a/base/database/utils.go +++ b/base/database/utils.go @@ -38,6 +38,18 @@ func SystemPackages(tx *gorm.DB, accountID int, groups map[string]string) *gorm. Joins("JOIN package_name pn on pn.id = spkg.name_id") } +func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { + return Systems(tx, accountID, groups). + Joins(`JOIN (SELECT system_id, + jsonb_object_keys(update_data)::bigint as package_id, + jsonb_path_query(update_data, '$.*') as update_data + FROM system_package_data + WHERE rh_account_id = ?) as spkg + ON spkg.system_id = sp.id`, accountID). + Joins("JOIN package p on p.id = spkg.package_id"). + Joins("JOIN package_name pn on pn.id = p.name_id") +} + func Packages(tx *gorm.DB) *gorm.DB { return tx.Table("package p"). Joins("JOIN package_name pn on p.name_id = pn.id"). diff --git a/manager/controllers/system_packages.go b/manager/controllers/system_packages.go index fcd9bc456..d427a62dc 100644 --- a/manager/controllers/system_packages.go +++ b/manager/controllers/system_packages.go @@ -74,9 +74,7 @@ type SystemPackageDBLoad struct { } func systemPackageQuery(db *gorm.DB, account int, groups map[string]string, inventoryID string) *gorm.DB { - query := database.SystemPackages(db, account, groups). - Joins("LEFT JOIN package pi ON pi.id = spkg.installable_id"). - Joins("LEFT JOIN package pa ON pa.id = spkg.applicable_id"). + query := database.SystemPackageData(db, account, groups). Joins("LEFT JOIN strings AS descr ON p.description_hash = descr.id"). Joins("LEFT JOIN strings AS sum ON p.summary_hash = sum.id"). Select(SystemPackagesSelect). From b8dbc9ff3c76900feba8ff57d187a2e3493b7571 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Wed, 27 Sep 2023 14:51:16 +0200 Subject: [PATCH 04/15] RHINENG-2282: update test data --- dev/test_data.sql | 13 +++++++++++++ 1 file changed, 13 insertions(+) diff --git a/dev/test_data.sql b/dev/test_data.sql index 16d39deaf..6ff47a847 100644 --- a/dev/test_data.sql +++ b/dev/test_data.sql @@ -240,3 +240,16 @@ ALTER TABLE repo ALTER COLUMN id RESTART WITH 100; ALTER TABLE package ALTER COLUMN id RESTART WITH 100; ALTER TABLE package_name ALTER COLUMN id RESTART WITH 150; ALTER TABLE baseline ALTER COLUMN id RESTART WITH 100; + +truncate table system_package_data; +INSERT INTO system_package_data (rh_account_id, system_id, update_data) VALUES +(3, 12, '{"1": [{"evra": "5.10.13-200.fc31.x86_64", "status": "Installable"}], "2": [{"evra": "1:76.0.1-1.fc31.x86_64", "status": "Installable"}]}'), +(3, 13, '{"1": [], "2": [{"evra": "76.0.1-2.fc31.x86_64", "status": "Installable"}, {"evra": "77.0.1-1.fc31.x86_64", "status": "Applicable"}], "3": [], "4": []}'), +(3, 16, '{"1": [{"evra": "5.10.13-201.fc31.x86_64", "status": "Installable"}, {"evra": "5.10.13-201.fc31.x86_64", "status": "Applicable"}]}'); + +truncate table package_system_data; +INSERT INTO package_system_data (rh_account_id, package_name_id, update_data) VALUES +(3, 101, '{"12": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}, {"evra": "5.10.13-200.fc31.x86_64", "status": "Installable"}], "13": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}], "16": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}, {"evra": "5.10.13-201.fc31.x86_64", "status": "Installable"}]}'), +(3, 102, '{"12": [{"evra": "76.0.1-1.fc31.x86_64", "status": "Installed"}, {"evra": "1:76.0.1-1.fc31.x86_64", "status": "Installable"}], "13": [{"evra": "76.0.1-1.fc31.x86_64", "status": "Installed"}, {"evra": "76.0.1-2.fc31.x86_64", "status": "Installable"}, {"evra": "77.0.1-1.fc31.x86_64", "status": "Applicable"}]}'), +(3, 103, '{"13": [{"evra": "4.4.19-8.el8_0.x86_64", "status": "Installed"}]}'), +(3, 104, '{"13": [{"evra": "7.61.1-8.el8.x86_64", "status": "Installed"}]}'); From 8dfe27099433f695ea3c2d024c2eaf0d30e7214c Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Mon, 2 Oct 2023 15:59:39 +0200 Subject: [PATCH 05/15] RHINENG-2283: use package_system_data in /package/systems API --- base/database/utils.go | 11 +++++ manager/controllers/package_systems.go | 43 ++++++++----------- manager/controllers/package_systems_export.go | 8 ++-- 3 files changed, 34 insertions(+), 28 deletions(-) diff --git a/base/database/utils.go b/base/database/utils.go index 022b73265..aa17711e6 100644 --- a/base/database/utils.go +++ b/base/database/utils.go @@ -50,6 +50,17 @@ func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *go Joins("JOIN package_name pn on pn.id = p.name_id") } +func PackageSystemData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { + return Systems(tx, accountID, groups). + Joins(`JOIN (SELECT package_name_id as name_id, + jsonb_object_keys(update_data)::bigint as system_id, + jsonb_path_query(update_data, '$.*') as update_data + FROM package_system_data + WHERE rh_account_id = ?) as spkg + ON spkg.system_id = sp.id`, accountID). + Joins("JOIN package_name pn on pn.id = spkg.name_id") +} + func Packages(tx *gorm.DB) *gorm.DB { return tx.Table("package p"). Joins("JOIN package_name pn on p.name_id = pn.id"). diff --git a/manager/controllers/package_systems.go b/manager/controllers/package_systems.go index 4810ac14e..24a4acc8f 100644 --- a/manager/controllers/package_systems.go +++ b/manager/controllers/package_systems.go @@ -26,14 +26,11 @@ var PackageSystemsOpts = ListOpts{ type PackageSystemItemCommon struct { SystemIDAttribute SystemDisplayName - InstalledEVRA string `json:"installed_evra" csv:"installed_evra" query:"p.evra" gorm:"column:installed_evra"` - AvailableEVRA string `json:"available_evra" csv:"available_evra" query:"null" gorm:"-"` - Updatable bool `json:"updatable" csv:"updatable" query:"(spkg.installable_id IS NOT NULL)" gorm:"column:updatable"` + InstalledEVRA string `json:"installed_evra" csv:"installed_evra" query:"jsonb_path_query_array(update_data, '$ ? (@.status == \"Installed\")')->0->>'evra'" gorm:"column:installed_evra"` + AvailableEVRA string `json:"available_evra" csv:"available_evra" query:"jsonb_path_query_array(update_data, '$ ? (@.status != \"Installed\")')-> -1 ->>'evra'" gorm:"column:available_evra"` + Updatable bool `json:"updatable" csv:"updatable" query:"(update_status(spkg.update_data) = 'Installable')" gorm:"column:updatable"` Tags SystemTagsList `json:"tags" csv:"tags" query:"null" gorm:"-"` BaselineAttributes - // helper to get AvailableEVRA (latest_evra) - InstallableEVRA string `json:"-" csv:"-" query:"pi.evra" gorm:"column:installable_evra"` - ApplicableEVRA string `json:"-" csv:"-" query:"pa.evra" gorm:"column:applicable_evra"` } type PackageSystemItemV2 struct { @@ -68,29 +65,31 @@ type PackageSystemsResponseV3 struct { Meta ListMeta `json:"meta"` } -func packagesByNameQuery(db *gorm.DB, pkgName string) *gorm.DB { - return db.Table("package p"). +func packagesByNameExist(db *gorm.DB, pkgName string) (int64, error) { + var exist int64 + err := db.Table("package p"). Joins("INNER JOIN package_name pn ON p.name_id = pn.id"). - Where("pn.name = ?", pkgName) + Where("pn.name = ?", pkgName). + Limit(1). + Pluck("pn.id", &exist).Error + + return exist, err } -func packageSystemsQuery(db *gorm.DB, acc int, groups map[string]string, packageName string, packageIDs []int, +func packageSystemsQuery(db *gorm.DB, acc int, groups map[string]string, packageName string, ) *gorm.DB { - query := database.SystemPackages(db, acc, groups). + query := database.PackageSystemData(db, acc, groups). Select(PackageSystemsSelect). - Joins("LEFT JOIN package pi ON pi.id = spkg.installable_id"). - Joins("LEFT JOIN package pa ON pa.id = spkg.applicable_id"). Joins("LEFT JOIN baseline bl ON sp.baseline_id = bl.id AND sp.rh_account_id = bl.rh_account_id"). Where("sp.stale = false"). - Where("pn.name = ?", packageName). - Where("spkg.package_id in (?)", packageIDs) + Where("pn.name = ?", packageName) + return query } func packageSystemsCommon(db *gorm.DB, c *gin.Context) (*gorm.DB, *ListMeta, []string, error) { account := c.GetInt(utils.KeyAccount) groups := c.GetStringMapString(utils.KeyInventoryGroups) - var filters map[string]FilterData packageName := c.Param("package_name") if packageName == "" { @@ -98,18 +97,18 @@ func packageSystemsCommon(db *gorm.DB, c *gin.Context) (*gorm.DB, *ListMeta, []s return nil, nil, nil, errors.New("package_name param not found") } - var packageIDs []int - if err := packagesByNameQuery(db, packageName).Pluck("p.id", &packageIDs).Error; err != nil { + exist, err := packagesByNameExist(db, packageName) + if err != nil { LogAndRespError(c, err, "database error") return nil, nil, nil, err } - if len(packageIDs) == 0 { + if exist == 0 { LogAndRespNotFound(c, errors.New("not found"), "package not found") return nil, nil, nil, errors.New("package not found") } - query := packageSystemsQuery(db, account, groups, packageName, packageIDs) + query := packageSystemsQuery(db, account, groups, packageName) filters, err := ParseAllFilters(c, PackageSystemsOpts) if err != nil { return nil, nil, nil, err @@ -250,10 +249,6 @@ func packageSystemDBLookups2PackageSystemItemsV3(systems []PackageSystemDBLookup utils.LogDebug("err", err.Error(), "inventory_id", systems[i].ID, "system groups parsing failed") } data[i] = systems[i].PackageSystemItemV3 - data[i].AvailableEVRA = data[i].InstallableEVRA - if len(data[i].ApplicableEVRA) > 0 { - data[i].AvailableEVRA = data[i].ApplicableEVRA - } } return data, total } diff --git a/manager/controllers/package_systems_export.go b/manager/controllers/package_systems_export.go index bb7718727..53c716bf8 100644 --- a/manager/controllers/package_systems_export.go +++ b/manager/controllers/package_systems_export.go @@ -42,18 +42,18 @@ func PackageSystemsExportHandler(c *gin.Context) { } db := middlewares.DBFromContext(c) - var packageIDs []int - if err := packagesByNameQuery(db, packageName).Pluck("p.id", &packageIDs).Error; err != nil { + exist, err := packagesByNameExist(db, packageName) + if err != nil { LogAndRespError(c, err, "database error") return } - if len(packageIDs) == 0 { + if exist == 0 { LogAndRespNotFound(c, errors.New("not found"), "package not found") return } - query := packageSystemsQuery(db, account, groups, packageName, packageIDs) + query := packageSystemsQuery(db, account, groups, packageName) filters, err := ParseAllFilters(c, PackageSystemsOpts) if err != nil { return From 4929dcbe5a2b6674b9fb90a2ffd8c63f890ef3f2 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Tue, 3 Oct 2023 16:09:21 +0200 Subject: [PATCH 06/15] RHINENG-2281: transform json from list to map so we can easily access installed/installable/applicable packages --- ..._package_data_tables_data_migration.up.sql | 150 +++++++++++++++++- database_admin/schema/create_schema.sql | 48 +++--- dev/test_data.sql | 14 +- 3 files changed, 182 insertions(+), 30 deletions(-) diff --git a/database_admin/migrations/120_package_data_tables_data_migration.up.sql b/database_admin/migrations/120_package_data_tables_data_migration.up.sql index 44b15ea87..00eba5e19 100644 --- a/database_admin/migrations/120_package_data_tables_data_migration.up.sql +++ b/database_admin/migrations/120_package_data_tables_data_migration.up.sql @@ -16,9 +16,9 @@ DO $$ RAISE NOTICE 'Migrating account % (%/%)', account_id, rownum, total; FOR sys_id, update_list IN SELECT system_id, - array_agg(CONCAT('"', package_id, '":[', '{"evra":"' || i.evra || '","status":"Installable"}', + array_agg(CONCAT('"', package_id, '":{', '"installable":"' || i.evra || '"', CASE WHEN i.evra IS NOT NULL AND a.evra IS NOT NULL THEN ',' ELSE '' END, - '{"evra":"' || a.evra || '","status":"Applicable"}', ']')) as update_list + '"applicable":"' || a.evra || '"', '}')) as update_list FROM system_package2 sp LEFT JOIN package i ON sp.installable_id = i.id LEFT JOIN package a ON sp.applicable_id = a.id @@ -32,9 +32,9 @@ DO $$ FOR pkgname_id, update_list IN SELECT sp.name_id, - array_agg(CONCAT('"', sp.system_id, '":[{"evra":"', p.evra,'", "status": "Installed"}', - ',{"evra":"' || i.evra || '","status":"Installable"}', - ',{"evra":"' || a.evra || '","status":"Applicable"}', ']')) as update_list + array_agg(CONCAT('"', sp.system_id, '":{"installed":"', p.evra,'"', + ',"installable":"' || i.evra || '"', + ',"applicable":"' || a.evra || '"', ']')) as update_list FROM system_package2 sp JOIN package p ON p.id = sp.package_id LEFT JOIN package i ON sp.installable_id = i.id @@ -51,3 +51,143 @@ DO $$ $$ ; + +DROP FUNCTION IF EXISTS update_status(update_data jsonb); + +CREATE OR REPLACE FUNCTION delete_system(inventory_id_in uuid) + RETURNS TABLE + ( + deleted_inventory_id uuid + ) +AS +$delete_system$ +DECLARE + v_system_id INT; + v_account_id INT; +BEGIN + -- opt out to refresh cache and then delete + SELECT id, rh_account_id + FROM system_platform + WHERE inventory_id = inventory_id_in + LIMIT 1 + FOR UPDATE OF system_platform + INTO v_system_id, v_account_id; + + IF v_system_id IS NULL OR v_account_id IS NULL THEN + RAISE NOTICE 'Not found'; + RETURN; + END IF; + + UPDATE system_platform + SET stale = true + WHERE rh_account_id = v_account_id + AND id = v_system_id; + + DELETE + FROM system_advisories + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + DELETE + FROM system_repo + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + DELETE + FROM system_package + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + DELETE + FROM system_package2 + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + DELETE + FROM system_package_data + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + UPDATE package_system_data + SET update_data = update_data - v_system_id::text + WHERE rh_account_id = v_account_id; + DELETE + FROM package_system_data + WHERE rh_account_id = v_account_id + AND (update_data IS NULL OR update_data = '{}'::jsonb); + + RETURN QUERY DELETE FROM system_platform + WHERE rh_account_id = v_account_id AND + id = v_system_id + RETURNING inventory_id; +END; +$delete_system$ LANGUAGE 'plpgsql'; + +CREATE OR REPLACE FUNCTION delete_systems(inventory_ids UUID[]) + RETURNS INTEGER +AS +$$ +DECLARE + tmp_cnt INTEGER; +BEGIN + + WITH systems as ( + SELECT rh_account_id, id + FROM system_platform + WHERE inventory_id = ANY (inventory_ids) + ORDER BY rh_account_id, id FOR UPDATE OF system_platform), + marked as ( + UPDATE system_platform sp + SET stale = true + WHERE (rh_account_id, id) in (select rh_account_id, id from systems) + ), + advisories as ( + DELETE + FROM system_advisories + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + repos as ( + DELETE + FROM system_repo + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + packages as ( + DELETE + FROM system_package + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + packages2 as ( + DELETE + FROM system_package2 + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + system_package_data as ( + DELETE + FROM system_package_data + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + package_system_data_u as ( + UPDATE package_system_data psd + SET update_data = update_data - s.id::text + FROM (select rh_account_id, id from systems) s + WHERE psd.rh_account_id = s.rh_account_id + ), + package_system_data_d as ( + DELETE + FROM package_system_data + WHERE rh_account_id in (select rh_account_id from systems) + AND (update_data IS NULL OR update_data = '{}'::jsonb) + ), + 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; diff --git a/database_admin/schema/create_schema.sql b/database_admin/schema/create_schema.sql index dec0a978b..532cdc903 100644 --- a/database_admin/schema/create_schema.sql +++ b/database_admin/schema/create_schema.sql @@ -392,6 +392,19 @@ BEGIN WHERE rh_account_id = v_account_id AND system_id = v_system_id; + DELETE + FROM system_package_data + WHERE rh_account_id = v_account_id + AND system_id = v_system_id; + + UPDATE package_system_data + SET update_data = update_data - v_system_id::text + WHERE rh_account_id = v_account_id; + DELETE + FROM package_system_data + WHERE rh_account_id = v_account_id + AND (update_data IS NULL OR update_data = '{}'::jsonb); + RETURN QUERY DELETE FROM system_platform WHERE rh_account_id = v_account_id AND id = v_system_id @@ -437,6 +450,23 @@ BEGIN FROM system_package2 WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) ), + system_package_data as ( + DELETE + FROM system_package_data + WHERE (rh_account_id, system_id) in (select rh_account_id, id from systems) + ), + package_system_data_u as ( + UPDATE package_system_data psd + SET update_data = update_data - s.id::text + FROM (select rh_account_id, id from systems) s + WHERE psd.rh_account_id = s.rh_account_id + ), + package_system_data_d as ( + DELETE + FROM package_system_data + WHERE rh_account_id in (select rh_account_id from systems) + AND (update_data IS NULL OR update_data = '{}'::jsonb) + ), deleted as ( DELETE FROM system_platform @@ -610,24 +640,6 @@ END; $$ LANGUAGE plpgsql; -CREATE OR REPLACE FUNCTION update_status(update_data jsonb) - RETURNS TEXT as -$$ -DECLARE - len int; -BEGIN - len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status != "Installed")')); - IF len IS NULL or len = 0 THEN - RETURN 'None'; - END IF; - len = jsonb_array_length(jsonb_path_query_array(update_data, '$ ? (@.status == "Installable")')); - IF len > 0 THEN - RETURN 'Installable'; - END IF; - RETURN 'Applicable'; -END; -$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE; - -- --------------------------------------------------------------------------- -- Tables diff --git a/dev/test_data.sql b/dev/test_data.sql index 6ff47a847..a3d673478 100644 --- a/dev/test_data.sql +++ b/dev/test_data.sql @@ -243,13 +243,13 @@ ALTER TABLE baseline ALTER COLUMN id RESTART WITH 100; truncate table system_package_data; INSERT INTO system_package_data (rh_account_id, system_id, update_data) VALUES -(3, 12, '{"1": [{"evra": "5.10.13-200.fc31.x86_64", "status": "Installable"}], "2": [{"evra": "1:76.0.1-1.fc31.x86_64", "status": "Installable"}]}'), -(3, 13, '{"1": [], "2": [{"evra": "76.0.1-2.fc31.x86_64", "status": "Installable"}, {"evra": "77.0.1-1.fc31.x86_64", "status": "Applicable"}], "3": [], "4": []}'), -(3, 16, '{"1": [{"evra": "5.10.13-201.fc31.x86_64", "status": "Installable"}, {"evra": "5.10.13-201.fc31.x86_64", "status": "Applicable"}]}'); +(3, 12, '{"1": {"installable": "5.10.13-200.fc31.x86_64"}, "2": {"installable": "1:76.0.1-1.fc31.x86_64"}}'), +(3, 13, '{"1": {}, "2": {"applicable": "77.0.1-1.fc31.x86_64", "installable": "76.0.1-2.fc31.x86_64"}, "3": {}, "4": {}}'), +(3, 16, '{"1": {"installable": "5.10.13-201.fc31.x86_64", "applicable": "5.10.13-201.fc31.x86_64"}}'); truncate table package_system_data; INSERT INTO package_system_data (rh_account_id, package_name_id, update_data) VALUES -(3, 101, '{"12": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}, {"evra": "5.10.13-200.fc31.x86_64", "status": "Installable"}], "13": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}], "16": [{"evra": "5.6.13-200.fc31.x86_64", "status": "Installed"}, {"evra": "5.10.13-201.fc31.x86_64", "status": "Installable"}]}'), -(3, 102, '{"12": [{"evra": "76.0.1-1.fc31.x86_64", "status": "Installed"}, {"evra": "1:76.0.1-1.fc31.x86_64", "status": "Installable"}], "13": [{"evra": "76.0.1-1.fc31.x86_64", "status": "Installed"}, {"evra": "76.0.1-2.fc31.x86_64", "status": "Installable"}, {"evra": "77.0.1-1.fc31.x86_64", "status": "Applicable"}]}'), -(3, 103, '{"13": [{"evra": "4.4.19-8.el8_0.x86_64", "status": "Installed"}]}'), -(3, 104, '{"13": [{"evra": "7.61.1-8.el8.x86_64", "status": "Installed"}]}'); +(3, 101, '{"12": {"installed": "5.6.13-200.fc31.x86_64", "installable": "5.10.13-200.fc31.x86_64"}, "13": {"installed": "5.6.13-200.fc31.x86_64"}, "16": {"installed": "5.6.13-200.fc31.x86_64", "installable": "5.10.13-201.fc31.x86_64"}}'), +(3, 102, '{"12": {"installed": "76.0.1-1.fc31.x86_64", "installable": "1:76.0.1-1.fc31.x86_64"}, "13": {"installed": "76.0.1-1.fc31.x86_64", "applicable": "77.0.1-1.fc31.x86_64", "installable": "76.0.1-2.fc31.x86_64"}}'), +(3, 103, '{"13": {"installed": "4.4.19-8.el8_0.x86_64"}}'), +(3, 104, '{"13": {"installed": "7.61.1-8.el8.x86_64"}}'); From 3d586d61ca69472297f79d734a3e6d2dd209b429 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 5 Oct 2023 15:41:16 +0200 Subject: [PATCH 07/15] RHINENG-2283: update /packages/systems API to map json --- base/models/models.go | 6 +++ manager/controllers/package_systems.go | 8 ++-- manager/controllers/system_packages.go | 21 ++++------ manager/controllers/system_packages_export.go | 41 +++++++++++++------ 4 files changed, 48 insertions(+), 28 deletions(-) diff --git a/base/models/models.go b/base/models/models.go index df274e509..c875a6931 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -132,6 +132,12 @@ type PackageUpdate struct { Status string `json:"status"` } +type PackageUpdateData struct { + Installed string `json:"installed,omitempty"` + Installable string `json:"installable,omitempty"` + Applicable string `'json:"applicable,omitempty"` +} + type DeletedSystem struct { InventoryID string WhenDeleted time.Time diff --git a/manager/controllers/package_systems.go b/manager/controllers/package_systems.go index 24a4acc8f..d80cdf356 100644 --- a/manager/controllers/package_systems.go +++ b/manager/controllers/package_systems.go @@ -26,9 +26,9 @@ var PackageSystemsOpts = ListOpts{ type PackageSystemItemCommon struct { SystemIDAttribute SystemDisplayName - InstalledEVRA string `json:"installed_evra" csv:"installed_evra" query:"jsonb_path_query_array(update_data, '$ ? (@.status == \"Installed\")')->0->>'evra'" gorm:"column:installed_evra"` - AvailableEVRA string `json:"available_evra" csv:"available_evra" query:"jsonb_path_query_array(update_data, '$ ? (@.status != \"Installed\")')-> -1 ->>'evra'" gorm:"column:available_evra"` - Updatable bool `json:"updatable" csv:"updatable" query:"(update_status(spkg.update_data) = 'Installable')" gorm:"column:updatable"` + InstalledEVRA string `json:"installed_evra" csv:"installed_evra" query:"update_data->>'installed'" gorm:"column:installed_evra"` + AvailableEVRA string `json:"available_evra" csv:"available_evra" query:"COALESCE(update_data->>'applicable', update_data->>'installable')" gorm:"column:available_evra"` + Updatable bool `json:"updatable" csv:"updatable" query:"(update_data->>'installable' IS NOT NULL)" gorm:"column:updatable"` Tags SystemTagsList `json:"tags" csv:"tags" query:"null" gorm:"-"` BaselineAttributes } @@ -43,7 +43,7 @@ type PackageSystemItemV3 struct { SystemSatelliteManaged BaselineIDAttr OSAttributes - UpdateStatus string `json:"update_status" csv:"update_status" query:"CASE WHEN spkg.installable_id is not null THEN 'Installable' WHEN spkg.applicable_id is not null THEN 'Applicable' ELSE 'None' END" gorm:"column:update_status"` + UpdateStatus string `json:"update_status" csv:"update_status" query:"case when update_data ? 'installable' then 'Installable' when update_data ? 'applicable' then 'Applicable' else 'None' end" gorm:"column:update_status"` SystemGroups } diff --git a/manager/controllers/system_packages.go b/manager/controllers/system_packages.go index d427a62dc..67f414016 100644 --- a/manager/controllers/system_packages.go +++ b/manager/controllers/system_packages.go @@ -66,9 +66,7 @@ var SystemPackagesOpts = ListOpts{ type SystemPackageDBLoad struct { SystemPackagesAttrsV3 - // helper to get Updates - InstallableEVRA string `json:"-" csv:"-" query:"pi.evra" gorm:"column:installable_evra"` - ApplicableEVRA string `json:"-" csv:"-" query:"pa.evra" gorm:"column:applicable_evra"` + Updates []byte `json:"updates" query:"spkg.update_data" gorm:"column:updates"` // a helper to get total number of systems MetaTotalHelper } @@ -175,16 +173,15 @@ func buildSystemPackageData(loaded []SystemPackageDBLoad) (int, []SystemPackageD data := make([]SystemPackageDataV3, len(loaded)) for i, sp := range loaded { data[i].SystemPackagesAttrsV3 = sp.SystemPackagesAttrsV3 - // keep only latest installable and applicable - if len(sp.InstallableEVRA) > 0 && sp.InstallableEVRA != sp.EVRA { - data[i].Updates = append(data[i].Updates, models.PackageUpdate{ - EVRA: sp.InstallableEVRA, Status: "Installable", - }) + if sp.Updates == nil { + continue } - if len(sp.ApplicableEVRA) > 0 && sp.ApplicableEVRA != sp.EVRA { - data[i].Updates = append(data[i].Updates, models.PackageUpdate{ - EVRA: sp.ApplicableEVRA, Status: "Applicable", - }) + installable, applicable := findLatestEVRA(sp) + if installable.EVRA != sp.EVRA { + data[i].Updates = append(data[i].Updates, installable) + } + if applicable.EVRA != sp.EVRA { + data[i].Updates = append(data[i].Updates, applicable) } } return total, data diff --git a/manager/controllers/system_packages_export.go b/manager/controllers/system_packages_export.go index 9a20fad6c..053bf9f9b 100644 --- a/manager/controllers/system_packages_export.go +++ b/manager/controllers/system_packages_export.go @@ -1,8 +1,10 @@ package controllers import ( + "app/base/models" "app/base/utils" "app/manager/middlewares" + "encoding/json" "errors" "net/http" @@ -85,14 +87,34 @@ func SystemPackagesExportHandler(c *gin.Context) { OutputExportData(c, data) } +func findLatestEVRA(pkg SystemPackageDBLoad) (installable models.PackageUpdate, applicable models.PackageUpdate) { + installable = models.PackageUpdate{ + EVRA: pkg.EVRA, + } + applicable = installable + if pkg.Updates == nil { + return + } + var updates models.PackageUpdateData + if err := json.Unmarshal(pkg.Updates, &updates); err != nil { + panic(err) + } + if updates.Installable != "" { + installable.EVRA = updates.Installable + applicable.EVRA = updates.Installable + } + if updates.Applicable != "" { + applicable.EVRA = updates.Applicable + } + return +} + func buildSystemPackageInlineV2(pkgs []SystemPackageDBLoad) []SystemPackageInlineV2 { data := make([]SystemPackageInlineV2, len(pkgs)) for i, v := range pkgs { data[i].SystemPackagesAttrsCommon = v.SystemPackagesAttrsCommon - data[i].LatestEVRA = v.EVRA - if len(v.InstallableEVRA) > 0 { - data[i].LatestEVRA = v.InstallableEVRA - } + installable, _ := findLatestEVRA(v) + data[i].LatestEVRA = installable.EVRA } return data } @@ -101,14 +123,9 @@ func buildSystemPackageInlineV3(pkgs []SystemPackageDBLoad) []SystemPackageInlin data := make([]SystemPackageInlineV3, len(pkgs)) for i, v := range pkgs { data[i].SystemPackagesAttrsV3 = v.SystemPackagesAttrsV3 - data[i].LatestInstallable = v.EVRA - if len(v.InstallableEVRA) > 0 { - data[i].LatestInstallable = v.InstallableEVRA - } - data[i].LatestApplicable = data[i].LatestInstallable - if len(v.ApplicableEVRA) > 0 { - data[i].LatestApplicable = v.ApplicableEVRA - } + latestInstallable, latestApplicable := findLatestEVRA(v) + data[i].LatestInstallable = latestInstallable.EVRA + data[i].LatestApplicable = latestApplicable.EVRA } return data } From 210f6e66a48cd81fc9db12d923960c0d43fb1d7f Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 5 Oct 2023 15:44:15 +0200 Subject: [PATCH 08/15] RHINENG-2281: update /packages API to map json --- base/database/utils.go | 18 +++++++++--------- manager/controllers/packages.go | 6 +++--- 2 files changed, 12 insertions(+), 12 deletions(-) diff --git a/base/database/utils.go b/base/database/utils.go index aa17711e6..f16dd0cb9 100644 --- a/base/database/utils.go +++ b/base/database/utils.go @@ -26,9 +26,12 @@ func SystemAdvisories(tx *gorm.DB, accountID int, groups map[string]string) *gor Joins("JOIN system_advisories sa on sa.system_id = sp.id AND sa.rh_account_id = ?", accountID) } -func SystemPackagesShort(tx *gorm.DB, accountID int) *gorm.DB { - return tx.Table("system_package2 spkg"). - Where("spkg.rh_account_id = ?", accountID) +func PackageSystemDataShort(tx *gorm.DB, accountID int) *gorm.DB { + return tx.Select(`pd.package_name_id as name_id, + jsonb_object_keys(pd.update_data)::bigint as system_id, + jsonb_path_query(update_data, '$.*') as update_data`). + Table("package_system_data pd"). + Where("pd.rh_account_id = ?", accountID) } func SystemPackages(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { @@ -51,13 +54,10 @@ func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *go } func PackageSystemData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { + spkg := PackageSystemDataShort(tx, accountID) return Systems(tx, accountID, groups). - Joins(`JOIN (SELECT package_name_id as name_id, - jsonb_object_keys(update_data)::bigint as system_id, - jsonb_path_query(update_data, '$.*') as update_data - FROM package_system_data - WHERE rh_account_id = ?) as spkg - ON spkg.system_id = sp.id`, accountID). + Joins(`JOIN (?) as spkg + ON spkg.system_id = sp.id`, spkg). Joins("JOIN package_name pn on pn.id = spkg.name_id") } diff --git a/manager/controllers/packages.go b/manager/controllers/packages.go index 0041ffb91..af771e413 100644 --- a/manager/controllers/packages.go +++ b/manager/controllers/packages.go @@ -77,8 +77,8 @@ type PackagesResponse struct { type queryItem struct { NameID int `query:"spkg.name_id" gorm:"column:name_id"` SystemsInstalled int `json:"systems_installed" query:"count(*)" gorm:"column:systems_installed"` - SystemsInstallable int `json:"systems_installable" query:"count(*) filter (where spkg.installable_id is not null)" gorm:"column:systems_installable"` - SystemsApplicable int `json:"systems_applicable" query:"count(*) filter (where spkg.installable_id is not null or spkg.applicable_id is not null)" gorm:"column:systems_applicable"` + SystemsInstallable int `json:"systems_installable" query:"count(*) filter (where update_data ? 'installable')" gorm:"column:systems_installable"` + SystemsApplicable int `json:"systems_applicable" query:"count(*) filter (where (update_data ?| ARRAY['installable','applicable']))" gorm:"column:systems_applicable"` } var queryItemSelect = database.MustGetSelect(&queryItem{}) @@ -98,7 +98,7 @@ func packagesQuery(db *gorm.DB, filters map[string]FilterData, acc int, groups m // We need to apply tag filtering on subquery systemsWithPkgsInstalledQ, _ = ApplyInventoryFilter(filters, systemsWithPkgsInstalledQ, "sp.inventory_id") - subQ := database.SystemPackagesShort(db, acc). + subQ := db.Table("(?) as spkg", database.PackageSystemDataShort(db, acc)). Select(queryItemSelect). Where("spkg.system_id IN (?)", systemsWithPkgsInstalledQ). Group("spkg.name_id") From 0e66ef10b069dcde4b75b3e1648b0d93e7b0c639 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 5 Oct 2023 15:45:45 +0200 Subject: [PATCH 09/15] RHINENG-2282: update /systems/packages API to map json --- manager/controllers/system_packages.go | 4 ++-- manager/controllers/system_packages_export.go | 8 ++++++-- 2 files changed, 8 insertions(+), 4 deletions(-) diff --git a/manager/controllers/system_packages.go b/manager/controllers/system_packages.go index 67f414016..107b7b106 100644 --- a/manager/controllers/system_packages.go +++ b/manager/controllers/system_packages.go @@ -18,7 +18,7 @@ type SystemPackagesAttrsCommon struct { EVRA string `json:"evra" csv:"evra" query:"p.evra" gorm:"column:evra"` Summary string `json:"summary" csv:"summary" query:"sum.value" gorm:"column:summary"` Description string `json:"description" csv:"description" query:"descr.value" gorm:"column:description"` - Updatable bool `json:"updatable" csv:"updatable" query:"(spkg.installable_id is not null)" gorm:"column:updatable"` + Updatable bool `json:"updatable" csv:"updatable" query:"(update_data->>'installable' IS NOT NULL)" gorm:"column:updatable"` } type SystemPackageUpdates struct { @@ -32,7 +32,7 @@ type SystemPackagesAttrsV2 struct { // nolint: lll type SystemPackagesAttrsV3 struct { SystemPackagesAttrsCommon - UpdateStatus string `json:"update_status" csv:"update_status" query:"CASE WHEN spkg.installable_id is not null THEN 'Installable' WHEN spkg.applicable_id is not null THEN 'Applicable' ELSE 'None' END" gorm:"column:update_status"` + UpdateStatus string `json:"update_status" csv:"update_status" query:"case when spkg.update_data ? 'installable' then 'Installable' when spkg.update_data ? 'applicable' then 'Applicable' else 'None' end" gorm:"column:update_status"` } type SystemPackageDataV2 struct { diff --git a/manager/controllers/system_packages_export.go b/manager/controllers/system_packages_export.go index 053bf9f9b..7cbba6389 100644 --- a/manager/controllers/system_packages_export.go +++ b/manager/controllers/system_packages_export.go @@ -89,9 +89,13 @@ func SystemPackagesExportHandler(c *gin.Context) { func findLatestEVRA(pkg SystemPackageDBLoad) (installable models.PackageUpdate, applicable models.PackageUpdate) { installable = models.PackageUpdate{ - EVRA: pkg.EVRA, + EVRA: pkg.EVRA, + Status: "Installable", + } + applicable = models.PackageUpdate{ + EVRA: pkg.EVRA, + Status: "Applicable", } - applicable = installable if pkg.Updates == nil { return } From 2b864b38c6b51213914081674125f1e8b6454c83 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Fri, 6 Oct 2023 11:07:18 +0200 Subject: [PATCH 10/15] RHINENG-2281: update package cache to map json --- tasks/caches/refresh_packages_caches.go | 24 ++++++++------------ tasks/caches/refresh_packages_caches_test.go | 2 +- 2 files changed, 10 insertions(+), 16 deletions(-) diff --git a/tasks/caches/refresh_packages_caches.go b/tasks/caches/refresh_packages_caches.go index 7095cd552..8c79ef1c2 100644 --- a/tasks/caches/refresh_packages_caches.go +++ b/tasks/caches/refresh_packages_caches.go @@ -30,7 +30,7 @@ func RefreshPackagesCaches(accID *int) error { for i, acc := range accs { acc := acc utils.LogInfo("account", acc, "#", i, "Refreshing account") - if err = getCounts(&pkgSysCounts, &acc); err != nil { + if err = getCounts(&pkgSysCounts, acc); err != nil { utils.LogError("err", err.Error(), "Refresh failed") continue } @@ -71,7 +71,7 @@ func accountsWithoutCache() ([]int, error) { return accs, errors.Wrap(err, "failed to get accounts without cache") } -func getCounts(pkgSysCounts *[]models.PackageAccountData, accID *int) error { +func getCounts(pkgSysCounts *[]models.PackageAccountData, accID int) error { defer utils.ObserveSecondsSince(time.Now(), packageRefreshPartDuration.WithLabelValues("get-counts")) utils.LogDebug("Getting counts of installable and applicable systems") err := tasks.WithReadReplicaTx(func(tx *gorm.DB) error { @@ -83,22 +83,16 @@ func getCounts(pkgSysCounts *[]models.PackageAccountData, accID *int) error { sp.rh_account_id rh_account_id, spkg.name_id package_name_id, count(*) as systems_installed, - count(*) filter (where spkg.installable_id is not null) as systems_installable, - count(*) filter (where spkg.installable_id is not null or spkg.applicable_id is not null) as systems_applicable + count(*) filter (where update_data ? 'installable') as systems_installable, + count(*) filter (where (update_data ?| ARRAY['installable', 'applicable'])) as systems_applicable `). - Joins("JOIN system_package2 spkg ON sp.id = spkg.system_id AND sp.rh_account_id = spkg.rh_account_id"). - Joins("JOIN rh_account acc ON sp.rh_account_id = acc.id"). - Joins("JOIN inventory.hosts ih ON sp.inventory_id = ih.id"). + Joins("JOIN (?) spkg ON sp.id = spkg.system_id AND sp.rh_account_id = spkg.rh_account_id", + database.SystemPackageData(tx, accID, nil)). Where("sp.packages_installed > 0 AND sp.stale = FALSE"). Group("sp.rh_account_id, spkg.name_id"). - Order("sp.rh_account_id, spkg.name_id") - if accID != nil { - utils.LogDebug("Getting counts for single account") - q.Where("sp.rh_account_id = ?", *accID) - } else { - utils.LogDebug("Getting counts for multiple accounts") - q.Where("acc.valid_package_cache = FALSE") - } + Order("sp.rh_account_id, spkg.name_id"). + Where("sp.rh_account_id = ?", accID) + utils.LogDebug("Getting counts for single account") return q.Find(pkgSysCounts).Error }) return errors.Wrap(err, "failed to get counts") diff --git a/tasks/caches/refresh_packages_caches_test.go b/tasks/caches/refresh_packages_caches_test.go index ce3e1f6a1..536d5bdbe 100644 --- a/tasks/caches/refresh_packages_caches_test.go +++ b/tasks/caches/refresh_packages_caches_test.go @@ -30,7 +30,7 @@ func TestGetCounts(t *testing.T) { utils.SkipWithoutDB(t) core.SetupTestEnvironment() - err := getCounts(&_counts, &_acc) + err := getCounts(&_counts, _acc) assert.Nil(t, err) assert.Equal(t, 4, len(_counts)) } From c89a50c536fee9e05034121fcf3a287de2493358 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Fri, 6 Oct 2023 13:43:17 +0200 Subject: [PATCH 11/15] RHINENG-2281: remove system_package table from /packages/version --- base/database/utils.go | 7 ------- base/models/models.go | 4 ---- manager/controllers/package_versions.go | 4 ++-- 3 files changed, 2 insertions(+), 13 deletions(-) diff --git a/base/database/utils.go b/base/database/utils.go index f16dd0cb9..1f1176d80 100644 --- a/base/database/utils.go +++ b/base/database/utils.go @@ -34,13 +34,6 @@ func PackageSystemDataShort(tx *gorm.DB, accountID int) *gorm.DB { Where("pd.rh_account_id = ?", accountID) } -func SystemPackages(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { - return Systems(tx, accountID, groups). - Joins("JOIN system_package2 spkg on spkg.system_id = sp.id AND spkg.rh_account_id = ?", accountID). - Joins("JOIN package p on p.id = spkg.package_id"). - Joins("JOIN package_name pn on pn.id = spkg.name_id") -} - func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { return Systems(tx, accountID, groups). Joins(`JOIN (SELECT system_id, diff --git a/base/models/models.go b/base/models/models.go index c875a6931..84839cd60 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -122,10 +122,6 @@ type SystemPackage struct { ApplicableID *int64 } -func (SystemPackage) TableName() string { - return "system_package2" -} - type PackageUpdate struct { EVRA string `json:"evra"` Advisory string `json:"-"` // don't show it in API, we can probably remove it completely later diff --git a/manager/controllers/package_versions.go b/manager/controllers/package_versions.go index 31b1f61a5..e0d04eecd 100644 --- a/manager/controllers/package_versions.go +++ b/manager/controllers/package_versions.go @@ -46,10 +46,10 @@ func packagesNameID(db *gorm.DB, pkgName string) *gorm.DB { } func packageVersionsQuery(db *gorm.DB, acc int, groups map[string]string, packageNameIDs []int) *gorm.DB { - query := database.SystemPackages(db, acc, groups). + query := database.SystemPackageData(db, acc, groups). Distinct(PackageVersionSelect). Where("sp.stale = false"). - Where("spkg.name_id in (?)", packageNameIDs) + Where("p.name_id in (?)", packageNameIDs) return query } From b9fb570df4edf6f0c03755dd0e8460e58a5403a7 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Tue, 10 Oct 2023 10:10:06 +0200 Subject: [PATCH 12/15] RHINENG-2284: move subquery into SystemPackageDataShort() --- base/database/utils.go | 29 +++++++++++++++++------------ 1 file changed, 17 insertions(+), 12 deletions(-) diff --git a/base/database/utils.go b/base/database/utils.go index 1f1176d80..e931d0809 100644 --- a/base/database/utils.go +++ b/base/database/utils.go @@ -26,26 +26,31 @@ func SystemAdvisories(tx *gorm.DB, accountID int, groups map[string]string) *gor Joins("JOIN system_advisories sa on sa.system_id = sp.id AND sa.rh_account_id = ?", accountID) } -func PackageSystemDataShort(tx *gorm.DB, accountID int) *gorm.DB { - return tx.Select(`pd.package_name_id as name_id, - jsonb_object_keys(pd.update_data)::bigint as system_id, - jsonb_path_query(update_data, '$.*') as update_data`). - Table("package_system_data pd"). - Where("pd.rh_account_id = ?", accountID) +func SystemPackageDataShort(tx *gorm.DB, accountID int) *gorm.DB { + return tx.Select(`system_id, + jsonb_object_keys(update_data)::bigint as package_id, + jsonb_path_query(update_data, '$.*') as update_data`). + Table("system_package_data"). + Where("rh_account_id = ?", accountID) } func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { + spkg := SystemPackageDataShort(tx, accountID) return Systems(tx, accountID, groups). - Joins(`JOIN (SELECT system_id, - jsonb_object_keys(update_data)::bigint as package_id, - jsonb_path_query(update_data, '$.*') as update_data - FROM system_package_data - WHERE rh_account_id = ?) as spkg - ON spkg.system_id = sp.id`, accountID). + Joins(`JOIN (?) as spkg + ON spkg.system_id = sp.id`, spkg). Joins("JOIN package p on p.id = spkg.package_id"). Joins("JOIN package_name pn on pn.id = p.name_id") } +func PackageSystemDataShort(tx *gorm.DB, accountID int) *gorm.DB { + return tx.Select(`pd.package_name_id as name_id, + jsonb_object_keys(pd.update_data)::bigint as system_id, + jsonb_path_query(update_data, '$.*') as update_data`). + Table("package_system_data pd"). + Where("pd.rh_account_id = ?", accountID) +} + func PackageSystemData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB { spkg := PackageSystemDataShort(tx, accountID) return Systems(tx, accountID, groups). From 2da643533db0782d31e17a9e08d58e4b7f4c8901 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 12 Oct 2023 16:45:57 +0200 Subject: [PATCH 13/15] RHINENG-2284: updated evaluation to store data in {system_package,package_system}_data tables --- base/database/database.go | 2 +- base/models/models.go | 28 ++- evaluator/evaluate_packages.go | 346 ++++++++++++++++----------------- 3 files changed, 195 insertions(+), 181 deletions(-) diff --git a/base/database/database.go b/base/database/database.go index ffecf5bbb..68628284e 100644 --- a/base/database/database.go +++ b/base/database/database.go @@ -24,7 +24,7 @@ func OnConflictUpdateMulti(db *gorm.DB, keys []string, updateCols ...string) *go type UpExpr struct { Name string - Expr string + Expr interface{} } func OnConflictDoUpdateExpr(db *gorm.DB, keys []string, updateExprs ...UpExpr) *gorm.DB { diff --git a/base/models/models.go b/base/models/models.go index 84839cd60..1b014b7e2 100644 --- a/base/models/models.go +++ b/base/models/models.go @@ -122,6 +122,26 @@ type SystemPackage struct { ApplicableID *int64 } +type SystemPackageData struct { + RhAccountID int `gorm:"primaryKey"` + SystemID int64 `gorm:"primaryKey"` + UpdateData []byte +} + +func (SystemPackageData) TableName() string { + return "system_package_data" +} + +type PackageSystemData struct { + RhAccountID int `gorm:"primaryKey"` + PackageNameID int64 `gorm:"primaryKey"` + UpdateData []byte +} + +func (PackageSystemData) TableName() string { + return "package_system_data" +} + type PackageUpdate struct { EVRA string `json:"evra"` Advisory string `json:"-"` // don't show it in API, we can probably remove it completely later @@ -131,9 +151,15 @@ type PackageUpdate struct { type PackageUpdateData struct { Installed string `json:"installed,omitempty"` Installable string `json:"installable,omitempty"` - Applicable string `'json:"applicable,omitempty"` + Applicable string `json:"applicable,omitempty"` } +// for a given system holds map[package_id]->update_data_json +type SystemPackageUpdateData map[int64]PackageUpdateData + +// for given package_name holds map[system_id]->update_data_json +type PackageSystemUpdateData map[int64]PackageUpdateData + type DeletedSystem struct { InventoryID string WhenDeleted time.Time diff --git a/evaluator/evaluate_packages.go b/evaluator/evaluate_packages.go index 9eb8480f2..451c350a4 100644 --- a/evaluator/evaluate_packages.go +++ b/evaluator/evaluate_packages.go @@ -5,7 +5,9 @@ import ( "app/base/models" "app/base/utils" "app/base/vmaas" + "encoding/json" "fmt" + "strconv" "strings" "time" @@ -26,13 +28,13 @@ func analyzePackages(tx *gorm.DB, system *models.SystemPlatform, vmaasData *vmaa return 0, 0, errors.Wrap(err, "lazy package save failed") } - pkgByName, err := loadPackages(tx, system, vmaasData) + pkgByName, installed, updatable, err := loadPackages(tx, system, vmaasData) if err != nil { evaluationCnt.WithLabelValues("error-pkg-data").Inc() return 0, 0, errors.Wrap(err, "Unable to load package data") } - installed, updatable, err = updateSystemPackages(tx, system, pkgByName, vmaasData) + err = updateSystemPackages(tx, system, pkgByName) if err != nil { evaluationCnt.WithLabelValues("error-system-pkgs").Inc() return 0, 0, errors.Wrap(err, "Unable to update system packages") @@ -137,233 +139,219 @@ func updatePackageNameDB(missing *models.PackageName) error { // Find relevant package data based on vmaas results func loadPackages(tx *gorm.DB, system *models.SystemPlatform, - vmaasData *vmaas.UpdatesV3Response) (*map[string]namedPackage, error) { + vmaasData *vmaas.UpdatesV3Response) (map[string]namedPackage, int, int, error) { defer utils.ObserveSecondsSince(time.Now(), evaluationPartDuration.WithLabelValues("packages-load")) - packages, err := loadSystemNEVRAsFromDB(tx, system, vmaasData) + packages, installed, updatable, err := loadSystemNEVRAsFromDB(tx, system, vmaasData) if err != nil { - return nil, errors.Wrap(err, "loading packages") + return nil, 0, 0, errors.Wrap(err, "loading packages") } - - pkgByNevra := packages2NevraMap(packages) - return &pkgByNevra, nil -} - -func packages2NevraMap(packages []namedPackage) map[string]namedPackage { - pkgByNevra := make(map[string]namedPackage, len(packages)) - for _, p := range packages { - // make sure nevra contains epoch even if epoch==0 - nevraString := utils.NEVRAStringE(p.Name, p.EVRA, true) - pkgByNevra[nevraString] = p - } - return pkgByNevra + return packages, installed, updatable, nil } +// nolint: funlen func loadSystemNEVRAsFromDB(tx *gorm.DB, system *models.SystemPlatform, - vmaasData *vmaas.UpdatesV3Response) ([]namedPackage, error) { + vmaasData *vmaas.UpdatesV3Response) (map[string]namedPackage, int, int, error) { + installed := 0 + updatable := 0 updates := vmaasData.GetUpdateList() numUpdates := len(updates) - packageIDs := make([]int64, 0, numUpdates) - packages := make([]namedPackage, 0, numUpdates) - id2index := make(map[int64]int, numUpdates) - i := 0 - for nevra := range updates { + packages := make(map[string]namedPackage, numUpdates*2) + for nevra, pkgUpdate := range updates { + if !isValidNevra(nevra) { + continue + } + installed++ + availableUpdates := pkgUpdate.GetAvailableUpdates() + if len(availableUpdates) > 0 { + updatable++ + } pkgMeta, ok := memoryPackageCache.GetByNevra(nevra) + // before we used nevra.EVRAString() function which shows only non zero epoch, keep it consistent + // maybe we need here something like: evra := strings.TrimPrefix(upData.GetEVRA(), "0:") if ok { - packageIDs = append(packageIDs, pkgMeta.ID) - p := namedPackage{ - NameID: pkgMeta.NameID, - Name: pkgMeta.Name, - PackageID: pkgMeta.ID, - EVRA: pkgMeta.Evra, - WasStored: false, + pkgUpdateData := packageUpdateData(pkgMeta.Evra, availableUpdates) + packages[nevra] = namedPackage{ + NameID: pkgMeta.NameID, + Name: pkgMeta.Name, + PackageID: pkgMeta.ID, + EVRA: pkgMeta.Evra, + Change: Add, + UpdateData: pkgUpdateData, } - packages = append(packages, p) - id2index[pkgMeta.ID] = i - i++ } } - rows, err := tx.Table("system_package2"). - Select("package_id, installable_id, applicable_id"). - Where("rh_account_id = ? AND system_id = ?", system.RhAccountID, system.ID). - Where("package_id in (?)", packageIDs). + + rows, err := tx.Table("(?) as t", database.SystemPackageDataShort(tx, system.RhAccountID)). + Joins("JOIN package p ON p.id = t.package_id"). + Joins("JOIN package_name pn on pn.id = p.name_id"). + Select("t.package_id, pn.name, p.name_id, p.evra, t.update_data"). + Where("system_id = ?", system.ID). Rows() if err != nil { - return nil, err + return nil, 0, 0, err } - var columns namedPackage for rows.Next() { - err = tx.ScanRows(rows, &columns) + var packageID int64 + var nameID int64 + var name string + var evra string + var jsonb []byte + var updateData models.PackageUpdateData + err = rows.Scan(&packageID, &name, &nameID, &evra, &jsonb) if err != nil { - return nil, err + return nil, 0, 0, err + } + nevra := utils.NEVRAStringE(name, evra, true) + err = json.Unmarshal(jsonb, &updateData) + if err != nil { + return nil, 0, 0, err + } + if p, ok := packages[nevra]; ok { + if isEqual(p.UpdateData, updateData) { + p.Change = Keep + } else { + p.Change = Update + } + } else { + packages[nevra] = namedPackage{ + NameID: nameID, + PackageID: packageID, + EVRA: evra, + Change: Remove, + UpdateData: updateData, + } } - index := id2index[columns.PackageID] - packages[index].WasStored = true - packages[index].InstallableID = columns.InstallableID - packages[index].ApplicableID = columns.ApplicableID - } - utils.LogInfo("inventoryID", system.InventoryID, "packages", numUpdates, "already stored", len(packages)) - return packages, err -} - -func isValidNevra(nevra string, packagesByNEVRA *map[string]namedPackage) bool { - // skip "phantom" package - if strings.HasPrefix(nevra, "gpg-pubkey") { - return false } - - // Check whether we have that NEVRA in DB - currentNamedPackage := (*packagesByNEVRA)[nevra] - if currentNamedPackage.PackageID == 0 { - utils.LogTrace("nevra", nevra, "Unknown package") - return false + if err := rows.Close(); err != nil { + return nil, 0, 0, err } - return true + utils.LogInfo("inventoryID", system.InventoryID, "packages", numUpdates, "already stored", len(packages)) + return packages, installed, updatable, err } -func latestPkgsChanged(currentNamedPackage *namedPackage, installableID, applicableID int64) bool { - currentInstallableID, currentApplicableID := int64(0), int64(0) - if currentNamedPackage.InstallableID != nil { - currentInstallableID = *currentNamedPackage.InstallableID - } - if currentNamedPackage.ApplicableID != nil { - currentApplicableID = *currentNamedPackage.ApplicableID - } - - if installableID == currentInstallableID && applicableID == currentApplicableID { - // If the update_data we want to store is null, we skip only if there was a row for this specific - // system_package already stored. - if installableID == 0 && applicableID == 0 && currentNamedPackage.WasStored { - return false - } - - // If its not null, then the previous check ensured that the old update data matches new one - if installableID != 0 || applicableID != 0 { - return false +func packageUpdateData(installedEvra string, + availableUpdates []vmaas.UpdatesV3ResponseAvailableUpdates) models.PackageUpdateData { + data := models.PackageUpdateData{Installed: installedEvra} + for _, p := range availableUpdates { + if p.Package != nil { + // before we used nevra.EVRAString() function which shows only non zero epoch, keep it consistent + evra := strings.TrimPrefix(*p.EVRA, "0:") + switch p.StatusID { + case APPLICABLE: + data.Applicable = evra + case INSTALLABLE: + data.Installable = evra + } } } - return true + return data } -func createSystemPackage(nevra string, - updateData *vmaas.UpdatesV3ResponseUpdateList, - system *models.SystemPlatform, - packagesByNEVRA *map[string]namedPackage) (systemPackagePtr *models.SystemPackage, updatesChanged bool) { - installableID, applicableID := latestPackagesFromVmaasResponse(updateData) - - // Skip overwriting entries which have the same data as before - currentNamedPackage := (*packagesByNEVRA)[nevra] - if !latestPkgsChanged(¤tNamedPackage, installableID, applicableID) { - return nil, false - } +func isEqual(a, b models.PackageUpdateData) bool { + return a.Applicable == b.Applicable && a.Installable == b.Installable && a.Installed == b.Installed +} - systemPackage := models.SystemPackage{ - RhAccountID: system.RhAccountID, - SystemID: system.ID, - PackageID: currentNamedPackage.PackageID, - NameID: currentNamedPackage.NameID, - } - if installableID != 0 { - systemPackage.InstallableID = &installableID - } - if applicableID != 0 { - systemPackage.ApplicableID = &applicableID - } - return &systemPackage, true +func isValidNevra(nevra string) bool { + // skip "phantom" package + return !strings.HasPrefix(nevra, "gpg-pubkey") } func updateSystemPackages(tx *gorm.DB, system *models.SystemPlatform, - packagesByNEVRA *map[string]namedPackage, - vmaasData *vmaas.UpdatesV3Response) (installed, updatable int, err error) { + packagesByNEVRA map[string]namedPackage) error { defer utils.ObserveSecondsSince(time.Now(), evaluationPartDuration.WithLabelValues("packages-store")) - updates := vmaasData.GetUpdateList() - if err := deleteOldSystemPackages(tx, system, packagesByNEVRA); err != nil { - return 0, 0, err + // update system_package_data + if err := updateSystemPackageData(tx, system, packagesByNEVRA); err != nil { + return err } - toStore := make([]models.SystemPackage, 0, len(updates)) - for nevra, updateData := range updates { - isValid := isValidNevra(nevra, packagesByNEVRA) - if !isValid { + // update package_system_data + err := updatePackageSystemData(tx, system, packagesByNEVRA) + return err +} + +func systemPackageUpdateData(pkgDataMap map[string]namedPackage) models.SystemPackageUpdateData { + updateData := make(models.SystemPackageUpdateData, len(pkgDataMap)) + for _, pkg := range pkgDataMap { + if pkg.Change == Remove { continue } - installed++ - if len(updateData.GetAvailableUpdates()) > 0 { - updatable++ - } + updateData[pkg.PackageID] = pkg.UpdateData + } + return updateData +} - systemPackagePtr, updatesChanged := createSystemPackage(nevra, updateData, system, packagesByNEVRA) - if updatesChanged { - toStore = append(toStore, *systemPackagePtr) - } +func updateSystemPackageData(tx *gorm.DB, system *models.SystemPlatform, + pkgDataMap map[string]namedPackage) error { + jsonb, err := json.Marshal(systemPackageUpdateData(pkgDataMap)) + if err != nil { + return err } - return installed, updatable, errors.Wrap( - database.UnnestInsert(tx, - "INSERT INTO system_package2 (rh_account_id, system_id, package_id, name_id, installable_id, applicable_id)"+ - " (select * from unnest($1::int[], $2::bigint[], $3::bigint[], $4::bigint[], $5::bigint[], $6::bigint[]))"+ - " ON CONFLICT (rh_account_id, system_id, package_id)"+ - " DO UPDATE SET installable_id = EXCLUDED.installable_id, applicable_id = EXCLUDED.applicable_id", toStore), - "Storing system packages") + row := models.SystemPackageData{RhAccountID: system.RhAccountID, SystemID: system.ID, UpdateData: jsonb} + if len(pkgDataMap) > 0 { + return database.OnConflictUpdateMulti(tx, []string{"rh_account_id", "system_id"}, "update_data").Create(row).Error + } + return tx.Delete(&models.SystemPackageData{}, system.RhAccountID, system.ID).Error } -func latestPackagesFromVmaasResponse(updateData *vmaas.UpdatesV3ResponseUpdateList) (int64, int64) { - var ( - latestInstallable, latestApplicable string - installableID, applicableID int64 - ) - uniqUpdates := make(map[string]bool) - for _, upData := range updateData.GetAvailableUpdates() { - nevra := upData.GetPackage() - if len(nevra) == 0 { - // no update - continue - } - // Keep only unique entries for each update in the list - if !uniqUpdates[nevra] { - uniqUpdates[nevra] = true - switch upData.StatusID { - case INSTALLABLE: - latestInstallable = nevra - case APPLICABLE: - latestApplicable = nevra +func updatePackageSystemData(tx *gorm.DB, system *models.SystemPlatform, pkgDataMap map[string]namedPackage) error { + removeNameIDs := make([]int64, 0, len(pkgDataMap)) + tx = tx.Session(&gorm.Session{PrepareStmt: true}) + for _, pkg := range pkgDataMap { + switch pkg.Change { + case Remove: + removeNameIDs = append(removeNameIDs, pkg.NameID) + case Add: + fallthrough + case Update: + // handle updated packages + jsonb, err := json.Marshal(models.PackageSystemUpdateData{system.ID: pkg.UpdateData}) + if err != nil { + return err + } + row := models.PackageSystemData{RhAccountID: system.RhAccountID, PackageNameID: pkg.NameID, UpdateData: jsonb} + err = database.OnConflictDoUpdateExpr(tx, []string{"rh_account_id", "package_name_id"}, + database.UpExpr{Name: "update_data", + Expr: gorm.Expr("package_system_data.update_data || ?", jsonb)}). + Create(row).Error + if err != nil { + return err } } } - if len(latestInstallable) > 0 { - if installableFromCache, ok := memoryPackageCache.GetByNevra(latestInstallable); ok { - installableID = installableFromCache.ID - } - } - if len(latestApplicable) > 0 { - if applicableFromCache, ok := memoryPackageCache.GetByNevra(latestApplicable); ok { - applicableID = applicableFromCache.ID + + // handle removed packages + if len(removeNameIDs) > 0 { + err := tx.Model(&models.PackageSystemData{}). + Where("rh_account_id = ? and package_name_id in (?)", system.RhAccountID, removeNameIDs). + Update("update_data", gorm.Expr("update_data - ?", strconv.FormatInt(system.ID, 10))).Error + if err != nil { + return err } + // remove package names with no systems + return tx.Where("rh_account_id = ? and package_name_id in (?)", system.RhAccountID, removeNameIDs). + Where("(update_data IS NULL OR update_date == '{}'::jsonb)"). + Delete(&models.PackageSystemData{}).Error } - return installableID, applicableID + return nil } -func deleteOldSystemPackages(tx *gorm.DB, system *models.SystemPlatform, - packagesByNEVRA *map[string]namedPackage) error { - pkgIds := make([]int64, 0, len(*packagesByNEVRA)) - for _, pkg := range *packagesByNEVRA { - pkgIds = append(pkgIds, pkg.PackageID) - } - - err := tx.Where("rh_account_id = ? ", system.RhAccountID). - Where("system_id = ?", system.ID). - Where("package_id not in (?)", pkgIds). - Delete(&models.SystemPackage{}).Error +type ChangeType int8 - return errors.Wrap(err, "Deleting outdated system packages") -} +const ( + None ChangeType = iota + Add + Keep + Update + Remove +) type namedPackage struct { - NameID int64 - Name string - PackageID int64 - EVRA string - WasStored bool - InstallableID *int64 - ApplicableID *int64 + NameID int64 + Name string + PackageID int64 + EVRA string + Change ChangeType + UpdateData models.PackageUpdateData } From cc2eb11ebd517cf28473d0ddaf96582f62ef98a6 Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Mon, 16 Oct 2023 16:58:47 +0200 Subject: [PATCH 14/15] RHINENG-2284: update test to check {system_package,package_system}_data tables --- base/database/testing.go | 71 ++++++++++++++++++++++++++++++++-------- 1 file changed, 58 insertions(+), 13 deletions(-) diff --git a/base/database/testing.go b/base/database/testing.go index fdffb44a9..afc84e368 100644 --- a/base/database/testing.go +++ b/base/database/testing.go @@ -9,7 +9,9 @@ import ( "testing" "time" + "github.com/lib/pq" "github.com/stretchr/testify/assert" + "gorm.io/gorm" ) func DebugWithCachesCheck(part string, fun func()) { @@ -246,13 +248,28 @@ func CheckEVRAsInDBSynced(t *testing.T, nExpected int, synced bool, evras ...str } func CheckSystemPackages(t *testing.T, accountID int, systemID int64, nExpected int, packageIDs ...int64) { - var systemPackages []models.SystemPackage - query := Db.Where("rh_account_id = ? AND system_id = ?", accountID, systemID) + // check system_package_data + var foundIDs []int64 + sysQuery := Db.Table(`(SELECT jsonb_object_keys(update_data)::bigint as package_id + FROM system_package_data + WHERE rh_account_id = ? AND system_id = ?) as t`, accountID, systemID) if len(packageIDs) > 0 { - query = query.Where("package_id IN (?)", packageIDs) + sysQuery = sysQuery.Where("package_id in (?)", packageIDs) } - assert.Nil(t, query.Find(&systemPackages).Error) - assert.Equal(t, nExpected, len(systemPackages)) + assert.Nil(t, sysQuery.Pluck("package_id", &foundIDs).Error) + assert.Equal(t, nExpected, len(foundIDs)) + + // check package_system_data + var foundNameIDs []int64 + pkgQuery := Db.Table("package_system_data psd"). + Where("psd.rh_account_id = ? AND psd.update_data->? IS NOT NULL", accountID, strconv.FormatInt(systemID, 10)) + if len(packageIDs) > 0 { + pkgQuery = pkgQuery.Joins("JOIN package p ON p.name_id = psd.package_name_id"). + Where("p.id in (?)", packageIDs) + } + + assert.Nil(t, pkgQuery.Pluck("package_name_id", &foundNameIDs).Error) + assert.Equal(t, nExpected, len(foundNameIDs)) } func CheckSystemRepos(t *testing.T, rhAccountID int, systemID int64, repoIDs []int64) { @@ -286,15 +303,37 @@ func DeleteAdvisoryAccountData(t *testing.T, rhAccountID int, advisoryIDs []int6 } func DeleteSystemPackages(t *testing.T, accountID int, systemID int64, pkgIDs ...int64) { - query := Db.Model(&models.SystemPackage{}).Where("rh_account_id = ? AND system_id = ?", accountID, systemID) + // delete system_package_data if len(pkgIDs) > 0 { - query = query.Where("package_id in (?)", pkgIDs) + keys := make([]string, len(pkgIDs)) + for i, pid := range pkgIDs { + keys[i] = strconv.FormatInt(pid, 10) + } + assert.Nil(t, Db.Model(&models.SystemPackageData{}). + Where("rh_account_id = ? and system_id = ?", accountID, systemID). + Update("update_data", gorm.Expr("update_data - ?::text[]", pq.StringArray(keys))).Error) + // remove completely if there's no package left + assert.Nil(t, Db.Where("rh_account_id = ? and system_id = ? and update_data = '{}'::jsonb", accountID, systemID). + Delete(&models.SystemPackageData{}).Error) + } else { + assert.Nil(t, Db.Where("rh_account_id = ? AND system_id = ?", accountID, systemID). + Delete(&models.SystemPackageData{}).Error) } - assert.Nil(t, query.Delete(&models.SystemPackage{}).Error) - var count int64 // ensure deleted - assert.Nil(t, query.Count(&count).Error) - assert.Equal(t, int64(0), count) + // delete package_system_data + systemIDKey := strconv.FormatInt(systemID, 10) + query := Db.Table("package_system_data psd"). + Where("psd.rh_account_id = ? AND psd.update_data->? IS NOT NULL", accountID, systemIDKey) + if len(pkgIDs) > 0 { + query.Where("package_name_id IN (SELECT name_id FROM package WHERE id IN (?))", pkgIDs) + } + assert.Nil(t, query.Update("update_data", gorm.Expr("update_data - ?", systemIDKey)).Error) + // remove completely if there's no system left + query = Db.Where("rh_account_id = ? AND update_data = '{}'::jsonb", accountID) + if len(pkgIDs) > 0 { + query.Where("package_name_id IN (SELECT name_id FROM package WHERE id IN (?))", pkgIDs) + } + assert.Nil(t, query.Delete(&models.PackageSystemData{}).Error) } func DeleteSystemRepos(t *testing.T, rhAccountID int, systemID int64, repoIDs []int64) { @@ -306,8 +345,14 @@ func DeleteSystemRepos(t *testing.T, rhAccountID int, systemID int64, repoIDs [] func DeleteNewlyAddedPackages(t *testing.T) { query := Db.Table("package p"). Where("id >= 100"). - Where("NOT EXISTS (SELECT 1 FROM system_package2 sp WHERE" + - " p.id = sp.package_id OR p.id = sp.installable_id OR p.id = sp.applicable_id)") + Where(`NOT EXISTS (SELECT 1 + FROM (SELECT package_name_id, + jsonb_path_query(update_data, '$.*') as update_data + FROM package_system_data) as psd + WHERE p.name_id = psd.package_name_id + AND p.evra in (psd.update_data->>'installed', psd.update_data->>'installable', + psd.update_data->>'applicable') + )`) assert.Nil(t, query.Delete(models.Package{}).Error) var cnt int64 assert.Nil(t, query.Count(&cnt).Error) From a85afef9cfbfbc5728c80aecc98f0604c49d3fcf Mon Sep 17 00:00:00 2001 From: Michael Mraka Date: Thu, 7 Dec 2023 18:23:23 +0100 Subject: [PATCH 15/15] RHINENG-2281: update tasks to {system_package,package_system}_data tables --- tasks/cleaning/clean_unused_data.go | 13 +++++++++---- 1 file changed, 9 insertions(+), 4 deletions(-) diff --git a/tasks/cleaning/clean_unused_data.go b/tasks/cleaning/clean_unused_data.go index 1ee0144a1..01b08988d 100644 --- a/tasks/cleaning/clean_unused_data.go +++ b/tasks/cleaning/clean_unused_data.go @@ -35,10 +35,15 @@ func deleteUnusedPackages() { // before changing the query below test its performance on big data otherwise it can lock database subq := tx.Select("id").Table("package p"). Where("synced = ?", false). - Where("NOT EXISTS" + - " (SELECT 1 FROM system_package2 sp WHERE" + - " p.id = sp.package_id OR p.id = sp.installable_id OR p.id = sp.applicable_id)", - ).Limit(deleteUnusedDataLimit) + Where(`NOT EXISTS (SELECT 1 + FROM (SELECT package_name_id, + jsonb_path_query(update_data, '$.*') as update_data + FROM package_system_data) as psd + WHERE p.name_id = psd.package_name_id + AND p.evra in (psd.update_data->>'installed', psd.update_data->>'installable', + psd.update_data->>'applicable') + )`). + Limit(deleteUnusedDataLimit) err := tx.Delete(&models.Package{}, "id IN (?)", subq).Error