forked from choobs/mysqlgt
-
Notifications
You must be signed in to change notification settings - Fork 0
/
install-mysqlgt-5.5.sql
291 lines (246 loc) · 16.2 KB
/
install-mysqlgt-5.5.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
-- 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=InnoDB
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
IF @allowed_operations = '' THEN
SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to grant ', new_table_priv_processed, ' (not allowed to grant anything for database ', @new_db, ')', @allowed_operations);
ELSE
SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to grant ', new_table_priv_processed, ' (only allowed to grant ', @allowed_operations, ' for database ', @new_db, ')');
END IF;
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
IF @allowed_operations = '' THEN
SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to revoke ', new_table_priv_processed, ' (not allowed to revoke anything for database ', @new_db, ')', @allowed_operations);
ELSE
SET error_message = CONCAT(@invoker_user,'@',@invoker_host,' is not allowed to revoke ', new_table_priv_processed, ' (only allowed to revoke ', @allowed_operations, ' for database ', @new_db, ')');
END IF;
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*`;