diff --git a/internal/db/queries/payments.sql b/internal/db/queries/payments.sql new file mode 100644 index 0000000..bf15bad --- /dev/null +++ b/internal/db/queries/payments.sql @@ -0,0 +1,19 @@ +-- name: CreatePayment :one +INSERT INTO payments (user_id, amount, currency, status, payment_processor_id, paid_at) +VALUES (?, ?, ?, ?, ?, ?) +RETURNING *; + +-- name: GetPaymentByID :one +SELECT * FROM payments +WHERE id = ?; + +-- name: GetPaymentsByUserID :many +SELECT * FROM payments +WHERE user_id = ? +ORDER BY created_at DESC; + +-- name: UpdatePaymentStatus :one +UPDATE payments +SET status = ?, paid_at = CASE WHEN ? IS NOT NULL THEN ? ELSE paid_at END +WHERE id = ? +RETURNING *; \ No newline at end of file diff --git a/internal/db/queries/sites.sql b/internal/db/queries/sites.sql new file mode 100644 index 0000000..0b2f012 --- /dev/null +++ b/internal/db/queries/sites.sql @@ -0,0 +1,27 @@ +-- name: CreateSite :one +INSERT INTO sites (user_id, domain) +VALUES (?, ?) +RETURNING *; + +-- name: GetSiteByID :one +SELECT * FROM sites +WHERE id = ?; + +-- name: GetSitesByUserID :many +SELECT * FROM sites +WHERE user_id = ? +ORDER BY created_at DESC; + +-- name: GetSiteByDomain :one +SELECT * FROM sites +WHERE domain = ?; + +-- name: UpdateSiteDomain :one +UPDATE sites +SET domain = ? +WHERE id = ? +RETURNING *; + +-- name: DeleteSite :exec +DELETE FROM sites +WHERE id = ?; \ No newline at end of file diff --git a/internal/db/queries/users.sql b/internal/db/queries/users.sql new file mode 100644 index 0000000..e78c4a1 --- /dev/null +++ b/internal/db/queries/users.sql @@ -0,0 +1,26 @@ +-- name: CreateUser :one +INSERT INTO users (keycloak_id, name, email) +VALUES (?, ?, ?) +RETURNING *; + +-- name: GetUserByID :one +SELECT * FROM users +WHERE id = ?; + +-- name: GetUserByKeycloakID :one +SELECT * FROM users +WHERE keycloak_id = ?; + +-- name: UpdateUser :one +UPDATE users +SET name = ?, email = ? +WHERE id = ? +RETURNING *; + +-- name: DeleteUser :exec +DELETE FROM users +WHERE id = ?; + +-- name: ListUsers :many +SELECT * FROM users +ORDER BY name; \ No newline at end of file diff --git a/internal/db/schema.sql b/internal/db/schema.sql new file mode 100644 index 0000000..9366ffe --- /dev/null +++ b/internal/db/schema.sql @@ -0,0 +1,61 @@ +-- internal/db/schema.sql + +CREATE TABLE users ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + keycloak_id TEXT UNIQUE NOT NULL, + name TEXT NOT NULL, + email TEXT UNIQUE NOT NULL, + created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE sites ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + user_id INTEGER NOT NULL, + domain TEXT UNIQUE NOT NULL, + created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE +); + +CREATE TABLE payments ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + user_id INTEGER NOT NULL, + amount INTEGER NOT NULL, -- Store amount in cents to avoid floating point issues + currency TEXT NOT NULL DEFAULT 'USD', + status TEXT NOT NULL, -- e.g., 'succeeded', 'pending', 'failed' + payment_processor_id TEXT UNIQUE, -- ID from your payment processor (e.g., Stripe Payment Intent ID) + paid_at TIMESTAMP, + created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE +); + +-- Create indexes for foreign keys and frequently queried columns +CREATE INDEX idx_sites_user_id ON sites(user_id); +CREATE INDEX idx_payments_user_id ON payments(user_id); +CREATE INDEX idx_users_keycloak_id ON users(keycloak_id); +CREATE INDEX idx_sites_domain ON sites(domain); +CREATE INDEX idx_payments_payment_processor_id ON payments(payment_processor_id); + +-- Triggers to update 'updated_at' timestamps +CREATE TRIGGER trigger_users_updated_at +AFTER UPDATE ON users +FOR EACH ROW +BEGIN + UPDATE users SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id; +END; + +CREATE TRIGGER trigger_sites_updated_at +AFTER UPDATE ON sites +FOR EACH ROW +BEGIN + UPDATE sites SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id; +END; + +CREATE TRIGGER trigger_payments_updated_at +AFTER UPDATE ON payments +FOR EACH ROW +BEGIN + UPDATE payments SET updated_at = CURRENT_TIMESTAMP WHERE id = OLD.id; +END; \ No newline at end of file diff --git a/internal/db/sqlc.yaml b/internal/db/sqlc.yaml new file mode 100644 index 0000000..531ea94 --- /dev/null +++ b/internal/db/sqlc.yaml @@ -0,0 +1,17 @@ +# internal/db/sqlc.yaml +version: "2" +sql: + - engine: "sqlite" + # Paths are relative to this sqlc.yaml file + schema: "schema.sql" # Will look for internal/db/schema.sql + queries: "queries/" # Will look for internal/db/queries/ + gen: + go: + package: "db" # Package name for the generated Go code + out: "." # Output directory for generated Go code (i.e., internal/db/) + sql_package: "database/sql" + emit_json_tags: true + emit_prepared_queries: false + emit_interface: true # Generates a Querier interface + emit_exact_table_names: false + emit_empty_slices: true