DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` FUNCTION `account`.`user_hasRoutinePriv`(vType ENUM('PROCEDURE', 'FUNCTION'), vChain VARCHAR(100), vUserFk INT ) RETURNS tinyint(1) NOT DETERMINISTIC READS SQL DATA BEGIN /** * Search if the user has privileges on routines. * * @param vType procedure or function * @param vChain string passed with this syntax dbName.tableName * @param vUserFk user to ckeck * @return vHasPrivilege */ DECLARE vHasPrivilege BOOL DEFAULT FALSE; DECLARE vDb VARCHAR(50); DECLARE vObject VARCHAR(50); DECLARE vChainExists BOOL; DECLARE vExecutePriv INT DEFAULT 262144; -- 262144 = CONV(1000000000000000000, 2, 10) -- 1000000000000000000 execution permission expressed in binary base SET vDb = SUBSTRING_INDEX(vChain, '.', 1); SET vChain = SUBSTRING(vChain, LENGTH(vDb) + 2); SET vObject = SUBSTRING_INDEX(vChain, '.', 1); SELECT COUNT(*) INTO vChainExists FROM mysql.proc WHERE db = vDb AND `name` = vObject AND `type` = vType LIMIT 1; IF NOT vChainExists THEN RETURN FALSE; END IF; DROP TEMPORARY TABLE IF EXISTS tRole; CREATE TEMPORARY TABLE tRole (INDEX (`name`)) ENGINE = MEMORY SELECT r.`name` FROM user u JOIN roleRole rr ON rr.role = u.role JOIN `role` r ON r.id = rr.inheritsFrom WHERE u.id = vUserFk; SELECT TRUE INTO vHasPrivilege FROM mysql.global_priv gp JOIN tRole tr ON tr.name = gp.`User` OR CONCAT('$', tr.name) = gp.`User` WHERE JSON_VALUE(gp.Priv, '$.access') >= vExecutePriv AND gp.Host = '' LIMIT 1; IF NOT vHasPrivilege THEN SELECT TRUE INTO vHasPrivilege FROM mysql.db db JOIN tRole tr ON tr.name = db.`User` WHERE db.Db = vDb AND db.Execute_priv = 'Y'; END IF; IF NOT vHasPrivilege THEN SELECT TRUE INTO vHasPrivilege FROM mysql.procs_priv pp JOIN tRole tr ON tr.name = pp.`User` WHERE pp.Db = vDb AND pp.Routine_name = vObject AND pp.Routine_type = vType AND pp.Proc_priv = 'Execute' LIMIT 1; END IF; DROP TEMPORARY TABLE tRole; RETURN vHasPrivilege; END$$ DELIMITER ;