Monorepo for Tangled tangled.org

appview/db: rework issues table

adds generated `at_uri` column. a lot easier for comments to refer to an
issue now. ingesting comments also does not require a lookup, we can
directly use the at-uri of the parent-issue in db queries.

Signed-off-by: oppiliappan <me@oppi.li>

oppi.li cd2126cf 7f516681

verified
Changed files
+134
appview
db
+134
appview/db/db.go
··· 734 734 return err 735 735 }) 736 736 737 + // remove issue_at from issues and replace with generated column 738 + // 739 + // this requires a full table recreation because stored columns 740 + // cannot be added via alter 741 + // 742 + // couple other changes: 743 + // - columns renamed to be more consistent 744 + // - adds edited and deleted fields 745 + // 746 + // disable foreign-keys for the next migration 747 + conn.ExecContext(ctx, "pragma foreign_keys = off;") 748 + runMigration(conn, "remove-issue-at-from-issues", func(tx *sql.Tx) error { 749 + _, err := tx.Exec(` 750 + create table if not exists issues_new ( 751 + -- identifiers 752 + id integer primary key autoincrement, 753 + did text not null, 754 + rkey text not null, 755 + at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue' || '/' || rkey) stored, 756 + 757 + -- at identifiers 758 + repo_at text not null, 759 + 760 + -- content 761 + issue_id integer not null, 762 + title text not null, 763 + body text not null, 764 + open integer not null default 1, 765 + created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 766 + edited text, -- timestamp 767 + deleted text, -- timestamp 768 + 769 + unique(did, rkey), 770 + unique(repo_at, issue_id), 771 + unique(at_uri), 772 + foreign key (repo_at) references repos(at_uri) on delete cascade 773 + ); 774 + `) 775 + if err != nil { 776 + return err 777 + } 778 + 779 + // transfer data 780 + _, err = tx.Exec(` 781 + insert into issues_new (id, did, rkey, repo_at, issue_id, title, body, open, created) 782 + select 783 + i.id, 784 + i.owner_did, 785 + i.rkey, 786 + i.repo_at, 787 + i.issue_id, 788 + i.title, 789 + i.body, 790 + i.open, 791 + i.created 792 + from issues i; 793 + `) 794 + if err != nil { 795 + return err 796 + } 797 + 798 + // drop old table 799 + _, err = tx.Exec(`drop table issues`) 800 + if err != nil { 801 + return err 802 + } 803 + 804 + // rename new table 805 + _, err = tx.Exec(`alter table issues_new rename to issues`) 806 + return err 807 + }) 808 + conn.ExecContext(ctx, "pragma foreign_keys = on;") 809 + 810 + // - renames the comments table to 'issue_comments' 811 + // - rework issue comments to update constraints: 812 + // * unique(did, rkey) 813 + // * remove comment-id and just use the global ID 814 + // * foreign key (repo_at, issue_id) 815 + // - new columns 816 + // * column "reply_to" which can be any other comment 817 + // * column "at-uri" which is a generated column 818 + runMigration(conn, "rework-issue-comments", func(tx *sql.Tx) error { 819 + _, err := tx.Exec(` 820 + create table if not exists issue_comments ( 821 + -- identifiers 822 + id integer primary key autoincrement, 823 + did text not null, 824 + rkey text, 825 + at_uri text generated always as ('at://' || did || '/' || 'sh.tangled.repo.issue.comment' || '/' || rkey) stored, 826 + 827 + -- at identifiers 828 + issue_at text not null, 829 + reply_to text, -- at_uri of parent comment 830 + 831 + -- content 832 + body text not null, 833 + created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')), 834 + edited text, 835 + deleted text, 836 + 837 + -- constraints 838 + unique(did, rkey), 839 + unique(at_uri), 840 + foreign key (issue_at) references issues(at_uri) on delete cascade 841 + ); 842 + `) 843 + if err != nil { 844 + return err 845 + } 846 + 847 + // transfer data 848 + _, err = tx.Exec(` 849 + insert into issue_comments (id, did, rkey, issue_at, body, created, edited, deleted) 850 + select 851 + c.id, 852 + c.owner_did, 853 + c.rkey, 854 + i.at_uri, -- get at_uri from issues table 855 + c.body, 856 + c.created, 857 + c.edited, 858 + c.deleted 859 + from comments c 860 + join issues i on c.repo_at = i.repo_at and c.issue_id = i.issue_id; 861 + `) 862 + if err != nil { 863 + return err 864 + } 865 + 866 + // drop old table 867 + _, err = tx.Exec(`drop table comments`) 868 + return err 869 + }) 870 + 737 871 return &DB{db}, nil 738 872 } 739 873