Skip to content
New issue

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

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

Already on GitHub? Sign in to your account

POC2: precalculate data for /packages APIs #1343

Closed
wants to merge 15 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion base/database/database.go
Original file line number Diff line number Diff line change
Expand Up @@ -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 {
Expand Down
71 changes: 58 additions & 13 deletions base/database/testing.go
Original file line number Diff line number Diff line change
Expand Up @@ -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()) {
Expand Down Expand Up @@ -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) {
Expand Down Expand Up @@ -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) {
Expand All @@ -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)
Expand Down
31 changes: 26 additions & 5 deletions base/database/utils.go
Original file line number Diff line number Diff line change
Expand Up @@ -26,15 +26,36 @@ 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 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 SystemPackages(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB {
func SystemPackageData(tx *gorm.DB, accountID int, groups map[string]string) *gorm.DB {
spkg := SystemPackageDataShort(tx, accountID)
return Systems(tx, accountID, groups).
Joins("JOIN system_package2 spkg on spkg.system_id = sp.id AND spkg.rh_account_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).
Joins(`JOIN (?) as spkg
ON spkg.system_id = sp.id`, spkg).
Joins("JOIN package_name pn on pn.id = spkg.name_id")
}

Expand Down
32 changes: 30 additions & 2 deletions base/models/models.go
Original file line number Diff line number Diff line change
Expand Up @@ -122,8 +122,24 @@ type SystemPackage struct {
ApplicableID *int64
}

func (SystemPackage) TableName() string {
return "system_package2"
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 {
Expand All @@ -132,6 +148,18 @@ 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"`
}

// 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
Expand Down
20 changes: 20 additions & 0 deletions database_admin/migrations/119_package_data_tables.down.sql
Original file line number Diff line number Diff line change
@@ -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;
64 changes: 64 additions & 0 deletions database_admin/migrations/119_package_data_tables.up.sql
Original file line number Diff line number Diff line change
@@ -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;
Loading
Loading