515 lines
16 KiB
TypeScript
515 lines
16 KiB
TypeScript
import type { Database, Statement } from "bun:sqlite";
|
|
import {
|
|
type ColumnMap,
|
|
type ColumnShorthandMap,
|
|
generateColumnDefinitionSQL,
|
|
normalizeColumns,
|
|
} from "./columns";
|
|
import { SchemaError } from "./error";
|
|
import { Prequel } from "./prequel";
|
|
|
|
/** Types that may appear in a row */
|
|
type Value = string | number | null;
|
|
|
|
export class PrequelIDNotFoundError extends Error {
|
|
constructor(tableName: string, id: Value) {
|
|
super(`ID ${id} not found in ${tableName}`);
|
|
}
|
|
}
|
|
|
|
export class PrequelEmptyResultsError extends Error {
|
|
constructor() {
|
|
super("No results found on a query which requires results");
|
|
}
|
|
}
|
|
|
|
/** An arbitrarily shaped Row */
|
|
interface ArbitraryRow {
|
|
[key: string]: Value;
|
|
}
|
|
|
|
function shapeForQuery<T>(obj: Partial<T>): Record<string, Value> {
|
|
const asInsertDataShape: Record<string, Value> = {};
|
|
|
|
const keys = Object.keys(obj);
|
|
|
|
for (const key of keys) {
|
|
const val = obj[key as keyof T];
|
|
|
|
if (typeof val !== "string" && typeof val !== "number" && val !== null) {
|
|
throw new SchemaError(
|
|
`Invalid value in query: ${key}: ${val} (type: ${typeof val})`,
|
|
);
|
|
}
|
|
|
|
const asQueryKey = `$${key}`;
|
|
asInsertDataShape[asQueryKey] = val as Value;
|
|
}
|
|
|
|
return asInsertDataShape;
|
|
}
|
|
|
|
/**
|
|
* Represents a table in a database.
|
|
*
|
|
* @typeParam RowShape - The shape of the rows in the table.
|
|
*/
|
|
export class Table<RowShape> {
|
|
private _name: string;
|
|
private _db: Database;
|
|
private _columnDefinitions: ColumnMap<RowShape>;
|
|
private _columnNames: string[];
|
|
private _createTableSQL: string;
|
|
private _primaryColumnName = "ROWID";
|
|
private _insertQuery: Statement<RowShape, [ArbitraryRow]>;
|
|
private _updateQuery: Statement<RowShape, [ArbitraryRow]>;
|
|
private _findQuery: Statement<RowShape, [string]>;
|
|
private _deleteQuery: Statement<void, [string]>;
|
|
private _deleteRowQuery: Statement<void, [ArbitraryRow]>;
|
|
private _sizeQuery: Statement<{ count: number }, []>;
|
|
private _truncateQuery: Statement<void, []>;
|
|
|
|
constructor(
|
|
db: Database | Prequel,
|
|
name: string,
|
|
cols: ColumnShorthandMap<RowShape>,
|
|
) {
|
|
if (db instanceof Prequel) {
|
|
this._db = db.db;
|
|
} else {
|
|
this._db = db;
|
|
}
|
|
this._name = name;
|
|
this._columnDefinitions = normalizeColumns(cols);
|
|
this._columnNames = Object.keys(this._columnDefinitions);
|
|
|
|
const columnSQLParts: string[] = [];
|
|
const updateColumnSQLParts: string[] = [];
|
|
|
|
for (const columnName of this._columnNames) {
|
|
const columnDefinition =
|
|
this._columnDefinitions[
|
|
columnName as keyof typeof this._columnDefinitions
|
|
];
|
|
|
|
// Identify a primary column besides ROWID if specified
|
|
if (columnDefinition.primary && this._primaryColumnName === "ROWID") {
|
|
this._primaryColumnName = columnName;
|
|
}
|
|
|
|
// Add non-primary columns to the generic update query
|
|
if (!columnDefinition.primary) {
|
|
updateColumnSQLParts.push(`"${columnName}" = $${columnName}`);
|
|
}
|
|
|
|
// Generate column definitions for CREATE TABLE
|
|
columnSQLParts.push(
|
|
generateColumnDefinitionSQL(columnName, columnDefinition),
|
|
);
|
|
}
|
|
|
|
// Generate SQL for common queries
|
|
const columnSQL = columnSQLParts.join(", ");
|
|
const updateColumnSQL = updateColumnSQLParts.join(", ");
|
|
const allCols = this._columnNames.join(", ");
|
|
const allColVars = this._columnNames
|
|
.map((colName) => `$${colName}`)
|
|
.join(", ");
|
|
|
|
this._createTableSQL = `CREATE TABLE IF NOT EXISTS "${name}" (${columnSQL});`;
|
|
const insertSql = `INSERT INTO "${name}" (${allCols}) VALUES (${allColVars}) RETURNING *;`;
|
|
const updateSql = `UPDATE "${name}" SET ${updateColumnSQL} WHERE "${this._primaryColumnName}" = $${this._primaryColumnName} RETURNING *;`;
|
|
const getByIdSql = `SELECT * FROM "${name}" WHERE "${this._primaryColumnName}" = ? LIMIT 1;`;
|
|
const delByIdSql = `DELETE FROM "${name}" WHERE "${this._primaryColumnName}" = ?;`;
|
|
const deleteRowSql = `DELETE FROM "${name}" WHERE "${this._primaryColumnName}" = $${this._primaryColumnName};`;
|
|
const truncateQuery = `DELETE FROM "${name}";`;
|
|
|
|
// Ensure the table exists in the database
|
|
this.db.exec(this._createTableSQL);
|
|
|
|
// Prepare common queries
|
|
this._insertQuery = this.db.query<RowShape, ArbitraryRow>(insertSql);
|
|
this._updateQuery = this.db.query<RowShape, ArbitraryRow>(updateSql);
|
|
this._findQuery = this.db.query<RowShape, string>(getByIdSql);
|
|
this._deleteQuery = this.db.query<void, string>(delByIdSql);
|
|
this._sizeQuery = this.db.query<{ count: number }, []>(
|
|
`SELECT count(*) as count FROM ${name}`,
|
|
);
|
|
this._deleteRowQuery = this.db.query<void, ArbitraryRow>(deleteRowSql);
|
|
this._truncateQuery = this.db.query<void, []>(truncateQuery);
|
|
|
|
// If using with a Prequel instance, ensure the table is attached
|
|
// This is only for when creating tables directly and passing in a Prequel instance
|
|
if (db instanceof Prequel) {
|
|
if (!db.hasTable(name)) {
|
|
db.attachTable(this);
|
|
}
|
|
}
|
|
}
|
|
|
|
protected hasColumn(colName: string) {
|
|
return this._columnNames.includes(colName);
|
|
}
|
|
|
|
/**
|
|
* Generates a reference string for a column in the table.
|
|
*
|
|
* @param colName - The name of the column to reference. If not provided, the primary column name is used.
|
|
* @returns A string representing the reference to the specified column or the primary column if no column name is provided.
|
|
* @throws {SchemaError} If the specified column name does not exist in the table schema.
|
|
*/
|
|
public reference(colName?: keyof RowShape): string {
|
|
if (colName === undefined) {
|
|
return `${this._name}(${this._primaryColumnName})`;
|
|
}
|
|
|
|
const asString = String(colName);
|
|
|
|
if (!this.hasColumn(asString)) {
|
|
throw new SchemaError(
|
|
"No such column available for reference",
|
|
this._name,
|
|
asString,
|
|
);
|
|
}
|
|
|
|
return `${this._name}(${asString})`;
|
|
}
|
|
|
|
/**
|
|
* Inserts a new row into the table.
|
|
*
|
|
* @param data - The data to be inserted, conforming to the RowShape interface.
|
|
* @returns The inserted row, conforming to the RowShape interface.
|
|
*/
|
|
public insert(data: RowShape): RowShape {
|
|
const asInsertDataShape = shapeForQuery<RowShape>(data);
|
|
return this._insertQuery.get(asInsertDataShape) as RowShape;
|
|
}
|
|
|
|
/**
|
|
* Inserts a partial row into the table and returns the inserted row.
|
|
*
|
|
* @param data - An object containing the partial data to be inserted. The keys should match the column names of the table.
|
|
* @returns The inserted row as an object of type `RowShape`.
|
|
*
|
|
* @typeParam RowShape - The shape of the row in the table.
|
|
*/
|
|
public insertPartial(data: Partial<RowShape>): RowShape {
|
|
const asInsertDataShape: ArbitraryRow = shapeForQuery<RowShape>(data);
|
|
const keys = Object.keys(data);
|
|
const colNames = keys.join(", ");
|
|
const varNames = keys.map((keyName) => `$${keyName}`);
|
|
|
|
const query = this._db.prepare(
|
|
`INSERT INTO ${this} (${colNames}) VALUES (${varNames}) RETURNING *;`,
|
|
);
|
|
|
|
return query.get(asInsertDataShape) as RowShape;
|
|
}
|
|
|
|
/**
|
|
* Updates a row in the table with the provided data.
|
|
*
|
|
* @param data - The data to update the row with, conforming to the RowShape interface.
|
|
* @returns The updated row data if the update is successful, or `null` if it fails.
|
|
* @throws Will throw an error if the primary column name is "ROWID".
|
|
*/
|
|
public update(data: RowShape): RowShape | null {
|
|
if (this._primaryColumnName === "ROWID") {
|
|
throw new Error(
|
|
"Cannot use `Table.update()` without setting a primary column",
|
|
);
|
|
}
|
|
|
|
const asInsertDataShape: ArbitraryRow = shapeForQuery<RowShape>(data);
|
|
return this._updateQuery.get(asInsertDataShape);
|
|
}
|
|
|
|
/**
|
|
* Updates rows in the table that match the specified conditions with the provided data.
|
|
*
|
|
* @param data - An object containing the data to update. The keys should correspond to the column names.
|
|
* @param conditions - An object containing the conditions to match the rows that need to be updated. The keys should correspond to the column names.
|
|
* @returns An array of updated rows.
|
|
*/
|
|
public updateWhere(
|
|
data: Partial<RowShape>,
|
|
conditions: Partial<RowShape>,
|
|
): RowShape[] {
|
|
const keys = Object.keys(data);
|
|
const setParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const setClause = setParts.join(", ");
|
|
|
|
const whereKeys = Object.keys(conditions);
|
|
const whereParts = whereKeys.map((key) => `"${key}" = $${key}`);
|
|
const whereClause = whereParts.join(" AND ");
|
|
|
|
const query = this._db.prepare<RowShape, ArbitraryRow>(
|
|
`UPDATE ${this} SET ${setClause} WHERE ${whereClause} RETURNING *;`,
|
|
);
|
|
|
|
const shapedData = shapeForQuery({
|
|
...data,
|
|
...conditions,
|
|
});
|
|
|
|
return query.all(shapedData);
|
|
}
|
|
|
|
/**
|
|
* Updates all rows in the table with the provided data and returns the updated rows.
|
|
*
|
|
* @param data - An object containing the partial data to update the rows with.
|
|
* The keys of this object should match the column names of the table.
|
|
* @returns An array of updated rows.
|
|
*/
|
|
public updateAll(data: Partial<RowShape>): RowShape[] {
|
|
const keys = Object.keys(data);
|
|
const setParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const setClause = setParts.join(", ");
|
|
|
|
const query = this._db.prepare<RowShape, ArbitraryRow>(
|
|
`UPDATE ${this} SET ${setClause} RETURNING *;`,
|
|
);
|
|
|
|
return query.all(shapeForQuery(data));
|
|
}
|
|
|
|
/**
|
|
* Checks if an entry with the specified ID exists in the table.
|
|
*
|
|
* @param id - The ID of the entry to check for existence.
|
|
* @returns `true` if an entry with the specified ID exists, otherwise `false`.
|
|
*/
|
|
public exists(id: Value): boolean {
|
|
return this.findOneById(id) !== null;
|
|
}
|
|
|
|
/**
|
|
* Checks if a row exists in the table that matches the given conditions.
|
|
*
|
|
* @param conditions - An object representing the conditions to match against.
|
|
* Each key-value pair represents a column and the value to match.
|
|
* @returns `true` if a matching row is found, otherwise `false`.
|
|
*/
|
|
public existsWhere(conditions: Partial<RowShape>): boolean {
|
|
return this.findOneWhere(conditions) !== null;
|
|
}
|
|
|
|
/**
|
|
* Counts the number of rows in the table that match the specified conditions.
|
|
* @param conditions The shape of data to count rows by
|
|
* @returns The number of rows that match the specified conditions.
|
|
*/
|
|
public countWhere(conditions: Partial<RowShape>): number {
|
|
const keys = Object.keys(conditions);
|
|
const whereParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const whereClause = whereParts.join(" AND ");
|
|
const query = this._db.prepare<{ count: number }, ArbitraryRow>(
|
|
`SELECT count(*) as count FROM ${this} WHERE ${whereClause};`,
|
|
);
|
|
|
|
const shapedData = shapeForQuery(conditions);
|
|
const countResult = query.get(shapedData) ?? { count: 0 };
|
|
return countResult.count;
|
|
}
|
|
|
|
/**
|
|
* Finds a single row by its unique identifier.
|
|
*
|
|
* @param id - The unique identifier of the row to find.
|
|
* @returns The row shape if found, otherwise `null`.
|
|
*/
|
|
public findOneById(id: Value): RowShape | null {
|
|
return this._findQuery.get(`${id}`);
|
|
}
|
|
|
|
/**
|
|
* Finds a single row by its unique identifier. Throws an error if no row is found.
|
|
*
|
|
* @param id - The unique identifier of the row to find.
|
|
* @returns The row shape if found, otherwise `null`.
|
|
*
|
|
* @throws {Error} If no row is found with the specified ID.
|
|
*/
|
|
public findOneByIdOrFail(id: Value): RowShape {
|
|
const found = this.findOneById(id);
|
|
|
|
if (!found) {
|
|
throw new PrequelIDNotFoundError(this.name, id);
|
|
}
|
|
|
|
return found;
|
|
}
|
|
|
|
/**
|
|
* Retrieves all rows from the table.
|
|
*
|
|
* @returns {RowShape[]} An array of all rows in the table.
|
|
*/
|
|
public findAll(): RowShape[] {
|
|
return this._db.prepare<RowShape, []>(`SELECT * FROM ${this}`).all();
|
|
}
|
|
|
|
/**
|
|
* Finds a single row in the table that matches the specified conditions.
|
|
*
|
|
* @param conditions - An object representing the conditions to match. The keys are column names and the values are the values to match.
|
|
* @returns The first row that matches the conditions, or `null` if no matching row is found.
|
|
*/
|
|
public findOneWhere(conditions: Partial<RowShape>): RowShape | null {
|
|
const keys = Object.keys(conditions);
|
|
const whereParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const whereClause = whereParts.join(" AND ");
|
|
const query = this._db.prepare<RowShape, ArbitraryRow>(
|
|
`SELECT * FROM ${this} WHERE ${whereClause};`,
|
|
);
|
|
|
|
return query.get(shapeForQuery(conditions));
|
|
}
|
|
|
|
/**
|
|
* Finds a single row in the table that matches the specified conditions. Throws an error if no row is found.
|
|
*
|
|
* @param conditions - An object representing the conditions to match. The keys are column names and the values are the values to match.
|
|
* @returns The first row that matches the conditions, or `null` if no matching row is found.
|
|
*
|
|
* @throws {Error} If no row is found that matches the specified conditions.
|
|
*/
|
|
public findOneWhereOrFail(conditions: Partial<RowShape>): RowShape {
|
|
const found = this.findOneWhere(conditions);
|
|
|
|
if (!found) {
|
|
throw new PrequelEmptyResultsError();
|
|
}
|
|
|
|
return found;
|
|
}
|
|
|
|
/**
|
|
* Finds all rows in the table that match the specified conditions.
|
|
*
|
|
* @param conditions - An object containing key-value pairs that represent the conditions for the query.
|
|
* The keys are column names and the values are the values to match.
|
|
* @returns An array of rows that match the specified conditions.
|
|
*/
|
|
public findAllWhere(conditions: Partial<RowShape>): RowShape[] {
|
|
const keys = Object.keys(conditions);
|
|
const whereParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const whereClause = whereParts.join(" AND ");
|
|
const query = this._db.prepare<RowShape, ArbitraryRow>(
|
|
`SELECT * FROM ${this} WHERE ${whereClause};`,
|
|
);
|
|
|
|
return query.all(shapeForQuery(conditions));
|
|
}
|
|
|
|
/**
|
|
* Deletes a row
|
|
*
|
|
* @param row - The row in the table to delete
|
|
* @returns The updated row data if the update is successful, or `null` if it fails.
|
|
* @throws Will throw an error if the primary column name is "ROWID".
|
|
*/
|
|
public delete(data: RowShape): void {
|
|
if (this._primaryColumnName === "ROWID") {
|
|
throw new Error(
|
|
"Cannot use `Table.delete()` without setting a primary column",
|
|
);
|
|
}
|
|
|
|
const asDeleteDataShape: ArbitraryRow = shapeForQuery<RowShape>(data);
|
|
this._deleteRowQuery.run(asDeleteDataShape);
|
|
}
|
|
|
|
/**
|
|
* Deletes a record from the table by its ID.
|
|
*
|
|
* @param id - The unique identifier of the record to be deleted.
|
|
* @returns void
|
|
*/
|
|
public deleteById = (id: Value): void => {
|
|
if (this._primaryColumnName === "ROWID") {
|
|
throw new Error(
|
|
"Cannot use `Table.deleteById()` without setting a primary column",
|
|
);
|
|
}
|
|
|
|
this._deleteQuery.run(`${id}`);
|
|
};
|
|
|
|
/**
|
|
* Deletes all rows in the table that match the specified conditions.
|
|
*
|
|
* @param conditions - An object representing the conditions to match. The keys are column names and the values are the values to match.
|
|
*/
|
|
public deleteWhere(conditions: Partial<RowShape>): void {
|
|
const keys = Object.keys(conditions);
|
|
const whereParts = keys.map((key) => `"${key}" = $${key}`);
|
|
const whereClause = whereParts.join(" AND ");
|
|
const query = this._db.prepare<void, ArbitraryRow>(
|
|
`DELETE FROM ${this} WHERE ${whereClause};`,
|
|
);
|
|
|
|
query.run(shapeForQuery(conditions));
|
|
}
|
|
|
|
/**
|
|
* Deletes all rows in the table.
|
|
*/
|
|
public deleteAll(): void {
|
|
this._truncateQuery.run();
|
|
}
|
|
|
|
/**
|
|
* Retrieves the size of the table.
|
|
*
|
|
* @deprecated Use `count()` instead.
|
|
* @returns {number} The number of rows in the table.
|
|
* @throws {Error} If the row count query fails.
|
|
*/
|
|
public size(): number {
|
|
return this.count();
|
|
}
|
|
|
|
/**
|
|
* Retrieves the size of the table.
|
|
*
|
|
* @returns {number} The number of rows in the table.
|
|
* @throws {Error} If the row count query fails.
|
|
*/
|
|
public count(): number {
|
|
const res = this._sizeQuery.get();
|
|
|
|
if (res === null) {
|
|
throw new Error("Failed to count rows");
|
|
}
|
|
|
|
return res.count;
|
|
}
|
|
|
|
public toString() {
|
|
return `"${this._name}"`;
|
|
}
|
|
|
|
get name() {
|
|
return this._name;
|
|
}
|
|
|
|
get db() {
|
|
return this._db;
|
|
}
|
|
|
|
get columns() {
|
|
return this._columnNames;
|
|
}
|
|
|
|
get schema(): string {
|
|
return this._createTableSQL;
|
|
}
|
|
|
|
get idColumnName(): string {
|
|
return this._primaryColumnName;
|
|
}
|
|
}
|