# SQLite Writer SQLite DDL (Data Definition Language) writer for RelSpec. Converts database schemas to SQLite-compatible SQL statements. ## Features - **Automatic Schema Flattening** - SQLite doesn't support PostgreSQL-style schemas, so table names are automatically flattened (e.g., `public.users` → `public_users`) - **Type Mapping** - Converts PostgreSQL data types to SQLite type affinities (TEXT, INTEGER, REAL, NUMERIC, BLOB) - **Auto-Increment Detection** - Automatically converts SERIAL types and auto-increment columns to `INTEGER PRIMARY KEY AUTOINCREMENT` - **Function Translation** - Converts PostgreSQL functions to SQLite equivalents (e.g., `now()` → `CURRENT_TIMESTAMP`) - **Boolean Handling** - Maps boolean values to INTEGER (true=1, false=0) - **Constraint Generation** - Creates indexes, unique constraints, and documents foreign keys - **Identifier Quoting** - Properly quotes identifiers using double quotes ## Usage ### Convert PostgreSQL to SQLite ```bash relspec convert --from pgsql --from-conn "postgres://user:pass@localhost/mydb" \ --to sqlite --to-path schema.sql ``` ### Convert DBML to SQLite ```bash relspec convert --from dbml --from-path schema.dbml \ --to sqlite --to-path schema.sql ``` ### Multi-Schema Databases SQLite doesn't support schemas, so multi-schema databases are automatically flattened: ```bash # Input has auth.users and public.posts # Output will have auth_users and public_posts relspec convert --from json --from-path multi_schema.json \ --to sqlite --to-path flattened.sql ``` ## Type Mapping | PostgreSQL Type | SQLite Affinity | Examples | |----------------|-----------------|----------| | TEXT | TEXT | varchar, text, char, citext, uuid, timestamp, json | | INTEGER | INTEGER | int, integer, smallint, bigint, serial, boolean | | REAL | REAL | real, float, double precision | | NUMERIC | NUMERIC | numeric, decimal | | BLOB | BLOB | bytea, blob | ## Auto-Increment Handling Columns are converted to `INTEGER PRIMARY KEY AUTOINCREMENT` when they meet these criteria: - Marked as primary key - Integer type - Have `AutoIncrement` flag set, OR - Type contains "serial", OR - Default value contains "nextval" **Example:** ```sql -- Input (PostgreSQL) CREATE TABLE users ( id SERIAL PRIMARY KEY, name VARCHAR(100) ); -- Output (SQLite) CREATE TABLE "users" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT, "name" TEXT ); ``` ## Default Value Translation | PostgreSQL | SQLite | Notes | |-----------|--------|-------| | `now()`, `CURRENT_TIMESTAMP` | `CURRENT_TIMESTAMP` | Timestamp functions | | `CURRENT_DATE` | `CURRENT_DATE` | Date function | | `CURRENT_TIME` | `CURRENT_TIME` | Time function | | `true`, `false` | `1`, `0` | Boolean values | | `gen_random_uuid()` | *(removed)* | SQLite has no built-in UUID | | `nextval(...)` | *(removed)* | Handled by AUTOINCREMENT | ## Foreign Keys Foreign keys are generated as commented-out ALTER TABLE statements for reference: ```sql -- Foreign key: fk_posts_user_id -- ALTER TABLE "posts" ADD CONSTRAINT "posts_fk_posts_user_id" -- FOREIGN KEY ("user_id") -- REFERENCES "users" ("id"); -- Note: Foreign keys should be defined in CREATE TABLE for better SQLite compatibility ``` For production use, define foreign keys directly in the CREATE TABLE statement or execute the ALTER TABLE commands after creating all tables. ## Constraints - **Primary Keys**: Inline for auto-increment columns, separate constraint for composite keys - **Unique Constraints**: Converted to `CREATE UNIQUE INDEX` statements - **Check Constraints**: Generated as comments (should be added to CREATE TABLE manually) - **Indexes**: Generated without PostgreSQL-specific features (no GIN, GiST, operator classes) ## Output Structure Generated SQL follows this order: 1. Header comments 2. `PRAGMA foreign_keys = ON;` 3. CREATE TABLE statements (sorted by schema, then table) 4. CREATE INDEX statements 5. CREATE UNIQUE INDEX statements (for unique constraints) 6. Check constraint comments 7. Foreign key comments ## Example **Input (multi-schema PostgreSQL):** ```sql CREATE SCHEMA auth; CREATE TABLE auth.users ( id SERIAL PRIMARY KEY, username VARCHAR(50) UNIQUE NOT NULL, created_at TIMESTAMP DEFAULT now() ); CREATE SCHEMA public; CREATE TABLE public.posts ( id SERIAL PRIMARY KEY, user_id INTEGER REFERENCES auth.users(id), title VARCHAR(200) NOT NULL, published BOOLEAN DEFAULT false ); ``` **Output (SQLite with flattened schemas):** ```sql -- SQLite Database Schema -- Database: mydb -- Generated by RelSpec -- Note: Schema names have been flattened (e.g., public.users -> public_users) -- Enable foreign key constraints PRAGMA foreign_keys = ON; -- Schema: auth (flattened into table names) CREATE TABLE "auth_users" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT, "username" TEXT NOT NULL, "created_at" TEXT DEFAULT CURRENT_TIMESTAMP ); CREATE UNIQUE INDEX "auth_users_users_username_key" ON "auth_users" ("username"); -- Schema: public (flattened into table names) CREATE TABLE "public_posts" ( "id" INTEGER PRIMARY KEY AUTOINCREMENT, "user_id" INTEGER NOT NULL, "title" TEXT NOT NULL, "published" INTEGER DEFAULT 0 ); -- Foreign key: posts_user_id_fkey -- ALTER TABLE "public_posts" ADD CONSTRAINT "public_posts_posts_user_id_fkey" -- FOREIGN KEY ("user_id") -- REFERENCES "auth_users" ("id"); -- Note: Foreign keys should be defined in CREATE TABLE for better SQLite compatibility ``` ## Programmatic Usage ```go import ( "git.warky.dev/wdevs/relspecgo/pkg/models" "git.warky.dev/wdevs/relspecgo/pkg/writers" "git.warky.dev/wdevs/relspecgo/pkg/writers/sqlite" ) func main() { // Create writer (automatically enables schema flattening) writer := sqlite.NewWriter(&writers.WriterOptions{ OutputPath: "schema.sql", }) // Write database schema db := &models.Database{ Name: "mydb", Schemas: []*models.Schema{ // ... your schema data }, } err := writer.WriteDatabase(db) if err != nil { panic(err) } } ``` ## Notes - Schema flattening is **always enabled** for SQLite output (cannot be disabled) - Constraint and index names are prefixed with the flattened table name to avoid collisions - Generated SQL is compatible with SQLite 3.x - Foreign key constraints require `PRAGMA foreign_keys = ON;` to be enforced - For complex schemas, review and test the generated SQL before use in production