forked from tangled.org/core
this repo has no description

appview/db: migrations for issues

Changed files
+128
appview
+62
appview/db/migrations/20250305_113405.sql
···
+
-- Simplified SQLite Database Migration Script for Issues and Comments
+
+
-- Migration for issues table
+
CREATE TABLE issues_new (
+
id integer primary key autoincrement,
+
owner_did text not null,
+
repo_at text not null,
+
issue_id integer not null,
+
title text not null,
+
body text not null,
+
open integer not null default 1,
+
created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
+
issue_at text,
+
unique(repo_at, issue_id),
+
foreign key (repo_at) references repos(at_uri) on delete cascade
+
);
+
+
-- Migrate data to new issues table
+
INSERT INTO issues_new (
+
id, owner_did, repo_at, issue_id,
+
title, body, open, created, issue_at
+
)
+
SELECT
+
id, owner_did, repo_at, issue_id,
+
title, body, open, created, issue_at
+
FROM issues;
+
+
-- Drop old issues table
+
DROP TABLE issues;
+
+
-- Rename new issues table
+
ALTER TABLE issues_new RENAME TO issues;
+
+
-- Migration for comments table
+
CREATE TABLE comments_new (
+
id integer primary key autoincrement,
+
owner_did text not null,
+
issue_id integer not null,
+
repo_at text not null,
+
comment_id integer not null,
+
comment_at text not null,
+
body text not null,
+
created text not null default (strftime('%Y-%m-%dT%H:%M:%SZ', 'now')),
+
unique(issue_id, comment_id),
+
foreign key (repo_at, issue_id) references issues(repo_at, issue_id) on delete cascade
+
);
+
+
-- Migrate data to new comments table
+
INSERT INTO comments_new (
+
id, owner_did, issue_id, repo_at,
+
comment_id, comment_at, body, created
+
)
+
SELECT
+
id, owner_did, issue_id, repo_at,
+
comment_id, comment_at, body, created
+
FROM comments;
+
+
-- Drop old comments table
+
DROP TABLE comments;
+
+
-- Rename new comments table
+
ALTER TABLE comments_new RENAME TO comments;
+66
appview/db/migrations/validate.sql
···
+
-- Validation Queries for Database Migration
+
+
-- 1. Verify Issues Table Structure
+
PRAGMA table_info(issues);
+
+
-- 2. Verify Comments Table Structure
+
PRAGMA table_info(comments);
+
+
-- 3. Check Total Row Count Consistency
+
SELECT
+
'Issues Row Count' AS check_type,
+
(SELECT COUNT(*) FROM issues) AS row_count
+
UNION ALL
+
SELECT
+
'Comments Row Count' AS check_type,
+
(SELECT COUNT(*) FROM comments) AS row_count;
+
+
-- 4. Verify Unique Constraint on Issues
+
SELECT
+
repo_at,
+
issue_id,
+
COUNT(*) as duplicate_count
+
FROM issues
+
GROUP BY repo_at, issue_id
+
HAVING duplicate_count > 1;
+
+
-- 5. Verify Foreign Key Integrity for Comments
+
SELECT
+
'Orphaned Comments' AS check_type,
+
COUNT(*) AS orphaned_count
+
FROM comments c
+
LEFT JOIN issues i ON c.repo_at = i.repo_at AND c.issue_id = i.issue_id
+
WHERE i.id IS NULL;
+
+
-- 6. Check Foreign Key Constraint
+
PRAGMA foreign_key_list(comments);
+
+
-- 7. Sample Data Integrity Check
+
SELECT
+
'Sample Issues' AS check_type,
+
repo_at,
+
issue_id,
+
title,
+
created
+
FROM issues
+
LIMIT 5;
+
+
-- 8. Sample Comments Data Integrity Check
+
SELECT
+
'Sample Comments' AS check_type,
+
repo_at,
+
issue_id,
+
comment_id,
+
body,
+
created
+
FROM comments
+
LIMIT 5;
+
+
-- 9. Verify Constraint on Comments (Issue ID and Comment ID Uniqueness)
+
SELECT
+
issue_id,
+
comment_id,
+
COUNT(*) as duplicate_count
+
FROM comments
+
GROUP BY issue_id, comment_id
+
HAVING duplicate_count > 1;