From 1e6d984d95c78d20092ed61ff32cdbf11df6c58f Mon Sep 17 00:00:00 2001 From: "Daniel J. Summers" Date: Sun, 26 Nov 2023 18:48:42 -0500 Subject: [PATCH] Remove ID col from doc table --- src/app/lib/Data.php | 2 +- src/app/lib/documents/Configuration.php | 5 +- src/app/lib/documents/Definition.php | 40 +++++++-- src/app/lib/documents/Document.php | 38 ++++---- src/app/lib/documents/Query.php | 110 ++++++++++++++++++------ 5 files changed, 139 insertions(+), 56 deletions(-) diff --git a/src/app/lib/Data.php b/src/app/lib/Data.php index 0e74246..bb2a919 100644 --- a/src/app/lib/Data.php +++ b/src/app/lib/Data.php @@ -98,7 +98,7 @@ class Data Query::whereJsonPathMatches('$2')); $params = [ Query::jsonbDocParam([ 'userId' => $userId ]), - sprintf("$.history[0].status ? (@ $op \"%s\")", RequestAction::Answered->name) + sprintf('$.history[0].status ? (@ %s "%s")', $op, RequestAction::Answered->name) ]; return self::mapToJournalRequest( Document::customList($sql, $params, Request::class, Document::mapFromJson(...)), true); diff --git a/src/app/lib/documents/Configuration.php b/src/app/lib/documents/Configuration.php index c881936..1088eac 100644 --- a/src/app/lib/documents/Configuration.php +++ b/src/app/lib/documents/Configuration.php @@ -11,7 +11,7 @@ use PgSql\Connection; class Configuration { /** @var string $connectionString The connection string to use when establishing a database connection */ - public static string $connectionString = ""; + public static string $connectionString = ''; /** @var ?Connection $pgConn The active connection */ private static ?Connection $pgConn = null; @@ -19,6 +19,9 @@ class Configuration /** @var ?string $startUp The name of a function to run on first connection to the database */ public static ?string $startUp = null; + /** @var string $keyName The key name for document IDs (default "id") */ + public static string $keyName = 'id'; + /** * Ensure that the connection string is set, either explicitly, by environment variables, or with defaults */ diff --git a/src/app/lib/documents/Definition.php b/src/app/lib/documents/Definition.php index 2aa6ee2..ffd3792 100644 --- a/src/app/lib/documents/Definition.php +++ b/src/app/lib/documents/Definition.php @@ -18,7 +18,19 @@ class Definition */ public static function createTable(string $name): string { - return "CREATE TABLE IF NOT EXISTS $name (id TEXT NOT NULL PRIMARY KEY, data JSONB NOT NULL)"; + return "CREATE TABLE IF NOT EXISTS $name (data JSONB NOT NULL)"; + } + + /** + * Create a statement to create a key for a document table + * + * @param string $tableName The table (or schema/table) for which a key should be created + * @return string A `CREATE INDEX` statement for a unique key for the document table + */ + public static function createKey(string $tableName): string + { + return sprintf('CREATE UNIQUE INDEX IF NOT EXISTS idx_%s_key ON %s ((data -> \'%s\'))', + self::extractTable($tableName), $tableName, Configuration::$keyName); } /** @@ -30,21 +42,21 @@ class Definition */ public static function createIndex(string $name, DocumentIndex $type): string { - $extraOps = $type == DocumentIndex::Full ? '' : ' jsonb_path_ops'; - $schemaAndTable = explode('.', $name); - $tableName = end($schemaAndTable); - return "CREATE INDEX IF NOT EXISTS idx_$tableName ON $name USING GIN (data$extraOps)"; + return sprintf('CREATE INDEX IF NOT EXISTS idx_%s ON %s USING GIN (data%s)', + self::extractTable($name), $name, $type == DocumentIndex::Full ? '' : ' jsonb_path_ops'); } /** * Ensure the given document table exists * - * @param string $name The name of the table + * @param string $tableName The name of the table */ - public static function ensureTable(string $name): void + public static function ensureTable(string $tableName): void { /** @var Result|bool $result */ - $result = pg_query(pg_conn(), self::createTable($name)); + $result = pg_query(pg_conn(), self::createTable($tableName)); + if ($result) pg_free_result($result); + $result = pg_query(pg_conn(), self::createKey($tableName)); if ($result) pg_free_result($result); } @@ -60,4 +72,16 @@ class Definition $result = pg_query(pg_conn(), self::createIndex($name, $type)); if ($result) pg_free_result($result); } + + /** + * Extract just the table name from a possible `schema.table` name + * + * @param string $name The name of the table, possibly including the schema + * @return string The table name + */ + private static function extractTable(string $name): string + { + $schemaAndTable = explode('.', $name); + return end($schemaAndTable); + } } diff --git a/src/app/lib/documents/Document.php b/src/app/lib/documents/Document.php index 43cff83..1512bf1 100644 --- a/src/app/lib/documents/Document.php +++ b/src/app/lib/documents/Document.php @@ -3,6 +3,7 @@ declare(strict_types=1); namespace BitBadger\PgDocuments; +use Exception; use JsonMapper; use PgSql\Result; @@ -45,13 +46,17 @@ class Document /** * Execute a document-focused statement that does not return results - * + * * @param string $query The query to be executed - * @param string $docId The ID of the document on which action should be taken * @param array|object $document The array or object representing the document + * @throws Exception If the document's ID is null */ - private static function executeNonQuery(string $query, string $docId, array|object $document): void + private static function executeNonQuery(string $query, array|object $document): void { + $docId = is_array($document) + ? $document[Configuration::$keyName] + : get_object_vars($document)[Configuration::$keyName]; + if (is_null($docId)) throw new Exception('PgDocument: ID cannot be NULL'); /** @var Result|bool $result */ $result = pg_query_params(pg_conn(), $query, [ $docId, Query::jsonbDocParam($document) ]); if ($result) pg_free_result($result); @@ -61,24 +66,22 @@ class Document * Insert a document * * @param string $tableName The name of the table into which a document should be inserted - * @param string $docId The ID of the document to be inserted * @param array|object $document The array or object representing the document */ - public static function insert(string $tableName, string $docId, array|object $document): void + public static function insert(string $tableName, array|object $document): void { - self::executeNonQuery(Query::insert($tableName), $docId, $document); + self::executeNonQuery(Query::insert($tableName), $document); } /** * Save (upsert) a document * * @param string $tableName The name of the table into which a document should be inserted - * @param string $docId The ID of the document to be inserted * @param array|object $document The array or object representing the document */ - public static function save(string $tableName, string $docId, array|object $document): void + public static function save(string $tableName, array|object $document): void { - self::executeNonQuery(Query::save($tableName), $docId, $document); + self::executeNonQuery(Query::save($tableName), $document); } /** @@ -291,24 +294,22 @@ class Document * Update a full document * * @param string $tableName The table in which the document should be updated - * @param string $docId The ID of the document to be updated * @param array|object $document The document to be updated */ - public static function updateFull(string $tableName, string $docId, array|object $document): void + public static function updateFull(string $tableName, array|object $document): void { - self::executeNonQuery(Query::updateFull($tableName), $docId, $document); + self::executeNonQuery(Query::updateFull($tableName), $document); } /** * Update a partial document by its ID * * @param string $tableName The table in which the document should be updated - * @param string $docId The ID of the document to be updated * @param array|object $document The partial document to be updated */ - public static function updatePartialById(string $tableName, string $docId, array|object $document): void + public static function updatePartialById(string $tableName, array|object $document): void { - self::executeNonQuery(Query::updatePartialById($tableName), $docId, $document); + self::executeNonQuery(Query::updatePartialById($tableName), $document); } /** @@ -318,7 +319,8 @@ class Document * @param array|object $criteria The JSON containment criteria * @param array|object $document The document to be updated */ - public static function updatePartialByContains(string $tableName, array|object $criteria, array|object $document): void + public static function updatePartialByContains(string $tableName, array|object $criteria, + array|object $document): void { /** @var Result|bool $result */ $result = pg_query_params(pg_conn(), Query::updatePartialByContains($tableName), @@ -336,7 +338,7 @@ class Document public static function updatePartialByJsonPath(string $tableName, string $jsonPath, array|object $document): void { /** @var Result|bool $result */ - $result = pg_query_params(pg_conn(), Query::updatePartialByContains($tableName), + $result = pg_query_params(pg_conn(), Query::updatePartialByJsonPath($tableName), [ $jsonPath, Query::jsonbDocParam($document) ]); if ($result) pg_free_result($result); } @@ -349,7 +351,7 @@ class Document */ public static function deleteById(string $tableName, string $docId): void { - self::executeNonQuery(Query::deleteById($tableName), $docId, []); + self::executeNonQuery(Query::deleteById($tableName), [ Configuration::$keyName => $docId ]); } /** diff --git a/src/app/lib/documents/Query.php b/src/app/lib/documents/Query.php index 3806fa5..9d12dbe 100644 --- a/src/app/lib/documents/Query.php +++ b/src/app/lib/documents/Query.php @@ -16,7 +16,18 @@ class Query { return "SELECT data FROM $tableName"; } - + + /** + * Create a `WHERE` clause fragment to implement a key check condition + * + * @param string $paramName The name of the parameter to be replaced when the query is executed + * @return string A `WHERE` clause fragment with the named key and parameter + */ + public static function whereById(string $paramName): string + { + return sprintf("data -> '%s' = %s", Configuration::$keyName, $paramName); + } + /** * Create a `WHERE` clause fragment to implement a @> (JSON contains) condition * @@ -50,33 +61,41 @@ class Query return json_encode($it); } - /// Create ID and data parameters for a query - /* let docParameters<'T> docId (doc : 'T) = - [ "@id", Sql.string docId; "@data", jsonbDocParam doc ] - */ /** * Query to insert a document * * @param string $tableName The name of the table into which the document will be inserted - * @return string The `INSERT` statement (with `@id` and `@data` parameters defined) + * @return string The `INSERT` statement (with `$1` parameter defined for the document) */ public static function insert(string $tableName): string { - return "INSERT INTO $tableName (id, data) VALUES ($1, $2)"; + return sprintf('INSERT INTO %s (data) VALUES ($1)', $tableName); } /** * Query to save a document, inserting it if it does not exist and updating it if it does (AKA "upsert") * * @param string $tableName The name of the table into which the document will be saved - * @return string The `INSERT`/`ON CONFLICT DO UPDATE` statement (with `@id` and `@data` parameters defined) + * @return string The `INSERT`/`ON CONFLICT DO UPDATE` statement (with `$1` parameter defined for the document) */ public static function save(string $tableName): string { - return "INSERT INTO $tableName (id, data) VALUES ($1, $2) - ON CONFLICT (id) DO UPDATE SET data = EXCLUDED.data"; + return sprintf('INSERT INTO %s (data) VALUES ($1) ON CONFLICT (data) DO UPDATE SET data = EXCLUDED.data', + $tableName); } - + + /** + * Query to count documents in a table + * + * @param string $tableName The name of the table for which documents should be counted + * @param string $where The condition for which documents should be counted + * @return string A `SELECT` statement to obtain the count of documents for the given table + */ + private static function countQuery(string $tableName, string $where): string + { + return "SELECT COUNT(*) AS it FROM $tableName WHERE $where"; + } + /** * Query to count all documents in a table * @@ -85,7 +104,7 @@ class Query */ public static function countAll(string $tableName): string { - return "SELECT COUNT(id) AS it FROM $tableName"; + return self::countQuery($tableName, '1 = 1'); } /** @@ -96,7 +115,7 @@ class Query */ public static function countByContains(string $tableName): string { - return "SELECT COUNT(id) AS it FROM $tableName WHERE " . self::whereDataContains('$1'); + return self::countQuery($tableName, self::whereDataContains('$1')); } /** @@ -107,9 +126,20 @@ class Query */ public static function countByJsonPath(string $tableName): string { - return "SELECT COUNT(id) AS it FROM $tableName WHERE " . self::whereJsonPathMatches('$1'); + return self::countQuery($tableName, self::whereJsonPathMatches('$1')); + } + + /** + * Query to check document existence + * + * @param string $tableName The name of the table in which document existence should be checked + * @param string $where The criteria for which document existence should be checked + * @return string A `SELECT` statement to check document existence for the given criteria + */ + private static function existsQuery(string $tableName, string $where): string + { + return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE $where) AS it"; } - /** * Query to determine if a document exists for the given ID * @@ -118,7 +148,7 @@ class Query */ public static function existsById(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE id = $1) AS it"; + return self::existsQuery($tableName, self::whereById('$1')); } /** @@ -129,7 +159,7 @@ class Query */ public static function existsByContains(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE " . self::whereDataContains('$1') . ' AS it'; + return self::existsQuery($tableName, self::whereDataContains('$1')); } /** @@ -140,7 +170,7 @@ class Query */ public static function existsByJsonPath(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE " . self::whereJsonPathMatches('$1') . ' AS it'; + return self::existsQuery($tableName, self::whereJsonPathMatches('$1')); } /** @@ -151,7 +181,7 @@ class Query */ public static function findById(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE id = $1'; + return sprintf('%s WHERE %s', self::selectFromTable($tableName), self::whereById('$1')); } /** @@ -162,7 +192,7 @@ class Query */ public static function findByContains(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE ' . self::whereDataContains('$1'); + return sprintf('%s WHERE %s', self::selectFromTable($tableName), self::whereDataContains('$1')); } /** @@ -173,7 +203,7 @@ class Query */ public static function findByJsonPath(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE ' . self::whereJsonPathMatches('$1'); + return sprintf('%s WHERE %s', self::selectFromTable($tableName), self::whereJsonPathMatches('$1')); } /** @@ -184,7 +214,19 @@ class Query */ public static function updateFull(string $tableName): string { - return "UPDATE $tableName SET data = $2 WHERE id = $1"; + return sprintf('UPDATE %s SET data = $2 WHERE %s', $tableName, self::whereById('$1')); + } + + /** + * Query to apply a partial update to a document + * + * @param string $tableName The name of the table in which documents should be updated + * @param string $where The `WHERE` clause specifying which documents should be updated + * @return string An `UPDATE` statement to update a partial document ($1 is ID, $2 is document) + */ + private static function updatePartial(string $tableName, string $where): string + { + return sprintf('UPDATE %s SET data = data || $2 WHERE %s', $tableName, $where); } /** @@ -195,7 +237,7 @@ class Query */ public static function updatePartialById(string $tableName): string { - return "UPDATE $tableName SET data = data || $2 WHERE id = $1"; + return self::updatePartial($tableName, self::whereById('$1')); } /** @@ -206,7 +248,7 @@ class Query */ public static function updatePartialByContains(string $tableName): string { - return "UPDATE $tableName SET data = data || $2 WHERE " . self::whereDataContains('$1'); + return self::updatePartial($tableName, self::whereDataContains('$1')); } /** @@ -217,7 +259,19 @@ class Query */ public static function updatePartialByJsonPath(string $tableName): string { - return "UPDATE $tableName SET data = data || $2 WHERE " . self::whereJsonPathMatches('$1'); + return self::updatePartial($tableName, self::whereJsonPathMatches('$1')); + } + + /** + * Query to delete documents + * + * @param string $tableName The name of the table from which documents should be deleted + * @param string $where The criteria by which documents should be deleted + * @return string A `DELETE` statement to delete documents in the specified table + */ + private static function deleteQuery(string $tableName, string $where): string + { + return "DELETE FROM $tableName WHERE $where"; } /** @@ -228,7 +282,7 @@ class Query */ public static function deleteById(string $tableName): string { - return "DELETE FROM $tableName WHERE id = $1"; + return self::deleteQuery($tableName, self::whereById('$1')); } /** @@ -239,7 +293,7 @@ class Query */ public static function deleteByContains(string $tableName): string { - return "DELETE FROM $tableName WHERE " . self::whereDataContains('$1'); + return self::deleteQuery($tableName, self::whereDataContains('$1')); } /** @@ -250,6 +304,6 @@ class Query */ public static function deleteByJsonPath(string $tableName): string { - return "DELETE FROM $tableName WHERE " . self::whereJsonPathMatches('$1'); + return self::deleteQuery($tableName, self::whereJsonPathMatches('$1')); } }