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 | -- Create project-related tables in monorail db. |
| 7 | |
| 8 | |
| 9 | -- The User table has the mapping from user_id to email addresses, and |
| 10 | -- user settings information that is needed almost every time that |
| 11 | -- we load a user. E.g., when showing issue owners on the list page. |
| 12 | CREATE TABLE User ( |
| 13 | user_id INT UNSIGNED NOT NULL, |
| 14 | email VARCHAR(255) NOT NULL, -- lowercase |
| 15 | |
| 16 | is_site_admin BOOLEAN DEFAULT FALSE, |
| 17 | obscure_email BOOLEAN DEFAULT TRUE, |
| 18 | |
| 19 | -- TODO(jrobbins): Move some of these to UserPrefs. |
| 20 | notify_issue_change BOOLEAN DEFAULT TRUE, -- Pref |
| 21 | notify_starred_issue_change BOOLEAN DEFAULT TRUE, -- Pref |
| 22 | email_compact_subject BOOLEAN DEFAULT FALSE, -- Pref |
| 23 | email_view_widget BOOLEAN DEFAULT TRUE, -- Pref |
| 24 | notify_starred_ping BOOLEAN DEFAULT FALSE, -- Pref |
| 25 | banned VARCHAR(80), |
| 26 | after_issue_update ENUM ( |
| 27 | 'up_to_list', 'stay_same_issue', 'next_in_list'), -- Pref |
| 28 | keep_people_perms_open BOOLEAN DEFAULT FALSE, -- Pref |
| 29 | preview_on_hover BOOLEAN DEFAULT TRUE, -- Pref |
| 30 | ignore_action_limits BOOLEAN DEFAULT FALSE, |
| 31 | last_visit_timestamp INT, |
| 32 | email_bounce_timestamp INT, |
| 33 | vacation_message VARCHAR(80), |
| 34 | |
| 35 | PRIMARY KEY (user_id), |
| 36 | UNIQUE KEY (email) |
| 37 | ) ENGINE=INNODB; |
| 38 | |
| 39 | -- Row to represent all deleted users i Monorail. |
| 40 | INSERT IGNORE INTO User (user_id, email) VALUES (1, ''); |
| 41 | |
| 42 | -- The UserPrefs table has open-ended key/value pairs that affect how |
| 43 | -- we present information to that user when we generate a web page for |
| 44 | -- that user or send an email to that user. E.g., ("code_font", |
| 45 | -- "true") would mean that issue content should be shown to that user |
| 46 | -- in a monospace font. Only non-default preference values are |
| 47 | -- stored: users who have never set any preferences will have no rows. |
| 48 | CREATE TABLE UserPrefs ( |
| 49 | user_id INT UNSIGNED NOT NULL, |
| 50 | name VARCHAR(40), |
| 51 | value VARCHAR(80), |
| 52 | |
| 53 | UNIQUE KEY (user_id, name) |
| 54 | ) ENGINE=INNODB; |
| 55 | |
| 56 | |
| 57 | CREATE TABLE UserCommits ( |
| 58 | commit_sha VARCHAR(40), |
| 59 | author_id INT UNSIGNED NOT NULL, |
| 60 | commit_time INT NOT NULL, |
| 61 | commit_message TEXT, |
| 62 | commit_repo_url VARCHAR(255), |
| 63 | |
| 64 | PRIMARY KEY (commit_sha), |
| 65 | INDEX (author_id, commit_time), |
| 66 | INDEX (commit_time) |
| 67 | ) ENGINE=INNODB; |
| 68 | |
| 69 | CREATE TABLE Project ( |
| 70 | project_id SMALLINT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 71 | project_name VARCHAR(80) NOT NULL, |
| 72 | |
| 73 | summary TEXT, |
| 74 | description TEXT, |
| 75 | |
| 76 | state ENUM ('live', 'archived', 'deletable') NOT NULL, |
| 77 | access ENUM ('anyone', 'members_only') NOT NULL, |
| 78 | read_only_reason VARCHAR(80), -- normally empty for read-write. |
| 79 | state_reason VARCHAR(80), -- optional reason for doomed project. |
| 80 | delete_time INT, -- if set, automatically transition to state deletable. |
| 81 | |
| 82 | issue_notify_address VARCHAR(80), |
| 83 | attachment_bytes_used BIGINT DEFAULT 0, |
| 84 | attachment_quota BIGINT DEFAULT 0, -- 50 MB default set in python code. |
| 85 | |
| 86 | cached_content_timestamp INT, |
| 87 | recent_activity_timestamp INT, |
| 88 | moved_to VARCHAR(250), |
| 89 | process_inbound_email BOOLEAN DEFAULT FALSE, |
| 90 | |
| 91 | only_owners_remove_restrictions BOOLEAN DEFAULT FALSE, |
| 92 | only_owners_see_contributors BOOLEAN DEFAULT FALSE, |
| 93 | |
| 94 | revision_url_format VARCHAR(250), |
| 95 | |
| 96 | home_page VARCHAR(250), |
| 97 | docs_url VARCHAR(250), |
| 98 | source_url VARCHAR(250), |
| 99 | logo_gcs_id VARCHAR(250), |
| 100 | logo_file_name VARCHAR(250), |
| 101 | |
| 102 | issue_notify_always_detailed BOOLEAN DEFAULT FALSE, |
| 103 | |
| 104 | PRIMARY KEY (project_id), |
| 105 | UNIQUE KEY (project_name) |
| 106 | ) ENGINE=INNODB; |
| 107 | |
| 108 | |
| 109 | CREATE TABLE User2Project ( |
| 110 | project_id SMALLINT UNSIGNED NOT NULL, |
| 111 | user_id INT UNSIGNED NOT NULL, |
| 112 | role_name ENUM ('owner', 'committer', 'contributor'), |
| 113 | |
| 114 | PRIMARY KEY (project_id, user_id), |
| 115 | INDEX (user_id), |
| 116 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 117 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 118 | ) ENGINE=INNODB; |
| 119 | |
| 120 | |
| 121 | CREATE TABLE LinkedAccount ( |
| 122 | parent_id INT UNSIGNED NOT NULL, |
| 123 | child_id INT UNSIGNED NOT NULL, |
| 124 | |
| 125 | KEY (parent_id), |
| 126 | UNIQUE KEY (child_id), |
| 127 | FOREIGN KEY (parent_id) REFERENCES User(user_id), |
| 128 | FOREIGN KEY (child_id) REFERENCES User(user_id) |
| 129 | ) ENGINE=INNODB; |
| 130 | |
| 131 | |
| 132 | CREATE TABLE LinkedAccountInvite ( |
| 133 | parent_id INT UNSIGNED NOT NULL, |
| 134 | child_id INT UNSIGNED NOT NULL, |
| 135 | |
| 136 | KEY (parent_id), |
| 137 | UNIQUE KEY (child_id), |
| 138 | FOREIGN KEY (parent_id) REFERENCES User(user_id), |
| 139 | FOREIGN KEY (child_id) REFERENCES User(user_id) |
| 140 | ) ENGINE=INNODB; |
| 141 | |
| 142 | |
| 143 | CREATE TABLE ExtraPerm ( |
| 144 | project_id SMALLINT UNSIGNED NOT NULL, |
| 145 | user_id INT UNSIGNED NOT NULL, |
| 146 | perm VARCHAR(80), |
| 147 | |
| 148 | PRIMARY KEY (project_id, user_id, perm), |
| 149 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 150 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 151 | ) ENGINE=INNODB; |
| 152 | |
| 153 | |
| 154 | CREATE TABLE MemberNotes ( |
| 155 | project_id SMALLINT UNSIGNED NOT NULL, |
| 156 | user_id INT UNSIGNED NOT NULL, |
| 157 | notes TEXT, |
| 158 | |
| 159 | PRIMARY KEY (project_id, user_id), |
| 160 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 161 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 162 | ) ENGINE=INNODB; |
| 163 | |
| 164 | |
| 165 | CREATE TABLE AutocompleteExclusion ( |
| 166 | project_id SMALLINT UNSIGNED NOT NULL, |
| 167 | user_id INT UNSIGNED NOT NULL, |
| 168 | ac_exclude BOOLEAN DEFAULT TRUE, |
| 169 | no_expand BOOLEAN DEFAULT FALSE, |
| 170 | |
| 171 | PRIMARY KEY (project_id, user_id), |
| 172 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 173 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 174 | ) ENGINE=INNODB; |
| 175 | |
| 176 | |
| 177 | CREATE TABLE UserStar ( |
| 178 | starred_user_id INT UNSIGNED NOT NULL, |
| 179 | user_id INT UNSIGNED NOT NULL, |
| 180 | |
| 181 | PRIMARY KEY (starred_user_id, user_id), |
| 182 | INDEX (user_id), |
| 183 | FOREIGN KEY (user_id) REFERENCES User(user_id), |
| 184 | FOREIGN KEY (starred_user_id) REFERENCES User(user_id) |
| 185 | ) ENGINE=INNODB; |
| 186 | |
| 187 | |
| 188 | CREATE TABLE ProjectStar ( |
| 189 | project_id SMALLINT UNSIGNED NOT NULL, |
| 190 | user_id INT UNSIGNED NOT NULL, |
| 191 | |
| 192 | PRIMARY KEY (project_id, user_id), |
| 193 | INDEX (user_id), |
| 194 | FOREIGN KEY (user_id) REFERENCES User(user_id), |
| 195 | FOREIGN KEY (project_id) REFERENCES Project(project_id) |
| 196 | ) ENGINE=INNODB; |
| 197 | |
| 198 | |
| 199 | CREATE TABLE UserGroup ( |
| 200 | user_id INT UNSIGNED NOT NULL, |
| 201 | group_id INT UNSIGNED NOT NULL, |
| 202 | role ENUM ('owner', 'member') NOT NULL DEFAULT 'member', |
| 203 | |
| 204 | PRIMARY KEY (user_id, group_id), |
| 205 | INDEX (group_id), |
| 206 | FOREIGN KEY (user_id) REFERENCES User(user_id), |
| 207 | FOREIGN KEY (group_id) REFERENCES User(user_id) |
| 208 | |
| 209 | ) ENGINE=INNODB; |
| 210 | |
| 211 | |
| 212 | CREATE TABLE UserGroupSettings ( |
| 213 | group_id INT UNSIGNED NOT NULL, |
| 214 | |
| 215 | who_can_view_members ENUM ('owners', 'members', 'anyone'), |
| 216 | |
| 217 | external_group_type ENUM ( |
| 218 | 'chrome_infra_auth', 'mdb', 'baggins', 'computed'), |
| 219 | -- timestamps in seconds since the epoch. |
| 220 | last_sync_time INT, |
| 221 | notify_members BOOL DEFAULT TRUE, |
| 222 | notify_group BOOL DEFAULT FALSE, |
| 223 | |
| 224 | PRIMARY KEY (group_id), |
| 225 | FOREIGN KEY (group_id) REFERENCES User(user_id) |
| 226 | ) ENGINE=INNODB; |
| 227 | |
| 228 | |
| 229 | CREATE TABLE Group2Project ( |
| 230 | group_id INT UNSIGNED NOT NULL, |
| 231 | project_id SMALLINT UNSIGNED NOT NULL, |
| 232 | |
| 233 | PRIMARY KEY (group_id, project_id), |
| 234 | |
| 235 | FOREIGN KEY (group_id) REFERENCES UserGroupSettings(group_id), |
| 236 | FOREIGN KEY (project_id) REFERENCES Project(project_id) |
| 237 | ) ENGINE=INNODB; |
| 238 | |
| 239 | |
| 240 | -- These are quick-edit commands that the user can easily repeat. |
| 241 | CREATE TABLE QuickEditHistory ( |
| 242 | user_id INT UNSIGNED NOT NULL, |
| 243 | project_id SMALLINT UNSIGNED NOT NULL, |
| 244 | slot_num SMALLINT UNSIGNED NOT NULL, |
| 245 | |
| 246 | command VARCHAR(255) NOT NULL, |
| 247 | comment TEXT NOT NULL, |
| 248 | |
| 249 | PRIMARY KEY (user_id, project_id, slot_num), |
| 250 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 251 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 252 | ) ENGINE=INNODB; |
| 253 | |
| 254 | |
| 255 | -- This allows us to offer the most recent command to the user again |
| 256 | -- as the default quick-edit command for next time. |
| 257 | CREATE TABLE QuickEditMostRecent ( |
| 258 | user_id INT UNSIGNED NOT NULL, |
| 259 | project_id SMALLINT UNSIGNED NOT NULL, |
| 260 | slot_num SMALLINT UNSIGNED NOT NULL, |
| 261 | |
| 262 | PRIMARY KEY (user_id, project_id), |
| 263 | FOREIGN KEY (project_id) REFERENCES Project(project_id), |
| 264 | FOREIGN KEY (user_id) REFERENCES User(user_id) |
| 265 | ) ENGINE=INNODB; |