Skip to content

Commit

Permalink
POC: migrate system_package with admin api
Browse files Browse the repository at this point in the history
Co-authored-by: dkuc <[email protected]>
  • Loading branch information
psegedy and dkuc committed Dec 5, 2023
1 parent 6c79cb6 commit 6e2b6a7
Show file tree
Hide file tree
Showing 5 changed files with 194 additions and 48 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
DROP PROCEDURE copy_system_packages;
99 changes: 85 additions & 14 deletions database_admin/migrations/117_migrate_system_package2.up.sql
Original file line number Diff line number Diff line change
@@ -1,16 +1,87 @@
/*
Loops through the PK(account_id, system_id, package_id) in chunks of 1000 and inserts it into the new table.
Assumptions:
1. the system_packages2 table is empty.
2. No new system_packages comes in when this is running.
*/

-- migrate syste_package partitions one by one
DO
CREATE OR REPLACE PROCEDURE copy_system_packages()
LANGUAGE plpgsql
AS
$$
DECLARE
part text;
BEGIN
FOR part IN (SELECT tablename from pg_tables t where t.tablename ~ '^system_package_[0-9]+$')
LOOP
RAISE NOTICE 'Copying the % partition', part;
EXECUTE 'INSERT INTO system_package2 (rh_account_id, system_id, name_id, package_id, installable_id, applicable_id)
( SELECT rh_account_id, system_id, name_id, package_id, NULL, NULL FROM ' ||
part || ') ON CONFLICT DO NOTHING';
END LOOP;
END
$$ LANGUAGE plpgsql;
DECLARE
rows_inserted INTEGER := 0;
account_idx integer := 0;
system_idx bigint := 0;
package_idx bigint := 0;
BEGIN
LOOP
INSERT INTO system_package2
SELECT rh_account_id,
system_id,
name_id,
package_id,
(SELECT id
FROM package
WHERE package.name_id = system_package.name_id
AND evra =
JSONB_PATH_QUERY_ARRAY(update_data, '$[*] ? (@.status== "Installable").evra') ->> 0),
(SELECT id
FROM package
WHERE package.name_id = system_package.name_id
AND evra = JSONB_PATH_QUERY_ARRAY(update_data, '$[*] ? (@.status== "Applicable").evra') ->> 0)
FROM system_package
WHERE (rh_account_id = account_idx AND system_id = system_idx AND package_id > package_idx)
OR (rh_account_id = account_idx AND system_id > system_idx)
ORDER BY rh_account_id, system_id, package_id
LIMIT 1000;

GET DIAGNOSTICS rows_inserted = ROW_COUNT;

COMMIT;

/* I Originally did not include this if statement but I couldn't get the select to use the PK index when I had all 3 where clauses
1. rh_account_id = account_idx AND system_id = system_idx AND package_id > package_idx
2. rh_account_id = account_idx AND system_id > system_idx
3. rh_account_id > account_idx
So I just copied and pasted the same select / insert and used the final clause when the first two return 0 rows
*/
IF rows_inserted = 0 THEN
INSERT INTO system_package2
SELECT rh_account_id,
system_id,
name_id,
package_id,
(SELECT id
FROM package
WHERE package.name_id = system_package.name_id
AND evra = JSONB_PATH_QUERY_ARRAY(update_data, '$[*] ? (@.status== "Installable").evra') ->> 0),
(SELECT id
FROM package
WHERE package.name_id = system_package.name_id
AND evra = JSONB_PATH_QUERY_ARRAY(update_data, '$[*] ? (@.status== "Applicable").evra') ->> 0)
FROM system_package
WHERE rh_account_id > account_idx
ORDER BY rh_account_id, system_id, package_id
LIMIT 1000;

GET DIAGNOSTICS rows_inserted = ROW_COUNT;

COMMIT;
END IF;

EXIT WHEN rows_inserted = 0;

/* Store the highest values of our account/system/package ids are up to.
Should be O(1) because it can just look at the tail of the PK index*/
SELECT rh_account_id, system_id, package_id
INTO account_idx, system_idx, package_idx
FROM system_package2
ORDER BY rh_account_id DESC, system_id DESC, package_id DESC
LIMIT 1;

END LOOP;
END
$$;
82 changes: 48 additions & 34 deletions docs/admin/openapi.json
Original file line number Diff line number Diff line change
Expand Up @@ -48,9 +48,42 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
}
},
"security": [
{
"RhIdentity": []
}
]
}
},
"/migrate_system_package": {
"put": {
"summary": "Migrate system_package data to system_package2",
"description": "Migrate system_package data to system_package2",
"operationId": "migrateSystemPackage",
"responses": {
"200": {
"description": "OK",
"content": {
"application/json": {
"schema": {
"type": "string"
}
}
}
},
"500": {
"description": "Internal Server Error",
"content": {
"application/json": {
"schema": {
"type": "object",
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -90,9 +123,7 @@
"application/octet-stream": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -132,9 +163,7 @@
"application/octet-stream": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -174,9 +203,7 @@
"application/octet-stream": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -216,9 +243,7 @@
"application/octet-stream": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -253,9 +278,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -300,9 +323,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -358,9 +379,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -416,9 +435,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -477,9 +494,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -514,9 +529,7 @@
"application/json": {
"schema": {
"type": "object",
"additionalProperties": {
"type": "object"
}
"additionalProperties": true
}
}
}
Expand Down Expand Up @@ -551,5 +564,6 @@
"in": "header"
}
}
}
},
"x-original-swagger-version": "2.0"
}
1 change: 1 addition & 0 deletions manager/routes/routes.go
Original file line number Diff line number Diff line change
Expand Up @@ -96,6 +96,7 @@ func InitAdmin(app *gin.Engine) {
api.GET("/check-caches", admin.CheckCaches)
api.PUT("/refresh-packages", admin.RefreshPackagesHandler)
api.PUT("/refresh-packages/:account", admin.RefreshPackagesAccountHandler)
api.PUT("/migrate_system_package", admin.MigrateSystemPackage)
api.GET("/sessions", admin.GetActiveSessionsHandler)
api.GET("/sessions/:search", admin.GetActiveSessionsHandler)
api.DELETE("/sessions/:pid", admin.TerminateSessionHandler)
Expand Down
59 changes: 59 additions & 0 deletions turnpike/controllers/admin.go
Original file line number Diff line number Diff line change
Expand Up @@ -286,3 +286,62 @@ func getPprof(address, param, query string) ([]byte, error) {
}
return resBody, nil
}

// @Summary Migrate system_package data to system_package2
// @Description Migrate system_package data to system_package2
// @ID migrateSystemPackage
// @Security RhIdentity
// @Accept json
// @Produce json
// @Success 200 {object} string
// @Failure 500 {object} map[string]interface{}
// @Router /migrate_system_package [put]
func MigrateSystemPackage(c *gin.Context) {
utils.LogInfo("starting system_package data migration")
var cnt int64
db := database.Db

db.Table("system_package2").Count(&cnt)
if cnt > 0 {
utils.LogInfo("System_package2 table is not empty")
c.JSON(http.StatusNoContent, "System_package2 table is not empty, nothing to do.")
return
}

go func() {
if err := db.Exec(`
ALTER TABLE system_package2 DROP CONSTRAINT system_package2_applicable_id_fkey;
ALTER TABLE system_package2 DROP CONSTRAINT system_package2_installable_id_fkey;
ALTER TABLE system_package2 DROP CONSTRAINT system_package2_name_id_fkey;
ALTER TABLE system_package2 DROP CONSTRAINT system_package2_package_id_fkey;
ALTER TABLE system_package2 DROP CONSTRAINT system_package2_rh_account_id_system_id_fkey;
DROP INDEX system_package2_account_pkg_name_idx;
DROP INDEX system_package2_package_id_idx;
`).Error; err != nil {
utils.LogError("err", err.Error(), "Couldn't remove constraints and indexes")
return
}

if err := db.Exec("CALL copy_system_packages();").Error; err != nil {
utils.LogError("err", err.Error(), "Migration failed")
return
}

// nolint:lll
if err := db.Exec(`
ALTER TABLE system_package2 ADD CONSTRAINT system_package2_applicable_id_fkey FOREIGN KEY (applicable_id) REFERENCES package(id);
ALTER TABLE system_package2 ADD CONSTRAINT system_package2_installable_id_fkey FOREIGN KEY (installable_id) REFERENCES package(id);
ALTER TABLE system_package2 ADD CONSTRAINT system_package2_name_id_fkey FOREIGN KEY (name_id) REFERENCES package_name(id);
ALTER TABLE system_package2 ADD CONSTRAINT system_package2_package_id_fkey FOREIGN KEY (package_id) REFERENCES package(id);
ALTER TABLE system_package2 ADD CONSTRAINT system_package2_rh_account_id_system_id_fkey FOREIGN KEY (rh_account_id, system_id) REFERENCES system_platform (rh_account_id, id);
CREATE INDEX IF NOT EXISTS system_package2_account_pkg_name_idx
ON system_package2 (rh_account_id, name_id) INCLUDE (system_id, package_id, installable_id, applicable_id);
CREATE INDEX IF NOT EXISTS system_package2_package_id_idx on system_package2 (package_id);
`).Error; err != nil {
utils.LogError("err", err.Error(), "Couldn't add constraints and indexes")
return
}
utils.LogInfo("System_package migration completed")
}()
c.JSON(http.StatusOK, "Migration started")
}

0 comments on commit 6e2b6a7

Please sign in to comment.