Adrià Vilanova MartÃnez | f19ea43 | 2024-01-23 20:20:52 +0100 | [diff] [blame^] | 1 | -- Copyright 2016 The Chromium Authors |
| 2 | -- Use of this source code is governed by a BSD-style license that can be |
| 3 | -- found in the LICENSE file. |
Copybara | 854996b | 2021-09-07 19:36:02 +0000 | [diff] [blame] | 4 | |
| 5 | |
| 6 | DROP PROCEDURE IF EXISTS InspectStatusCase; |
| 7 | DROP PROCEDURE IF EXISTS CleanupStatusCase; |
| 8 | DROP PROCEDURE IF EXISTS InspectLabelCase; |
| 9 | DROP PROCEDURE IF EXISTS CleanupLabelCase; |
| 10 | DROP PROCEDURE IF EXISTS InspectPermissionCase; |
| 11 | DROP PROCEDURE IF EXISTS CleanupPermissionCase; |
| 12 | DROP PROCEDURE IF EXISTS InspectComponentCase; |
| 13 | DROP PROCEDURE IF EXISTS CleanupComponentCase; |
| 14 | DROP PROCEDURE IF EXISTS CleanupCase; |
| 15 | |
| 16 | delimiter // |
| 17 | |
| 18 | CREATE PROCEDURE InspectStatusCase(IN in_pid SMALLINT UNSIGNED) |
| 19 | BEGIN |
| 20 | DECLARE done INT DEFAULT FALSE; |
| 21 | |
| 22 | DECLARE c_id INT; |
| 23 | DECLARE c_pid SMALLINT UNSIGNED; |
| 24 | DECLARE c_status VARCHAR(80) BINARY; |
| 25 | |
| 26 | DECLARE curs CURSOR FOR SELECT id, project_id, status FROM StatusDef WHERE project_id=in_pid AND rank IS NOT NULL ORDER BY rank; |
| 27 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 28 | |
| 29 | OPEN curs; |
| 30 | |
| 31 | wks_loop: LOOP |
| 32 | FETCH curs INTO c_id, c_pid, c_status; |
| 33 | IF done THEN |
| 34 | LEAVE wks_loop; |
| 35 | END IF; |
| 36 | |
| 37 | -- This is the canonical capitalization of the well-known status. |
| 38 | SELECT c_status AS 'Processing:'; |
| 39 | |
| 40 | -- Alternate forms are a) in the same project, and b) spelled the same, |
| 41 | -- but c) not the same exact status. |
| 42 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 43 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 44 | INSERT INTO alt_ids SELECT id FROM StatusDef WHERE project_id=c_pid AND status COLLATE UTF8_GENERAL_CI LIKE c_status AND id!=c_id; |
| 45 | SELECT status AS 'Alternate forms:' FROM StatusDef WHERE id IN (SELECT id FROM alt_ids); |
| 46 | SELECT id AS 'Offending issues:' FROM Issue WHERE status_id IN (SELECT id FROM alt_ids); |
| 47 | END LOOP; |
| 48 | |
| 49 | CLOSE curs; |
| 50 | END; |
| 51 | // |
| 52 | |
| 53 | CREATE PROCEDURE CleanupStatusCase(IN in_pid SMALLINT UNSIGNED) |
| 54 | BEGIN |
| 55 | DECLARE done INT DEFAULT FALSE; |
| 56 | |
| 57 | DECLARE c_id INT; |
| 58 | DECLARE c_pid SMALLINT UNSIGNED; |
| 59 | DECLARE c_status VARCHAR(80) BINARY; |
| 60 | |
| 61 | DECLARE curs CURSOR FOR SELECT id, project_id, status FROM StatusDef WHERE project_id=in_pid AND rank IS NOT NULL ORDER BY rank; |
| 62 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 63 | |
| 64 | OPEN curs; |
| 65 | |
| 66 | wks_loop: LOOP |
| 67 | FETCH curs INTO c_id, c_pid, c_status; |
| 68 | IF done THEN |
| 69 | LEAVE wks_loop; |
| 70 | END IF; |
| 71 | |
| 72 | SELECT c_status AS 'Processing:'; |
| 73 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 74 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 75 | INSERT INTO alt_ids SELECT id FROM StatusDef WHERE project_id=c_pid AND status COLLATE UTF8_GENERAL_CI LIKE c_status AND id!=c_id; |
| 76 | |
| 77 | -- Fix offending issues first, to avoid foreign key constraints. |
| 78 | UPDATE Issue SET status_id=c_id WHERE status_id IN (SELECT id FROM alt_ids); |
| 79 | |
| 80 | -- Then remove the alternate status definitions. |
| 81 | DELETE FROM StatusDef WHERE id IN (SELECT id FROM alt_ids); |
| 82 | END LOOP; |
| 83 | |
| 84 | CLOSE curs; |
| 85 | END; |
| 86 | // |
| 87 | |
| 88 | CREATE PROCEDURE InspectLabelCase(IN in_pid SMALLINT UNSIGNED) |
| 89 | BEGIN |
| 90 | DECLARE done INT DEFAULT FALSE; |
| 91 | |
| 92 | DECLARE c_id INT; |
| 93 | DECLARE c_pid SMALLINT UNSIGNED; |
| 94 | DECLARE c_label VARCHAR(80) BINARY; |
| 95 | |
| 96 | DECLARE curs CURSOR FOR SELECT id, project_id, label FROM LabelDef WHERE project_id=in_pid AND rank IS NOT NULL ORDER BY rank; |
| 97 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 98 | |
| 99 | OPEN curs; |
| 100 | |
| 101 | wkl_loop: LOOP |
| 102 | FETCH curs INTO c_id, c_pid, c_label; |
| 103 | IF done THEN |
| 104 | LEAVE wkl_loop; |
| 105 | END IF; |
| 106 | |
| 107 | -- This is the canonical capitalization of the well-known label. |
| 108 | SELECT c_label AS 'Processing:'; |
| 109 | |
| 110 | -- Alternate forms are a) in the same project, and b) spelled the same, |
| 111 | -- but c) not the same exact label. |
| 112 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 113 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 114 | INSERT INTO alt_ids SELECT id FROM LabelDef WHERE project_id=c_pid AND label COLLATE UTF8_GENERAL_CI LIKE c_label AND id!=c_id; |
| 115 | SELECT label AS 'Alternate forms:' FROM LabelDef WHERE id IN (SELECT id FROM alt_ids); |
| 116 | SELECT issue_id AS 'Offending issues:' FROM Issue2Label WHERE label_id IN (SELECT id FROM alt_ids); |
| 117 | END LOOP; |
| 118 | |
| 119 | CLOSE curs; |
| 120 | END; |
| 121 | // |
| 122 | |
| 123 | CREATE PROCEDURE CleanupLabelCase(IN in_pid SMALLINT UNSIGNED) |
| 124 | BEGIN |
| 125 | DECLARE done INT DEFAULT FALSE; |
| 126 | |
| 127 | DECLARE c_id INT; |
| 128 | DECLARE c_pid SMALLINT UNSIGNED; |
| 129 | DECLARE c_label VARCHAR(80) BINARY; |
| 130 | |
| 131 | DECLARE curs CURSOR FOR SELECT id, project_id, label FROM LabelDef WHERE project_id=in_pid AND rank IS NOT NULL ORDER BY rank; |
| 132 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 133 | |
| 134 | OPEN curs; |
| 135 | |
| 136 | wkl_loop: LOOP |
| 137 | FETCH curs INTO c_id, c_pid, c_label; |
| 138 | IF done THEN |
| 139 | LEAVE wkl_loop; |
| 140 | END IF; |
| 141 | |
| 142 | SELECT c_label AS 'Processing:'; |
| 143 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 144 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 145 | INSERT INTO alt_ids SELECT id FROM LabelDef WHERE project_id=c_pid AND label COLLATE UTF8_GENERAL_CI LIKE c_label AND id!=c_id; |
| 146 | |
| 147 | -- Fix offending issues first, to avoid foreign key constraints. |
| 148 | -- DELETE after UPDATE IGNORE to catch issues with two spellings. |
| 149 | UPDATE IGNORE Issue2Label SET label_id=c_id WHERE label_id IN (SELECT id FROM alt_ids); |
| 150 | DELETE FROM Issue2Label WHERE label_id IN (SELECT id FROM alt_ids); |
| 151 | |
| 152 | -- Then remove the alternate label definitions. |
| 153 | DELETE FROM LabelDef WHERE id IN (SELECT id FROM alt_ids); |
| 154 | END LOOP; |
| 155 | |
| 156 | CLOSE curs; |
| 157 | END; |
| 158 | // |
| 159 | |
| 160 | CREATE PROCEDURE InspectPermissionCase(IN in_pid SMALLINT UNSIGNED) |
| 161 | BEGIN |
| 162 | DECLARE done INT DEFAULT FALSE; |
| 163 | |
| 164 | DECLARE c_id INT; |
| 165 | DECLARE c_pid SMALLINT UNSIGNED; |
| 166 | DECLARE c_label VARCHAR(80) BINARY; |
| 167 | |
| 168 | -- This complex query takes the Actions table (defined below) and combines it |
| 169 | -- with the set of all permissions granted in the project to construct a list |
| 170 | -- of all possible Restrict-Action-Permission labels. It then combines that |
| 171 | -- with LabelDef to see which ones are actually used (whether or not they are |
| 172 | -- also defined as well-known labels). |
| 173 | DECLARE curs CURSOR FOR SELECT LabelDef.id, LabelDef.project_id, RapDef.label FROM ( |
| 174 | SELECT DISTINCT CONCAT_WS('-', 'Restrict', Actions.action, ExtraPerm.perm) |
| 175 | AS label FROM ExtraPerm, Actions where ExtraPerm.project_id=16) AS RapDef |
| 176 | LEFT JOIN LabelDef |
| 177 | ON BINARY RapDef.label = BINARY LabelDef.label |
| 178 | WHERE LabelDef.project_id=in_pid; |
| 179 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 180 | |
| 181 | DROP TEMPORARY TABLE IF EXISTS Actions; |
| 182 | CREATE TEMPORARY TABLE Actions (action VARCHAR(80)); |
| 183 | INSERT INTO Actions (action) VALUES ('View'), ('EditIssue'), ('AddIssueComment'), ('DeleteIssue'), ('ViewPrivateArtifact'); |
| 184 | |
| 185 | OPEN curs; |
| 186 | |
| 187 | perm_loop: LOOP |
| 188 | FETCH curs INTO c_id, c_pid, c_label; |
| 189 | IF done THEN |
| 190 | LEAVE perm_loop; |
| 191 | END IF; |
| 192 | |
| 193 | -- This is the canonical capitalization of the permission. |
| 194 | SELECT c_label AS 'Processing:'; |
| 195 | |
| 196 | -- Alternate forms are a) in the same project, and b) spelled the same, |
| 197 | -- but c) not the same exact label. |
| 198 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 199 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 200 | INSERT INTO alt_ids SELECT id FROM LabelDef WHERE project_id=c_pid AND label COLLATE UTF8_GENERAL_CI LIKE c_label AND id!=c_id; |
| 201 | SELECT label AS 'Alternate forms:' FROM LabelDef WHERE id IN (SELECT id FROM alt_ids); |
| 202 | SELECT issue_id AS 'Offending issues:' FROM Issue2Label WHERE label_id IN (SELECT id FROM alt_ids); |
| 203 | END LOOP; |
| 204 | |
| 205 | CLOSE curs; |
| 206 | END; |
| 207 | // |
| 208 | |
| 209 | CREATE PROCEDURE CleanupPermissionCase(IN in_pid SMALLINT UNSIGNED) |
| 210 | BEGIN |
| 211 | DECLARE done INT DEFAULT FALSE; |
| 212 | |
| 213 | DECLARE c_id INT; |
| 214 | DECLARE c_pid SMALLINT UNSIGNED; |
| 215 | DECLARE c_label VARCHAR(80) BINARY; |
| 216 | |
| 217 | -- This complex query takes the Actions table (defined below) and combines |
| 218 | -- it with the set of all permissions granted in the project to construct a |
| 219 | -- list of all possible Restrict-Action-Permission labels. It then combines |
| 220 | -- that with LabelDef to see which ones are actually used (whether or not |
| 221 | -- they are also defined as well-known labels). |
| 222 | DECLARE curs CURSOR FOR SELECT LabelDef.id, LabelDef.project_id, RapDef.label FROM ( |
| 223 | SELECT DISTINCT CONCAT_WS('-', 'Restrict', Actions.action, ExtraPerm.perm) |
| 224 | AS label FROM ExtraPerm, Actions where ExtraPerm.project_id=16) AS RapDef |
| 225 | LEFT JOIN LabelDef |
| 226 | ON BINARY RapDef.label = BINARY LabelDef.label |
| 227 | WHERE LabelDef.project_id=in_pid; |
| 228 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 229 | |
| 230 | DROP TEMPORARY TABLE IF EXISTS Actions; |
| 231 | CREATE TEMPORARY TABLE Actions (action VARCHAR(80)); |
| 232 | INSERT INTO Actions (action) VALUES ('View'), ('EditIssue'), ('AddIssueComment'), ('DeleteIssue'), ('ViewPrivateArtifact'); |
| 233 | |
| 234 | OPEN curs; |
| 235 | |
| 236 | perm_loop: LOOP |
| 237 | FETCH curs INTO c_id, c_pid, c_label; |
| 238 | IF done THEN |
| 239 | LEAVE perm_loop; |
| 240 | END IF; |
| 241 | |
| 242 | -- This is the canonical capitalization of the permission. |
| 243 | SELECT c_label AS 'Processing:'; |
| 244 | |
| 245 | -- Alternate forms are a) in the same project, and b) spelled the same, |
| 246 | -- but c) not the same exact label. |
| 247 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 248 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 249 | INSERT INTO alt_ids SELECT id FROM LabelDef WHERE project_id=c_pid AND label COLLATE UTF8_GENERAL_CI LIKE c_label AND id!=c_id; |
| 250 | |
| 251 | -- Fix offending issues first, to avoid foreign key constraings. |
| 252 | -- DELETE after UPDATE IGNORE to catch issues with two spellings. |
| 253 | UPDATE IGNORE Issue2Label SET label_id=c_id WHERE label_id IN (SELECT id FROM alt_ids); |
| 254 | DELETE FROM Issue2Label WHERE label_id IN (SELECT id FROM alt_ids); |
| 255 | |
| 256 | -- Then remove the alternate label definitions. |
| 257 | DELETE FROM LabelDef WHERE id IN (SELECT id FROM alt_ids); |
| 258 | END LOOP; |
| 259 | |
| 260 | CLOSE curs; |
| 261 | |
| 262 | -- Remove ExtraPerm rows where the user isn't a member of the project. |
| 263 | DELETE FROM ExtraPerm WHERE project_id=in_pid AND user_id NOT IN ( |
| 264 | SELECT user_id FROM User2Project WHERE project_id=in_pid); |
| 265 | END; |
| 266 | // |
| 267 | |
| 268 | CREATE PROCEDURE InspectComponentCase(IN in_pid SMALLINT UNSIGNED) |
| 269 | BEGIN |
| 270 | DECLARE done INT DEFAULT FALSE; |
| 271 | |
| 272 | DECLARE c_id INT; |
| 273 | DECLARE c_pid SMALLINT UNSIGNED; |
| 274 | DECLARE c_path VARCHAR(80) BINARY; |
| 275 | |
| 276 | DECLARE curs CURSOR FOR SELECT id, project_id, path FROM ComponentDef WHERE project_id=in_pid AND docstring IS NOT NULL ORDER BY path; |
| 277 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 278 | |
| 279 | OPEN curs; |
| 280 | |
| 281 | wks_loop: LOOP |
| 282 | FETCH curs INTO c_id, c_pid, c_path; |
| 283 | IF done THEN |
| 284 | LEAVE wks_loop; |
| 285 | END IF; |
| 286 | |
| 287 | -- This is the canonical capitalization of the component path. |
| 288 | SELECT c_path AS 'Processing:'; |
| 289 | |
| 290 | -- Alternate forms are a) in the same project, and b) spelled the same, |
| 291 | -- but c) not the same exact path. |
| 292 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 293 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 294 | INSERT INTO alt_ids SELECT id FROM ComponentDef WHERE project_id=c_pid AND path COLLATE UTF8_GENERAL_CI LIKE c_path AND id!=c_id; |
| 295 | SELECT path AS 'Alternate forms:' FROM ComponentDef WHERE id IN (SELECT id FROM alt_ids); |
| 296 | SELECT issue_id AS 'Offending issues:' FROM Issue2Component WHERE component_id IN (SELECT id FROM alt_ids); |
| 297 | END LOOP; |
| 298 | |
| 299 | CLOSE curs; |
| 300 | END; |
| 301 | // |
| 302 | |
| 303 | CREATE PROCEDURE CleanupComponentCase(IN in_pid SMALLINT UNSIGNED) |
| 304 | BEGIN |
| 305 | DECLARE done INT DEFAULT FALSE; |
| 306 | |
| 307 | DECLARE c_id INT; |
| 308 | DECLARE c_pid SMALLINT UNSIGNED; |
| 309 | DECLARE c_path VARCHAR(80) BINARY; |
| 310 | |
| 311 | DECLARE curs CURSOR FOR SELECT id, project_id, path FROM ComponentDef WHERE project_id=in_pid AND docstring IS NOT NULL ORDER BY path; |
| 312 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; |
| 313 | |
| 314 | OPEN curs; |
| 315 | |
| 316 | wks_loop: LOOP |
| 317 | FETCH curs INTO c_id, c_pid, c_path; |
| 318 | IF done THEN |
| 319 | LEAVE wks_loop; |
| 320 | END IF; |
| 321 | |
| 322 | SELECT c_path AS 'Processing:'; |
| 323 | DROP TEMPORARY TABLE IF EXISTS alt_ids; |
| 324 | CREATE TEMPORARY TABLE alt_ids (id INT); |
| 325 | INSERT INTO alt_ids SELECT id FROM ComponentDef WHERE project_id=c_pid AND path COLLATE UTF8_GENERAL_CI LIKE c_path AND id!=c_id; |
| 326 | |
| 327 | -- Fix offending issues first, to avoid foreign key constraints. |
| 328 | -- DELETE after UPDATE IGNORE to catch issues with two spellings. |
| 329 | UPDATE IGNORE Issue2Component SET component_id=c_id WHERE component_id IN (SELECT id FROM alt_ids); |
| 330 | DELETE FROM Issue2Component WHERE component_id IN (SELECT id FROM alt_ids); |
| 331 | |
| 332 | -- Then remove the alternate path definitions. |
| 333 | DELETE FROM ComponentDef WHERE id IN (SELECT id FROM alt_ids); |
| 334 | END LOOP; |
| 335 | |
| 336 | CLOSE curs; |
| 337 | END; |
| 338 | // |
| 339 | |
| 340 | |
| 341 | CREATE PROCEDURE CleanupCase(IN in_pid SMALLINT UNSIGNED) |
| 342 | BEGIN |
| 343 | CALL CleanupStatusCase(in_pid); |
| 344 | CALL CleanupLabelCase(in_pid); |
| 345 | CALL CleanupPermissionCase(in_pid); |
| 346 | CALL CleanupComponentCase(in_pid); |
| 347 | END; |
| 348 | // |
| 349 | |
| 350 | |
| 351 | delimiter ; |