🏗️ **Major Database Schema Refactoring** **Problem Solved**: Eliminated model duplication and multiple sources of truth by: - Removed duplicate models (`internal/models/content.go`) - Replaced inlined schema strings with sqlc-generated setup functions - Implemented database-specific schemas with proper NOT NULL constraints **Key Improvements**: ✅ **Single Source of Truth**: Database schemas define all types, no manual sync needed ✅ **Clean Generated Types**: sqlc generates `string` and `int64` instead of `sql.NullString/sql.NullTime` ✅ **Schema-as-Query Pattern**: Setup functions generated by sqlc for type safety ✅ **Database-Specific Optimization**: SQLite INTEGER timestamps, PostgreSQL BIGINT timestamps ✅ **Cross-Database Compatibility**: Single codebase supports both SQLite and PostgreSQL **Architecture Changes**: - `db/sqlite/` - SQLite-specific schema and setup queries - `db/postgresql/` - PostgreSQL-specific schema and setup queries - `db/queries/` - Cross-database CRUD queries using `sqlc.arg()` syntax - `internal/db/database.go` - Database abstraction with runtime selection - `internal/api/models.go` - Clean API models for requests/responses **Version Control System**: Complete element-level history with user attribution and rollback **Verification**: ✅ Full API workflow tested (create → update → rollback → versions) **Production Ready**: Supports SQLite (development) → PostgreSQL (production) migration
36 lines
1.3 KiB
SQL
36 lines
1.3 KiB
SQL
-- SQLite-specific schema with INTEGER timestamps
|
|
-- Main content table (current versions only)
|
|
CREATE TABLE content (
|
|
id TEXT NOT NULL,
|
|
site_id TEXT NOT NULL,
|
|
value TEXT NOT NULL,
|
|
type TEXT NOT NULL CHECK (type IN ('text', 'markdown', 'link')),
|
|
created_at INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL,
|
|
updated_at INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL,
|
|
last_edited_by TEXT DEFAULT 'system' NOT NULL,
|
|
PRIMARY KEY (id, site_id)
|
|
);
|
|
|
|
-- Version history table for rollback functionality
|
|
CREATE TABLE content_versions (
|
|
version_id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
content_id TEXT NOT NULL,
|
|
site_id TEXT NOT NULL,
|
|
value TEXT NOT NULL,
|
|
type TEXT NOT NULL,
|
|
created_at INTEGER DEFAULT (strftime('%s', 'now')) NOT NULL,
|
|
created_by TEXT DEFAULT 'system' NOT NULL
|
|
);
|
|
|
|
-- Indexes for performance
|
|
CREATE INDEX IF NOT EXISTS idx_content_site_id ON content(site_id);
|
|
CREATE INDEX IF NOT EXISTS idx_content_updated_at ON content(updated_at);
|
|
CREATE INDEX IF NOT EXISTS idx_content_versions_lookup ON content_versions(content_id, site_id, created_at DESC);
|
|
|
|
-- Trigger to automatically update updated_at timestamp
|
|
CREATE TRIGGER IF NOT EXISTS update_content_updated_at
|
|
AFTER UPDATE ON content
|
|
FOR EACH ROW
|
|
BEGIN
|
|
UPDATE content SET updated_at = strftime('%s', 'now') WHERE id = NEW.id AND site_id = NEW.site_id;
|
|
END; |