···11--- Simplified SQLite Database Migration Script for Issues and Comments
22-33--- Migration for issues table
44-CREATE TABLE issues_new (
55- id integer primary key autoincrement,
66- owner_did text not null,
77- repo_at text not null,
88- issue_id integer not null,
99- title text not null,
1010- body text not null,
1111- open integer not null default 1,
1212- created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
1313- issue_at text,
1414- unique(repo_at, issue_id),
1515- foreign key (repo_at) references repos(at_uri) on delete cascade
1616-);
1717-1818--- Migrate data to new issues table
1919-INSERT INTO issues_new (
2020- id, owner_did, repo_at, issue_id,
2121- title, body, open, created, issue_at
2222-)
2323-SELECT
2424- id, owner_did, repo_at, issue_id,
2525- title, body, open, created, issue_at
2626-FROM issues;
2727-2828--- Drop old issues table
2929-DROP TABLE issues;
3030-3131--- Rename new issues table
3232-ALTER TABLE issues_new RENAME TO issues;
3333-3434--- Migration for comments table
3535-CREATE TABLE comments_new (
3636- id integer primary key autoincrement,
3737- owner_did text not null,
3838- issue_id integer not null,
3939- repo_at text not null,
4040- comment_id integer not null,
4141- comment_at text not null,
4242- body text not null,
4343- created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
4444- unique(issue_id, comment_id),
4545- foreign key (repo_at, issue_id) references issues(repo_at, issue_id) on delete cascade
4646-);
4747-4848--- Migrate data to new comments table
4949-INSERT INTO comments_new (
5050- id, owner_did, issue_id, repo_at,
5151- comment_id, comment_at, body, created
5252-)
5353-SELECT
5454- id, owner_did, issue_id, repo_at,
5555- comment_id, comment_at, body, created
5656-FROM comments;
5757-5858--- Drop old comments table
5959-DROP TABLE comments;
6060-6161--- Rename new comments table
6262-ALTER TABLE comments_new RENAME TO comments;
-66
appview/db/migrations/validate.sql
···11--- Validation Queries for Database Migration
22-33--- 1. Verify Issues Table Structure
44-PRAGMA table_info(issues);
55-66--- 2. Verify Comments Table Structure
77-PRAGMA table_info(comments);
88-99--- 3. Check Total Row Count Consistency
1010-SELECT
1111- 'Issues Row Count' AS check_type,
1212- (SELECT COUNT(*) FROM issues) AS row_count
1313-UNION ALL
1414-SELECT
1515- 'Comments Row Count' AS check_type,
1616- (SELECT COUNT(*) FROM comments) AS row_count;
1717-1818--- 4. Verify Unique Constraint on Issues
1919-SELECT
2020- repo_at,
2121- issue_id,
2222- COUNT(*) as duplicate_count
2323-FROM issues
2424-GROUP BY repo_at, issue_id
2525-HAVING duplicate_count > 1;
2626-2727--- 5. Verify Foreign Key Integrity for Comments
2828-SELECT
2929- 'Orphaned Comments' AS check_type,
3030- COUNT(*) AS orphaned_count
3131-FROM comments c
3232-LEFT JOIN issues i ON c.repo_at = i.repo_at AND c.issue_id = i.issue_id
3333-WHERE i.id IS NULL;
3434-3535--- 6. Check Foreign Key Constraint
3636-PRAGMA foreign_key_list(comments);
3737-3838--- 7. Sample Data Integrity Check
3939-SELECT
4040- 'Sample Issues' AS check_type,
4141- repo_at,
4242- issue_id,
4343- title,
4444- created
4545-FROM issues
4646-LIMIT 5;
4747-4848--- 8. Sample Comments Data Integrity Check
4949-SELECT
5050- 'Sample Comments' AS check_type,
5151- repo_at,
5252- issue_id,
5353- comment_id,
5454- body,
5555- created
5656-FROM comments
5757-LIMIT 5;
5858-5959--- 9. Verify Constraint on Comments (Issue ID and Comment ID Uniqueness)
6060-SELECT
6161- issue_id,
6262- comment_id,
6363- COUNT(*) as duplicate_count
6464-FROM comments
6565-GROUP BY issue_id, comment_id
6666-HAVING duplicate_count > 1;