Monorepo for Tangled
tangled.org
1package db
2
3import (
4 "context"
5 "database/sql"
6 "fmt"
7 "log/slog"
8 "reflect"
9 "strings"
10
11 _ "github.com/mattn/go-sqlite3"
12 "tangled.org/core/log"
13)
14
15type DB struct {
16 *sql.DB
17 logger *slog.Logger
18}
19
20type Execer interface {
21 Query(query string, args ...any) (*sql.Rows, error)
22 QueryContext(ctx context.Context, query string, args ...any) (*sql.Rows, error)
23 QueryRow(query string, args ...any) *sql.Row
24 QueryRowContext(ctx context.Context, query string, args ...any) *sql.Row
25 Exec(query string, args ...any) (sql.Result, error)
26 ExecContext(ctx context.Context, query string, args ...any) (sql.Result, error)
27 Prepare(query string) (*sql.Stmt, error)
28 PrepareContext(ctx context.Context, query string) (*sql.Stmt, error)
29}
30
31func Make(ctx context.Context, dbPath string) (*DB, error) {
32 // https://github.com/mattn/go-sqlite3#connection-string
33 opts := []string{
34 "_foreign_keys=1",
35 "_journal_mode=WAL",
36 "_synchronous=NORMAL",
37 "_auto_vacuum=incremental",
38 }
39
40 logger := log.FromContext(ctx)
41 logger = log.SubLogger(logger, "db")
42
43 db, err := sql.Open("sqlite3", dbPath+"?"+strings.Join(opts, "&"))
44 if err != nil {
45 return nil, err
46 }
47
48 conn, err := db.Conn(ctx)
49 if err != nil {
50 return nil, err
51 }
52 defer conn.Close()
53
54 _, err = conn.ExecContext(ctx, `
55 create table if not exists registrations (
56 id integer primary key autoincrement,
57 domain text not null unique,
58 did text not null,
59 secret text not null,
60 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
61 registered text
62 );
63 create table if not exists public_keys (
64 id integer primary key autoincrement,
65 did text not null,
66 name text not null,
67 key text not null,
68 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
69 unique(did, name, key)
70 );
71 create table if not exists repos (
72 id integer primary key autoincrement,
73 did text not null,
74 name text not null,
75 knot text not null,
76 rkey text not null,
77 at_uri text not null unique,
78 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
79 unique(did, name, knot, rkey)
80 );
81 create table if not exists collaborators (
82 id integer primary key autoincrement,
83 did text not null,
84 repo integer not null,
85 foreign key (repo) references repos(id) on delete cascade
86 );
87 create table if not exists follows (
88 user_did text not null,
89 subject_did text not null,
90 rkey text not null,
91 followed_at text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
92 primary key (user_did, subject_did),
93 check (user_did <> subject_did)
94 );
95 create table if not exists issues (
96 id integer primary key autoincrement,
97 owner_did text not null,
98 repo_at text not null,
99 issue_id integer not null,
100 title text not null,
101 body text not null,
102 open integer not null default 1,
103 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
104 issue_at text,
105 unique(repo_at, issue_id),
106 foreign key (repo_at) references repos(at_uri) on delete cascade
107 );
108 create table if not exists comments (
109 id integer primary key autoincrement,
110 owner_did text not null,
111 issue_id integer not null,
112 repo_at text not null,
113 comment_id integer not null,
114 comment_at text not null,
115 body text not null,
116 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
117 unique(issue_id, comment_id),
118 foreign key (repo_at, issue_id) references issues(repo_at, issue_id) on delete cascade
119 );
120 create table if not exists pulls (
121 -- identifiers
122 id integer primary key autoincrement,
123 pull_id integer not null,
124
125 -- at identifiers
126 repo_at text not null,
127 owner_did text not null,
128 rkey text not null,
129 pull_at text,
130
131 -- content
132 title text not null,
133 body text not null,
134 target_branch text not null,
135 state integer not null default 0 check (state in (0, 1, 2)), -- open, merged, closed
136
137 -- meta
138 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
139
140 -- constraints
141 unique(repo_at, pull_id),
142 foreign key (repo_at) references repos(at_uri) on delete cascade
143 );
144
145 -- every pull must have atleast 1 submission: the initial submission
146 create table if not exists pull_submissions (
147 -- identifiers
148 id integer primary key autoincrement,
149 pull_id integer not null,
150
151 -- at identifiers
152 repo_at text not null,
153
154 -- content, these are immutable, and require a resubmission to update
155 round_number integer not null default 0,
156 patch text,
157
158 -- meta
159 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
160
161 -- constraints
162 unique(repo_at, pull_id, round_number),
163 foreign key (repo_at, pull_id) references pulls(repo_at, pull_id) on delete cascade
164 );
165
166 create table if not exists pull_comments (
167 -- identifiers
168 id integer primary key autoincrement,
169 pull_id integer not null,
170 submission_id integer not null,
171
172 -- at identifiers
173 repo_at text not null,
174 owner_did text not null,
175 comment_at text not null,
176
177 -- content
178 body text not null,
179
180 -- meta
181 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
182
183 -- constraints
184 foreign key (repo_at, pull_id) references pulls(repo_at, pull_id) on delete cascade,
185 foreign key (submission_id) references pull_submissions(id) on delete cascade
186 );
187
188 create table if not exists _jetstream (
189 id integer primary key autoincrement,
190 last_time_us integer not null
191 );
192
193 create table if not exists repo_issue_seqs (
194 repo_at text primary key,
195 next_issue_id integer not null default 1
196 );
197
198 create table if not exists repo_pull_seqs (
199 repo_at text primary key,
200 next_pull_id integer not null default 1
201 );
202
203 create table if not exists stars (
204 id integer primary key autoincrement,
205 starred_by_did text not null,
206 repo_at text not null,
207 rkey text not null,
208 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
209 foreign key (repo_at) references repos(at_uri) on delete cascade,
210 unique(starred_by_did, repo_at)
211 );
212
213 create table if not exists reactions (
214 id integer primary key autoincrement,
215 reacted_by_did text not null,
216 thread_at text not null,
217 kind text not null,
218 rkey text not null,
219 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
220 unique(reacted_by_did, thread_at, kind)
221 );
222
223 create table if not exists emails (
224 id integer primary key autoincrement,
225 did text not null,
226 email text not null,
227 verified integer not null default 0,
228 verification_code text not null,
229 last_sent text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
230 is_primary integer not null default 0,
231 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
232 unique(did, email)
233 );
234
235 create table if not exists artifacts (
236 -- id
237 id integer primary key autoincrement,
238 did text not null,
239 rkey text not null,
240
241 -- meta
242 repo_at text not null,
243 tag binary(20) not null,
244 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
245
246 -- data
247 blob_cid text not null,
248 name text not null,
249 size integer not null default 0,
250 mimetype string not null default "*/*",
251
252 -- constraints
253 unique(did, rkey), -- record must be unique
254 unique(repo_at, tag, name), -- for a given tag object, each file must be unique
255 foreign key (repo_at) references repos(at_uri) on delete cascade
256 );
257
258 create table if not exists profile (
259 -- id
260 id integer primary key autoincrement,
261 did text not null,
262
263 -- data
264 description text not null,
265 include_bluesky integer not null default 0,
266 location text,
267
268 -- constraints
269 unique(did)
270 );
271 create table if not exists profile_links (
272 -- id
273 id integer primary key autoincrement,
274 did text not null,
275
276 -- data
277 link text not null,
278
279 -- constraints
280 foreign key (did) references profile(did) on delete cascade
281 );
282 create table if not exists profile_stats (
283 -- id
284 id integer primary key autoincrement,
285 did text not null,
286
287 -- data
288 kind text not null check (kind in (
289 "merged-pull-request-count",
290 "closed-pull-request-count",
291 "open-pull-request-count",
292 "open-issue-count",
293 "closed-issue-count",
294 "repository-count"
295 )),
296
297 -- constraints
298 foreign key (did) references profile(did) on delete cascade
299 );
300 create table if not exists profile_pinned_repositories (
301 -- id
302 id integer primary key autoincrement,
303 did text not null,
304
305 -- data
306 at_uri text not null,
307
308 -- constraints
309 unique(did, at_uri),
310 foreign key (did) references profile(did) on delete cascade,
311 foreign key (at_uri) references repos(at_uri) on delete cascade
312 );
313
314 create table if not exists oauth_requests (
315 id integer primary key autoincrement,
316 auth_server_iss text not null,
317 state text not null,
318 did text not null,
319 handle text not null,
320 pds_url text not null,
321 pkce_verifier text not null,
322 dpop_auth_server_nonce text not null,
323 dpop_private_jwk text not null
324 );
325
326 create table if not exists oauth_sessions (
327 id integer primary key autoincrement,
328 did text not null,
329 handle text not null,
330 pds_url text not null,
331 auth_server_iss text not null,
332 access_jwt text not null,
333 refresh_jwt text not null,
334 dpop_pds_nonce text,
335 dpop_auth_server_nonce text not null,
336 dpop_private_jwk text not null,
337 expiry text not null
338 );
339
340 create table if not exists punchcard (
341 did text not null,
342 date text not null, -- yyyy-mm-dd
343 count integer,
344 primary key (did, date)
345 );
346
347 create table if not exists spindles (
348 id integer primary key autoincrement,
349 owner text not null,
350 instance text not null,
351 verified text, -- time of verification
352 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
353
354 unique(owner, instance)
355 );
356
357 create table if not exists spindle_members (
358 -- identifiers for the record
359 id integer primary key autoincrement,
360 did text not null,
361 rkey text not null,
362
363 -- data
364 instance text not null,
365 subject text not null,
366 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
367
368 -- constraints
369 unique (did, instance, subject)
370 );
371
372 create table if not exists pipelines (
373 -- identifiers
374 id integer primary key autoincrement,
375 knot text not null,
376 rkey text not null,
377
378 repo_owner text not null,
379 repo_name text not null,
380
381 -- every pipeline must be associated with exactly one commit
382 sha text not null check (length(sha) = 40),
383 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
384
385 -- trigger data
386 trigger_id integer not null,
387
388 unique(knot, rkey),
389 foreign key (trigger_id) references triggers(id) on delete cascade
390 );
391
392 create table if not exists triggers (
393 -- primary key
394 id integer primary key autoincrement,
395
396 -- top-level fields
397 kind text not null,
398
399 -- pushTriggerData fields
400 push_ref text,
401 push_new_sha text check (length(push_new_sha) = 40),
402 push_old_sha text check (length(push_old_sha) = 40),
403
404 -- pullRequestTriggerData fields
405 pr_source_branch text,
406 pr_target_branch text,
407 pr_source_sha text check (length(pr_source_sha) = 40),
408 pr_action text
409 );
410
411 create table if not exists pipeline_statuses (
412 -- identifiers
413 id integer primary key autoincrement,
414 spindle text not null,
415 rkey text not null,
416
417 -- referenced pipeline. these form the (did, rkey) pair
418 pipeline_knot text not null,
419 pipeline_rkey text not null,
420
421 -- content
422 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
423 workflow text not null,
424 status text not null,
425 error text,
426 exit_code integer not null default 0,
427
428 unique (spindle, rkey),
429 foreign key (pipeline_knot, pipeline_rkey)
430 references pipelines (knot, rkey)
431 on delete cascade
432 );
433
434 create table if not exists repo_languages (
435 -- identifiers
436 id integer primary key autoincrement,
437
438 -- repo identifiers
439 repo_at text not null,
440 ref text not null,
441 is_default_ref integer not null default 0,
442
443 -- language breakdown
444 language text not null,
445 bytes integer not null check (bytes >= 0),
446
447 unique(repo_at, ref, language)
448 );
449
450 create table if not exists signups_inflight (
451 id integer primary key autoincrement,
452 email text not null unique,
453 invite_code text not null,
454 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now'))
455 );
456
457 create table if not exists strings (
458 -- identifiers
459 did text not null,
460 rkey text not null,
461
462 -- content
463 filename text not null,
464 description text,
465 content text not null,
466 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
467 edited text,
468
469 primary key (did, rkey)
470 );
471
472 create table if not exists label_definitions (
473 -- identifiers
474 id integer primary key autoincrement,
475 did text not null,
476 rkey text not null,
477 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.label.definition' || '/' || rkey) stored,
478
479 -- content
480 name text not null,
481 value_type text not null check (value_type in (
482 "null",
483 "boolean",
484 "integer",
485 "string"
486 )),
487 value_format text not null default "any",
488 value_enum text, -- comma separated list
489 scope text not null, -- comma separated list of nsid
490 color text,
491 multiple integer not null default 0,
492 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
493
494 -- constraints
495 unique (did, rkey)
496 unique (at_uri)
497 );
498
499 -- ops are flattened, a record may contain several additions and deletions, but the table will include one row per add/del
500 create table if not exists label_ops (
501 -- identifiers
502 id integer primary key autoincrement,
503 did text not null,
504 rkey text not null,
505 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.label.op' || '/' || rkey) stored,
506
507 -- content
508 subject text not null,
509 operation text not null check (operation in ("add", "del")),
510 operand_key text not null,
511 operand_value text not null,
512 -- we need two time values: performed is declared by the user, indexed is calculated by the av
513 performed text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
514 indexed text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
515
516 -- constraints
517 -- traditionally (did, rkey) pair should be unique, but not in this case
518 -- operand_key should reference a label definition
519 foreign key (operand_key) references label_definitions (at_uri) on delete cascade,
520 unique (did, rkey, subject, operand_key, operand_value)
521 );
522
523 create table if not exists repo_labels (
524 -- identifiers
525 id integer primary key autoincrement,
526
527 -- repo identifiers
528 repo_at text not null,
529
530 -- label to subscribe to
531 label_at text not null,
532
533 unique (repo_at, label_at)
534 );
535
536 create table if not exists notifications (
537 id integer primary key autoincrement,
538 recipient_did text not null,
539 actor_did text not null,
540 type text not null,
541 entity_type text not null,
542 entity_id text not null,
543 read integer not null default 0,
544 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
545 repo_id integer references repos(id),
546 issue_id integer references issues(id),
547 pull_id integer references pulls(id)
548 );
549
550 create table if not exists notification_preferences (
551 id integer primary key autoincrement,
552 user_did text not null unique,
553 repo_starred integer not null default 1,
554 issue_created integer not null default 1,
555 issue_commented integer not null default 1,
556 pull_created integer not null default 1,
557 pull_commented integer not null default 1,
558 followed integer not null default 1,
559 pull_merged integer not null default 1,
560 issue_closed integer not null default 1,
561 email_notifications integer not null default 0
562 );
563
564 create table if not exists reference_links (
565 id integer primary key autoincrement,
566 from_at text not null,
567 to_at text not null,
568 unique (from_at, to_at)
569 );
570
571 create table if not exists migrations (
572 id integer primary key autoincrement,
573 name text unique
574 );
575
576 -- indexes for better performance
577 create index if not exists idx_notifications_recipient_created on notifications(recipient_did, created desc);
578 create index if not exists idx_notifications_recipient_read on notifications(recipient_did, read);
579 create index if not exists idx_references_from_at on reference_links(from_at);
580 create index if not exists idx_references_to_at on reference_links(to_at);
581 `)
582 if err != nil {
583 return nil, err
584 }
585
586 // run migrations
587 runMigration(conn, logger, "add-description-to-repos", func(tx *sql.Tx) error {
588 tx.Exec(`
589 alter table repos add column description text check (length(description) <= 200);
590 `)
591 return nil
592 })
593
594 runMigration(conn, logger, "add-rkey-to-pubkeys", func(tx *sql.Tx) error {
595 // add unconstrained column
596 _, err := tx.Exec(`
597 alter table public_keys
598 add column rkey text;
599 `)
600 if err != nil {
601 return err
602 }
603
604 // backfill
605 _, err = tx.Exec(`
606 update public_keys
607 set rkey = ''
608 where rkey is null;
609 `)
610 if err != nil {
611 return err
612 }
613
614 return nil
615 })
616
617 runMigration(conn, logger, "add-rkey-to-comments", func(tx *sql.Tx) error {
618 _, err := tx.Exec(`
619 alter table comments drop column comment_at;
620 alter table comments add column rkey text;
621 `)
622 return err
623 })
624
625 runMigration(conn, logger, "add-deleted-and-edited-to-issue-comments", func(tx *sql.Tx) error {
626 _, err := tx.Exec(`
627 alter table comments add column deleted text; -- timestamp
628 alter table comments add column edited text; -- timestamp
629 `)
630 return err
631 })
632
633 runMigration(conn, logger, "add-source-info-to-pulls-and-submissions", func(tx *sql.Tx) error {
634 _, err := tx.Exec(`
635 alter table pulls add column source_branch text;
636 alter table pulls add column source_repo_at text;
637 alter table pull_submissions add column source_rev text;
638 `)
639 return err
640 })
641
642 runMigration(conn, logger, "add-source-to-repos", func(tx *sql.Tx) error {
643 _, err := tx.Exec(`
644 alter table repos add column source text;
645 `)
646 return err
647 })
648
649 // disable foreign-keys for the next migration
650 // NOTE: this cannot be done in a transaction, so it is run outside [0]
651 //
652 // [0]: https://sqlite.org/pragma.html#pragma_foreign_keys
653 conn.ExecContext(ctx, "pragma foreign_keys = off;")
654 runMigration(conn, logger, "recreate-pulls-column-for-stacking-support", func(tx *sql.Tx) error {
655 _, err := tx.Exec(`
656 create table pulls_new (
657 -- identifiers
658 id integer primary key autoincrement,
659 pull_id integer not null,
660
661 -- at identifiers
662 repo_at text not null,
663 owner_did text not null,
664 rkey text not null,
665
666 -- content
667 title text not null,
668 body text not null,
669 target_branch text not null,
670 state integer not null default 0 check (state in (0, 1, 2, 3)), -- closed, open, merged, deleted
671
672 -- source info
673 source_branch text,
674 source_repo_at text,
675
676 -- stacking
677 stack_id text,
678 change_id text,
679 parent_change_id text,
680
681 -- meta
682 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
683
684 -- constraints
685 unique(repo_at, pull_id),
686 foreign key (repo_at) references repos(at_uri) on delete cascade
687 );
688
689 insert into pulls_new (
690 id, pull_id,
691 repo_at, owner_did, rkey,
692 title, body, target_branch, state,
693 source_branch, source_repo_at,
694 created
695 )
696 select
697 id, pull_id,
698 repo_at, owner_did, rkey,
699 title, body, target_branch, state,
700 source_branch, source_repo_at,
701 created
702 FROM pulls;
703
704 drop table pulls;
705 alter table pulls_new rename to pulls;
706 `)
707 return err
708 })
709 conn.ExecContext(ctx, "pragma foreign_keys = on;")
710
711 runMigration(conn, logger, "add-spindle-to-repos", func(tx *sql.Tx) error {
712 tx.Exec(`
713 alter table repos add column spindle text;
714 `)
715 return nil
716 })
717
718 // drop all knot secrets, add unique constraint to knots
719 //
720 // knots will henceforth use service auth for signed requests
721 runMigration(conn, logger, "no-more-secrets", func(tx *sql.Tx) error {
722 _, err := tx.Exec(`
723 create table registrations_new (
724 id integer primary key autoincrement,
725 domain text not null,
726 did text not null,
727 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
728 registered text,
729 read_only integer not null default 0,
730 unique(domain, did)
731 );
732
733 insert into registrations_new (id, domain, did, created, registered, read_only)
734 select id, domain, did, created, registered, 1 from registrations
735 where registered is not null;
736
737 drop table registrations;
738 alter table registrations_new rename to registrations;
739 `)
740 return err
741 })
742
743 // recreate and add rkey + created columns with default constraint
744 runMigration(conn, logger, "rework-collaborators-table", func(tx *sql.Tx) error {
745 // create new table
746 // - repo_at instead of repo integer
747 // - rkey field
748 // - created field
749 _, err := tx.Exec(`
750 create table collaborators_new (
751 -- identifiers for the record
752 id integer primary key autoincrement,
753 did text not null,
754 rkey text,
755
756 -- content
757 subject_did text not null,
758 repo_at text not null,
759
760 -- meta
761 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
762
763 -- constraints
764 foreign key (repo_at) references repos(at_uri) on delete cascade
765 )
766 `)
767 if err != nil {
768 return err
769 }
770
771 // copy data
772 _, err = tx.Exec(`
773 insert into collaborators_new (id, did, rkey, subject_did, repo_at)
774 select
775 c.id,
776 r.did,
777 '',
778 c.did,
779 r.at_uri
780 from collaborators c
781 join repos r on c.repo = r.id
782 `)
783 if err != nil {
784 return err
785 }
786
787 // drop old table
788 _, err = tx.Exec(`drop table collaborators`)
789 if err != nil {
790 return err
791 }
792
793 // rename new table
794 _, err = tx.Exec(`alter table collaborators_new rename to collaborators`)
795 return err
796 })
797
798 runMigration(conn, logger, "add-rkey-to-issues", func(tx *sql.Tx) error {
799 _, err := tx.Exec(`
800 alter table issues add column rkey text not null default '';
801
802 -- get last url section from issue_at and save to rkey column
803 update issues
804 set rkey = replace(issue_at, rtrim(issue_at, replace(issue_at, '/', '')), '');
805 `)
806 return err
807 })
808
809 // repurpose the read-only column to "needs-upgrade"
810 runMigration(conn, logger, "rename-registrations-read-only-to-needs-upgrade", func(tx *sql.Tx) error {
811 _, err := tx.Exec(`
812 alter table registrations rename column read_only to needs_upgrade;
813 `)
814 return err
815 })
816
817 // require all knots to upgrade after the release of total xrpc
818 runMigration(conn, logger, "migrate-knots-to-total-xrpc", func(tx *sql.Tx) error {
819 _, err := tx.Exec(`
820 update registrations set needs_upgrade = 1;
821 `)
822 return err
823 })
824
825 // require all knots to upgrade after the release of total xrpc
826 runMigration(conn, logger, "migrate-spindles-to-xrpc-owner", func(tx *sql.Tx) error {
827 _, err := tx.Exec(`
828 alter table spindles add column needs_upgrade integer not null default 0;
829 `)
830 return err
831 })
832
833 // remove issue_at from issues and replace with generated column
834 //
835 // this requires a full table recreation because stored columns
836 // cannot be added via alter
837 //
838 // couple other changes:
839 // - columns renamed to be more consistent
840 // - adds edited and deleted fields
841 //
842 // disable foreign-keys for the next migration
843 conn.ExecContext(ctx, "pragma foreign_keys = off;")
844 runMigration(conn, logger, "remove-issue-at-from-issues", func(tx *sql.Tx) error {
845 _, err := tx.Exec(`
846 create table if not exists issues_new (
847 -- identifiers
848 id integer primary key autoincrement,
849 did text not null,
850 rkey text not null,
851 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue' || '/' || rkey) stored,
852
853 -- at identifiers
854 repo_at text not null,
855
856 -- content
857 issue_id integer not null,
858 title text not null,
859 body text not null,
860 open integer not null default 1,
861 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
862 edited text, -- timestamp
863 deleted text, -- timestamp
864
865 unique(did, rkey),
866 unique(repo_at, issue_id),
867 unique(at_uri),
868 foreign key (repo_at) references repos(at_uri) on delete cascade
869 );
870 `)
871 if err != nil {
872 return err
873 }
874
875 // transfer data
876 _, err = tx.Exec(`
877 insert into issues_new (id, did, rkey, repo_at, issue_id, title, body, open, created)
878 select
879 i.id,
880 i.owner_did,
881 i.rkey,
882 i.repo_at,
883 i.issue_id,
884 i.title,
885 i.body,
886 i.open,
887 i.created
888 from issues i;
889 `)
890 if err != nil {
891 return err
892 }
893
894 // drop old table
895 _, err = tx.Exec(`drop table issues`)
896 if err != nil {
897 return err
898 }
899
900 // rename new table
901 _, err = tx.Exec(`alter table issues_new rename to issues`)
902 return err
903 })
904 conn.ExecContext(ctx, "pragma foreign_keys = on;")
905
906 // - renames the comments table to 'issue_comments'
907 // - rework issue comments to update constraints:
908 // * unique(did, rkey)
909 // * remove comment-id and just use the global ID
910 // * foreign key (repo_at, issue_id)
911 // - new columns
912 // * column "reply_to" which can be any other comment
913 // * column "at-uri" which is a generated column
914 runMigration(conn, logger, "rework-issue-comments", func(tx *sql.Tx) error {
915 _, err := tx.Exec(`
916 create table if not exists issue_comments (
917 -- identifiers
918 id integer primary key autoincrement,
919 did text not null,
920 rkey text,
921 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue.comment' || '/' || rkey) stored,
922
923 -- at identifiers
924 issue_at text not null,
925 reply_to text, -- at_uri of parent comment
926
927 -- content
928 body text not null,
929 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
930 edited text,
931 deleted text,
932
933 -- constraints
934 unique(did, rkey),
935 unique(at_uri),
936 foreign key (issue_at) references issues(at_uri) on delete cascade
937 );
938 `)
939 if err != nil {
940 return err
941 }
942
943 // transfer data
944 _, err = tx.Exec(`
945 insert into issue_comments (id, did, rkey, issue_at, body, created, edited, deleted)
946 select
947 c.id,
948 c.owner_did,
949 c.rkey,
950 i.at_uri, -- get at_uri from issues table
951 c.body,
952 c.created,
953 c.edited,
954 c.deleted
955 from comments c
956 join issues i on c.repo_at = i.repo_at and c.issue_id = i.issue_id;
957 `)
958 if err != nil {
959 return err
960 }
961
962 // drop old table
963 _, err = tx.Exec(`drop table comments`)
964 return err
965 })
966
967 // add generated at_uri column to pulls table
968 //
969 // this requires a full table recreation because stored columns
970 // cannot be added via alter
971 //
972 // disable foreign-keys for the next migration
973 conn.ExecContext(ctx, "pragma foreign_keys = off;")
974 runMigration(conn, logger, "add-at-uri-to-pulls", func(tx *sql.Tx) error {
975 _, err := tx.Exec(`
976 create table if not exists pulls_new (
977 -- identifiers
978 id integer primary key autoincrement,
979 pull_id integer not null,
980 at_uri text generated always as ('at://' || owner_did || '/' || 'sh.tangled.repo.pull' || '/' || rkey) stored,
981
982 -- at identifiers
983 repo_at text not null,
984 owner_did text not null,
985 rkey text not null,
986
987 -- content
988 title text not null,
989 body text not null,
990 target_branch text not null,
991 state integer not null default 0 check (state in (0, 1, 2, 3)), -- closed, open, merged, deleted
992
993 -- source info
994 source_branch text,
995 source_repo_at text,
996
997 -- stacking
998 stack_id text,
999 change_id text,
1000 parent_change_id text,
1001
1002 -- meta
1003 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
1004
1005 -- constraints
1006 unique(repo_at, pull_id),
1007 unique(at_uri),
1008 foreign key (repo_at) references repos(at_uri) on delete cascade
1009 );
1010 `)
1011 if err != nil {
1012 return err
1013 }
1014
1015 // transfer data
1016 _, err = tx.Exec(`
1017 insert into pulls_new (
1018 id, pull_id, repo_at, owner_did, rkey,
1019 title, body, target_branch, state,
1020 source_branch, source_repo_at,
1021 stack_id, change_id, parent_change_id,
1022 created
1023 )
1024 select
1025 id, pull_id, repo_at, owner_did, rkey,
1026 title, body, target_branch, state,
1027 source_branch, source_repo_at,
1028 stack_id, change_id, parent_change_id,
1029 created
1030 from pulls;
1031 `)
1032 if err != nil {
1033 return err
1034 }
1035
1036 // drop old table
1037 _, err = tx.Exec(`drop table pulls`)
1038 if err != nil {
1039 return err
1040 }
1041
1042 // rename new table
1043 _, err = tx.Exec(`alter table pulls_new rename to pulls`)
1044 return err
1045 })
1046 conn.ExecContext(ctx, "pragma foreign_keys = on;")
1047
1048 // remove repo_at and pull_id from pull_submissions and replace with pull_at
1049 //
1050 // this requires a full table recreation because stored columns
1051 // cannot be added via alter
1052 //
1053 // disable foreign-keys for the next migration
1054 conn.ExecContext(ctx, "pragma foreign_keys = off;")
1055 runMigration(conn, logger, "remove-repo-at-pull-id-from-pull-submissions", func(tx *sql.Tx) error {
1056 _, err := tx.Exec(`
1057 create table if not exists pull_submissions_new (
1058 -- identifiers
1059 id integer primary key autoincrement,
1060 pull_at text not null,
1061
1062 -- content, these are immutable, and require a resubmission to update
1063 round_number integer not null default 0,
1064 patch text,
1065 source_rev text,
1066
1067 -- meta
1068 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
1069
1070 -- constraints
1071 unique(pull_at, round_number),
1072 foreign key (pull_at) references pulls(at_uri) on delete cascade
1073 );
1074 `)
1075 if err != nil {
1076 return err
1077 }
1078
1079 // transfer data, constructing pull_at from pulls table
1080 _, err = tx.Exec(`
1081 insert into pull_submissions_new (id, pull_at, round_number, patch, created)
1082 select
1083 ps.id,
1084 'at://' || p.owner_did || '/sh.tangled.repo.pull/' || p.rkey,
1085 ps.round_number,
1086 ps.patch,
1087 ps.created
1088 from pull_submissions ps
1089 join pulls p on ps.repo_at = p.repo_at and ps.pull_id = p.pull_id;
1090 `)
1091 if err != nil {
1092 return err
1093 }
1094
1095 // drop old table
1096 _, err = tx.Exec(`drop table pull_submissions`)
1097 if err != nil {
1098 return err
1099 }
1100
1101 // rename new table
1102 _, err = tx.Exec(`alter table pull_submissions_new rename to pull_submissions`)
1103 return err
1104 })
1105 conn.ExecContext(ctx, "pragma foreign_keys = on;")
1106
1107 // knots may report the combined patch for a comparison, we can store that on the appview side
1108 // (but not on the pds record), because calculating the combined patch requires a git index
1109 runMigration(conn, logger, "add-combined-column-submissions", func(tx *sql.Tx) error {
1110 _, err := tx.Exec(`
1111 alter table pull_submissions add column combined text;
1112 `)
1113 return err
1114 })
1115
1116 runMigration(conn, logger, "add-pronouns-profile", func(tx *sql.Tx) error {
1117 _, err := tx.Exec(`
1118 alter table profile add column pronouns text;
1119 `)
1120 return err
1121 })
1122
1123 runMigration(conn, logger, "add-meta-column-repos", func(tx *sql.Tx) error {
1124 _, err := tx.Exec(`
1125 alter table repos add column website text;
1126 alter table repos add column topics text;
1127 `)
1128 return err
1129 })
1130
1131 runMigration(conn, logger, "add-usermentioned-preference", func(tx *sql.Tx) error {
1132 _, err := tx.Exec(`
1133 alter table notification_preferences add column user_mentioned integer not null default 1;
1134 `)
1135 return err
1136 })
1137
1138 // remove the foreign key constraints from stars.
1139 runMigration(conn, logger, "generalize-stars-subject", func(tx *sql.Tx) error {
1140 _, err := tx.Exec(`
1141 create table stars_new (
1142 id integer primary key autoincrement,
1143 did text not null,
1144 rkey text not null,
1145
1146 subject_at text not null,
1147
1148 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
1149 unique(did, rkey),
1150 unique(did, subject_at)
1151 );
1152
1153 insert into stars_new (
1154 id,
1155 did,
1156 rkey,
1157 subject_at,
1158 created
1159 )
1160 select
1161 id,
1162 starred_by_did,
1163 rkey,
1164 repo_at,
1165 created
1166 from stars;
1167
1168 drop table stars;
1169 alter table stars_new rename to stars;
1170
1171 create index if not exists idx_stars_created on stars(created);
1172 create index if not exists idx_stars_subject_at_created on stars(subject_at, created);
1173 `)
1174 return err
1175 })
1176
1177 return &DB{
1178 db,
1179 logger,
1180 }, nil
1181}
1182
1183type migrationFn = func(*sql.Tx) error
1184
1185func runMigration(c *sql.Conn, logger *slog.Logger, name string, migrationFn migrationFn) error {
1186 logger = logger.With("migration", name)
1187
1188 tx, err := c.BeginTx(context.Background(), nil)
1189 if err != nil {
1190 return err
1191 }
1192 defer tx.Rollback()
1193
1194 var exists bool
1195 err = tx.QueryRow("select exists (select 1 from migrations where name = ?)", name).Scan(&exists)
1196 if err != nil {
1197 return err
1198 }
1199
1200 if !exists {
1201 // run migration
1202 err = migrationFn(tx)
1203 if err != nil {
1204 logger.Error("failed to run migration", "err", err)
1205 return err
1206 }
1207
1208 // mark migration as complete
1209 _, err = tx.Exec("insert into migrations (name) values (?)", name)
1210 if err != nil {
1211 logger.Error("failed to mark migration as complete", "err", err)
1212 return err
1213 }
1214
1215 // commit the transaction
1216 if err := tx.Commit(); err != nil {
1217 return err
1218 }
1219
1220 logger.Info("migration applied successfully")
1221 } else {
1222 logger.Warn("skipped migration, already applied")
1223 }
1224
1225 return nil
1226}
1227
1228func (d *DB) Close() error {
1229 return d.DB.Close()
1230}
1231
1232type filter struct {
1233 key string
1234 arg any
1235 cmp string
1236}
1237
1238func newFilter(key, cmp string, arg any) filter {
1239 return filter{
1240 key: key,
1241 arg: arg,
1242 cmp: cmp,
1243 }
1244}
1245
1246func FilterEq(key string, arg any) filter { return newFilter(key, "=", arg) }
1247func FilterNotEq(key string, arg any) filter { return newFilter(key, "<>", arg) }
1248func FilterGte(key string, arg any) filter { return newFilter(key, ">=", arg) }
1249func FilterLte(key string, arg any) filter { return newFilter(key, "<=", arg) }
1250func FilterIs(key string, arg any) filter { return newFilter(key, "is", arg) }
1251func FilterIsNot(key string, arg any) filter { return newFilter(key, "is not", arg) }
1252func FilterIn(key string, arg any) filter { return newFilter(key, "in", arg) }
1253func FilterLike(key string, arg any) filter { return newFilter(key, "like", arg) }
1254func FilterNotLike(key string, arg any) filter { return newFilter(key, "not like", arg) }
1255func FilterContains(key string, arg any) filter {
1256 return newFilter(key, "like", fmt.Sprintf("%%%v%%", arg))
1257}
1258
1259func (f filter) Condition() string {
1260 rv := reflect.ValueOf(f.arg)
1261 kind := rv.Kind()
1262
1263 // if we have `FilterIn(k, [1, 2, 3])`, compile it down to `k in (?, ?, ?)`
1264 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array {
1265 if rv.Len() == 0 {
1266 // always false
1267 return "1 = 0"
1268 }
1269
1270 placeholders := make([]string, rv.Len())
1271 for i := range placeholders {
1272 placeholders[i] = "?"
1273 }
1274
1275 return fmt.Sprintf("%s %s (%s)", f.key, f.cmp, strings.Join(placeholders, ", "))
1276 }
1277
1278 return fmt.Sprintf("%s %s ?", f.key, f.cmp)
1279}
1280
1281func (f filter) Arg() []any {
1282 rv := reflect.ValueOf(f.arg)
1283 kind := rv.Kind()
1284 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array {
1285 if rv.Len() == 0 {
1286 return nil
1287 }
1288
1289 out := make([]any, rv.Len())
1290 for i := range rv.Len() {
1291 out[i] = rv.Index(i).Interface()
1292 }
1293 return out
1294 }
1295
1296 return []any{f.arg}
1297}