Skip to content

Commit

Permalink
Use a uuid as primary key for windows profiles (#15008)
Browse files Browse the repository at this point in the history
  • Loading branch information
mna authored Nov 7, 2023
1 parent bf8504a commit 9543bef
Show file tree
Hide file tree
Showing 7 changed files with 172 additions and 10 deletions.
1 change: 1 addition & 0 deletions server/datastore/mysql/hosts.go
Original file line number Diff line number Diff line change
Expand Up @@ -482,6 +482,7 @@ var hostRefs = []string{
var additionalHostRefsByUUID = map[string]string{
"host_mdm_apple_profiles": "host_uuid",
"host_mdm_apple_bootstrap_packages": "host_uuid",
"host_mdm_windows_profiles": "host_uuid",
}

func (ds *Datastore) DeleteHost(ctx context.Context, hid uint) error {
Expand Down
6 changes: 6 additions & 0 deletions server/datastore/mysql/hosts_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -5856,6 +5856,12 @@ func testHostsDeleteHosts(t *testing.T, ds *Datastore) {
_, err = ds.NewHostScriptExecutionRequest(context.Background(), &fleet.HostScriptRequestPayload{HostID: host.ID, ScriptContents: "foo"})
require.NoError(t, err)

_, err = ds.writer(context.Background()).Exec(`
INSERT INTO host_mdm_windows_profiles (host_uuid, profile_uuid, command_uuid)
VALUES (?, uuid(), uuid())
`, host.UUID)
require.NoError(t, err)

// Check there's an entry for the host in all the associated tables.
for _, hostRef := range hostRefs {
var ok bool
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
package tables

import (
"database/sql"
"fmt"
)

func init() {
MigrationClient.AddMigration(Up_20231107130934, Down_20231107130934)
}

func Up_20231107130934(tx *sql.Tx) error {
// add the profile_uuid column to the profiles table, keeping the old id.
// Note that we cannot set the default to uuid() as functions cannot be used
// as defaults in mysql 5.7. It will have to be generated in code when
// inserting. Cannot be set as primary key yet as it may have duplicates until
// we generate the uuids.
_, err := tx.Exec(`
ALTER TABLE mdm_windows_configuration_profiles
-- required to remove AUTO_INCREMENT because it must be a primary key
CHANGE COLUMN profile_id profile_id INT(10) UNSIGNED NOT NULL,
DROP PRIMARY KEY,
ADD COLUMN profile_uuid VARCHAR(36) NOT NULL DEFAULT ''
`)
if err != nil {
return fmt.Errorf("failed to alter mdm_windows_configuration_profiles table: %w", err)
}

// add the profile_uuid column to the host profiles table, keeping the old
// id. Cannot be set as primary key yet as it may have duplicates until we
// generate the uuids.
_, err = tx.Exec(`
ALTER TABLE host_mdm_windows_profiles
DROP PRIMARY KEY,
ADD COLUMN profile_uuid VARCHAR(36) NOT NULL DEFAULT ''
`)
if err != nil {
return fmt.Errorf("failed to alter host_mdm_windows_profiles table: %w", err)
}

// generate the uuids for the profiles table
_, err = tx.Exec(`
UPDATE
mdm_windows_configuration_profiles
SET
profile_uuid = uuid()
`)
if err != nil {
return fmt.Errorf("failed to update mdm_windows_configuration_profiles table: %w", err)
}

// update the host profiles table's profile_uuid based on its profile_id
_, err = tx.Exec(`
UPDATE
host_mdm_windows_profiles
SET
profile_uuid = COALESCE((
SELECT
mwcp.profile_uuid
FROM
mdm_windows_configuration_profiles mwcp
WHERE
host_mdm_windows_profiles.profile_id = mwcp.profile_id
), uuid())
`)
if err != nil {
return fmt.Errorf("failed to update host_mdm_windows_profiles table: %w", err)
}

// drop the now unused profile_id column from both tables
_, err = tx.Exec(`ALTER TABLE mdm_windows_configuration_profiles
ADD PRIMARY KEY (profile_uuid),
DROP COLUMN profile_id`)
if err != nil {
return fmt.Errorf("failed to drop column from mdm_windows_configuration_profiles table: %w", err)
}
_, err = tx.Exec(`ALTER TABLE host_mdm_windows_profiles
ADD PRIMARY KEY (host_uuid, profile_uuid),
DROP COLUMN profile_id`)
if err != nil {
return fmt.Errorf("failed to drop column from host_mdm_windows_profiles table: %w", err)
}

return nil
}

func Down_20231107130934(tx *sql.Tx) error {
return nil
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,60 @@
package tables

import (
"testing"

"github.com/jmoiron/sqlx"
"github.com/stretchr/testify/require"
)

func TestUp_20231107130934(t *testing.T) {
db := applyUpToPrev(t)

// create some profiles
idA := execNoErrLastID(t, db, `INSERT INTO mdm_windows_configuration_profiles (team_id, name, syncml) VALUES (0, 'A', '<Replace>A</Replace>')`)
idB := execNoErrLastID(t, db, `INSERT INTO mdm_windows_configuration_profiles (team_id, name, syncml) VALUES (1, 'B', '<Replace>B</Replace>')`)
idC := execNoErrLastID(t, db, `INSERT INTO mdm_windows_configuration_profiles (team_id, name, syncml) VALUES (0, 'C', '<Replace>C</Replace>')`)
nonExistingID := idC + 1000

// create some hosts profiles with one not related to an existing profile
execNoErr(t, db, `INSERT INTO host_mdm_windows_profiles (host_uuid, profile_id, command_uuid) VALUES ('h1', ?, 'c1')`, idA)
execNoErr(t, db, `INSERT INTO host_mdm_windows_profiles (host_uuid, profile_id, command_uuid) VALUES ('h2', ?, 'c2')`, idB)
execNoErr(t, db, `INSERT INTO host_mdm_windows_profiles (host_uuid, profile_id, command_uuid) VALUES ('h2', ?, 'c3')`, nonExistingID)
execNoErr(t, db, `INSERT INTO host_mdm_windows_profiles (host_uuid, profile_id, command_uuid) VALUES ('h2', ?, 'c4')`, idA)

// Apply current migration.
applyNext(t, db)

var profUUIDs []string
err := sqlx.Select(db, &profUUIDs, `SELECT profile_uuid FROM mdm_windows_configuration_profiles ORDER BY name`)
require.NoError(t, err)
require.Len(t, profUUIDs, 3)
require.NotEmpty(t, profUUIDs[0])
require.NotEmpty(t, profUUIDs[1])
require.NotEmpty(t, profUUIDs[2])

var hostUUIDs []string
// get hosts with profile A
err = sqlx.Select(db, &hostUUIDs, `SELECT host_uuid FROM host_mdm_windows_profiles WHERE profile_uuid = ? ORDER BY host_uuid`, profUUIDs[0])
require.NoError(t, err)
require.Equal(t, []string{"h1", "h2"}, hostUUIDs)

// get hosts with profile B
hostUUIDs = hostUUIDs[:0]
err = sqlx.Select(db, &hostUUIDs, `SELECT host_uuid FROM host_mdm_windows_profiles WHERE profile_uuid = ? ORDER BY host_uuid`, profUUIDs[1])
require.NoError(t, err)
require.Equal(t, []string{"h2"}, hostUUIDs)

// get hosts with profile C
hostUUIDs = hostUUIDs[:0]
err = sqlx.Select(db, &hostUUIDs, `SELECT host_uuid FROM host_mdm_windows_profiles WHERE profile_uuid = ? ORDER BY host_uuid`, profUUIDs[2])
require.NoError(t, err)
require.Empty(t, hostUUIDs)

// get profile uuid of non-existing profile
profUUIDs = profUUIDs[:0]
err = sqlx.Select(db, &profUUIDs, `SELECT profile_uuid FROM host_mdm_windows_profiles WHERE command_uuid = 'c3' ORDER BY profile_uuid`)
require.NoError(t, err)
require.Len(t, profUUIDs, 1)
require.NotEmpty(t, profUUIDs[0])
}
12 changes: 9 additions & 3 deletions server/datastore/mysql/migrations/tables/migration_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -76,9 +76,15 @@ func applyUpToPrev(t *testing.T) *sqlx.DB {
}
}

func execNoErr(t *testing.T, db *sqlx.DB, query string, args ...any) {
_, err := db.Exec(query, args...)
func execNoErrLastID(t *testing.T, db *sqlx.DB, query string, args ...any) int64 {
res, err := db.Exec(query, args...)
require.NoError(t, err)
id, _ := res.LastInsertId()
return id
}

func execNoErr(t *testing.T, db *sqlx.DB, query string, args ...any) {
execNoErrLastID(t, db, query, args...)
}

// applyNext performs the next migration in the chain.
Expand Down Expand Up @@ -119,7 +125,7 @@ func insertHost(t *testing.T, db *sqlx.DB) uint {
insertHostStmt := `
INSERT INTO hosts (
hostname, uuid, platform, osquery_version, os_version, build, platform_like, code_name,
cpu_type, cpu_subtype, cpu_brand, hardware_vendor, hardware_model, hardware_version,
cpu_type, cpu_subtype, cpu_brand, hardware_vendor, hardware_model, hardware_version,
hardware_serial, computer_name
) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
`
Expand Down
12 changes: 6 additions & 6 deletions server/datastore/mysql/schema.sql

Large diffs are not rendered by default.

2 changes: 1 addition & 1 deletion server/datastore/mysql/teams_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -89,7 +89,7 @@ func testTeamsGetSetDelete(t *testing.T, ds *Datastore) {
// TODO: once the datastore methods are implemented, use them in tests.
ExecAdhocSQL(t, ds, func(tx sqlx.ExtContext) error {
_, err := tx.ExecContext(context.Background(),
`INSERT INTO mdm_windows_configuration_profiles (name, syncml) VALUES (?, ?)`, team.ID, "<SyncML></SyncML>")
`INSERT INTO mdm_windows_configuration_profiles (profile_uuid, name, syncml) VALUES (uuid(), ?, ?)`, team.ID, "<SyncML></SyncML>")
return err
})

Expand Down

0 comments on commit 9543bef

Please sign in to comment.