diff --git a/.gitattributes b/.gitattributes new file mode 100644 index 0000000..bdb0cab --- /dev/null +++ b/.gitattributes @@ -0,0 +1,17 @@ +# Auto detect text files and perform LF normalization +* text=auto + +# Custom for Visual Studio +*.cs diff=csharp + +# Standard to msysgit +*.doc diff=astextplain +*.DOC diff=astextplain +*.docx diff=astextplain +*.DOCX diff=astextplain +*.dot diff=astextplain +*.DOT diff=astextplain +*.pdf diff=astextplain +*.PDF diff=astextplain +*.rtf diff=astextplain +*.RTF diff=astextplain diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..96374c4 --- /dev/null +++ b/.gitignore @@ -0,0 +1,43 @@ +# Windows image file caches +Thumbs.db +ehthumbs.db + +# Folder config file +Desktop.ini + +# Recycle Bin used on file shares +$RECYCLE.BIN/ + +# Windows Installer files +*.cab +*.msi +*.msm +*.msp + +# Windows shortcuts +*.lnk + +# ========================= +# Operating System Files +# ========================= + +# OSX +# ========================= + +.DS_Store +.AppleDouble +.LSOverride + +# Thumbnails +._* + +# Files that might appear on external disk +.Spotlight-V100 +.Trashes + +# Directories potentially created on remote AFP share +.AppleDB +.AppleDesktop +Network Trash Folder +Temporary Items +.apdisk diff --git a/LICENSE b/LICENSE new file mode 100644 index 0000000..935841d --- /dev/null +++ b/LICENSE @@ -0,0 +1,19 @@ +Copyright (c) 2015 Choobs Ltd. + +Permission is hereby granted, free of charge, to any person obtaining a copy +of this software and associated documentation files (the "Software"), to deal +in the Software without restriction, including without limitation the rights +to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +copies of the Software, and to permit persons to whom the Software is +furnished to do so, subject to the following conditions: + +The above copyright notice and this permission notice shall be included in all +copies or substantial portions of the Software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +SOFTWARE. \ No newline at end of file diff --git a/README.md b/README.md new file mode 100644 index 0000000..73f4268 --- /dev/null +++ b/README.md @@ -0,0 +1,120 @@ +Choobs MySQL Grants Toolkit +=========================== + +MySQL's [GRANT syntax](http://dev.mysql.com/doc/refman/5.0/en/grant.html "MySQL 5.0 Reference Manual") uses the WITH GRANT OPTION which lets you GRANT a permission to a user and then allows the user to GRANT that permission further. However a limitation of MySQL is that the option is automatically valid for **all** permissions you granted the user, not just the one that you specified with the WITH GRANT OPTION. + +This means that the moment you use the WITH GRANT OPTION the user automatically can give his permissions and the power to GRANT to another user. In effect with the help of another user the current user can gain all the permissions of the other user. + +This toolkit restricts the GRANT OPTION by adding a layer of checking which means you can only apply grants for a specific set of permissions (wether you have them or not). + +You can therefore limit the propagation of permissions between users to a well defined set of permissions and databases/tables. + +##Documentation + +MySQL stores table privileges in mysql.tables_priv and column privileges in mysql.columns_priv internally. However, since GRANT statement has the aforementioned issue, we avoid giving actual GRANT permissions to the users. +Instead, we give EXECUTE privilege to custom procedures which do what the GRANT/REVOKE statements do after checking if the user is allowed to grant the privilege. The list of privileges the user is allowed to grant is stored in a custom table. The users don't actually have the GRANT privilege, so they can't bypass the security using GRANT statement. + +#### Compatibility +Limited testing was done on MySQL and MariaDB. In principle any MySQL compatible database server version 5.0 and later should work. Please let us know if you have any issues with your database. + +#### Setup +Use the install-mysqlgt-5.0.sql for MySQL version >=5.0 and <5.5 and install-mysqlgt-5.5.sql for MySQL version >=5.5. The script must be run as root. + +After you run it, a new schema mysqlgt is created with tables mysqlgt.db_grant and mysqlgt.log and new procedures mysqlgt.gtSIMPLIFY_DATA, mysqlgt.gtGRANT and mysqlgt.gtREVOKE are created. + +To allow a user (say test_user) to grant only the specified privileges: + + * give EXECUTE permissions to the user to execute mysqlgt.gtGRANT and mysqlgt.gtREVOKE + * insert a row in mysqlgt.db_grant specifying what table privileges a user is allowed to grant + +##### Example: + +In the following example, a user test_user@localhost is allowed to grant SELECT, UPDATE, INSERT and DELETE privileges on database test_db: + +```sql +-- Allow EXECUTE for 'test_user'@'localhost' on mysqlgt procedures +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtREVOKE` TO 'test_user'@'localhost'; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtGRANT` TO 'test_user'@'localhost'; + +-- Allow the user to reload privileges after updating grants +-- make sure you are comfortable giving this permission to the user +-- allows reloading of logs, replication sync and a few other reloads +GRANT RELOAD ON *.* TO 'test_user'@'localhost'; + +REPLACE INTO `mysqlgt`.`db_grant` (`Host`, `Db`, `User`, `Table_priv`) VALUES +-- Allow SELECT,INSERT,UPDATE,DELETE GRANT for test@% on schema test + ('%', 'test_db', 'test_user', 'select,insert,update,delete') +``` + +Please note that in mysqlgt.db_grant, Host is set to '%'. Please check the [Known Issues](#known-issues) section for more information about why this is done here. + +#### Usage +Now, the user (test_user) will be allowed to grant/revoke privileges to/from other users in the following ways: + +```sql +CALL mysqlgt.gtGRANT ( PERMISSIONS, DB.TABLE[.COLUMN], USER@HOST ) +CALL mysqlgt.gtREVOKE ( PERMISSIONS, DB.TABLE[.COLUMN], USER@HOST ) +``` + +##### Examples: +###### Table privileges: + +```sql +CALL mysqlgt.gtGRANT ( 'Delete,Insert,Update', 'mydb.mytable', 'myuser@hostname' ); +CALL mysqlgt.gtREVOKE ( 'Update,Delete', 'mydb.mytable', 'myuser@hostname' ); +``` + +###### Column privileges: + +```sql +CALL mysqlgt.gtGRANT ( 'Select,Insert,Update', 'mydb.mytable.mycol', 'myuser@hostname' ); +CALL mysqlgt.gtREVOKE ( 'Select,Insert', 'mydb.mytable.mycol', 'myuser@hostname' ); +``` + +##### Notes: + +Please note that mysqlgt.gtGRANT and mysqlgt.gtREVOKE will not always replace single GRANT/REVOKE statement with a single call. Consider the following MySQL GRANT Statement: +```sql +GRANT SELECT (mycol1), INSERT (mycol1,mycol2), DELETE ON mydb.mytbl TO 'myuser'@'hostname'; +``` + +Equavalent mysqlgt calls to acheive the above will be: +```sql +CALL mysqlgt.gtGRANT ( 'Select,Insert', 'mydb.mytable.mycol1', 'myuser@hostname' ); +CALL mysqlgt.gtGRANT ( 'Insert', 'mydb.mytable.mycol2', 'myuser@hostname' ); +CALL mysqlgt.gtGRANT ( 'Delete', 'mydb.mytable', 'myuser@hostname' ); +``` + +Also, note that it currently only supports table and column privileges, it doesn't support database privileges. So, there is no equivalent for the following statement: +```sql +GRANT SELECT ON mydb.* TO 'myuser'@'hostname'; +``` +This feature is planned for future release. + +#### Known Issues +Because using the function `CURRENT_USER()` returns the DEFINER inside of our PROCEDURE instead of the calling user. We were forced to use `USER()` which returns the connected user. However this introduces the following issue. + +In the row in mysqlgt.db_grant, Host must be set to whatever the user connects with, not what is in the user db. If name resolve is enabled and you are in an intranet, it is possible that the server will get the hostname (instead of the IP) eg. user@my-pc-hostname instead of user@192.168.1.123 + +This can be an issue for configuration. The following approaches can be used to workaround this limitation: + + * disable dns resolve on the MySQL server (add skip-name-resolve under [mysqld] in my.ini) and use static IPs for your users + * use the exact hostname of your user + * use % to match anything, the user will already be authenticated by MySQL according to its HOST rules + +#### Contributing To Choobs MySQL Grants Toolkit + +Since this is hosted on github: + +**All issues and pull requests should be filed on the [choobs/mysqlgt](http://github.com/choobs/mysqlgt) repository.** + +Thank you. + +## Authors + + * Erik DeLamarter (erik.delamarter@choobs.com) + * Pravin Dahal + +## License + +The Choobs MySQL Grants Toolkit is open-sourced software licensed under the [MIT license](http://opensource.org/licenses/MIT) diff --git a/install-mysqlgt-5.0.sql b/install-mysqlgt-5.0.sql new file mode 100644 index 0000000..5d49cac --- /dev/null +++ b/install-mysqlgt-5.0.sql @@ -0,0 +1,281 @@ +-- Create the Schema +CREATE SCHEMA IF NOT EXISTS `mysqlgt`; + +-- Setup a user for internal use only with an unknown random password +-- CREATE USER `mysqlgt`@`*internal-only*`; +-- UPDATE mysql.`user` SET `Password` = PASSWORD(MD5(RAND())) WHERE `user` = 'mysqlgt' AND `Host` = "*internal-only*"; + +-- Setup mysqlgt tables and procedures +CREATE TABLE IF NOT EXISTS `mysqlgt`.`db_grant` ( + `Host` char(60) COLLATE utf8_bin NOT NULL DEFAULT '', + `Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '', + `User` char(16) COLLATE utf8_bin NOT NULL DEFAULT '', + `Table_priv` set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') CHARACTER SET utf8 NOT NULL DEFAULT '', + PRIMARY KEY (`Host`,`Db`,`User`), + KEY `User` (`User`) +) +ENGINE=MyISAM +DEFAULT CHARSET=utf8 +COLLATE=utf8_bin; + +CREATE TABLE IF NOT EXISTS `mysqlgt`.`log` ( + `idlog` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, + `timestamp` TIMESTAMP, + `user` char(77), # 16 + 1 + 60 + `destination` char(194), # 64 + 1 + 64 + 1 + 64 + `log` TEXT, + PRIMARY KEY (`idlog`) +) +ENGINE = InnoDB +DEFAULT CHARACTER SET = utf8 +COLLATE = utf8_general_ci; + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtSIMPLIFY_DATA`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtSIMPLIFY_DATA` ( + IN tbl_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77), # 16 + 1 + 60 + OUT new_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'), + OUT new_db char(64), + OUT new_table_name char(64), + OUT new_column_name char(64), + OUT new_user char(16), + OUT new_host char(60), + OUT invoker_user char(16), + OUT invoker_host char(60), + OUT allowed_operations set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') +) +SQL SECURITY DEFINER +BEGIN + DECLARE grant_s_priv, grant_u_priv, grant_d_priv, grant_i_priv TEXT; + + #break user@host to user and host + SET new_user = replace(substring(substring_index(new_user_at_host, '@', 1), length(substring_index(new_user_at_host, '@', 1 - 1)) + 1), '@', ''); + SET new_host = replace(substring(substring_index(new_user_at_host, '@', 2), length(substring_index(new_user_at_host, '@', 2 - 1)) + 1), '@', ''); + + #break db.tablename.columnname to db, tablename and columnname + SET new_db = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 1), length(substring_index(new_db_dot_table_dot_column, '.', 1 - 1)) + 1), '.', ''); + SET new_table_name = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 2), length(substring_index(new_db_dot_table_dot_column, '.', 2 - 1)) + 1), '.', ''); + SET new_column_name = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 3), length(substring_index(new_db_dot_table_dot_column, '.', 3 - 1)) + 1), '.', ''); + + IF (new_db = '') OR (new_table_name = '') THEN + DROP TABLE `Parameter_not_in_expected_format_db.table_column`; + END IF; + + #get invoker_user and invoker_host + SET invoker_user = replace(substring(substring_index(USER(), '@', 1), length(substring_index(USER(), '@', 1 - 1)) + 1), '@', ''); + SET invoker_host = replace(substring(substring_index(USER(), '@', 2), length(substring_index(USER(), '@', 2 - 1)) + 1), '@', ''); + + #read allowed operations + SELECT '' INTO allowed_operations; + SELECT `Table_priv` INTO allowed_operations FROM mysqlgt.db_grant WHERE (`User`=invoker_user OR `User`='') AND (`Host`=invoker_host OR `Host`='%') AND (`Db`=new_db); + + #if requested grant is 'all', set it to all grants (no point of this now, however could come handy in the future) + IF find_in_set('all', tbl_priv) THEN + SET new_table_priv = 'Select,Insert,Update,Delete,Create,Drop,References,Index,Alter,Create View,Show view,Trigger'; + ELSE + SET new_table_priv = tbl_priv; + END IF; + +END // +DELIMITER ; + + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtGRANT`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtGRANT` ( + IN new_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77) # 16 + 1 + 60 +) +MODIFIES SQL DATA +SQL SECURITY DEFINER +BEGIN + + DECLARE error_message TEXT; + DECLARE error_message_128 VARCHAR(128); + DECLARE allowed INT; + DECLARE allowed_operations_table, new_table_priv_processed set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'); + DECLARE operation_temp, allowed_operations_column, new_column_priv_processed, current_column_priv set('Select','Insert','Update','References'); + + CALL `mysqlgt`.`gtSIMPLIFY_DATA`( + new_table_priv, new_db_dot_table_dot_column, new_user_at_host, + @new_priv_processed, @new_db, @new_table_name, @new_column_name, + @new_user, @new_host, @invoker_user, @invoker_host, @allowed_operations + ); + + SELECT '' INTO new_table_priv_processed; + SELECT '' INTO new_column_priv_processed; + SELECT '' INTO allowed_operations_table; + SELECT '' INTO allowed_operations_column; + SELECT '' INTO current_column_priv; + + SELECT `Column_priv` INTO current_column_priv FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + + IF @new_column_name = '' THEN + SELECT @allowed_operations INTO allowed_operations_table; + SELECT @new_priv_processed INTO new_table_priv_processed; + SELECT ((allowed_operations_table & new_table_priv_processed) = new_table_priv_processed) INTO allowed; + ELSE + IF find_in_set('Select', @allowed_operations) THEN + SELECT 'Select' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Insert', @allowed_operations) THEN + SELECT 'Insert' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Update', @allowed_operations) THEN + SELECT 'Update' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('References', @allowed_operations) THEN + SELECT 'References' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + + SELECT @new_priv_processed INTO new_column_priv_processed; + SELECT ((allowed_operations_column & new_column_priv_processed) = new_column_priv_processed) INTO allowed; + END IF; + + #if allowed, insert to mysql internal table and log + IF allowed = 1 THEN + INSERT INTO `mysql`.`tables_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,CURRENT_USER(),CURRENT_TIMESTAMP(),new_table_priv_processed,new_column_priv_processed) + ON DUPLICATE KEY UPDATE `Table_priv` = (`Table_priv` | new_table_priv_processed), `Column_priv` = (current_column_priv | new_column_priv_processed), `Timestamp` = CURRENT_TIMESTAMP(), `Grantor` = CURRENT_USER(); + IF @new_column_name != '' THEN + INSERT INTO `mysql`.`columns_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,@new_column_name,CURRENT_TIMESTAMP(),new_column_priv_processed) + ON DUPLICATE KEY UPDATE `Column_priv` = (`Column_priv` | new_column_priv_processed), `Timestamp` = CURRENT_TIMESTAMP(); + END IF; + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,CONCAT('user granted ', new_table_priv_processed, ' to ', @new_user, '@', @new_host, ' on ', new_db_dot_table_dot_column)); + ELSE + SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to grant ', new_table_priv_processed, ', only allowed to grant ', @allowed_operations); + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,error_message); + DROP TABLE `Error_see_mysqlgt_log`; + END IF; + +END // +DELIMITER ; + + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtREVOKE`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtREVOKE` ( + IN unset_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77) # 16 + 1 + 60 +) +MODIFIES SQL DATA +SQL SECURITY DEFINER +BEGIN + + DECLARE val INT; + DECLARE error_message TEXT; + DECLARE error_message_128 VARCHAR(128); + DECLARE current_table_priv, new_table_priv, revoked_priv, allowed_operations_table set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'); + DECLARE allowed INT; + DECLARE revoked_column_priv, operation_temp, new_column_priv_column, new_column_priv_table, allowed_operations_column, current_column_priv_column, current_column_priv_table set('Select','Insert','Update','References'); + + CALL `mysqlgt`.`gtSIMPLIFY_DATA`( + unset_table_priv, new_db_dot_table_dot_column, new_user_at_host, + @unset_priv_processed, @new_db, @new_table_name, @new_column_name, + @new_user, @new_host, @invoker_user, @invoker_host, @allowed_operations + ); + + SELECT '' INTO current_table_priv; + SELECT '' INTO current_column_priv_column; + SELECT '' INTO current_column_priv_table; + SELECT '' INTO allowed_operations_column; + SELECT '' INTO revoked_column_priv; + SELECT '' INTO revoked_priv; + + SELECT `Table_priv` INTO current_table_priv FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + SELECT `Column_priv` INTO current_column_priv_column FROM `mysql`.`columns_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name AND `Column_name`=@new_column_name; + SELECT `Column_priv` INTO current_column_priv_table FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + + + IF @new_column_name = '' THEN + SELECT current_column_priv_table INTO new_column_priv_table; + + SELECT @unset_priv_processed INTO new_table_priv; + SELECT (current_table_priv & ~new_table_priv) INTO new_table_priv; + SELECT (current_table_priv & ~new_table_priv) INTO revoked_priv; + + SELECT @allowed_operations INTO allowed_operations_table; + SELECT ((revoked_priv & allowed_operations_table) = revoked_priv) INTO allowed; + ELSE + SELECT current_table_priv INTO new_table_priv; + + IF find_in_set('Select', @allowed_operations) THEN + SELECT 'Select' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Insert', @allowed_operations) THEN + SELECT 'Insert' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Update', @allowed_operations) THEN + SELECT 'Update' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('References', @allowed_operations) THEN + SELECT 'References' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + + SELECT @unset_priv_processed INTO new_column_priv_column; + SELECT (current_column_priv_column & ~new_column_priv_column) INTO new_column_priv_column; + SELECT (current_column_priv_column & ~new_column_priv_column) INTO revoked_column_priv; + + SELECT @unset_priv_processed INTO new_column_priv_table; + SELECT (current_column_priv_table & ~new_column_priv_table) INTO new_column_priv_table; + + SELECT ((revoked_column_priv & allowed_operations_column) = revoked_column_priv) INTO allowed; + + END IF; + + #if allowed, insert to mysql internal table and log + IF allowed = 1 THEN + IF new_table_priv = 0 AND new_column_priv_table = 0 THEN + #if it is deleted and column is not blank, it automatically seems to set the Table_priv to '' while not deleting the row + #so this works fine, however this needs to be tested with older version of MySQL + DELETE FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + ELSE + INSERT INTO `mysql`.`tables_priv` VALUES(@new_host, @new_db, @new_user, @new_table_name, CURRENT_USER(), CURRENT_TIMESTAMP(), new_table_priv, new_column_priv_table) + ON DUPLICATE KEY UPDATE `Table_priv` = new_table_priv, `Column_priv` = new_column_priv_table, `Timestamp` = CURRENT_TIMESTAMP(), `Grantor` = CURRENT_USER(); + END IF; + + IF @new_column_name != '' THEN + IF new_column_priv_column = 0 THEN + DELETE FROM `mysql`.`columns_priv` WHERE `Host`=@new_host and `Db`=@new_db and `User`=@new_user and `Table_name`=@new_table_name AND `Column_name`=@new_column_name; + ELSE + INSERT INTO `mysql`.`columns_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,@new_column_name,CURRENT_TIMESTAMP(),new_column_priv_column) + ON DUPLICATE KEY UPDATE `Column_priv` = new_column_priv_column, `Timestamp` = CURRENT_TIMESTAMP(); + END IF; + END IF; + + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,CONCAT('user revoked ', @unset_priv_processed, ' from ', @new_user, '@', @new_host, ' on ', new_db_dot_table_dot_column)); + ELSE + SET error_message = CONCAT(@invoker_user, '@', @invoker_host, ' is not allowed to revoke ', revoked_priv, ', only allowed to revoke ', @allowed_operations); + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,error_message); + DROP TABLE `Error_see_mysqlgt_log`; + END IF; + +END // +DELIMITER ; + + +-- Setup grants for the internal user so he can check permissions , insert to log and execute the procedures +GRANT INSERT ON `mysqlgt`.`log` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT ON `mysqlgt`.`db_grant` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT,INSERT,UPDATE,DELETE ON `mysql`.`tables_priv` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT,INSERT,UPDATE,DELETE ON `mysql`.`columns_priv` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtSIMPLIFY_DATA` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtGRANT` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtREVOKE` TO `mysqlgt`@`*internal-only*`; diff --git a/install-mysqlgt-5.5.sql b/install-mysqlgt-5.5.sql new file mode 100644 index 0000000..4fa5b55 --- /dev/null +++ b/install-mysqlgt-5.5.sql @@ -0,0 +1,283 @@ +-- Create the Schema +CREATE SCHEMA IF NOT EXISTS `mysqlgt`; + +-- Setup a user for internal use only with an unknown random password +CREATE USER `mysqlgt`@`*internal-only*`; +UPDATE mysql.`user` SET `Password` = PASSWORD(MD5(RAND())) WHERE `user` = 'mysqlgt' AND `Host` = "*internal-only*"; + +-- Setup mysqlgt tables and procedures +CREATE TABLE IF NOT EXISTS `mysqlgt`.`db_grant` ( + `Host` char(60) COLLATE utf8_bin NOT NULL DEFAULT '', + `Db` char(64) COLLATE utf8_bin NOT NULL DEFAULT '', + `User` char(16) COLLATE utf8_bin NOT NULL DEFAULT '', + `Table_priv` set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') CHARACTER SET utf8 NOT NULL DEFAULT '', + PRIMARY KEY (`Host`,`Db`,`User`), + KEY `User` (`User`) +) +ENGINE=MyISAM +DEFAULT CHARSET=utf8 +COLLATE=utf8_bin; + +CREATE TABLE IF NOT EXISTS `mysqlgt`.`log` ( + `idlog` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT, + `timestamp` TIMESTAMP, + `user` char(77), # 16 + 1 + 60 + `destination` char(194), # 64 + 1 + 64 + 1 + 64 + `log` TEXT, + PRIMARY KEY (`idlog`) +) +ENGINE = InnoDB +DEFAULT CHARACTER SET = utf8 +COLLATE = utf8_general_ci; + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtSIMPLIFY_DATA`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtSIMPLIFY_DATA` ( + IN tbl_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77), # 16 + 1 + 60 + OUT new_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'), + OUT new_db char(64), + OUT new_table_name char(64), + OUT new_column_name char(64), + OUT new_user char(16), + OUT new_host char(60), + OUT invoker_user char(16), + OUT invoker_host char(60), + OUT allowed_operations set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger') +) +SQL SECURITY DEFINER +BEGIN + DECLARE grant_s_priv, grant_u_priv, grant_d_priv, grant_i_priv TEXT; + + #break user@host to user and host + SET new_user = replace(substring(substring_index(new_user_at_host, '@', 1), length(substring_index(new_user_at_host, '@', 1 - 1)) + 1), '@', ''); + SET new_host = replace(substring(substring_index(new_user_at_host, '@', 2), length(substring_index(new_user_at_host, '@', 2 - 1)) + 1), '@', ''); + + #break db.tablename.columnname to db, tablename and columnname + SET new_db = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 1), length(substring_index(new_db_dot_table_dot_column, '.', 1 - 1)) + 1), '.', ''); + SET new_table_name = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 2), length(substring_index(new_db_dot_table_dot_column, '.', 2 - 1)) + 1), '.', ''); + SET new_column_name = replace(substring(substring_index(new_db_dot_table_dot_column, '.', 3), length(substring_index(new_db_dot_table_dot_column, '.', 3 - 1)) + 1), '.', ''); + + IF (new_db = '') OR (new_table_name = '') THEN + SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Parameter not in expected format db.table[.column]'; + END IF; + + #get invoker_user and invoker_host + SET invoker_user = replace(substring(substring_index(USER(), '@', 1), length(substring_index(USER(), '@', 1 - 1)) + 1), '@', ''); + SET invoker_host = replace(substring(substring_index(USER(), '@', 2), length(substring_index(USER(), '@', 2 - 1)) + 1), '@', ''); + + #read allowed operations + SELECT '' INTO allowed_operations; + SELECT `Table_priv` INTO allowed_operations FROM mysqlgt.db_grant WHERE (`User`=invoker_user OR `User`='') AND (`Host`=invoker_host OR `Host`='%') AND (`Db`=new_db); + + #if requested grant is 'all', set it to all grants (no point of this now, however could come handy in the future) + IF find_in_set('all', tbl_priv) THEN + SET new_table_priv = 'Select,Insert,Update,Delete,Create,Drop,References,Index,Alter,Create View,Show view,Trigger'; + ELSE + SET new_table_priv = tbl_priv; + END IF; + +END // +DELIMITER ; + + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtGRANT`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtGRANT` ( + IN new_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77) # 16 + 1 + 60 +) +MODIFIES SQL DATA +SQL SECURITY DEFINER +BEGIN + + DECLARE error_message TEXT; + DECLARE error_message_128 VARCHAR(128); + DECLARE allowed INT; + DECLARE allowed_operations_table, new_table_priv_processed set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'); + DECLARE operation_temp, allowed_operations_column, new_column_priv_processed, current_column_priv set('Select','Insert','Update','References'); + + CALL `mysqlgt`.`gtSIMPLIFY_DATA`( + new_table_priv, new_db_dot_table_dot_column, new_user_at_host, + @new_priv_processed, @new_db, @new_table_name, @new_column_name, + @new_user, @new_host, @invoker_user, @invoker_host, @allowed_operations + ); + + SELECT '' INTO new_table_priv_processed; + SELECT '' INTO new_column_priv_processed; + SELECT '' INTO allowed_operations_table; + SELECT '' INTO allowed_operations_column; + SELECT '' INTO current_column_priv; + + SELECT `Column_priv` INTO current_column_priv FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + + IF @new_column_name = '' THEN + SELECT @allowed_operations INTO allowed_operations_table; + SELECT @new_priv_processed INTO new_table_priv_processed; + SELECT ((allowed_operations_table & new_table_priv_processed) = new_table_priv_processed) INTO allowed; + ELSE + IF find_in_set('Select', @allowed_operations) THEN + SELECT 'Select' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Insert', @allowed_operations) THEN + SELECT 'Insert' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Update', @allowed_operations) THEN + SELECT 'Update' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('References', @allowed_operations) THEN + SELECT 'References' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + + SELECT @new_priv_processed INTO new_column_priv_processed; + SELECT ((allowed_operations_column & new_column_priv_processed) = new_column_priv_processed) INTO allowed; + END IF; + + #if allowed, insert to mysql internal table and log + IF allowed = 1 THEN + INSERT INTO `mysql`.`tables_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,CURRENT_USER(),CURRENT_TIMESTAMP(),new_table_priv_processed,new_column_priv_processed) + ON DUPLICATE KEY UPDATE `Table_priv` = (`Table_priv` | new_table_priv_processed), `Column_priv` = (current_column_priv | new_column_priv_processed), `Timestamp` = CURRENT_TIMESTAMP(), `Grantor` = CURRENT_USER(); + IF @new_column_name != '' THEN + INSERT INTO `mysql`.`columns_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,@new_column_name,CURRENT_TIMESTAMP(),new_column_priv_processed) + ON DUPLICATE KEY UPDATE `Column_priv` = (`Column_priv` | new_column_priv_processed), `Timestamp` = CURRENT_TIMESTAMP(); + END IF; + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,CONCAT('user granted ', new_table_priv_processed, ' to ', @new_user, '@', @new_host, ' on ', new_db_dot_table_dot_column)); + ELSE + SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to grant ', new_table_priv_processed, ', only allowed to grant ', @allowed_operations); + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,error_message); + SET error_message_128 = CONCAT(SUBSTRING(error_message,1,128-3), '...'); + SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = error_message_128; + END IF; + +END // +DELIMITER ; + + + +DROP PROCEDURE IF EXISTS `mysqlgt`.`gtREVOKE`; +DELIMITER // +CREATE DEFINER = `mysqlgt`@`*internal-only*` +PROCEDURE `mysqlgt`.`gtREVOKE` ( + IN unset_table_priv set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger','All'), + IN new_db_dot_table_dot_column char(194), # 64 + 1 + 64 + 1 + 64 + IN new_user_at_host char(77) # 16 + 1 + 60 +) +MODIFIES SQL DATA +SQL SECURITY DEFINER +BEGIN + + DECLARE val INT; + DECLARE error_message TEXT; + DECLARE error_message_128 VARCHAR(128); + DECLARE current_table_priv, new_table_priv, revoked_priv, allowed_operations_table set('Select','Insert','Update','Delete','Create','Drop','Grant','References','Index','Alter','Create View','Show view','Trigger'); + DECLARE allowed INT; + DECLARE revoked_column_priv, operation_temp, new_column_priv_column, new_column_priv_table, allowed_operations_column, current_column_priv_column, current_column_priv_table set('Select','Insert','Update','References'); + + CALL `mysqlgt`.`gtSIMPLIFY_DATA`( + unset_table_priv, new_db_dot_table_dot_column, new_user_at_host, + @unset_priv_processed, @new_db, @new_table_name, @new_column_name, + @new_user, @new_host, @invoker_user, @invoker_host, @allowed_operations + ); + + SELECT '' INTO current_table_priv; + SELECT '' INTO current_column_priv_column; + SELECT '' INTO current_column_priv_table; + SELECT '' INTO allowed_operations_column; + SELECT '' INTO revoked_column_priv; + SELECT '' INTO revoked_priv; + + SELECT `Table_priv` INTO current_table_priv FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + SELECT `Column_priv` INTO current_column_priv_column FROM `mysql`.`columns_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name AND `Column_name`=@new_column_name; + SELECT `Column_priv` INTO current_column_priv_table FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + + + IF @new_column_name = '' THEN + SELECT current_column_priv_table INTO new_column_priv_table; + + SELECT @unset_priv_processed INTO new_table_priv; + SELECT (current_table_priv & ~new_table_priv) INTO new_table_priv; + SELECT (current_table_priv & ~new_table_priv) INTO revoked_priv; + + SELECT @allowed_operations INTO allowed_operations_table; + SELECT ((revoked_priv & allowed_operations_table) = revoked_priv) INTO allowed; + ELSE + SELECT current_table_priv INTO new_table_priv; + + IF find_in_set('Select', @allowed_operations) THEN + SELECT 'Select' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Insert', @allowed_operations) THEN + SELECT 'Insert' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('Update', @allowed_operations) THEN + SELECT 'Update' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + IF find_in_set('References', @allowed_operations) THEN + SELECT 'References' INTO operation_temp; + SELECT operation_temp | allowed_operations_column INTO allowed_operations_column; + END IF; + + SELECT @unset_priv_processed INTO new_column_priv_column; + SELECT (current_column_priv_column & ~new_column_priv_column) INTO new_column_priv_column; + SELECT (current_column_priv_column & ~new_column_priv_column) INTO revoked_column_priv; + + SELECT @unset_priv_processed INTO new_column_priv_table; + SELECT (current_column_priv_table & ~new_column_priv_table) INTO new_column_priv_table; + + SELECT ((revoked_column_priv & allowed_operations_column) = revoked_column_priv) INTO allowed; + + END IF; + + #if allowed, insert to mysql internal table and log + IF allowed = 1 THEN + IF new_table_priv = 0 AND new_column_priv_table = 0 THEN + #if it is deleted and column is not blank, it automatically seems to set the Table_priv to '' while not deleting the row + #so this works fine, however this needs to be tested with older version of MySQL + DELETE FROM `mysql`.`tables_priv` WHERE `Host`=@new_host AND `Db`=@new_db AND `User`=@new_user AND `Table_name`=@new_table_name; + ELSE + INSERT INTO `mysql`.`tables_priv` VALUES(@new_host, @new_db, @new_user, @new_table_name, CURRENT_USER(), CURRENT_TIMESTAMP(), new_table_priv, new_column_priv_table) + ON DUPLICATE KEY UPDATE `Table_priv` = new_table_priv, `Column_priv` = new_column_priv_table, `Timestamp` = CURRENT_TIMESTAMP(), `Grantor` = CURRENT_USER(); + END IF; + + IF @new_column_name != '' THEN + IF new_column_priv_column = 0 THEN + DELETE FROM `mysql`.`columns_priv` WHERE `Host`=@new_host and `Db`=@new_db and `User`=@new_user and `Table_name`=@new_table_name AND `Column_name`=@new_column_name; + ELSE + INSERT INTO `mysql`.`columns_priv` VALUES(@new_host,@new_db,@new_user,@new_table_name,@new_column_name,CURRENT_TIMESTAMP(),new_column_priv_column) + ON DUPLICATE KEY UPDATE `Column_priv` = new_column_priv_column, `Timestamp` = CURRENT_TIMESTAMP(); + END IF; + END IF; + + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,CONCAT('user revoked ', @unset_priv_processed, ' from ', @new_user, '@', @new_host, ' on ', new_db_dot_table_dot_column)); + ELSE + SET error_message = CONCAT(@invoker_user, '@', @invoker_host, ' is not allowed to revoke ', revoked_priv, ', only allowed to revoke ', @allowed_operations); + INSERT INTO `mysqlgt`.`log` VALUES(NULL,CURRENT_TIMESTAMP(),CONCAT(@invoker_user,'@',@invoker_host),new_db_dot_table_dot_column,error_message); + SET error_message_128 = CONCAT(SUBSTRING(error_message,1,128-3), '...'); + SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = error_message_128; + END IF; + +END // +DELIMITER ; + + +-- Setup grants for the internal user so he can check permissions , insert to log and execute the procedures +GRANT INSERT ON `mysqlgt`.`log` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT ON `mysqlgt`.`db_grant` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT,INSERT,UPDATE,DELETE ON `mysql`.`tables_priv` TO `mysqlgt`@`*internal-only*`; +GRANT SELECT,INSERT,UPDATE,DELETE ON `mysql`.`columns_priv` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtSIMPLIFY_DATA` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtGRANT` TO `mysqlgt`@`*internal-only*`; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtREVOKE` TO `mysqlgt`@`*internal-only*`; diff --git a/user-setup-example.sql b/user-setup-example.sql new file mode 100644 index 0000000..f66ad23 --- /dev/null +++ b/user-setup-example.sql @@ -0,0 +1,12 @@ +-- Allow EXECUTE for 'test'@'localhost' on mysqlgt procedures +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtREVOKE` TO 'test'@'localhost'; +GRANT EXECUTE ON PROCEDURE `mysqlgt`.`gtGRANT` TO 'test'@'localhost'; + +-- Allow the user to reload privileges after updating grants +-- make sure you are comfortable giving this permission to the user +-- allows reloading of logs, replication sync and a few other reloads +GRANT RELOAD ON *.* TO 'test'@'localhost'; + +REPLACE INTO `mysqlgt`.`db_grant` (`Host`, `Db`, `User`, `Table_priv`) VALUES +-- Allow SELECT,INSERT,UPDATE,DELETE GRANT for test@% on schema test + ('%', 'test', 'test', 'select,insert,update,delete')