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 ); 532 533 create table if not exists migrations ( 534 id integer primary key autoincrement, 535 name text unique 536 ); 537 538 -- indexes for better star query performance 539 create index if not exists idx_stars_created on stars(created); 540 create index if not exists idx_stars_repo_at_created on stars(repo_at, created); 541 `) 542 if err != nil { 543 return nil, err 544 } 545 546 // run migrations 547 runMigration(conn, "add-description-to-repos", func(tx *sql.Tx) error { 548 tx.Exec(` 549 alter table repos add column description text check (length(description) <= 200); 550 `) 551 return nil 552 }) 553 554 runMigration(conn, "add-rkey-to-pubkeys", func(tx *sql.Tx) error { 555 // add unconstrained column 556 _, err := tx.Exec(` 557 alter table public_keys 558 add column rkey text; 559 `) 560 if err != nil { 561 return err 562 } 563 564 // backfill 565 _, err = tx.Exec(` 566 update public_keys 567 set rkey = '' 568 where rkey is null; 569 `) 570 if err != nil { 571 return err 572 } 573 574 return nil 575 }) 576 577 runMigration(conn, "add-rkey-to-comments", func(tx *sql.Tx) error { 578 _, err := tx.Exec(` 579 alter table comments drop column comment_at; 580 alter table comments add column rkey text; 581 `) 582 return err 583 }) 584 585 runMigration(conn, "add-deleted-and-edited-to-issue-comments", func(tx *sql.Tx) error { 586 _, err := tx.Exec(` 587 alter table comments add column deleted text; -- timestamp 588 alter table comments add column edited text; -- timestamp 589 `) 590 return err 591 }) 592 593 runMigration(conn, "add-source-info-to-pulls-and-submissions", func(tx *sql.Tx) error { 594 _, err := tx.Exec(` 595 alter table pulls add column source_branch text; 596 alter table pulls add column source_repo_at text; 597 alter table pull_submissions add column source_rev text; 598 `) 599 return err 600 }) 601 602 runMigration(conn, "add-source-to-repos", func(tx *sql.Tx) error { 603 _, err := tx.Exec(` 604 alter table repos add column source text; 605 `) 606 return err 607 }) 608 609 // disable foreign-keys for the next migration 610 // NOTE: this cannot be done in a transaction, so it is run outside [0] 611 // 612 // [0]: https://sqlite.org/pragma.html#pragma_foreign_keys 613 conn.ExecContext(ctx, "pragma foreign_keys = off;") 614 runMigration(conn, "recreate-pulls-column-for-stacking-support", func(tx *sql.Tx) error { 615 _, err := tx.Exec(` 616 create table pulls_new ( 617 -- identifiers 618 id integer primary key autoincrement, 619 pull_id integer not null, 620 621 -- at identifiers 622 repo_at text not null, 623 owner_did text not null, 624 rkey text not null, 625 626 -- content 627 title text not null, 628 body text not null, 629 target_branch text not null, 630 state integer not null default 0 check (state in (0, 1, 2, 3)), -- closed, open, merged, deleted 631 632 -- source info 633 source_branch text, 634 source_repo_at text, 635 636 -- stacking 637 stack_id text, 638 change_id text, 639 parent_change_id text, 640 641 -- meta 642 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 643 644 -- constraints 645 unique(repo_at, pull_id), 646 foreign key (repo_at) references repos(at_uri) on delete cascade 647 ); 648 649 insert into pulls_new ( 650 id, pull_id, 651 repo_at, owner_did, rkey, 652 title, body, target_branch, state, 653 source_branch, source_repo_at, 654 created 655 ) 656 select 657 id, pull_id, 658 repo_at, owner_did, rkey, 659 title, body, target_branch, state, 660 source_branch, source_repo_at, 661 created 662 FROM pulls; 663 664 drop table pulls; 665 alter table pulls_new rename to pulls; 666 `) 667 return err 668 }) 669 conn.ExecContext(ctx, "pragma foreign_keys = on;") 670 671 runMigration(conn, "add-spindle-to-repos", func(tx *sql.Tx) error { 672 tx.Exec(` 673 alter table repos add column spindle text; 674 `) 675 return nil 676 }) 677 678 // drop all knot secrets, add unique constraint to knots 679 // 680 // knots will henceforth use service auth for signed requests 681 runMigration(conn, "no-more-secrets", func(tx *sql.Tx) error { 682 _, err := tx.Exec(` 683 create table registrations_new ( 684 id integer primary key autoincrement, 685 domain text not null, 686 did text not null, 687 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 688 registered text, 689 read_only integer not null default 0, 690 unique(domain, did) 691 ); 692 693 insert into registrations_new (id, domain, did, created, registered, read_only) 694 select id, domain, did, created, registered, 1 from registrations 695 where registered is not null; 696 697 drop table registrations; 698 alter table registrations_new rename to registrations; 699 `) 700 return err 701 }) 702 703 // recreate and add rkey + created columns with default constraint 704 runMigration(conn, "rework-collaborators-table", func(tx *sql.Tx) error { 705 // create new table 706 // - repo_at instead of repo integer 707 // - rkey field 708 // - created field 709 _, err := tx.Exec(` 710 create table collaborators_new ( 711 -- identifiers for the record 712 id integer primary key autoincrement, 713 did text not null, 714 rkey text, 715 716 -- content 717 subject_did text not null, 718 repo_at text not null, 719 720 -- meta 721 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 722 723 -- constraints 724 foreign key (repo_at) references repos(at_uri) on delete cascade 725 ) 726 `) 727 if err != nil { 728 return err 729 } 730 731 // copy data 732 _, err = tx.Exec(` 733 insert into collaborators_new (id, did, rkey, subject_did, repo_at) 734 select 735 c.id, 736 r.did, 737 '', 738 c.did, 739 r.at_uri 740 from collaborators c 741 join repos r on c.repo = r.id 742 `) 743 if err != nil { 744 return err 745 } 746 747 // drop old table 748 _, err = tx.Exec(`drop table collaborators`) 749 if err != nil { 750 return err 751 } 752 753 // rename new table 754 _, err = tx.Exec(`alter table collaborators_new rename to collaborators`) 755 return err 756 }) 757 758 runMigration(conn, "add-rkey-to-issues", func(tx *sql.Tx) error { 759 _, err := tx.Exec(` 760 alter table issues add column rkey text not null default ''; 761 762 -- get last url section from issue_at and save to rkey column 763 update issues 764 set rkey = replace(issue_at, rtrim(issue_at, replace(issue_at, '/', '')), ''); 765 `) 766 return err 767 }) 768 769 // repurpose the read-only column to "needs-upgrade" 770 runMigration(conn, "rename-registrations-read-only-to-needs-upgrade", func(tx *sql.Tx) error { 771 _, err := tx.Exec(` 772 alter table registrations rename column read_only to needs_upgrade; 773 `) 774 return err 775 }) 776 777 // require all knots to upgrade after the release of total xrpc 778 runMigration(conn, "migrate-knots-to-total-xrpc", func(tx *sql.Tx) error { 779 _, err := tx.Exec(` 780 update registrations set needs_upgrade = 1; 781 `) 782 return err 783 }) 784 785 // require all knots to upgrade after the release of total xrpc 786 runMigration(conn, "migrate-spindles-to-xrpc-owner", func(tx *sql.Tx) error { 787 _, err := tx.Exec(` 788 alter table spindles add column needs_upgrade integer not null default 0; 789 `) 790 if err != nil { 791 return err 792 } 793 794 _, err = tx.Exec(` 795 update spindles set needs_upgrade = 1; 796 `) 797 return err 798 }) 799 800 // remove issue_at from issues and replace with generated column 801 // 802 // this requires a full table recreation because stored columns 803 // cannot be added via alter 804 // 805 // couple other changes: 806 // - columns renamed to be more consistent 807 // - adds edited and deleted fields 808 // 809 // disable foreign-keys for the next migration 810 conn.ExecContext(ctx, "pragma foreign_keys = off;") 811 runMigration(conn, "remove-issue-at-from-issues", func(tx *sql.Tx) error { 812 _, err := tx.Exec(` 813 create table if not exists issues_new ( 814 -- identifiers 815 id integer primary key autoincrement, 816 did text not null, 817 rkey text not null, 818 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue' || '/' || rkey) stored, 819 820 -- at identifiers 821 repo_at text not null, 822 823 -- content 824 issue_id integer not null, 825 title text not null, 826 body text not null, 827 open integer not null default 1, 828 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 829 edited text, -- timestamp 830 deleted text, -- timestamp 831 832 unique(did, rkey), 833 unique(repo_at, issue_id), 834 unique(at_uri), 835 foreign key (repo_at) references repos(at_uri) on delete cascade 836 ); 837 `) 838 if err != nil { 839 return err 840 } 841 842 // transfer data 843 _, err = tx.Exec(` 844 insert into issues_new (id, did, rkey, repo_at, issue_id, title, body, open, created) 845 select 846 i.id, 847 i.owner_did, 848 i.rkey, 849 i.repo_at, 850 i.issue_id, 851 i.title, 852 i.body, 853 i.open, 854 i.created 855 from issues i; 856 `) 857 if err != nil { 858 return err 859 } 860 861 // drop old table 862 _, err = tx.Exec(`drop table issues`) 863 if err != nil { 864 return err 865 } 866 867 // rename new table 868 _, err = tx.Exec(`alter table issues_new rename to issues`) 869 return err 870 }) 871 conn.ExecContext(ctx, "pragma foreign_keys = on;") 872 873 // - renames the comments table to 'issue_comments' 874 // - rework issue comments to update constraints: 875 // * unique(did, rkey) 876 // * remove comment-id and just use the global ID 877 // * foreign key (repo_at, issue_id) 878 // - new columns 879 // * column "reply_to" which can be any other comment 880 // * column "at-uri" which is a generated column 881 runMigration(conn, "rework-issue-comments", func(tx *sql.Tx) error { 882 _, err := tx.Exec(` 883 create table if not exists issue_comments ( 884 -- identifiers 885 id integer primary key autoincrement, 886 did text not null, 887 rkey text, 888 at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue.comment' || '/' || rkey) stored, 889 890 -- at identifiers 891 issue_at text not null, 892 reply_to text, -- at_uri of parent comment 893 894 -- content 895 body text not null, 896 created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 897 edited text, 898 deleted text, 899 900 -- constraints 901 unique(did, rkey), 902 unique(at_uri), 903 foreign key (issue_at) references issues(at_uri) on delete cascade 904 ); 905 `) 906 if err != nil { 907 return err 908 } 909 910 // transfer data 911 _, err = tx.Exec(` 912 insert into issue_comments (id, did, rkey, issue_at, body, created, edited, deleted) 913 select 914 c.id, 915 c.owner_did, 916 c.rkey, 917 i.at_uri, -- get at_uri from issues table 918 c.body, 919 c.created, 920 c.edited, 921 c.deleted 922 from comments c 923 join issues i on c.repo_at = i.repo_at and c.issue_id = i.issue_id; 924 `) 925 if err != nil { 926 return err 927 } 928 929 // drop old table 930 _, err = tx.Exec(`drop table comments`) 931 return err 932 }) 933 934 return &DB{db}, nil 935} 936 937type migrationFn = func(*sql.Tx) error 938 939func runMigration(c *sql.Conn, name string, migrationFn migrationFn) error { 940 tx, err := c.BeginTx(context.Background(), nil) 941 if err != nil { 942 return err 943 } 944 defer tx.Rollback() 945 946 var exists bool 947 err = tx.QueryRow("select exists (select 1 from migrations where name = ?)", name).Scan(&exists) 948 if err != nil { 949 return err 950 } 951 952 if !exists { 953 // run migration 954 err = migrationFn(tx) 955 if err != nil { 956 log.Printf("Failed to run migration %s: %v", name, err) 957 return err 958 } 959 960 // mark migration as complete 961 _, err = tx.Exec("insert into migrations (name) values (?)", name) 962 if err != nil { 963 log.Printf("Failed to mark migration %s as complete: %v", name, err) 964 return err 965 } 966 967 // commit the transaction 968 if err := tx.Commit(); err != nil { 969 return err 970 } 971 972 log.Printf("migration %s applied successfully", name) 973 } else { 974 log.Printf("skipped migration %s, already applied", name) 975 } 976 977 return nil 978} 979 980func (d *DB) Close() error { 981 return d.DB.Close() 982} 983 984type filter struct { 985 key string 986 arg any 987 cmp string 988} 989 990func newFilter(key, cmp string, arg any) filter { 991 return filter{ 992 key: key, 993 arg: arg, 994 cmp: cmp, 995 } 996} 997 998func FilterEq(key string, arg any) filter { return newFilter(key, "=", arg) } 999func FilterNotEq(key string, arg any) filter { return newFilter(key, "<>", arg) } 1000func FilterGte(key string, arg any) filter { return newFilter(key, ">=", arg) } 1001func FilterLte(key string, arg any) filter { return newFilter(key, "<=", arg) } 1002func FilterIs(key string, arg any) filter { return newFilter(key, "is", arg) } 1003func FilterIsNot(key string, arg any) filter { return newFilter(key, "is not", arg) } 1004func FilterIn(key string, arg any) filter { return newFilter(key, "in", arg) } 1005func FilterLike(key string, arg any) filter { return newFilter(key, "like", arg) } 1006func FilterNotLike(key string, arg any) filter { return newFilter(key, "not like", arg) } 1007func FilterContains(key string, arg any) filter { 1008 return newFilter(key, "like", fmt.Sprintf("%%%v%%", arg)) 1009} 1010 1011func (f filter) Condition() string { 1012 rv := reflect.ValueOf(f.arg) 1013 kind := rv.Kind() 1014 1015 // if we have `FilterIn(k, [1, 2, 3])`, compile it down to `k in (?, ?, ?)` 1016 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array { 1017 if rv.Len() == 0 { 1018 // always false 1019 return "1 = 0" 1020 } 1021 1022 placeholders := make([]string, rv.Len()) 1023 for i := range placeholders { 1024 placeholders[i] = "?" 1025 } 1026 1027 return fmt.Sprintf("%s %s (%s)", f.key, f.cmp, strings.Join(placeholders, ", ")) 1028 } 1029 1030 return fmt.Sprintf("%s %s ?", f.key, f.cmp) 1031} 1032 1033func (f filter) Arg() []any { 1034 rv := reflect.ValueOf(f.arg) 1035 kind := rv.Kind() 1036 if (kind == reflect.Slice && rv.Type().Elem().Kind() != reflect.Uint8) || kind == reflect.Array { 1037 if rv.Len() == 0 { 1038 return nil 1039 } 1040 1041 out := make([]any, rv.Len()) 1042 for i := range rv.Len() { 1043 out[i] = rv.Index(i).Interface() 1044 } 1045 return out 1046 } 1047 1048 return []any{f.arg} 1049}