/db.go (raw)
package main
import (
	"context"
	"database/sql"
	_ "embed"
	"fmt"
	"time"
	"github.com/mattn/go-sqlite3"
)
//go:embed schema.sql
var schema string
var migrations = []string{
	"", // migration #0 is reserved for schema initialization
	`
		ALTER TABLE AccessToken ADD COLUMN refresh_hash BLOB;
		ALTER TABLE AccessToken ADD COLUMN refresh_expires_at datetime;
		CREATE UNIQUE INDEX access_token_refresh_hash ON AccessToken(refresh_hash);
	`,
	`
		ALTER TABLE AuthCode ADD COLUMN nonce TEXT;
		CREATE TABLE IF NOT EXISTS SigningKey (
			id INTEGER PRIMARY KEY,
			kid TEXT NOT NULL UNIQUE,
			algorithm TEXT NOT NULL,
			private_key BLOB NOT NULL,
			created_at datetime NOT NULL
		);
	`,
	`
		ALTER TABLE AccessToken ADD COLUMN auth_time datetime;
		ALTER TABLE SigningKey RENAME TO SigningKey_old;
		CREATE TABLE SigningKey (
			id INTEGER PRIMARY KEY,
			kid TEXT NOT NULL UNIQUE,
			algorithm TEXT NOT NULL,
			private_key BLOB NOT NULL,
			created_at datetime NOT NULL
		);
		INSERT INTO SigningKey(id, kid, algorithm, private_key, created_at)
			SELECT id, kid, algorithm, private_key, created_at FROM SigningKey_old;
		DROP TABLE SigningKey_old;
		CREATE INDEX IF NOT EXISTS signing_key_created_at ON SigningKey(created_at);
	`,
	`
		ALTER TABLE User ADD COLUMN email TEXT;
	`,
	`
		ALTER TABLE User ADD COLUMN name TEXT;
	`,
	`
		ALTER TABLE AuthCode ADD COLUMN code_challenge TEXT;
		ALTER TABLE AuthCode ADD COLUMN code_challenge_method TEXT;
		ALTER TABLE Client ADD COLUMN pkce_requirement TEXT;
	`,
}
var errNoDBRows = sql.ErrNoRows
type DB struct {
	db *sql.DB
}
func openDB(filename string) (*DB, error) {
	sqlDB, err := sql.Open("sqlite3", filename+"?cache=shared&_foreign_keys=1")
	if err != nil {
		return nil, err
	}
	sqlDB.SetMaxOpenConns(1)
	db := &DB{sqlDB}
	if err := db.init(context.TODO()); err != nil {
		db.Close()
		return nil, err
	}
	return db, nil
}
func (db *DB) init(ctx context.Context) error {
	version, err := db.upgrade(ctx)
	if err != nil {
		return err
	}
	if version > 0 {
		return nil
	}
	// TODO: drop this
	defaultUser := User{Username: "root", Name: "Root User", Email: "root@example.invalid", Admin: true}
	if err := defaultUser.SetPassword("root"); err != nil {
		return err
	}
	return db.StoreUser(ctx, &defaultUser)
}
func (db *DB) upgrade(ctx context.Context) (version int, err error) {
	if err := db.db.QueryRowContext(ctx, "PRAGMA user_version").Scan(&version); err != nil {
		return 0, fmt.Errorf("failed to query schema version: %v", err)
	}
	if version == len(migrations) {
		return version, nil
	} else if version > len(migrations) {
		return version, fmt.Errorf("vireo (version %d) older than schema (version %d)", len(migrations), version)
	}
	tx, err := db.db.BeginTx(ctx, nil)
	if err != nil {
		return version, err
	}
	defer tx.Rollback()
	if version == 0 {
		if _, err := tx.ExecContext(ctx, schema); err != nil {
			return version, fmt.Errorf("failed to initialize schema: %v", err)
		}
	} else {
		for i := version; i < len(migrations); i++ {
			if _, err := tx.ExecContext(ctx, migrations[i]); err != nil {
				return version, fmt.Errorf("failed to execute migration #%v: %v", i, err)
			}
		}
	}
	// For some reason prepared statements don't work here
	_, err = tx.ExecContext(ctx, fmt.Sprintf("PRAGMA user_version = %d", len(migrations)))
	if err != nil {
		return version, fmt.Errorf("failed to bump schema version: %v", err)
	}
	return version, tx.Commit()
}
func (db *DB) Close() error {
	return db.db.Close()
}
func (db *DB) FetchUser(ctx context.Context, id ID[*User]) (*User, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM User WHERE id = ?", id)
	if err != nil {
		return nil, err
	}
	var user User
	err = scanRow(&user, rows)
	return &user, err
}
func (db *DB) FetchUserByUsername(ctx context.Context, username string) (*User, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM User WHERE username = ?", username)
	if err != nil {
		return nil, err
	}
	var user User
	err = scanRow(&user, rows)
	return &user, err
}
func (db *DB) StoreUser(ctx context.Context, user *User) error {
	return db.db.QueryRowContext(ctx, `
		INSERT INTO User(id, username, name, email, password_hash, admin)
		VALUES (:id, :username, :name, :email, :password_hash, :admin)
		ON CONFLICT(id) DO UPDATE SET
			username = :username,
			name = :name,
			email = :email,
			password_hash = :password_hash,
			admin = :admin
		RETURNING id
	`, entityArgs(user)...).Scan(&user.ID)
}
func (db *DB) ListUsers(ctx context.Context) ([]User, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM User")
	if err != nil {
		return nil, err
	}
	defer rows.Close()
	var l []User
	for rows.Next() {
		var user User
		if err := scan(&user, rows); err != nil {
			return nil, err
		}
		l = append(l, user)
	}
	return l, rows.Close()
}
func (db *DB) FetchClient(ctx context.Context, id ID[*Client]) (*Client, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM Client WHERE id = ?", id)
	if err != nil {
		return nil, err
	}
	var client Client
	err = scanRow(&client, rows)
	return &client, err
}
func (db *DB) FetchClientByClientID(ctx context.Context, clientID string) (*Client, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM Client WHERE client_id = ?", clientID)
	if err != nil {
		return nil, err
	}
	var client Client
	err = scanRow(&client, rows)
	return &client, err
}
func (db *DB) StoreClient(ctx context.Context, client *Client) error {
	return db.db.QueryRowContext(ctx, `
		INSERT INTO Client(id, client_id, client_secret_hash, owner,
			redirect_uris, client_name, client_uri, pkce_requirement)
		VALUES (:id, :client_id, :client_secret_hash, :owner,
			:redirect_uris, :client_name, :client_uri, :pkce_requirement)
		ON CONFLICT(id) DO UPDATE SET
			client_id = :client_id,
			client_secret_hash = :client_secret_hash,
			owner = :owner,
			redirect_uris = :redirect_uris,
			client_name = :client_name,
			client_uri = :client_uri,
			pkce_requirement = :pkce_requirement
		RETURNING id
	`, entityArgs(client)...).Scan(&client.ID)
}
func (db *DB) ListClients(ctx context.Context, owner ID[*User]) ([]Client, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM Client WHERE owner IS ?", owner)
	if err != nil {
		return nil, err
	}
	defer rows.Close()
	var l []Client
	for rows.Next() {
		var client Client
		if err := scan(&client, rows); err != nil {
			return nil, err
		}
		l = append(l, client)
	}
	return l, rows.Close()
}
func (db *DB) ListAuthorizedClients(ctx context.Context, user ID[*User]) ([]AuthorizedClient, error) {
	rows, err := db.db.QueryContext(ctx, `
		SELECT id, client_id, client_name, client_uri, token.expires_at
		FROM Client,
		(
			SELECT client, MAX(COALESCE(refresh_expires_at, expires_at)) as expires_at
			FROM AccessToken
			WHERE user = ?
			GROUP BY client
		) AS token
		WHERE Client.id = token.client
	`, user)
	if err != nil {
		return nil, err
	}
	var l []AuthorizedClient
	for rows.Next() {
		var authClient AuthorizedClient
		columns := authClient.Client.columns()
		var expiresAt string
		err := rows.Scan(columns["id"], columns["client_id"], columns["client_name"], columns["client_uri"], &expiresAt)
		if err != nil {
			return nil, err
		}
		authClient.ExpiresAt, err = time.Parse(sqlite3.SQLiteTimestampFormats[0], expiresAt)
		if err != nil {
			return nil, err
		}
		l = append(l, authClient)
	}
	return l, rows.Close()
}
func (db *DB) DeleteClient(ctx context.Context, id ID[*Client]) error {
	_, err := db.db.ExecContext(ctx, "DELETE FROM Client WHERE id = ?", id)
	return err
}
func (db *DB) FetchAccessToken(ctx context.Context, id ID[*AccessToken]) (*AccessToken, error) {
	rows, err := db.db.QueryContext(ctx, "SELECT * FROM AccessToken WHERE id = ?", id)
	if err != nil {
		return nil, err
	}
	var token AccessToken
	err = scanRow(&token, rows)
	return &token, err
}
func (db *DB) StoreAccessToken(ctx context.Context, token *AccessToken) error {
	return db.db.QueryRowContext(ctx, `
		INSERT INTO AccessToken(id, hash, user, client, scope, issued_at,
			expires_at, auth_time, refresh_hash, refresh_expires_at)
		VALUES (:id, :hash, :user, :client, :scope, :issued_at, :expires_at,
			:auth_time, :refresh_hash, :refresh_expires_at)
		ON CONFLICT(id) DO UPDATE SET
			hash = :hash,
			user = :user,
			client = :client,
			scope = :scope,
			issued_at = :issued_at,
			expires_at = :expires_at,
			auth_time = :auth_time,
			refresh_hash = :refresh_hash,
			refresh_expires_at = :refresh_expires_at
		RETURNING id
	`, entityArgs(token)...).Scan(&token.ID)
}
func (db *DB) DeleteAccessToken(ctx context.Context, id ID[*AccessToken]) error {
	_, err := db.db.ExecContext(ctx, "DELETE FROM AccessToken WHERE id = ?", id)
	return err
}
func (db *DB) RevokeClientUser(ctx context.Context, clientID ID[*Client], userID ID[*User]) error {
	tx, err := db.db.BeginTx(ctx, nil)
	if err != nil {
		return err
	}
	defer tx.Rollback()
	_, err = tx.ExecContext(ctx, `
		DELETE FROM AccessToken
		WHERE client = ? AND user = ?
	`, clientID, userID)
	if err != nil {
		return err
	}
	_, err = tx.ExecContext(ctx, `
		DELETE FROM AuthCode
		WHERE client = ? AND user = ?
	`, clientID, userID)
	if err != nil {
		return err
	}
	return tx.Commit()
}
func (db *DB) CreateAuthCode(ctx context.Context, code *AuthCode) error {
	return db.db.QueryRowContext(ctx, `
		INSERT INTO AuthCode(hash, created_at, user, client, scope, redirect_uri, nonce, code_challenge, code_challenge_method)
		VALUES (:hash, :created_at, :user, :client, :scope, :redirect_uri, :nonce, :code_challenge, :code_challenge_method)
		RETURNING id
	`, entityArgs(code)...).Scan(&code.ID)
}
func (db *DB) PopAuthCode(ctx context.Context, id ID[*AuthCode]) (*AuthCode, error) {
	rows, err := db.db.QueryContext(ctx, `
		DELETE FROM AuthCode
		WHERE id = ?
		RETURNING *
	`, id)
	if err != nil {
		return nil, err
	}
	var authCode AuthCode
	err = scanRow(&authCode, rows)
	return &authCode, err
}
func (db *DB) FetchSigningKeys(ctx context.Context) ([]SigningKey, error) {
	rows, err := db.db.QueryContext(ctx, `
		SELECT * FROM SigningKey
		ORDER BY created_at DESC
	`)
	if err != nil {
		return nil, err
	}
	defer rows.Close()
	var keys []SigningKey
	for rows.Next() {
		var key SigningKey
		if err := scan(&key, rows); err != nil {
			return nil, err
		}
		keys = append(keys, key)
	}
	if err := rows.Err(); err != nil {
		return nil, err
	}
	if len(keys) == 0 {
		return nil, errNoDBRows
	}
	return keys, nil
}
func (db *DB) StoreSigningKey(ctx context.Context, key *SigningKey) error {
	return db.db.QueryRowContext(ctx, `
		INSERT INTO SigningKey(kid, algorithm, private_key, created_at)
		VALUES (:kid, :algorithm, :private_key, :created_at)
		RETURNING id
	`, sql.Named("kid", key.KID), sql.Named("algorithm", key.Algorithm), sql.Named("private_key", key.PrivateKey), sql.Named("created_at", key.CreatedAt)).Scan(&key.ID)
}
func (db *DB) Maintain(ctx context.Context) error {
	_, err := db.db.ExecContext(ctx, `
		DELETE FROM AccessToken
		WHERE timediff('now', COALESCE(refresh_expires_at, expires_at)) > 0
	`)
	if err != nil {
		return err
	}
	_, err = db.db.ExecContext(ctx, `
		DELETE FROM AuthCode
		WHERE timediff(?, created_at) > 0
	`, time.Now().Add(-authCodeExpiration))
	if err != nil {
		return err
	}
	return nil
}
func scan(e entity, rows *sql.Rows) error {
	columns := e.columns()
	keys, err := rows.Columns()
	if err != nil {
		panic(err)
	}
	out := make([]interface{}, len(keys))
	for i, k := range keys {
		v, ok := columns[k]
		if !ok {
			panic(fmt.Errorf("unknown column %q", k))
		}
		out[i] = v
	}
	return rows.Scan(out...)
}
func scanRow(e entity, rows *sql.Rows) error {
	if !rows.Next() {
		return sql.ErrNoRows
	}
	if err := scan(e, rows); err != nil {
		return err
	}
	return rows.Close()
}
func entityArgs(e entity) []interface{} {
	columns := e.columns()
	l := make([]interface{}, 0, len(columns))
	for k, v := range columns {
		l = append(l, sql.Named(k, v))
	}
	return l
}