|
| 1 | +-- For all keywords that have a corresponding lowercased keyword, |
| 2 | +-- (these keywords should not have been created but there was a bug |
| 3 | +-- that created them; that has been fixed and no more are being created) |
| 4 | +WITH messed_up_keywords AS ( |
| 5 | + select keywords.id as upper_id, k.id as lower_id |
| 6 | + from keywords |
| 7 | + inner join keywords as k on LOWER(keywords.keyword) = k.keyword |
| 8 | + where LOWER(keywords.keyword) != keywords.keyword |
| 9 | +) |
| 10 | +-- Find all the crates that use the uppercased keyword BUT NOT the lowercased keyword |
| 11 | +-- (many crates are associated with both lower and upper cased because of a bug) |
| 12 | +, messed_up_crates AS ( |
| 13 | + select crate_id, upper_id, lower_id |
| 14 | + from crates_keywords |
| 15 | + inner join messed_up_keywords on crates_keywords.keyword_id = messed_up_keywords.upper_id |
| 16 | + where messed_up_keywords.lower_id not in ( |
| 17 | + select keyword_id |
| 18 | + from crates_keywords as ck |
| 19 | + where ck.crate_id = crates_keywords.crate_id |
| 20 | + ) |
| 21 | +) |
| 22 | +-- Associate these crates with the lowercased keyword AS WELL AS the uppercased keyword |
| 23 | +INSERT INTO crates_keywords (crate_id, keyword_id) |
| 24 | +SELECT crate_id, lower_id as keyword_id |
| 25 | +FROM messed_up_crates |
| 26 | +; |
| 27 | + |
| 28 | +-- For all keywords that have a corresponding lowercased keyword, |
| 29 | +-- (this is repeated exactly from above) |
| 30 | +WITH messed_up_keywords AS ( |
| 31 | + select keywords.id as upper_id, k.id as lower_id |
| 32 | + from keywords |
| 33 | + inner join keywords as k on LOWER(keywords.keyword) = k.keyword |
| 34 | + where LOWER(keywords.keyword) != keywords.keyword |
| 35 | +) |
| 36 | +-- Delete records associating crates to the uppercased keyword |
| 37 | +DELETE |
| 38 | +FROM crates_keywords |
| 39 | +WHERE crates_keywords.keyword_id IN ( |
| 40 | + SELECT upper_id FROM messed_up_keywords |
| 41 | +) |
| 42 | +; |
| 43 | + |
| 44 | +-- For all keywords that have a corresponding lowercased keyword, |
| 45 | +-- (this is repeated exactly from above) |
| 46 | +WITH messed_up_keywords AS ( |
| 47 | + select keywords.id as upper_id, k.id as lower_id |
| 48 | + from keywords |
| 49 | + inner join keywords as k on LOWER(keywords.keyword) = k.keyword |
| 50 | + where LOWER(keywords.keyword) != keywords.keyword |
| 51 | +) |
| 52 | +-- Delete the uppercased keyword |
| 53 | +-- No more crates should be associated with these keywords because of |
| 54 | +-- the previous delete. |
| 55 | +DELETE |
| 56 | +FROM keywords |
| 57 | +WHERE keywords.id IN ( |
| 58 | + SELECT upper_id FROM messed_up_keywords |
| 59 | +) |
| 60 | +; |
| 61 | + |
| 62 | +-- For all keywords that are not properly lowercased but do not |
| 63 | +-- have a corresponding lowercased keyword, update them to be |
| 64 | +-- lower cased, preserving any crate associations using them. |
| 65 | +UPDATE keywords |
| 66 | +SET keyword = lower(keyword) |
| 67 | +WHERE keyword != lower(keyword) |
| 68 | +; |
0 commit comments