Files
assetmgt/assets/database/migration_users_to_rbac.sql

142 lines
5.9 KiB
SQL

-- ===================================================
-- USER TO RBAC ROLE ASSIGNMENT MIGRATION SCRIPT
-- Date: 2025-01-22
-- Description: Migrate users from settings/view fields to user_role_assignments
-- Prerequisites: Run migration_profiles_to_rbac.sql first to create roles
-- ===================================================
START TRANSACTION;
-- ===================================================
-- MAPPING REFERENCE:
--
-- users.settings field values -> role names:
-- 'admin_profile' or view=4 -> TSS_Admin
-- 'distribution' -> Distribution
-- 'service' -> Service
-- 'firmware' -> Software_Tool
-- 'interface' -> Interface
-- 'superuser_profile' or view=1 -> Service
-- All others (including empty/NULL) -> Service
--
-- IGNORED/REMOVED PROFILES:
-- 'standard_profile', 'adminplus_profile', 'build', 'commerce',
-- 'garage', 'other'
-- ===================================================
-- Get role IDs
SET @role_tss_admin = (SELECT rowID FROM user_roles WHERE name = 'TSS_Admin' LIMIT 1);
SET @role_distribution = (SELECT rowID FROM user_roles WHERE name = 'Distribution' LIMIT 1);
SET @role_service = (SELECT rowID FROM user_roles WHERE name = 'Service' LIMIT 1);
SET @role_software_tool = (SELECT rowID FROM user_roles WHERE name = 'Software_Tool' LIMIT 1);
SET @role_interface = (SELECT rowID FROM user_roles WHERE name = 'Interface' LIMIT 1);
-- ===================================================
-- PHASE 1: MIGRATE USERS BY SETTINGS FIELD (profile name)
-- ===================================================
-- Users with 'admin_profile' setting -> TSS_Admin
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_tss_admin, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'admin_profile'
ON DUPLICATE KEY UPDATE updated = NOW();
-- Users with 'distribution' setting -> Distribution
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_distribution, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'distribution'
ON DUPLICATE KEY UPDATE updated = NOW();
-- Users with 'service' setting -> Service
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_service, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'service'
ON DUPLICATE KEY UPDATE updated = NOW();
-- Users with 'firmware' setting -> Software_Tool
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_software_tool, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'firmware'
ON DUPLICATE KEY UPDATE updated = NOW();
-- Users with 'interface' setting -> Interface
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_interface, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'interface'
ON DUPLICATE KEY UPDATE updated = NOW();
-- Users with 'superuser_profile' setting -> Service
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT id, @role_service, 1, 'migration_script', NOW(), NOW(), 1
FROM users
WHERE settings = 'superuser_profile'
ON DUPLICATE KEY UPDATE updated = NOW();
-- ===================================================
-- PHASE 2: MIGRATE USERS WITH EMPTY/NULL SETTINGS (use view field)
-- Only for users not already assigned a role
-- ===================================================
-- Users with view=4 (Admin) and no settings -> TSS_Admin
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT u.id, @role_tss_admin, 1, 'migration_script', NOW(), NOW(), 1
FROM users u
LEFT JOIN user_role_assignments ura ON u.id = ura.user_id AND ura.is_active = 1
WHERE (u.settings IS NULL OR u.settings = '')
AND u.view = '4'
AND ura.rowID IS NULL
ON DUPLICATE KEY UPDATE updated = NOW();
-- ===================================================
-- PHASE 3: CATCH-ALL - Any remaining users without role -> Service
-- ===================================================
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
SELECT u.id, @role_service, 1, 'migration_script', NOW(), NOW(), 1
FROM users u
LEFT JOIN user_role_assignments ura ON u.id = ura.user_id AND ura.is_active = 1
WHERE ura.rowID IS NULL
ON DUPLICATE KEY UPDATE updated = NOW();
-- ===================================================
-- VERIFICATION QUERIES
-- ===================================================
-- Check migration results: users per role
SELECT
ur.name as role_name,
COUNT(ura.user_id) as user_count
FROM user_roles ur
LEFT JOIN user_role_assignments ura ON ur.rowID = ura.role_id AND ura.is_active = 1
GROUP BY ur.rowID, ur.name
ORDER BY user_count DESC;
-- Check for users without role assignments (should be 0)
SELECT COUNT(*) as users_without_role
FROM users u
LEFT JOIN user_role_assignments ura ON u.id = ura.user_id AND ura.is_active = 1
WHERE ura.rowID IS NULL;
-- Compare old vs new: show users with their old settings and new role
SELECT
u.id,
u.username,
u.settings as old_profile,
u.view as old_view_level,
ur.name as new_role
FROM users u
LEFT JOIN user_role_assignments ura ON u.id = ura.user_id AND ura.is_active = 1
LEFT JOIN user_roles ur ON ura.role_id = ur.rowID
ORDER BY u.id
LIMIT 50;
-- ===================================================
-- Change ROLLBACK to COMMIT when ready to apply
-- ===================================================
COMMIT;