-62
appview/db/migrations/20250305_113405.sql
-62
appview/db/migrations/20250305_113405.sql
···
1
-
-- Simplified SQLite Database Migration Script for Issues and Comments
2
-
3
-
-- Migration for issues table
4
-
CREATE TABLE issues_new (
5
-
id integer primary key autoincrement,
6
-
owner_did text not null,
7
-
repo_at text not null,
8
-
issue_id integer not null,
9
-
title text not null,
10
-
body text not null,
11
-
open integer not null default 1,
12
-
created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
13
-
issue_at text,
14
-
unique(repo_at, issue_id),
15
-
foreign key (repo_at) references repos(at_uri) on delete cascade
16
-
);
17
-
18
-
-- Migrate data to new issues table
19
-
INSERT INTO issues_new (
20
-
id, owner_did, repo_at, issue_id,
21
-
title, body, open, created, issue_at
22
-
)
23
-
SELECT
24
-
id, owner_did, repo_at, issue_id,
25
-
title, body, open, created, issue_at
26
-
FROM issues;
27
-
28
-
-- Drop old issues table
29
-
DROP TABLE issues;
30
-
31
-
-- Rename new issues table
32
-
ALTER TABLE issues_new RENAME TO issues;
33
-
34
-
-- Migration for comments table
35
-
CREATE TABLE comments_new (
36
-
id integer primary key autoincrement,
37
-
owner_did text not null,
38
-
issue_id integer not null,
39
-
repo_at text not null,
40
-
comment_id integer not null,
41
-
comment_at text not null,
42
-
body text not null,
43
-
created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
44
-
unique(issue_id, comment_id),
45
-
foreign key (repo_at, issue_id) references issues(repo_at, issue_id) on delete cascade
46
-
);
47
-
48
-
-- Migrate data to new comments table
49
-
INSERT INTO comments_new (
50
-
id, owner_did, issue_id, repo_at,
51
-
comment_id, comment_at, body, created
52
-
)
53
-
SELECT
54
-
id, owner_did, issue_id, repo_at,
55
-
comment_id, comment_at, body, created
56
-
FROM comments;
57
-
58
-
-- Drop old comments table
59
-
DROP TABLE comments;
60
-
61
-
-- Rename new comments table
62
-
ALTER TABLE comments_new RENAME TO comments;
-66
appview/db/migrations/validate.sql
-66
appview/db/migrations/validate.sql
···
1
-
-- Validation Queries for Database Migration
2
-
3
-
-- 1. Verify Issues Table Structure
4
-
PRAGMA table_info(issues);
5
-
6
-
-- 2. Verify Comments Table Structure
7
-
PRAGMA table_info(comments);
8
-
9
-
-- 3. Check Total Row Count Consistency
10
-
SELECT
11
-
'Issues Row Count' AS check_type,
12
-
(SELECT COUNT(*) FROM issues) AS row_count
13
-
UNION ALL
14
-
SELECT
15
-
'Comments Row Count' AS check_type,
16
-
(SELECT COUNT(*) FROM comments) AS row_count;
17
-
18
-
-- 4. Verify Unique Constraint on Issues
19
-
SELECT
20
-
repo_at,
21
-
issue_id,
22
-
COUNT(*) as duplicate_count
23
-
FROM issues
24
-
GROUP BY repo_at, issue_id
25
-
HAVING duplicate_count > 1;
26
-
27
-
-- 5. Verify Foreign Key Integrity for Comments
28
-
SELECT
29
-
'Orphaned Comments' AS check_type,
30
-
COUNT(*) AS orphaned_count
31
-
FROM comments c
32
-
LEFT JOIN issues i ON c.repo_at = i.repo_at AND c.issue_id = i.issue_id
33
-
WHERE i.id IS NULL;
34
-
35
-
-- 6. Check Foreign Key Constraint
36
-
PRAGMA foreign_key_list(comments);
37
-
38
-
-- 7. Sample Data Integrity Check
39
-
SELECT
40
-
'Sample Issues' AS check_type,
41
-
repo_at,
42
-
issue_id,
43
-
title,
44
-
created
45
-
FROM issues
46
-
LIMIT 5;
47
-
48
-
-- 8. Sample Comments Data Integrity Check
49
-
SELECT
50
-
'Sample Comments' AS check_type,
51
-
repo_at,
52
-
issue_id,
53
-
comment_id,
54
-
body,
55
-
created
56
-
FROM comments
57
-
LIMIT 5;
58
-
59
-
-- 9. Verify Constraint on Comments (Issue ID and Comment ID Uniqueness)
60
-
SELECT
61
-
issue_id,
62
-
comment_id,
63
-
COUNT(*) as duplicate_count
64
-
FROM comments
65
-
GROUP BY issue_id, comment_id
66
-
HAVING duplicate_count > 1;