blob: b4451290e3ec4c3f76970ce8184cfd6689c38990 [file] [log] [blame]
Copybara854996b2021-09-07 19:36:02 +00001-- Copyright 2016 The Chromium Authors. All Rights Reserved.
2--
3-- Use of this source code is governed by a BSD-style
4-- license that can be found in the LICENSE file or at
5-- https://developers.google.com/open-source/licenses/bsd
6
7
8-- Create issue-realted tables in monorail db.
9
10
11CREATE TABLE StatusDef (
12 id INT NOT NULL AUTO_INCREMENT,
13 project_id SMALLINT UNSIGNED NOT NULL,
14 status VARCHAR(80) BINARY NOT NULL,
15 rank SMALLINT UNSIGNED,
16 means_open BOOLEAN,
17 docstring TEXT,
18 deprecated BOOLEAN DEFAULT FALSE,
19
20 PRIMARY KEY (id),
21 UNIQUE KEY (project_id, status),
22 FOREIGN KEY (project_id) REFERENCES Project(project_id)
23) ENGINE=INNODB;
24
25
26CREATE TABLE ComponentDef (
27 id INT NOT NULL AUTO_INCREMENT,
28 project_id SMALLINT UNSIGNED NOT NULL,
29
30 -- Note: parent components have paths that are prefixes of child components.
31 path VARCHAR(255) BINARY NOT NULL,
32 docstring TEXT,
33 deprecated BOOLEAN DEFAULT FALSE,
34 created INT,
35 creator_id INT UNSIGNED,
36 modified INT,
37 modifier_id INT UNSIGNED,
38 is_deleted BOOLEAN DEFAULT FALSE,
39
40 PRIMARY KEY (id),
41 FOREIGN KEY (project_id) REFERENCES Project(project_id),
42 FOREIGN KEY (creator_id) REFERENCES User(user_id),
43 FOREIGN KEY (modifier_id) REFERENCES User(user_id),
44 INDEX project_id2 (project_id, path)
45) ENGINE=INNODB;
46
47
48CREATE TABLE Component2Admin (
49 component_id INT NOT NULL,
50 admin_id INT UNSIGNED NOT NULL,
51
52 PRIMARY KEY (component_id, admin_id),
53
54 FOREIGN KEY (component_id) REFERENCES ComponentDef(id),
55 FOREIGN KEY (admin_id) REFERENCES User(user_id)
56) ENGINE=INNODB;
57
58
59CREATE TABLE Component2Cc (
60 component_id INT NOT NULL,
61 cc_id INT UNSIGNED NOT NULL,
62
63 PRIMARY KEY (component_id, cc_id),
64
65 FOREIGN KEY (component_id) REFERENCES ComponentDef(id),
66 FOREIGN KEY (cc_id) REFERENCES User(user_id)
67) ENGINE=INNODB;
68
69
70CREATE TABLE LabelDef (
71 id INT NOT NULL AUTO_INCREMENT,
72 project_id SMALLINT UNSIGNED NOT NULL,
73 label VARCHAR(80) BINARY NOT NULL COLLATE utf8mb4_unicode_ci,
74 rank SMALLINT UNSIGNED,
75 docstring TEXT,
76 deprecated BOOLEAN DEFAULT FALSE,
77
78 PRIMARY KEY (id),
79 UNIQUE KEY (project_id, label),
80 FOREIGN KEY (project_id) REFERENCES Project(project_id)
81) ENGINE=INNODB;
82
83
84CREATE TABLE Component2Label (
85 component_id INT NOT NULL,
86 label_id INT NOT NULL,
87
88 PRIMARY KEY (component_id, label_id),
89
90 FOREIGN KEY (component_id) REFERENCES ComponentDef(id),
91 FOREIGN KEY (label_id) REFERENCES LabelDef(id)
92) ENGINE=INNODB;
93
94
95CREATE TABLE FieldDef (
96 id INT NOT NULL AUTO_INCREMENT,
97 project_id SMALLINT UNSIGNED NOT NULL,
98 rank SMALLINT UNSIGNED,
99
100 field_name VARCHAR(80) BINARY NOT NULL,
101 -- TODO(jrobbins): more types
102 field_type ENUM ('enum_type', 'int_type', 'str_type', 'user_type', 'date_type', 'url_type', 'approval_type') NOT NULL,
103 applicable_type VARCHAR(80), -- No value means: offered for all issue types
104 applicable_predicate TEXT, -- No value means: TRUE
105 is_required BOOLEAN, -- true means required if applicable
106 is_niche BOOLEAN, -- true means user must click to reveal widget
107 is_multivalued BOOLEAN,
108 -- TODO(jrobbins): access controls: restrict, grant
109 -- Validation for int_type fields
110 min_value INT,
111 max_value INT,
112 -- Validation for str_type fields
113 regex VARCHAR(80),
114 -- Validation for user_type fields
115 needs_member BOOLEAN, -- User value can only be set to users who are members
116 needs_perm VARCHAR(80), -- User value can only be set to users w/ that perm
117 grants_perm VARCHAR(80), -- User named in this field gains this perm in the issue
118 -- notification options for user_type fields
119 notify_on ENUM ('never', 'any_comment') DEFAULT 'never' NOT NULL,
120 -- notification options for date_type fields
121 date_action ENUM ('no_action', 'ping_owner_only', 'ping_participants'),
122
123 -- TODO(jrobbins): default value
124 -- TODO(jrobbins): deprecated boolean?
125 docstring TEXT,
126 is_deleted BOOLEAN, -- If true, reap this field def after all values reaped.
127 approval_id INT,
128 is_phase_field BOOLEAN DEFAULT FALSE,
129 is_restricted_field BOOLEAN DEFAULT FALSE, -- If true, editors are restricted to the FieldDef2Editors tbl.
130
131 PRIMARY KEY (id),
132 UNIQUE KEY (project_id, field_name),
133 FOREIGN KEY (project_id) REFERENCES Project(project_id)
134) ENGINE=INNODB;
135
136
137CREATE TABLE FieldDef2Admin (
138 field_id INT NOT NULL,
139 admin_id INT UNSIGNED NOT NULL,
140
141 PRIMARY KEY (field_id, admin_id),
142 FOREIGN KEY (field_id) REFERENCES FieldDef(id),
143 FOREIGN KEY (admin_id) REFERENCES User(user_id)
144) ENGINE=INNODB;
145
146
147CREATE TABLE FieldDef2Editor (
148 field_id INT NOT NULL,
149 editor_id INT UNSIGNED NOT NULL,
150
151 PRIMARY KEY (field_id, editor_id),
152 FOREIGN KEY (field_id) REFERENCES FieldDef(id),
153 FOREIGN KEY (editor_id) REFERENCES User(user_id)
154) ENGINE=INNODB;
155
156
157CREATE TABLE Issue (
158 id INT NOT NULL AUTO_INCREMENT,
159 shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
160 project_id SMALLINT UNSIGNED NOT NULL,
161 local_id INT NOT NULL,
162
163 reporter_id INT UNSIGNED NOT NULL,
164 owner_id INT UNSIGNED,
165 status_id INT,
166
167 -- These are each timestamps in seconds since the epoch.
168 modified INT NOT NULL,
169 opened INT,
170 closed INT,
171 owner_modified INT,
172 status_modified INT,
173 component_modified INT,
174
175 derived_owner_id INT UNSIGNED,
176 derived_status_id INT,
177
178 deleted BOOLEAN,
179
180 -- These are denormalized fields that should be updated when child
181 -- records are added or removed for stars or attachments. If they
182 -- get out of sync, they can be updated via an UPDATE ... SELECT statement.
183 star_count INT DEFAULT 0,
184 attachment_count INT DEFAULT 0,
185
186 is_spam BOOLEAN DEFAULT FALSE,
187
188 PRIMARY KEY(id),
189 UNIQUE KEY (project_id, local_id),
190 INDEX (shard, status_id),
191 INDEX (shard, project_id),
192
193 FOREIGN KEY (project_id) REFERENCES Project(project_id),
194 FOREIGN KEY (reporter_id) REFERENCES User(user_id),
195 FOREIGN KEY (owner_id) REFERENCES User(user_id),
196 FOREIGN KEY (status_id) REFERENCES StatusDef(id),
197 FOREIGN KEY (derived_owner_id) REFERENCES User(user_id)
198) ENGINE=INNODB;
199
200
201-- This is a parallel table to the Issue table because we don't want
202-- any very wide columns in the Issue table that would slow it down.
203CREATE TABLE IssueSummary (
204 issue_id INT NOT NULL,
205 summary mediumtext COLLATE utf8mb4_unicode_ci,
206
207 PRIMARY KEY (issue_id),
208 FOREIGN KEY (issue_id) REFERENCES Issue(id)
209) ENGINE=INNODB CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
210
211
212CREATE TABLE Issue2Component (
213 issue_id INT NOT NULL,
214 issue_shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
215 component_id INT NOT NULL,
216 derived BOOLEAN DEFAULT FALSE,
217
218 PRIMARY KEY (issue_id, component_id, derived),
219 INDEX (component_id, issue_shard),
220
221 FOREIGN KEY (issue_id) REFERENCES Issue(id),
222 FOREIGN KEY (component_id) REFERENCES ComponentDef(id)
223) ENGINE=INNODB;
224
225
226CREATE TABLE Issue2Label (
227 issue_id INT NOT NULL,
228 issue_shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
229 label_id INT NOT NULL,
230 derived BOOLEAN DEFAULT FALSE,
231
232 PRIMARY KEY (issue_id, label_id, derived),
233 INDEX (label_id, issue_shard),
234
235 FOREIGN KEY (issue_id) REFERENCES Issue(id),
236 FOREIGN KEY (label_id) REFERENCES LabelDef(id)
237) ENGINE=INNODB;
238
239CREATE TABLE IssuePhaseDef (
240 id INT NOT NULL AUTO_INCREMENT,
241 name VARCHAR(255) BINARY NOT NULL,
242 rank SMALLINT UNSIGNED,
243
244 PRIMARY KEY (id)
245) ENGINE=INNODB;
246
247CREATE TABLE Issue2FieldValue (
248 issue_id INT NOT NULL,
249 issue_shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
250 field_id INT NOT NULL,
251
252 int_value INT,
253 str_value VARCHAR(1024),
254 user_id INT UNSIGNED,
255 date_value INT,
256 url_value VARCHAR(1024),
257
258 derived BOOLEAN DEFAULT FALSE,
259 phase_id INT,
260
261 INDEX (issue_id, field_id),
262 INDEX (field_id, issue_shard, int_value),
263 INDEX (field_id, issue_shard, str_value(255)),
264 INDEX (field_id, issue_shard, user_id),
265 INDEX (field_id, issue_shard, date_value),
266 INDEX (field_id, issue_shard, url_value(255)),
267
268 FOREIGN KEY (issue_id) REFERENCES Issue(id),
269 FOREIGN KEY (field_id) REFERENCES FieldDef(id),
270 FOREIGN KEY (user_id) REFERENCES User(user_id),
271 FOREIGN KEY (phase_id) REFERENCES IssuePhaseDef(id)
272) ENGINE=INNODB;
273
274
275CREATE TABLE Issue2Cc (
276 issue_id INT NOT NULL,
277 issue_shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
278 cc_id INT UNSIGNED NOT NULL,
279 derived BOOLEAN DEFAULT FALSE,
280
281 PRIMARY KEY (issue_id, cc_id),
282 INDEX (cc_id, issue_shard),
283
284 FOREIGN KEY (issue_id) REFERENCES Issue(id),
285 FOREIGN KEY (cc_id) REFERENCES User(user_id)
286) ENGINE=INNODB;
287
288
289CREATE TABLE Issue2Notify (
290 issue_id INT NOT NULL,
291 email VARCHAR(80) NOT NULL,
292
293 PRIMARY KEY (issue_id, email),
294
295 FOREIGN KEY (issue_id) REFERENCES Issue(id)
296) ENGINE=INNODB;
297
298
299CREATE TABLE IssueVisitHistory (
300 issue_id INT NOT NULL,
301 user_id INT UNSIGNED NOT NULL,
302 viewed INT NOT NULL,
303
304 PRIMARY KEY (user_id, issue_id),
305 INDEX (user_id, viewed),
306 FOREIGN KEY (issue_id) REFERENCES Issue(id),
307 FOREIGN KEY (user_id) REFERENCES User(user_id)
308) ENGINE=INNODB;
309
310
311CREATE TABLE IssueStar (
312 issue_id INT NOT NULL,
313 user_id INT UNSIGNED NOT NULL,
314
315 PRIMARY KEY (issue_id, user_id),
316 INDEX (user_id),
317 FOREIGN KEY (issue_id) REFERENCES Issue(id),
318 FOREIGN KEY (user_id) REFERENCES User(user_id)
319) ENGINE=INNODB;
320
321
322CREATE TABLE IssueRelation (
323 issue_id INT NOT NULL,
324 dst_issue_id INT NOT NULL,
325
326 -- Read as: src issue is blocked on dst issue.
327 kind ENUM ('blockedon', 'mergedinto') NOT NULL,
328
329 rank BIGINT,
330
331 PRIMARY KEY (issue_id, dst_issue_id, kind),
332 INDEX (issue_id),
333 INDEX (dst_issue_id),
334 FOREIGN KEY (issue_id) REFERENCES Issue(id),
335 FOREIGN KEY (dst_issue_id) REFERENCES Issue(id)
336) ENGINE=INNODB;
337
338
339CREATE TABLE DanglingIssueRelation (
340 issue_id INT NOT NULL,
341 dst_issue_project VARCHAR(80),
342 dst_issue_local_id INT,
343 ext_issue_identifier VARCHAR(255),
344
345 -- This table uses 'blocking' so that it can guarantee the src issue
346 -- always exists, while the dst issue is always the dangling one.
347 kind ENUM ('blockedon', 'blocking', 'mergedinto') NOT NULL,
348
349 PRIMARY KEY (issue_id, dst_issue_project, dst_issue_local_id, kind, ext_issue_identifier),
350 INDEX (issue_id),
351 INDEX (ext_issue_identifier),
352 FOREIGN KEY (issue_id) REFERENCES Issue(id)
353) ENGINE=INNODB;
354
355
356CREATE TABLE CommentContent (
357 id INT NOT NULL AUTO_INCREMENT,
358 -- TODO(jrobbins): drop comment_id after Comment.commentcontent_id is added.
359 comment_id INT NOT NULL, -- Note: no forign key reference.
360 content MEDIUMTEXT COLLATE utf8mb4_unicode_ci,
361 inbound_message MEDIUMTEXT COLLATE utf8mb4_unicode_ci,
362
363 PRIMARY KEY (id)
364) ENGINE=INNODB CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
365
366
367CREATE TABLE Comment (
368 id INT NOT NULL AUTO_INCREMENT,
369 issue_id INT NOT NULL,
370 created INT NOT NULL,
371 project_id SMALLINT UNSIGNED NOT NULL,
372
373 commenter_id INT UNSIGNED NOT NULL,
374 commentcontent_id INT, -- TODO(jrobbins) make this NOT NULL.
375
376 deleted_by INT UNSIGNED,
377 is_spam BOOLEAN DEFAULT FALSE,
378 -- TODO(lukasperaza) Update first comments SET is_description=TRUE
379 is_description BOOLEAN DEFAULT FALSE,
380
381 PRIMARY KEY(id),
382 INDEX (is_spam, project_id, created),
383 INDEX (commenter_id, created),
384 INDEX (commenter_id, deleted_by, issue_id),
385
386 FOREIGN KEY (project_id) REFERENCES Project(project_id),
387 FOREIGN KEY (issue_id) REFERENCES Issue(id),
388 FOREIGN KEY (commenter_id) REFERENCES User(user_id),
389 FOREIGN KEY (deleted_by) REFERENCES User(user_id),
390 FOREIGN KEY (commentcontent_id) REFERENCES CommentContent(id)
391) ENGINE=INNODB CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
392
393
394CREATE TABLE CommentImporter (
395 comment_id INT NOT NULL,
396 importer_id INT UNSIGNED NOT NULL,
397
398 PRIMARY KEY (comment_id),
399 FOREIGN KEY (comment_id) REFERENCES Comment(id),
400 FOREIGN KEY (importer_id) REFERENCES User(user_id)
401) ENGINE=INNODB;
402
403
404CREATE TABLE Attachment (
405 id INT NOT NULL AUTO_INCREMENT,
406
407 issue_id INT NOT NULL,
408 comment_id INT,
409
410 filename VARCHAR(255) NOT NULL,
411 filesize INT NOT NULL,
412 mimetype VARCHAR(255) NOT NULL,
413 deleted BOOLEAN,
414 gcs_object_id VARCHAR(1024) NOT NULL,
415
416 PRIMARY KEY (id),
417 INDEX (issue_id),
418 INDEX (comment_id),
419 FOREIGN KEY (issue_id) REFERENCES Issue(id)
420) ENGINE=INNODB;
421
422
423CREATE TABLE IssueUpdate (
424 id INT NOT NULL AUTO_INCREMENT,
425 issue_id INT NOT NULL,
426 comment_id INT,
427
428 field ENUM (
429 'summary', 'status', 'owner', 'cc', 'labels', 'blockedon', 'blocking', 'mergedinto',
430 'project', 'components', 'custom', 'is_spam' ) NOT NULL,
431 old_value MEDIUMTEXT COLLATE utf8mb4_unicode_ci,
432 new_value MEDIUMTEXT COLLATE utf8mb4_unicode_ci,
433 added_user_id INT UNSIGNED,
434 removed_user_id INT UNSIGNED,
435 custom_field_name VARCHAR(255),
436 is_spam BOOLEAN DEFAULT FALSE,
437
438 PRIMARY KEY (id),
439 INDEX (issue_id),
440 INDEX (comment_id),
441 FOREIGN KEY (issue_id) REFERENCES Issue(id)
442 -- FOREIGN KEY (added_user_id) REFERENCES User(user_id),
443 -- FOREIGN KEY (removed_user_id) REFERENCES User(user_id)
444) ENGINE=INNODB CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
445
446
447CREATE TABLE IssueFormerLocations (
448 issue_id INT NOT NULL,
449 project_id SMALLINT UNSIGNED NOT NULL,
450 local_id INT NOT NULL,
451
452 INDEX (issue_id),
453 UNIQUE KEY (project_id, local_id),
454 FOREIGN KEY (issue_id) REFERENCES Issue(id)
455) ENGINE=INNODB;
456
457
458CREATE TABLE Template (
459 id INT NOT NULL AUTO_INCREMENT,
460 project_id SMALLINT UNSIGNED NOT NULL,
461 name VARCHAR(255) BINARY NOT NULL,
462
463 content TEXT,
464 summary TEXT,
465 summary_must_be_edited BOOLEAN,
466 owner_id INT UNSIGNED,
467 status VARCHAR(255),
468 members_only BOOLEAN,
469 owner_defaults_to_member BOOLEAN,
470 component_required BOOLEAN DEFAULT FALSE,
471
472 PRIMARY KEY (id),
473 UNIQUE KEY (project_id, name),
474 FOREIGN KEY (project_id) REFERENCES Project(project_id)
475) ENGINE=INNODB;
476
477
478CREATE TABLE Template2Label (
479 template_id INT NOT NULL,
480 label VARCHAR(255) NOT NULL,
481
482 PRIMARY KEY (template_id, label),
483 FOREIGN KEY (template_id) REFERENCES Template(id)
484) ENGINE=INNODB;
485
486
487CREATE TABLE Template2Admin (
488 template_id INT NOT NULL,
489 admin_id INT UNSIGNED NOT NULL,
490
491 PRIMARY KEY (template_id, admin_id),
492 FOREIGN KEY (template_id) REFERENCES Template(id),
493 FOREIGN KEY (admin_id) REFERENCES User(user_id)
494) ENGINE=INNODB;
495
496
497CREATE TABLE Template2FieldValue (
498 template_id INT NOT NULL,
499 field_id INT NOT NULL,
500
501 int_value INT,
502 str_value VARCHAR(1024),
503 user_id INT UNSIGNED,
504 date_value INT,
505 url_value VARCHAR(1024),
506
507 INDEX (template_id, field_id),
508
509 FOREIGN KEY (template_id) REFERENCES Template(id),
510 FOREIGN KEY (field_id) REFERENCES FieldDef(id),
511 FOREIGN KEY (user_id) REFERENCES User(user_id)
512) ENGINE=INNODB;
513
514
515CREATE TABLE Template2Component (
516 template_id INT NOT NULL,
517 component_id INT NOT NULL,
518
519 PRIMARY KEY (template_id, component_id),
520
521 FOREIGN KEY (template_id) REFERENCES Template(id),
522 FOREIGN KEY (component_id) REFERENCES ComponentDef(id)
523) ENGINE=INNODB;
524
525
526CREATE TABLE Template2ApprovalValue (
527 approval_id INT NOT NULL,
528 template_id INT NOT NULL,
529 phase_id INT,
530 status ENUM ('needs_review', 'na', 'review_requested', 'review_started', 'need_info', 'approved', 'not_approved', 'not_set') DEFAULT 'not_set' NOT NULL,
531
532 PRIMARY KEY (approval_id, template_id),
533
534 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
535 FOREIGN KEY (template_id) REFERENCES Template(id),
536 FOREIGN KEY (phase_id) REFERENCES IssuePhaseDef(id)
537) ENGINE=INNODB;
538
539
540CREATE TABLE ProjectIssueConfig (
541 project_id SMALLINT UNSIGNED NOT NULL,
542
543 statuses_offer_merge VARCHAR(255) NOT NULL,
544 exclusive_label_prefixes VARCHAR(255) NOT NULL,
545 default_template_for_developers INT NOT NULL,
546 default_template_for_users INT NOT NULL,
547 default_col_spec TEXT,
548 default_sort_spec TEXT,
549 default_x_attr TEXT,
550 default_y_attr TEXT,
551
552 member_default_query TEXT,
553 custom_issue_entry_url TEXT,
554
555 PRIMARY KEY (project_id),
556 FOREIGN KEY (project_id) REFERENCES Project(project_id)
557) ENGINE=INNODB;
558
559
560CREATE TABLE FilterRule (
561 project_id SMALLINT UNSIGNED NOT NULL,
562 rank SMALLINT UNSIGNED,
563
564 -- TODO: or should this be broken down into structured fields?
565 predicate TEXT NOT NULL,
566 -- TODO: or should this be broken down into structured fields?
567 consequence TEXT NOT NULL,
568
569 INDEX (project_id),
570 FOREIGN KEY (project_id) REFERENCES Project(project_id)
571) ENGINE=INNODB;
572
573
574-- Each row in this table indicates an issue that needs to be reindexed
575-- in the GAE fulltext index by our batch indexing cron job.
576CREATE TABLE ReindexQueue (
577 issue_id INT NOT NULL,
578 created TIMESTAMP,
579
580 PRIMARY KEY (issue_id),
581 INDEX (created),
582 FOREIGN KEY (issue_id) REFERENCES Issue(id)
583) ENGINE=INNODB;
584
585
586-- This holds counters with the highest issue local_id that is
587-- already used in each project. Clients should atomically increment
588-- the value for current project and then use the new counter value
589-- when creating an issue.
590CREATE TABLE LocalIDCounter (
591 project_id SMALLINT UNSIGNED NOT NULL,
592 used_local_id INT NOT NULL,
593 used_spam_id INT NOT NULL,
594
595 PRIMARY KEY (project_id),
596 FOREIGN KEY (project_id) REFERENCES Project(project_id)
597) ENGINE=INNODB;
598
599
600-- This is a saved query. It can be configured by a project owner to
601-- be used by all visitors to that project. Or, it can be a a
602-- personal saved query that appears on a user's "Saved queries" page
603-- and executes in the scope of one or more projects.
604CREATE TABLE SavedQuery (
605 id INT NOT NULL AUTO_INCREMENT,
606 name VARCHAR(80) NOT NULL,
607
608 -- For now, we only allow saved queries to be based off ane of the built-in
609 -- query scopes, and those can never be deleted, so there can be no nesting,
610 -- dangling references, and thus no need for cascading deletes.
611 base_query_id INT,
612 query TEXT NOT NULL,
613
614 PRIMARY KEY (id)
615) ENGINE=INNODB;
616
617
618-- Rows for built-in queries. These are in the database soley so that
619-- foreign key constraints are satisfied. These rows ar never read or updated.
620INSERT IGNORE INTO SavedQuery VALUES
621 (1, 'All issues', 0, ''),
622 (2, 'Open issues', 0, 'is:open'),
623 (3, 'Open and owned by me', 0, 'is:open owner:me'),
624 (4, 'Open and reported by me', 0, 'is:open reporter:me'),
625 (5, 'Open and starred by me', 0, 'is:open is:starred'),
626 (6, 'New issues', 0, 'status:new'),
627 (7, 'Issues to verify', 0, 'status=fixed,done'),
628 (8, 'Open with comment by me', 0, 'is:open commentby:me');
629
630-- The sole purpose of this statement is to force user defined saved queries
631-- to have IDs greater than 100 so that 1-100 are reserved for built-ins.
632INSERT IGNORE INTO SavedQuery VALUES (100, '', 0, '');
633
634
635-- User personal queries default to executing in the context of the
636-- project where they were created, but the user can edit them to make
637-- them into cross-project queries. Project saved queries always
638-- implicitly execute in the context of a project.
639CREATE TABLE SavedQueryExecutesInProject (
640 query_id INT NOT NULL,
641 project_id SMALLINT UNSIGNED NOT NULL,
642
643 PRIMARY KEY (query_id, project_id),
644 INDEX (project_id),
645 FOREIGN KEY (project_id) REFERENCES Project(project_id),
646 FOREIGN KEY (query_id) REFERENCES SavedQuery(id)
647) ENGINE=INNODB;
648
649
650-- These are the queries edited by the project owner on the project
651-- admin pages.
652CREATE TABLE Project2SavedQuery (
653 project_id SMALLINT UNSIGNED NOT NULL,
654 rank SMALLINT UNSIGNED NOT NULL,
655 query_id INT NOT NULL,
656
657 -- TODO(jrobbins): visibility: owners, committers, contributors, anyone
658
659 PRIMARY KEY (project_id, rank),
660 FOREIGN KEY (project_id) REFERENCES Project(project_id),
661 FOREIGN KEY (query_id) REFERENCES SavedQuery(id)
662) ENGINE=INNODB;
663
664
665-- These are personal saved queries.
666CREATE TABLE User2SavedQuery (
667 user_id INT UNSIGNED NOT NULL,
668 rank SMALLINT UNSIGNED NOT NULL,
669 query_id INT NOT NULL,
670
671 -- TODO(jrobbins): daily and weekly digests, and the ability to have
672 -- certain subscriptions go to username+SOMETHING@example.com.
673 subscription_mode ENUM ('noemail', 'immediate') DEFAULT 'noemail' NOT NULL,
674
675 PRIMARY KEY (user_id, rank),
676 FOREIGN KEY (user_id) REFERENCES User(user_id),
677 FOREIGN KEY (query_id) REFERENCES SavedQuery(id)
678) ENGINE=INNODB;
679
680
681-- Created whenever a user reports an issue or comment as spam.
682-- Note this is distinct from a SpamVerdict, which is issued by
683-- the system rather than a human user.
684CREATE TABLE SpamReport (
685 -- when this report was generated
686 created TIMESTAMP NOT NULL,
687 -- when the reported content was generated
688 -- TODO(jrobbins): needs default current_time in MySQL 5.7.
689 content_created TIMESTAMP NOT NULL,
690 -- id of the reporting user
691 user_id INT UNSIGNED NOT NULL,
692 -- id of the reported user
693 reported_user_id INT UNSIGNED NOT NULL,
694 -- either this or issue_id must be set
695 comment_id INT,
696 -- either this or comment_id must be set
697 issue_id INT,
698
699 INDEX (issue_id),
700 INDEX (comment_id),
701 UNIQUE (user_id, comment_id, issue_id),
702 FOREIGN KEY (issue_id) REFERENCES Issue(id),
703 FOREIGN KEY (comment_id) REFERENCES Comment(id)
704) ENGINE=INNODB;
705
706
707-- Any time a human or the system sets is_spam to true,
708-- or changes it from true to false, we want to have a
709-- record of who did it and why.
710CREATE TABLE SpamVerdict (
711 -- when this verdict was generated
712 created TIMESTAMP NOT NULL,
713
714 -- id of the reporting user, may be null if it was
715 -- an automatic classification.
716 user_id INT UNSIGNED,
717
718 -- id of the containing project.
719 project_id INT NOT NULL,
720
721 -- either this or issue_id must be set.
722 comment_id INT,
723
724 -- either this or comment_id must be set.
725 issue_id INT,
726
727 -- If the classifier issued the verdict, this should be set.
728 classifier_confidence FLOAT,
729
730 -- This should reflect the new is_spam value that was applied
731 -- by this verdict, not the value it had prior.
732 is_spam BOOLEAN NOT NULL,
733
734 -- manual: a project owner marked it as spam.
735 -- threshhold: number of SpamReports from non-members was exceeded.
736 -- classifier: the automatic classifier reports it as spam.
737 -- fail_open: the classifier failed, resulting in a ham decision.
738 reason ENUM ("manual", "threshold", "classifier", "fail_open") NOT NULL,
739
740 overruled BOOL NOT NULL,
741
742 -- True indicates that the prediction service PRC failed and we gave up.
743 fail_open BOOL DEFAULT FALSE,
744
745 INDEX (issue_id),
746 INDEX (comment_id),
747 INDEX (classifier_confidence),
748 FOREIGN KEY (issue_id) REFERENCES Issue(id),
749 FOREIGN KEY (comment_id) REFERENCES Comment(id)
750
751) ENGINE=INNODB;
752
753
754-- These are user-curated lists of issues which can be re-ordered to
755-- prioritize work.
756CREATE TABLE Hotlist (
757 id INT UNSIGNED NOT NULL AUTO_INCREMENT,
758 name VARCHAR(80) NOT NULL,
759
760 summary TEXT,
761 description TEXT,
762
763 is_private BOOLEAN DEFAULT FALSE,
764 is_deleted BOOLEAN DEFAULT FALSE,
765 default_col_spec TEXT,
766
767 PRIMARY KEY (id)
768) ENGINE=INNODB;
769
770
771CREATE TABLE Hotlist2Issue (
772 hotlist_id INT UNSIGNED NOT NULL,
773 issue_id INT NOT NULL,
774
775 rank BIGINT NOT NULL,
776 adder_id INT UNSIGNED,
777 added INT,
778 note TEXT,
779
780 PRIMARY KEY (hotlist_id, issue_id),
781 INDEX (hotlist_id),
782 INDEX (issue_id),
783 FOREIGN KEY (hotlist_id) REFERENCES Hotlist(id),
784 FOREIGN KEY (issue_id) REFERENCES Issue(id),
785 FOREIGN KEY (adder_id) REFERENCES User(user_id)
786) ENGINE=INNODB;
787
788
789CREATE TABLE Hotlist2User (
790 hotlist_id INT UNSIGNED NOT NULL,
791 user_id INT UNSIGNED NOT NULL,
792
793 role_name ENUM ('owner', 'editor', 'follower') NOT NULL,
794
795 PRIMARY KEY (hotlist_id, user_id),
796 INDEX (hotlist_id),
797 INDEX (user_id),
798 FOREIGN KEY (hotlist_id) REFERENCES Hotlist(id),
799 FOREIGN KEY (user_id) REFERENCES User(user_id)
800) ENGINE=INNODB;
801
802
803CREATE TABLE HotlistStar (
804 hotlist_id INT UNSIGNED NOT NULL,
805 user_id INT UNSIGNED NOT NULL,
806
807 PRIMARY KEY (hotlist_id, user_id),
808 INDEX (user_id),
809 FOREIGN KEY (hotlist_id) REFERENCES Hotlist(id),
810 FOREIGN KEY (user_id) REFERENCES User(user_id)
811) ENGINE=INNODB;
812
813
814CREATE TABLE HotlistVisitHistory (
815 hotlist_id INT UNSIGNED NOT NULL,
816 user_id INT UNSIGNED NOT NULL,
817 viewed INT NOT NULL,
818
819 PRIMARY KEY (user_id, hotlist_id),
820 FOREIGN KEY (hotlist_id) REFERENCES Hotlist(id),
821 FOREIGN KEY (user_id) REFERENCES User(user_id)
822) ENGINE=INNODB;
823
824
825CREATE TABLE ComponentIssueClosedIndex (
826 closed_index INT NOT NULL,
827 PRIMARY KEY (closed_index)
828) ENGINE=INNODB;
829
830
831CREATE TABLE ApprovalDef2Approver (
832 approval_id INT NOT NULL,
833 approver_id INT UNSIGNED NOT NULL,
834 project_id SMALLINT UNSIGNED NOT NULL,
835
836 PRIMARY KEY (approval_id, approver_id),
837
838 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
839 FOREIGN KEY (approver_id) REFERENCES User(user_id),
840 FOREIGN KEY (project_id) REFERENCES Project(project_id)
841) ENGINE=INNODB;
842
843
844CREATE TABLE ApprovalDef2Survey (
845 approval_id INT NOT NULL,
846 survey TEXT,
847 project_id SMALLINT UNSIGNED NOT NULL,
848
849 PRIMARY KEY (approval_id),
850
851 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
852 FOREIGN KEY (project_id) REFERENCES Project(project_id)
853) ENGINE=INNODB;
854
855CREATE TABLE Issue2ApprovalValue (
856 issue_id INT NOT NULL,
857 approval_id INT NOT NULL,
858 phase_id INT,
859 status ENUM ('needs_review', 'na', 'review_requested', 'review_started', 'need_info', 'approved', 'not_approved', 'not_set') DEFAULT 'not_set' NOT NULL,
860 setter_id INT UNSIGNED,
861 set_on INT,
862
863 PRIMARY KEY (issue_id, approval_id),
864 FOREIGN KEY (setter_id) REFERENCES User(user_id),
865 FOREIGN KEY (issue_id) REFERENCES Issue(id),
866 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
867 FOREIGN KEY (phase_id) REFERENCES IssuePhaseDef(id)
868) ENGINE=INNODB;
869
870
871CREATE TABLE IssueApproval2Approver (
872 issue_id INT NOT NULL,
873 approval_id INT NOT NULL,
874 approver_id INT UNSIGNED NOT NULL,
875
876 PRIMARY KEY (issue_id, approval_id, approver_id),
877 FOREIGN KEY (issue_id) REFERENCES Issue(id),
878 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
879 FOREIGN KEY (approver_id) REFERENCES User(user_id)
880) ENGINE=INNODB;
881
882
883CREATE TABLE IssueApproval2Comment (
884 approval_id INT NOT NULL,
885 comment_id INT NOT NULL,
886
887 PRIMARY KEY (comment_id),
888 INDEX (approval_id),
889 FOREIGN KEY (approval_id) REFERENCES FieldDef(id),
890 FOREIGN KEY (comment_id) REFERENCES Comment(id)
891) ENGINE=INNODB;
892
893
894CREATE TABLE IssueSnapshot (
895 id INT NOT NULL AUTO_INCREMENT,
896 issue_id INT NOT NULL,
897 shard SMALLINT UNSIGNED DEFAULT 0 NOT NULL,
898 project_id SMALLINT UNSIGNED NOT NULL,
899 local_id INT NOT NULL,
900 reporter_id INT UNSIGNED NOT NULL,
901 owner_id INT UNSIGNED,
902 status_id INT,
903 period_start INT UNSIGNED NOT NULL,
904 period_end INT UNSIGNED NOT NULL,
905 is_open BOOLEAN DEFAULT TRUE,
906
907 PRIMARY KEY (id),
908 FOREIGN KEY (project_id) REFERENCES Project(project_id),
909 FOREIGN KEY (reporter_id) REFERENCES User(user_id),
910 FOREIGN KEY (owner_id) REFERENCES User(user_id),
911 FOREIGN KEY (status_id) REFERENCES StatusDef(id),
912 INDEX (shard, project_id, period_start, period_end),
913 INDEX by_period_start (shard, project_id, status_id, period_start),
914 INDEX by_period_end (shard, project_id, status_id, period_end),
915 KEY (issue_id, period_start, period_end)
916) ENGINE=INNODB;
917
918
919CREATE TABLE IssueSnapshot2Component (
920 issuesnapshot_id INT NOT NULL,
921 component_id INT NOT NULL,
922
923 PRIMARY KEY (issuesnapshot_id, component_id),
924 FOREIGN KEY (issuesnapshot_id) REFERENCES IssueSnapshot(id),
925 FOREIGN KEY (component_id) REFERENCES ComponentDef(id)
926) ENGINE=INNODB;
927
928
929CREATE TABLE IssueSnapshot2Label(
930 issuesnapshot_id INT NOT NULL,
931 label_id INT NOT NULL,
932
933 PRIMARY KEY (issuesnapshot_id, label_id),
934 FOREIGN KEY (issuesnapshot_id) REFERENCES IssueSnapshot(id),
935 FOREIGN KEY (label_id) REFERENCES LabelDef(id)
936) ENGINE=INNODB;
937
938
939CREATE TABLE IssueSnapshot2Cc(
940 issuesnapshot_id INT NOT NULL,
941 cc_id INT UNSIGNED NOT NULL,
942
943 PRIMARY KEY (issuesnapshot_id, cc_id),
944 FOREIGN KEY (issuesnapshot_id) REFERENCES IssueSnapshot(id),
945 FOREIGN KEY (cc_id) REFERENCES User(user_id)
946) ENGINE=INNODB;
947
948
949CREATE TABLE IssueSnapshot2Hotlist(
950 issuesnapshot_id INT NOT NULL,
951 hotlist_id INT UNSIGNED NOT NULL,
952
953 PRIMARY KEY (issuesnapshot_id, hotlist_id),
954 FOREIGN KEY (issuesnapshot_id) REFERENCES IssueSnapshot(id),
955 FOREIGN KEY (hotlist_id) REFERENCES Hotlist(id)
956) ENGINE=INNODB;