Implement RBAC migration and role management enhancements
- Added AJAX functionality to fetch role permissions for copying. - Introduced system role management with permission checks for updates. - Implemented role deletion with confirmation modal and backend handling. - Enhanced user role assignment migration scripts to transition from legacy profiles to RBAC. - Created SQL migration scripts for user roles and permissions mapping. - Updated user interface to support new role management features including copy permissions and system role indicators.
This commit is contained in:
228
assets/database/migration_users_to_rbac.sql
Normal file
228
assets/database/migration_users_to_rbac.sql
Normal file
@@ -0,0 +1,228 @@
|
||||
-- ===================================================
|
||||
-- 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:
|
||||
-- 'standard_profile' or empty with view 0-2 -> Standard
|
||||
-- 'superuser_profile' or view=2 -> Superuser
|
||||
-- 'admin_profile' or view=4 -> Admin
|
||||
-- 'adminplus_profile' or view=5 -> AdminPlus
|
||||
-- 'build' -> Build
|
||||
-- 'commerce' -> Commerce
|
||||
-- 'distribution' -> Distribution
|
||||
-- 'firmware' -> Firmware
|
||||
-- 'garage' -> Garage
|
||||
-- 'interface' -> Interface
|
||||
-- 'service' -> Service
|
||||
-- 'other' -> Other
|
||||
--
|
||||
-- users.view field (legacy permission level):
|
||||
-- 1 = SuperUser
|
||||
-- 2 = Create & Update
|
||||
-- 3 = Read-only
|
||||
-- 4 = Admin
|
||||
-- 5 = Admin+
|
||||
-- ===================================================
|
||||
|
||||
-- Get role IDs
|
||||
SET @role_standard = (SELECT rowID FROM user_roles WHERE name = 'Standard' LIMIT 1);
|
||||
SET @role_superuser = (SELECT rowID FROM user_roles WHERE name = 'Superuser' LIMIT 1);
|
||||
SET @role_admin = (SELECT rowID FROM user_roles WHERE name = 'Admin' LIMIT 1);
|
||||
SET @role_adminplus = (SELECT rowID FROM user_roles WHERE name = 'AdminPlus' LIMIT 1);
|
||||
SET @role_build = (SELECT rowID FROM user_roles WHERE name = 'Build' LIMIT 1);
|
||||
SET @role_commerce = (SELECT rowID FROM user_roles WHERE name = 'Commerce' LIMIT 1);
|
||||
SET @role_distribution = (SELECT rowID FROM user_roles WHERE name = 'Distribution' LIMIT 1);
|
||||
SET @role_firmware = (SELECT rowID FROM user_roles WHERE name = 'Firmware' LIMIT 1);
|
||||
SET @role_garage = (SELECT rowID FROM user_roles WHERE name = 'Garage' LIMIT 1);
|
||||
SET @role_interface = (SELECT rowID FROM user_roles WHERE name = 'Interface' LIMIT 1);
|
||||
SET @role_service = (SELECT rowID FROM user_roles WHERE name = 'Service' LIMIT 1);
|
||||
SET @role_other = (SELECT rowID FROM user_roles WHERE name = 'Other' LIMIT 1);
|
||||
|
||||
-- ===================================================
|
||||
-- PHASE 1: MIGRATE USERS BY SETTINGS FIELD (profile name)
|
||||
-- ===================================================
|
||||
|
||||
-- Users with 'standard_profile' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_standard, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'standard_profile'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'superuser_profile' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_superuser, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'superuser_profile'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'admin_profile' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_admin, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'admin_profile'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'adminplus_profile' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_adminplus, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'adminplus_profile'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'build' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_build, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'build'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'commerce' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_commerce, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'commerce'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'distribution' setting
|
||||
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 'firmware' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_firmware, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'firmware'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'garage' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_garage, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'garage'
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with 'interface' setting
|
||||
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 'service' setting
|
||||
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 'other' setting
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT id, @role_other, 1, 'migration_script', NOW(), NOW(), 1
|
||||
FROM users
|
||||
WHERE settings = 'other'
|
||||
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=5 (Admin+) and no settings
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT u.id, @role_adminplus, 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 = '5'
|
||||
AND ura.rowID IS NULL
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with view=4 (Admin) and no settings
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT u.id, @role_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();
|
||||
|
||||
-- Users with view=1 (SuperUser) and no settings
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT u.id, @role_superuser, 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 = '1'
|
||||
AND ura.rowID IS NULL
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- Users with view=2 or view=3 (Create/Update or Read-only) and no settings -> Standard
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT u.id, @role_standard, 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 IN ('2', '3')
|
||||
AND ura.rowID IS NULL
|
||||
ON DUPLICATE KEY UPDATE updated = NOW();
|
||||
|
||||
-- ===================================================
|
||||
-- PHASE 3: CATCH-ALL - Any remaining users without role -> Standard
|
||||
-- ===================================================
|
||||
|
||||
INSERT INTO `user_role_assignments` (`user_id`, `role_id`, `is_active`, `assigned_by`, `assigned_at`, `created`, `createdby`)
|
||||
SELECT u.id, @role_standard, 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;
|
||||
Reference in New Issue
Block a user