refactor: implement database-specific schema architecture with schema-as-query pattern
🏗️ **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
This commit is contained in:
42
insertr-server/db/postgresql/schema.sql
Normal file
42
insertr-server/db/postgresql/schema.sql
Normal file
@@ -0,0 +1,42 @@
|
||||
-- PostgreSQL-specific schema with BIGINT UNIX 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 BIGINT DEFAULT EXTRACT(EPOCH FROM NOW()) NOT NULL,
|
||||
updated_at BIGINT DEFAULT EXTRACT(EPOCH FROM 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 SERIAL PRIMARY KEY,
|
||||
content_id TEXT NOT NULL,
|
||||
site_id TEXT NOT NULL,
|
||||
value TEXT NOT NULL,
|
||||
type TEXT NOT NULL,
|
||||
created_at BIGINT DEFAULT EXTRACT(EPOCH FROM 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);
|
||||
|
||||
-- Function and trigger to automatically update updated_at timestamp
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = EXTRACT(EPOCH FROM NOW());
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
CREATE TRIGGER update_content_updated_at
|
||||
BEFORE UPDATE ON content
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
Reference in New Issue
Block a user