forked from tangled.org/core
Monorepo for Tangled — https://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_stars_created on stars(created); 580 create index if not exists idx_stars_repo_at_created on stars(repo_at, created); 581 create index if not exists idx_references_from_at on reference_links(from_at); 582 create index if not exists idx_references_to_at on reference_links(to_at); 583 `) 584 if err != nil { 585 return nil, err 586 } 587 588 // run migrations 589 runMigration(conn, logger, "add-description-to-repos", func(tx *sql.Tx) error { 590 tx.Exec(` 591 alter table repos add column description text check (length(description) <= 200); 592 `) 593 return nil 594 }) 595 596 runMigration(conn, logger, "add-rkey-to-pubkeys", func(tx *sql.Tx) error { 597 // add unconstrained column 598 _, err := tx.Exec(` 599 alter table public_keys 600 add column rkey text; 601 `) 602 if err != nil { 603 return err 604 } 605 606 // backfill 607 _, err = tx.Exec(` 608 update public_keys 609 set rkey = '' 610 where rkey is null; 611 `) 612 if err != nil { 613 return err 614 } 615 616 return nil 617 }) 618 619 runMigration(conn, logger, "add-rkey-to-comments", func(tx *sql.Tx) error { 620 _, err := tx.Exec(` 621 alter table comments drop column comment_at; 622 alter table comments add column rkey text; 623 `) 624 return err 625 }) 626 627 runMigration(conn, logger, "add-deleted-and-edited-to-issue-comments", func(tx *sql.Tx) error { 628 _, err := tx.Exec(` 629 alter table comments add column deleted text; -- timestamp 630 alter table comments add column edited text; -- timestamp 631 `) 632 return err 633 }) 634 635 runMigration(conn, logger, "add-source-info-to-pulls-and-submissions", func(tx *sql.Tx) error { 636 _, err := tx.Exec(` 637 alter table pulls add column source_branch text; 638 alter table pulls add column source_repo_at text; 639 alter table pull_submissions add column source_rev text; 640 `) 641 return err 642 }) 643 644 runMigration(conn, logger, "add-source-to-repos", func(tx *sql.Tx) error { 645 _, err := tx.Exec(` 646 alter table repos add column source text; 647 `) 648 return err 649 }) 650 651 // disable foreign-keys for the next migration 652 // NOTE: this cannot be done in a transaction, so it is run outside [0] 653 // 654 // [0]: https://sqlite.org/pragma.html#pragma_foreign_keys 655 conn.ExecContext(ctx, "pragma foreign_keys = off;") 656 runMigration(conn, logger, "recreate-pulls-column-for-stacking-support", func(tx *sql.Tx) error { 657 _, err := tx.Exec(` 658 create table pulls_new ( 659 -- identifiers 660 id integer primary key autoincrement, 661 pull_id integer not null, 662 663 -- at identifiers 664 repo_at text not null, 665 owner_did text not null, 666 rkey text not null, 667 668 -- content 669 title text not null, 670 body text not null, 671 target_branch text not null, 672 state integer not null default 0 check (state in (0, 1, 2, 3)), -- closed, open, merged, deleted 673 674 -- source info 675 source_branch text, 676 source_repo_at text, 677 678 -- stacking 679 stack_id text, 680 change_id text, 681 parent_change_id text, 682 683 -- meta 684 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 685 686 -- constraints 687 unique(repo_at, pull_id), 688 foreign key (repo_at) references repos(at_uri) on delete cascade 689 ); 690 691 insert into pulls_new ( 692 id, pull_id, 693 repo_at, owner_did, rkey, 694 title, body, target_branch, state, 695 source_branch, source_repo_at, 696 created 697 ) 698 select 699 id, pull_id, 700 repo_at, owner_did, rkey, 701 title, body, target_branch, state, 702 source_branch, source_repo_at, 703 created 704 FROM pulls; 705 706 drop table pulls; 707 alter table pulls_new rename to pulls; 708 `) 709 return err 710 }) 711 conn.ExecContext(ctx, "pragma foreign_keys = on;") 712 713 runMigration(conn, logger, "add-spindle-to-repos", func(tx *sql.Tx) error { 714 tx.Exec(` 715 alter table repos add column spindle text; 716 `) 717 return nil 718 }) 719 720 // drop all knot secrets, add unique constraint to knots 721 // 722 // knots will henceforth use service auth for signed requests 723 runMigration(conn, logger, "no-more-secrets", func(tx *sql.Tx) error { 724 _, err := tx.Exec(` 725 create table registrations_new ( 726 id integer primary key autoincrement, 727 domain text not null, 728 did text not null, 729 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 730 registered text, 731 read_only integer not null default 0, 732 unique(domain, did) 733 ); 734 735 insert into registrations_new (id, domain, did, created, registered, read_only) 736 select id, domain, did, created, registered, 1 from registrations 737 where registered is not null; 738 739 drop table registrations; 740 alter table registrations_new rename to registrations; 741 `) 742 return err 743 }) 744 745 // recreate and add rkey + created columns with default constraint 746 runMigration(conn, logger, "rework-collaborators-table", func(tx *sql.Tx) error { 747 // create new table 748 // - repo_at instead of repo integer 749 // - rkey field 750 // - created field 751 _, err := tx.Exec(` 752 create table collaborators_new ( 753 -- identifiers for the record 754 id integer primary key autoincrement, 755 did text not null, 756 rkey text, 757 758 -- content 759 subject_did text not null, 760 repo_at text not null, 761 762 -- meta 763 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 764 765 -- constraints 766 foreign key (repo_at) references repos(at_uri) on delete cascade 767 ) 768 `) 769 if err != nil { 770 return err 771 } 772 773 // copy data 774 _, err = tx.Exec(` 775 insert into collaborators_new (id, did, rkey, subject_did, repo_at) 776 select 777 c.id, 778 r.did, 779 '', 780 c.did, 781 r.at_uri 782 from collaborators c 783 join repos r on c.repo = r.id 784 `) 785 if err != nil { 786 return err 787 } 788 789 // drop old table 790 _, err = tx.Exec(`drop table collaborators`) 791 if err != nil { 792 return err 793 } 794 795 // rename new table 796 _, err = tx.Exec(`alter table collaborators_new rename to collaborators`) 797 return err 798 }) 799 800 runMigration(conn, logger, "add-rkey-to-issues", func(tx *sql.Tx) error { 801 _, err := tx.Exec(` 802 alter table issues add column rkey text not null default ''; 803 804 -- get last url section from issue_at and save to rkey column 805 update issues 806 set rkey = replace(issue_at, rtrim(issue_at, replace(issue_at, '/', '')), ''); 807 `) 808 return err 809 }) 810 811 // repurpose the read-only column to "needs-upgrade" 812 runMigration(conn, logger, "rename-registrations-read-only-to-needs-upgrade", func(tx *sql.Tx) error { 813 _, err := tx.Exec(` 814 alter table registrations rename column read_only to needs_upgrade; 815 `) 816 return err 817 }) 818 819 // require all knots to upgrade after the release of total xrpc 820 runMigration(conn, logger, "migrate-knots-to-total-xrpc", func(tx *sql.Tx) error { 821 _, err := tx.Exec(` 822 update registrations set needs_upgrade = 1; 823 `) 824 return err 825 }) 826 827 // require all knots to upgrade after the release of total xrpc 828 runMigration(conn, logger, "migrate-spindles-to-xrpc-owner", func(tx *sql.Tx) error { 829 _, err := tx.Exec(` 830 alter table spindles add column needs_upgrade integer not null default 0; 831 `) 832 return err 833 }) 834 835 // remove issue_at from issues and replace with generated column 836 // 837 // this requires a full table recreation because stored columns 838 // cannot be added via alter 839 // 840 // couple other changes: 841 // - columns renamed to be more consistent 842 // - adds edited and deleted fields 843 // 844 // disable foreign-keys for the next migration 845 conn.ExecContext(ctx, "pragma foreign_keys = off;") 846 runMigration(conn, logger, "remove-issue-at-from-issues", func(tx *sql.Tx) error { 847 _, err := tx.Exec(` 848 create table if not exists issues_new ( 849 -- identifiers 850 id integer primary key autoincrement, 851 did text not null, 852 rkey text not null, 853 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue' || '/' || rkey) stored, 854 855 -- at identifiers 856 repo_at text not null, 857 858 -- content 859 issue_id integer not null, 860 title text not null, 861 body text not null, 862 open integer not null default 1, 863 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 864 edited text, -- timestamp 865 deleted text, -- timestamp 866 867 unique(did, rkey), 868 unique(repo_at, issue_id), 869 unique(at_uri), 870 foreign key (repo_at) references repos(at_uri) on delete cascade 871 ); 872 `) 873 if err != nil { 874 return err 875 } 876 877 // transfer data 878 _, err = tx.Exec(` 879 insert into issues_new (id, did, rkey, repo_at, issue_id, title, body, open, created) 880 select 881 i.id, 882 i.owner_did, 883 i.rkey, 884 i.repo_at, 885 i.issue_id, 886 i.title, 887 i.body, 888 i.open, 889 i.created 890 from issues i; 891 `) 892 if err != nil { 893 return err 894 } 895 896 // drop old table 897 _, err = tx.Exec(`drop table issues`) 898 if err != nil { 899 return err 900 } 901 902 // rename new table 903 _, err = tx.Exec(`alter table issues_new rename to issues`) 904 return err 905 }) 906 conn.ExecContext(ctx, "pragma foreign_keys = on;") 907 908 // - renames the comments table to 'issue_comments' 909 // - rework issue comments to update constraints: 910 // * unique(did, rkey) 911 // * remove comment-id and just use the global ID 912 // * foreign key (repo_at, issue_id) 913 // - new columns 914 // * column "reply_to" which can be any other comment 915 // * column "at-uri" which is a generated column 916 runMigration(conn, logger, "rework-issue-comments", func(tx *sql.Tx) error { 917 _, err := tx.Exec(` 918 create table if not exists issue_comments ( 919 -- identifiers 920 id integer primary key autoincrement, 921 did text not null, 922 rkey text, 923 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue.comment' || '/' || rkey) stored, 924 925 -- at identifiers 926 issue_at text not null, 927 reply_to text, -- at_uri of parent comment 928 929 -- content 930 body text not null, 931 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 932 edited text, 933 deleted text, 934 935 -- constraints 936 unique(did, rkey), 937 unique(at_uri), 938 foreign key (issue_at) references issues(at_uri) on delete cascade 939 ); 940 `) 941 if err != nil { 942 return err 943 } 944 945 // transfer data 946 _, err = tx.Exec(` 947 insert into issue_comments (id, did, rkey, issue_at, body, created, edited, deleted) 948 select 949 c.id, 950 c.owner_did, 951 c.rkey, 952 i.at_uri, -- get at_uri from issues table 953 c.body, 954 c.created, 955 c.edited, 956 c.deleted 957 from comments c 958 join issues i on c.repo_at = i.repo_at and c.issue_id = i.issue_id; 959 `) 960 if err != nil { 961 return err 962 } 963 964 // drop old table 965 _, err = tx.Exec(`drop table comments`) 966 return err 967 }) 968 969 // add generated at_uri column to pulls table 970 // 971 // this requires a full table recreation because stored columns 972 // cannot be added via alter 973 // 974 // disable foreign-keys for the next migration 975 conn.ExecContext(ctx, "pragma foreign_keys = off;") 976 runMigration(conn, logger, "add-at-uri-to-pulls", func(tx *sql.Tx) error { 977 _, err := tx.Exec(` 978 create table if not exists pulls_new ( 979 -- identifiers 980 id integer primary key autoincrement, 981 pull_id integer not null, 982 at_uri text generated always as ('at://' || owner_did || '/' || 'sh.tangled.repo.pull' || '/' || rkey) stored, 983 984 -- at identifiers 985 repo_at text not null, 986 owner_did text not null, 987 rkey text not null, 988 989 -- content 990 title text not null, 991 body text not null, 992 target_branch text not null, 993 state integer not null default 0 check (state in (0, 1, 2, 3)), -- closed, open, merged, deleted 994 995 -- source info 996 source_branch text, 997 source_repo_at text, 998 999 -- stacking 1000 stack_id text, 1001 change_id text, 1002 parent_change_id text, 1003 1004 -- meta 1005 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 1006 1007 -- constraints 1008 unique(repo_at, pull_id), 1009 unique(at_uri), 1010 foreign key (repo_at) references repos(at_uri) on delete cascade 1011 ); 1012 `) 1013 if err != nil { 1014 return err 1015 } 1016 1017 // transfer data 1018 _, err = tx.Exec(` 1019 insert into pulls_new ( 1020 id, pull_id, repo_at, owner_did, rkey, 1021 title, body, target_branch, state, 1022 source_branch, source_repo_at, 1023 stack_id, change_id, parent_change_id, 1024 created 1025 ) 1026 select 1027 id, pull_id, repo_at, owner_did, rkey, 1028 title, body, target_branch, state, 1029 source_branch, source_repo_at, 1030 stack_id, change_id, parent_change_id, 1031 created 1032 from pulls; 1033 `) 1034 if err != nil { 1035 return err 1036 } 1037 1038 // drop old table 1039 _, err = tx.Exec(`drop table pulls`) 1040 if err != nil { 1041 return err 1042 } 1043 1044 // rename new table 1045 _, err = tx.Exec(`alter table pulls_new rename to pulls`) 1046 return err 1047 }) 1048 conn.ExecContext(ctx, "pragma foreign_keys = on;") 1049 1050 // remove repo_at and pull_id from pull_submissions and replace with pull_at 1051 // 1052 // this requires a full table recreation because stored columns 1053 // cannot be added via alter 1054 // 1055 // disable foreign-keys for the next migration 1056 conn.ExecContext(ctx, "pragma foreign_keys = off;") 1057 runMigration(conn, logger, "remove-repo-at-pull-id-from-pull-submissions", func(tx *sql.Tx) error { 1058 _, err := tx.Exec(` 1059 create table if not exists pull_submissions_new ( 1060 -- identifiers 1061 id integer primary key autoincrement, 1062 pull_at text not null, 1063 1064 -- content, these are immutable, and require a resubmission to update 1065 round_number integer not null default 0, 1066 patch text, 1067 source_rev text, 1068 1069 -- meta 1070 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 1071 1072 -- constraints 1073 unique(pull_at, round_number), 1074 foreign key (pull_at) references pulls(at_uri) on delete cascade 1075 ); 1076 `) 1077 if err != nil { 1078 return err 1079 } 1080 1081 // transfer data, constructing pull_at from pulls table 1082 _, err = tx.Exec(` 1083 insert into pull_submissions_new (id, pull_at, round_number, patch, created) 1084 select 1085 ps.id, 1086 'at://' || p.owner_did || '/sh.tangled.repo.pull/' || p.rkey, 1087 ps.round_number, 1088 ps.patch, 1089 ps.created 1090 from pull_submissions ps 1091 join pulls p on ps.repo_at = p.repo_at and ps.pull_id = p.pull_id; 1092 `) 1093 if err != nil { 1094 return err 1095 } 1096 1097 // drop old table 1098 _, err = tx.Exec(`drop table pull_submissions`) 1099 if err != nil { 1100 return err 1101 } 1102 1103 // rename new table 1104 _, err = tx.Exec(`alter table pull_submissions_new rename to pull_submissions`) 1105 return err 1106 }) 1107 conn.ExecContext(ctx, "pragma foreign_keys = on;") 1108 1109 // knots may report the combined patch for a comparison, we can store that on the appview side 1110 // (but not on the pds record), because calculating the combined patch requires a git index 1111 runMigration(conn, logger, "add-combined-column-submissions", func(tx *sql.Tx) error { 1112 _, err := tx.Exec(` 1113 alter table pull_submissions add column combined text; 1114 `) 1115 return err 1116 }) 1117 1118 runMigration(conn, logger, "add-pronouns-profile", func(tx *sql.Tx) error { 1119 _, err := tx.Exec(` 1120 alter table profile add column pronouns text; 1121 `) 1122 return err 1123 }) 1124 1125 runMigration(conn, logger, "add-meta-column-repos", func(tx *sql.Tx) error { 1126 _, err := tx.Exec(` 1127 alter table repos add column website text; 1128 alter table repos add column topics text; 1129 `) 1130 return err 1131 }) 1132 1133 runMigration(conn, logger, "add-usermentioned-preference", func(tx *sql.Tx) error { 1134 _, err := tx.Exec(` 1135 alter table notification_preferences add column user_mentioned integer not null default 1; 1136 `) 1137 return err 1138 }) 1139 1140 return &DB{ 1141 db, 1142 logger, 1143 }, nil 1144} 1145 1146type migrationFn = func(*sql.Tx) error 1147 1148func runMigration(c *sql.Conn, logger *slog.Logger, name string, migrationFn migrationFn) error { 1149 logger = logger.With("migration", name) 1150 1151 tx, err := c.BeginTx(context.Background(), nil) 1152 if err != nil { 1153 return err 1154 } 1155 defer tx.Rollback() 1156 1157 var exists bool 1158 err = tx.QueryRow("select exists (select 1 from migrations where name = ?)", name).Scan(&exists) 1159 if err != nil { 1160 return err 1161 } 1162 1163 if !exists { 1164 // run migration 1165 err = migrationFn(tx) 1166 if err != nil { 1167 logger.Error("failed to run migration", "err", err) 1168 return err 1169 } 1170 1171 // mark migration as complete 1172 _, err = tx.Exec("insert into migrations (name) values (?)", name) 1173 if err != nil { 1174 logger.Error("failed to mark migration as complete", "err", err) 1175 return err 1176 } 1177 1178 // commit the transaction 1179 if err := tx.Commit(); err != nil { 1180 return err 1181 } 1182 1183 logger.Info("migration applied successfully") 1184 } else { 1185 logger.Warn("skipped migration, already applied") 1186 } 1187 1188 return nil 1189} 1190 1191func (d *DB) Close() error { 1192 return d.DB.Close() 1193} 1194 1195type filter struct { 1196 key string 1197 arg any 1198 cmp string 1199} 1200 1201func newFilter(key, cmp string, arg any) filter { 1202 return filter{ 1203 key: key, 1204 arg: arg, 1205 cmp: cmp, 1206 } 1207} 1208 1209func FilterEq(key string, arg any) filter { return newFilter(key, "=", arg) } 1210func FilterNotEq(key string, arg any) filter { return newFilter(key, "<>", arg) } 1211func FilterGte(key string, arg any) filter { return newFilter(key, ">=", arg) } 1212func FilterLte(key string, arg any) filter { return newFilter(key, "<=", arg) } 1213func FilterIs(key string, arg any) filter { return newFilter(key, "is", arg) } 1214func FilterIsNot(key string, arg any) filter { return newFilter(key, "is not", arg) } 1215func FilterIn(key string, arg any) filter { return newFilter(key, "in", arg) } 1216func FilterLike(key string, arg any) filter { return newFilter(key, "like", arg) } 1217func FilterNotLike(key string, arg any) filter { return newFilter(key, "not like", arg) } 1218func FilterContains(key string, arg any) filter { 1219 return newFilter(key, "like", fmt.Sprintf("%%%v%%", arg)) 1220} 1221 1222func (f filter) Condition() string { 1223 rv := reflect.ValueOf(f.arg) 1224 kind := rv.Kind() 1225 1226 // if we have `FilterIn(k, [1, 2, 3])`, compile it down to `k in (?, ?, ?)` 1227 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array { 1228 if rv.Len() == 0 { 1229 // always false 1230 return "1 = 0" 1231 } 1232 1233 placeholders := make([]string, rv.Len()) 1234 for i := range placeholders { 1235 placeholders[i] = "?" 1236 } 1237 1238 return fmt.Sprintf("%s %s (%s)", f.key, f.cmp, strings.Join(placeholders, ", ")) 1239 } 1240 1241 return fmt.Sprintf("%s %s ?", f.key, f.cmp) 1242} 1243 1244func (f filter) Arg() []any { 1245 rv := reflect.ValueOf(f.arg) 1246 kind := rv.Kind() 1247 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array { 1248 if rv.Len() == 0 { 1249 return nil 1250 } 1251 1252 out := make([]any, rv.Len()) 1253 for i := range rv.Len() { 1254 out[i] = rv.Index(i).Interface() 1255 } 1256 return out 1257 } 1258 1259 return []any{f.arg} 1260}