566 lines
14 KiB
SQL
566 lines
14 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `account`.`role_syncPrivileges`()
|
|
BEGIN
|
|
/**
|
|
* Synchronizes permissions of MySQL role users based on role hierarchy.
|
|
* The computed role users of permission mix will be named according to
|
|
* pattern [vGenRolePrefix][roleName].
|
|
*
|
|
* If [vTplUser]@[vRoleHost] user exists, it will be taken as a template for
|
|
* basic attributes.
|
|
*
|
|
* Warning! This procedure should only be called when MySQL privileges
|
|
* are modified. If role hierarchy is modified, you must call the role_sync()
|
|
* procedure wich calls this internally.
|
|
*/
|
|
DECLARE vIsMariaDb BOOL DEFAULT VERSION() LIKE '%MariaDB%';
|
|
DECLARE vVersion INT DEFAULT SUBSTRING_INDEX(VERSION(), '.', 1);
|
|
DECLARE vTplUser VARCHAR(255);
|
|
DECLARE vRoleHost VARCHAR(255);
|
|
DECLARE vUserPrefix VARCHAR(2);
|
|
DECLARE vUserHost VARCHAR(255);
|
|
DECLARE vGenRolePrefix VARCHAR(2);
|
|
DECLARE vGenRoleHost VARCHAR(255);
|
|
DECLARE vPrefixedLike VARCHAR(255);
|
|
DECLARE vPassword VARCHAR(255) DEFAULT '';
|
|
|
|
SELECT rolePrefix, userPrefix, userHost, tplUser
|
|
INTO vGenRolePrefix, vUserPrefix, vUserHost, vTplUser
|
|
FROM roleConfig;
|
|
|
|
-- Deletes computed role users
|
|
|
|
SET vPrefixedLike = CONCAT(vGenRolePrefix, '%');
|
|
SET vGenRoleHost = vUserHost;
|
|
|
|
IF vIsMariaDb THEN
|
|
SET vRoleHost = '';
|
|
|
|
DELETE FROM mysql.global_priv
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
|
|
DELETE FROM mysql.roles_mapping
|
|
WHERE `User` LIKE vPrefixedLike
|
|
OR (
|
|
`Role` LIKE vPrefixedLike
|
|
AND (`User`, `Host`) = ('root', 'localhost')
|
|
);
|
|
ELSE
|
|
SET vRoleHost = 'localhost';
|
|
|
|
DELETE FROM mysql.user
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
END IF;
|
|
|
|
DELETE FROM mysql.db
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
|
|
DELETE FROM mysql.tables_priv
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
|
|
DELETE FROM mysql.columns_priv
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
|
|
DELETE FROM mysql.procs_priv
|
|
WHERE `User` LIKE vPrefixedLike;
|
|
|
|
DELETE FROM mysql.proxies_priv
|
|
WHERE `Proxied_user` LIKE vPrefixedLike;
|
|
|
|
-- Temporary tables
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tRole;
|
|
CREATE TEMPORARY TABLE tRole
|
|
(INDEX (id))
|
|
ENGINE = MEMORY
|
|
SELECT
|
|
id,
|
|
`name` `role`,
|
|
CONCAT(vGenRolePrefix, `name`) prefixedRole
|
|
FROM `role`
|
|
WHERE hasLogin;
|
|
|
|
-- Get role inheritance
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tRoleInherit;
|
|
CREATE TEMPORARY TABLE tRoleInherit
|
|
(INDEX (inheritsFrom))
|
|
ENGINE = MEMORY
|
|
SELECT
|
|
r.prefixedRole,
|
|
ri.`name` inheritsFrom
|
|
FROM tRole r
|
|
JOIN `roleRole` rr ON rr.role = r.id
|
|
JOIN `role` ri ON ri.id = rr.inheritsFrom
|
|
JOIN mysql.`user` u
|
|
ON u.`User` = ri.`name` AND u.`Host` = vRoleHost;
|
|
|
|
-- Recreate role users
|
|
|
|
IF vIsMariaDb THEN
|
|
-- Roles
|
|
|
|
INSERT INTO mysql.global_priv (`Host`, `User`, `Priv`)
|
|
SELECT vRoleHost, prefixedRole,
|
|
JSON_OBJECT(
|
|
'is_role', TRUE,
|
|
'access', 0
|
|
)
|
|
FROM tRole r
|
|
UNION
|
|
SELECT vRoleHost, CONCAT(vGenRolePrefix, 'root'),
|
|
JSON_OBJECT(
|
|
'is_role', TRUE,
|
|
'access', 0
|
|
);
|
|
|
|
INSERT INTO mysql.roles_mapping (`Host`, `User`, `Role`, `Admin_option`)
|
|
SELECT vRoleHost, prefixedRole, inheritsFrom, 'N'
|
|
FROM tRoleInherit
|
|
UNION
|
|
SELECT vRoleHost, CONCAT(vGenRolePrefix, 'root'), prefixedRole, 'Y'
|
|
FROM tRole;
|
|
|
|
INSERT INTO mysql.roles_mapping (`Host`, `User`, `Role`, `Admin_option`)
|
|
SELECT 'localhost', 'root', prefixedRole, 'Y'
|
|
FROM tRole
|
|
UNION
|
|
SELECT 'localhost', 'root', CONCAT(vGenRolePrefix, 'root'), 'Y';
|
|
|
|
-- Role users
|
|
|
|
INSERT INTO mysql.global_priv (
|
|
`User`,
|
|
`Host`,
|
|
`Priv`
|
|
)
|
|
SELECT
|
|
r.prefixedRole,
|
|
vGenRoleHost,
|
|
JSON_MERGE_PATCH(
|
|
IFNULL(t.`Priv`, '{}'),
|
|
IFNULL(u.`Priv`, '{}'),
|
|
JSON_OBJECT(
|
|
'mysql_old_password', JSON_VALUE(t.`Priv`, '$.mysql_old_password'),
|
|
'mysql_native_password', JSON_VALUE(t.`Priv`, '$.mysql_native_password'),
|
|
'authentication_string', JSON_VALUE(t.`Priv`, '$.authentication_string'),
|
|
'ssl_type', JSON_VALUE(t.`Priv`, '$.ssl_type'),
|
|
'default_role', r.prefixedRole,
|
|
'access', 0,
|
|
'is_role', FALSE
|
|
)
|
|
)
|
|
FROM tRole r
|
|
LEFT JOIN mysql.global_priv t
|
|
ON (t.`User`, t.Host) = (vTplUser, vRoleHost)
|
|
LEFT JOIN mysql.global_priv u
|
|
ON (u.`User`, u.Host) = (r.`role`, vRoleHost);
|
|
|
|
INSERT INTO mysql.roles_mapping (`Host`, `User`, `Role`, `Admin_option`)
|
|
SELECT vGenRoleHost, prefixedRole, prefixedRole, 'N'
|
|
FROM tRole;
|
|
|
|
-- Accounts
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tAccounts;
|
|
CREATE TEMPORARY TABLE tAccounts
|
|
(INDEX (`name`))
|
|
ENGINE = MEMORY
|
|
SELECT p.`User` `name`, r.prefixedRole
|
|
FROM mysql.global_priv p
|
|
JOIN `user` u ON u.`name` = p.`User`
|
|
JOIN tRole r ON r.`id` = u.`role`
|
|
WHERE JSON_EXTRACT(p.`Priv`, '$.autogenerated') = 'true';
|
|
|
|
UPDATE mysql.global_priv p
|
|
JOIN tAccounts c ON c.`name` = p.`User`
|
|
SET p.`Priv` = JSON_SET(p.`Priv`, '$.default_role', c.prefixedRole)
|
|
WHERE p.`Host` = vUserHost;
|
|
|
|
UPDATE IGNORE mysql.roles_mapping m
|
|
JOIN tAccounts c ON c.`name` = m.`User`
|
|
SET m.`Role` = c.prefixedRole
|
|
WHERE m.`Host` = vUserHost;
|
|
|
|
DROP TEMPORARY TABLE tAccounts;
|
|
ELSE
|
|
DROP TEMPORARY TABLE IF EXISTS tUser;
|
|
CREATE TEMPORARY TABLE tUser
|
|
SELECT
|
|
r.prefixedRole `User`,
|
|
vGenRoleHost `Host`,
|
|
IFNULL(t.`authentication_string`,
|
|
'') `authentication_string`,
|
|
IFNULL(t.`plugin`,
|
|
'mysql_native_password') `plugin`,
|
|
IFNULL(IF('' != u.`ssl_type`,
|
|
u.`ssl_type`, t.`ssl_type`),
|
|
'') `ssl_type`,
|
|
IFNULL(IF('' != u.`ssl_cipher`,
|
|
u.`ssl_cipher`, t.`ssl_cipher`),
|
|
'') `ssl_cipher`,
|
|
IFNULL(IF('' != u.`x509_issuer`,
|
|
u.`x509_issuer`, t.`x509_issuer`),
|
|
'') `x509_issuer`,
|
|
IFNULL(IF('' != u.`x509_subject`,
|
|
u.`x509_subject`, t.`x509_subject`),
|
|
'') `x509_subject`,
|
|
IFNULL(IF(0 != u.`max_questions`,
|
|
u.`max_questions`, t.`max_questions`),
|
|
0) `max_questions`,
|
|
IFNULL(IF(0 != u.`max_updates`,
|
|
u.`max_updates`, t.`max_updates`),
|
|
0) `max_updates`,
|
|
IFNULL(IF(0 != u.`max_connections`,
|
|
u.`max_connections`, t.`max_connections`),
|
|
0) `max_connections`,
|
|
IFNULL(IF(0 != u.`max_user_connections`,
|
|
u.`max_user_connections`, t.`max_user_connections`),
|
|
0) `max_user_connections`
|
|
FROM tRole r
|
|
LEFT JOIN mysql.user t
|
|
ON t.`User` = vTplUser
|
|
AND t.`Host` = vRoleHost
|
|
LEFT JOIN mysql.user u
|
|
ON u.`User` = r.role
|
|
AND u.`Host` = vRoleHost;
|
|
|
|
IF vVersion <= 5 THEN
|
|
SELECT `Password` INTO vPassword
|
|
FROM mysql.user
|
|
WHERE `User` = vTplUser
|
|
AND `Host` = vRoleHost;
|
|
|
|
INSERT INTO mysql.user (
|
|
`User`,
|
|
`Host`,
|
|
`Password`,
|
|
`authentication_string`,
|
|
`plugin`,
|
|
`ssl_type`,
|
|
`ssl_cipher`,
|
|
`x509_issuer`,
|
|
`x509_subject`,
|
|
`max_questions`,
|
|
`max_updates`,
|
|
`max_connections`,
|
|
`max_user_connections`
|
|
)
|
|
SELECT
|
|
`User`,
|
|
`Host`,
|
|
vPassword,
|
|
`authentication_string`,
|
|
`plugin`,
|
|
`ssl_type`,
|
|
`ssl_cipher`,
|
|
`x509_issuer`,
|
|
`x509_subject`,
|
|
`max_questions`,
|
|
`max_updates`,
|
|
`max_connections`,
|
|
`max_user_connections`
|
|
FROM tUser;
|
|
ELSE
|
|
INSERT INTO mysql.user (
|
|
`User`,
|
|
`Host`,
|
|
`authentication_string`,
|
|
`plugin`,
|
|
`ssl_type`,
|
|
`ssl_cipher`,
|
|
`x509_issuer`,
|
|
`x509_subject`,
|
|
`max_questions`,
|
|
`max_updates`,
|
|
`max_connections`,
|
|
`max_user_connections`
|
|
)
|
|
SELECT
|
|
`User`,
|
|
`Host`,
|
|
`authentication_string`,
|
|
`plugin`,
|
|
`ssl_type`,
|
|
`ssl_cipher`,
|
|
`x509_issuer`,
|
|
`x509_subject`,
|
|
`max_questions`,
|
|
`max_updates`,
|
|
`max_connections`,
|
|
`max_user_connections`
|
|
FROM tUser;
|
|
END IF;
|
|
|
|
DROP TEMPORARY TABLE tUser;
|
|
|
|
-- Proxy privileges
|
|
|
|
INSERT INTO mysql.proxies_priv (
|
|
`User`,
|
|
`Host`,
|
|
`Proxied_user`,
|
|
`Proxied_host`,
|
|
`Grantor`
|
|
)
|
|
SELECT
|
|
'',
|
|
vUserHost,
|
|
prefixedRole,
|
|
vGenRoleHost,
|
|
CONCAT(prefixedRole, '@', vGenRoleHost)
|
|
FROM tRole;
|
|
|
|
-- Global privileges
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tUserPriv;
|
|
CREATE TEMPORARY TABLE tUserPriv
|
|
(INDEX (prefixedRole))
|
|
ENGINE = MEMORY
|
|
SELECT
|
|
r.prefixedRole,
|
|
MAX(u.`Select_priv`) `Select_priv`,
|
|
MAX(u.`Insert_priv`) `Insert_priv`,
|
|
MAX(u.`Update_priv`) `Update_priv`,
|
|
MAX(u.`Delete_priv`) `Delete_priv`,
|
|
MAX(u.`Create_priv`) `Create_priv`,
|
|
MAX(u.`Drop_priv`) `Drop_priv`,
|
|
MAX(u.`Reload_priv`) `Reload_priv`,
|
|
MAX(u.`Shutdown_priv`) `Shutdown_priv`,
|
|
MAX(u.`Process_priv`) `Process_priv`,
|
|
MAX(u.`File_priv`) `File_priv`,
|
|
MAX(u.`Grant_priv`) `Grant_priv`,
|
|
MAX(u.`References_priv`) `References_priv`,
|
|
MAX(u.`Index_priv`) `Index_priv`,
|
|
MAX(u.`Alter_priv`) `Alter_priv`,
|
|
MAX(u.`Show_db_priv`) `Show_db_priv`,
|
|
MAX(u.`Super_priv`) `Super_priv`,
|
|
MAX(u.`Create_tmp_table_priv`) `Create_tmp_table_priv`,
|
|
MAX(u.`Lock_tables_priv`) `Lock_tables_priv`,
|
|
MAX(u.`Execute_priv`) `Execute_priv`,
|
|
MAX(u.`Repl_slave_priv`) `Repl_slave_priv`,
|
|
MAX(u.`Repl_client_priv`) `Repl_client_priv`,
|
|
MAX(u.`Create_view_priv`) `Create_view_priv`,
|
|
MAX(u.`Show_view_priv`) `Show_view_priv`,
|
|
MAX(u.`Create_routine_priv`) `Create_routine_priv`,
|
|
MAX(u.`Alter_routine_priv`) `Alter_routine_priv`,
|
|
MAX(u.`Create_user_priv`) `Create_user_priv`,
|
|
MAX(u.`Event_priv`) `Event_priv`,
|
|
MAX(u.`Trigger_priv`) `Trigger_priv`,
|
|
MAX(u.`Create_tablespace_priv`) `Create_tablespace_priv`
|
|
FROM tRoleInherit r
|
|
JOIN mysql.user u
|
|
ON u.`User` = r.inheritsFrom
|
|
AND u.`Host`= vRoleHost
|
|
GROUP BY r.prefixedRole;
|
|
|
|
UPDATE mysql.user u
|
|
JOIN tUserPriv t
|
|
ON u.`User` = t.prefixedRole
|
|
AND u.`Host` = vGenRoleHost
|
|
SET
|
|
u.`Select_priv`
|
|
= t.`Select_priv`,
|
|
u.`Insert_priv`
|
|
= t.`Insert_priv`,
|
|
u.`Update_priv`
|
|
= t.`Update_priv`,
|
|
u.`Delete_priv`
|
|
= t.`Delete_priv`,
|
|
u.`Create_priv`
|
|
= t.`Create_priv`,
|
|
u.`Drop_priv`
|
|
= t.`Drop_priv`,
|
|
u.`Reload_priv`
|
|
= t.`Reload_priv`,
|
|
u.`Shutdown_priv`
|
|
= t.`Shutdown_priv`,
|
|
u.`Process_priv`
|
|
= t.`Process_priv`,
|
|
u.`File_priv`
|
|
= t.`File_priv`,
|
|
u.`Grant_priv`
|
|
= t.`Grant_priv`,
|
|
u.`References_priv`
|
|
= t.`References_priv`,
|
|
u.`Index_priv`
|
|
= t.`Index_priv`,
|
|
u.`Alter_priv`
|
|
= t.`Alter_priv`,
|
|
u.`Show_db_priv`
|
|
= t.`Show_db_priv`,
|
|
u.`Super_priv`
|
|
= t.`Super_priv`,
|
|
u.`Create_tmp_table_priv`
|
|
= t.`Create_tmp_table_priv`,
|
|
u.`Lock_tables_priv`
|
|
= t.`Lock_tables_priv`,
|
|
u.`Execute_priv`
|
|
= t.`Execute_priv`,
|
|
u.`Repl_slave_priv`
|
|
= t.`Repl_slave_priv`,
|
|
u.`Repl_client_priv`
|
|
= t.`Repl_client_priv`,
|
|
u.`Create_view_priv`
|
|
= t.`Create_view_priv`,
|
|
u.`Show_view_priv`
|
|
= t.`Show_view_priv`,
|
|
u.`Create_routine_priv`
|
|
= t.`Create_routine_priv`,
|
|
u.`Alter_routine_priv`
|
|
= t.`Alter_routine_priv`,
|
|
u.`Create_user_priv`
|
|
= t.`Create_user_priv`,
|
|
u.`Event_priv`
|
|
= t.`Event_priv`,
|
|
u.`Trigger_priv`
|
|
= t.`Trigger_priv`,
|
|
u.`Create_tablespace_priv`
|
|
= t.`Create_tablespace_priv`;
|
|
|
|
DROP TEMPORARY TABLE tUserPriv;
|
|
|
|
-- Schema level privileges
|
|
|
|
INSERT INTO mysql.db (
|
|
`User`,
|
|
`Host`,
|
|
`Db`,
|
|
`Select_priv`,
|
|
`Insert_priv`,
|
|
`Update_priv`,
|
|
`Delete_priv`,
|
|
`Create_priv`,
|
|
`Drop_priv`,
|
|
`Grant_priv`,
|
|
`References_priv`,
|
|
`Index_priv`,
|
|
`Alter_priv`,
|
|
`Create_tmp_table_priv`,
|
|
`Lock_tables_priv`,
|
|
`Create_view_priv`,
|
|
`Show_view_priv`,
|
|
`Create_routine_priv`,
|
|
`Alter_routine_priv`,
|
|
`Execute_priv`,
|
|
`Event_priv`,
|
|
`Trigger_priv`
|
|
)
|
|
SELECT
|
|
r.prefixedRole,
|
|
vGenRoleHost,
|
|
t.`Db`,
|
|
MAX(t.`Select_priv`),
|
|
MAX(t.`Insert_priv`),
|
|
MAX(t.`Update_priv`),
|
|
MAX(t.`Delete_priv`),
|
|
MAX(t.`Create_priv`),
|
|
MAX(t.`Drop_priv`),
|
|
MAX(t.`Grant_priv`),
|
|
MAX(t.`References_priv`),
|
|
MAX(t.`Index_priv`),
|
|
MAX(t.`Alter_priv`),
|
|
MAX(t.`Create_tmp_table_priv`),
|
|
MAX(t.`Lock_tables_priv`),
|
|
MAX(t.`Create_view_priv`),
|
|
MAX(t.`Show_view_priv`),
|
|
MAX(t.`Create_routine_priv`),
|
|
MAX(t.`Alter_routine_priv`),
|
|
MAX(t.`Execute_priv`),
|
|
MAX(t.`Event_priv`),
|
|
MAX(t.`Trigger_priv`)
|
|
FROM tRoleInherit r
|
|
JOIN mysql.db t
|
|
ON t.`User` = r.inheritsFrom
|
|
AND t.`Host`= vRoleHost
|
|
GROUP BY r.prefixedRole, t.`Db`;
|
|
|
|
-- Table level privileges
|
|
|
|
INSERT INTO mysql.tables_priv (
|
|
`User`,
|
|
`Host`,
|
|
`Db`,
|
|
`Table_name`,
|
|
`Grantor`,
|
|
`Timestamp`,
|
|
`Table_priv`,
|
|
`Column_priv`
|
|
)
|
|
SELECT
|
|
r.prefixedRole,
|
|
vGenRoleHost,
|
|
t.`Db`,
|
|
t.`Table_name`,
|
|
t.`Grantor`,
|
|
MAX(t.`Timestamp`),
|
|
IFNULL(GROUP_CONCAT(NULLIF(t.`Table_priv`, '')), ''),
|
|
IFNULL(GROUP_CONCAT(NULLIF(t.`Column_priv`, '')), '')
|
|
FROM tRoleInherit r
|
|
JOIN mysql.tables_priv t
|
|
ON t.`User` = r.inheritsFrom
|
|
AND t.`Host`= vRoleHost
|
|
GROUP BY r.prefixedRole, t.`Db`, t.`Table_name`;
|
|
|
|
-- Column level privileges
|
|
|
|
INSERT INTO mysql.columns_priv (
|
|
`User`,
|
|
`Host`,
|
|
`Db`,
|
|
`Table_name`,
|
|
`Column_name`,
|
|
`Timestamp`,
|
|
`Column_priv`
|
|
)
|
|
SELECT
|
|
r.prefixedRole,
|
|
vGenRoleHost,
|
|
t.`Db`,
|
|
t.`Table_name`,
|
|
t.`Column_name`,
|
|
MAX(t.`Timestamp`),
|
|
IFNULL(GROUP_CONCAT(NULLIF(t.`Column_priv`, '')), '')
|
|
FROM tRoleInherit r
|
|
JOIN mysql.columns_priv t
|
|
ON t.`User` = r.inheritsFrom
|
|
AND t.`Host`= vRoleHost
|
|
GROUP BY r.prefixedRole, t.`Db`, t.`Table_name`, t.`Column_name`;
|
|
|
|
-- Routine privileges
|
|
|
|
INSERT IGNORE INTO mysql.procs_priv (
|
|
`User`,
|
|
`Host`,
|
|
`Db`,
|
|
`Routine_name`,
|
|
`Routine_type`,
|
|
`Grantor`,
|
|
`Timestamp`,
|
|
`Proc_priv`
|
|
)
|
|
SELECT
|
|
r.prefixedRole,
|
|
vGenRoleHost,
|
|
t.`Db`,
|
|
t.`Routine_name`,
|
|
t.`Routine_type`,
|
|
t.`Grantor`,
|
|
t.`Timestamp`,
|
|
t.`Proc_priv`
|
|
FROM tRoleInherit r
|
|
JOIN mysql.procs_priv t
|
|
ON t.`User` = r.inheritsFrom
|
|
AND t.`Host`= vRoleHost;
|
|
END IF;
|
|
|
|
-- Cleanup
|
|
|
|
DROP TEMPORARY TABLE
|
|
tRole,
|
|
tRoleInherit;
|
|
|
|
FLUSH PRIVILEGES;
|
|
END$$
|
|
DELIMITER ;
|