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