From 7421f9c78828eefd25996dac0950b7a63df1b321 Mon Sep 17 00:00:00 2001 From: "Daniel J. Summers" Date: Sat, 26 Aug 2023 17:18:05 -0400 Subject: [PATCH] Much work on queries --- src/app/Data.php | 14 ++--- src/app/documents/Configuration.php | 23 +------- src/app/documents/Definition.php | 4 +- src/app/documents/Document.php | 83 +++++++++++++---------------- src/app/documents/Query.php | 38 ++++++------- src/app/documents/functions.php | 11 ---- src/app/index.php | 8 +-- 7 files changed, 66 insertions(+), 115 deletions(-) diff --git a/src/app/Data.php b/src/app/Data.php index dfcb6f1..9bdfc3b 100644 --- a/src/app/Data.php +++ b/src/app/Data.php @@ -17,7 +17,7 @@ class Data public static function configure() { Configuration::$connectionString = 'pgsql:host=localhost;port=5432;dbname=leafjson;user=leaf;password=leaf'; - //Configuration::$startUp = '\MyPrayerJournal\Data::startUp'; + Configuration::$startUp = '\MyPrayerJournal\Data::startUp'; } /** @@ -103,12 +103,12 @@ class Data */ private static function getJournalByAnswered(string $userId, string $op): array { - $sql = Query::selectFromTable(self::REQ_TABLE) - . ' WHERE ' . Query::whereDataContains('$1') . ' AND ' . Query::whereJsonPathMatches('$2'); - $params = [ - Query::jsonbDocParam([ 'userId' => $userId ]), - '$.history[*].action (@ ' . $op . ' "' . RequestAction::Answered->name . '")' - ]; + $isAnswered = str_replace(':path', + "'$.history[*].action ? (@ $op \"" . RequestAction::Answered->name . "\")'", + Query::whereJsonPathMatches(':path')); + $sql = sprintf("%s WHERE %s AND $isAnswered", Query::selectFromTable(self::REQ_TABLE), + Query::whereDataContains(':criteria')); + $params = [ ':criteria' => Query::jsonbDocParam([ 'userId' => $userId ]) ]; return self::mapToJournalRequest( Document::customList($sql, $params, Request::class, Document::mapFromJson(...)), true); } diff --git a/src/app/documents/Configuration.php b/src/app/documents/Configuration.php index c90786e..2aaa2f0 100644 --- a/src/app/documents/Configuration.php +++ b/src/app/documents/Configuration.php @@ -3,8 +3,6 @@ declare(strict_types=1); namespace BitBadger\PgSQL\Documents; -use \PgSql\Connection; - /** * Document table configuration */ @@ -16,9 +14,6 @@ class Configuration /** @var ?\PDO $conn The active connection */ private static ?\PDO $conn = null; - /** @var ?Connection $rawConn An active non-PDO PostgreSQL connection */ - private static ?Connection $rawConn = null; - /** @var ?string $startUp The name of a function to run on first connection to the database */ public static ?string $startUp = null; @@ -40,7 +35,7 @@ class Configuration /** * Get the database connection, connecting on first request * - * @return PDO The PDO object representing the connection + * @return \PDO The PDO object representing the connection */ public static function getConn(): \PDO { @@ -54,22 +49,6 @@ class Configuration } return self::$conn; } - - /** - * - */ - public static function getRawConn(): Connection - { - if (is_null(self::$rawConn)) { - self::ensureConnectionString(); - self::$rawConn = pg_connect(str_replace(';', ' ', self::$connectionString)); - - if (!is_null(self::$startUp)) { - call_user_func(self::$startUp); - } - } - return self::$rawConn; - } } require('functions.php'); diff --git a/src/app/documents/Definition.php b/src/app/documents/Definition.php index aa6a41a..a9ece6d 100644 --- a/src/app/documents/Definition.php +++ b/src/app/documents/Definition.php @@ -28,8 +28,8 @@ class Definition */ public static function createIndex(string $name, DocumentIndex $type): string { - $extraOps = $type == DocumentIndex::Full ? "" : " jsonb_path_ops"; - $schemaAndTable = explode(".", $name); + $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)"; } diff --git a/src/app/documents/Document.php b/src/app/documents/Document.php index 55df2cb..f402980 100644 --- a/src/app/documents/Document.php +++ b/src/app/documents/Document.php @@ -4,7 +4,6 @@ declare(strict_types=1); namespace BitBadger\PgSQL\Documents; use PDOStatement; -use PgSql\Result; /** Document manipulation functions */ class Document @@ -12,6 +11,9 @@ class Document /** JSON Mapper instance to use for creating a domain type instance from a document */ private static ?\JsonMapper $mapper = null; + /** Attribute that prevents PDO from attempting its own PREPARE on a query */ + private const NO_PREPARE = [ \PDO::ATTR_EMULATE_PREPARES => false ]; + /** * Map a domain type from the JSON document retrieved * @@ -52,9 +54,9 @@ class Document */ private static function executeNonQuery(string $query, string $docId, array|object $document) { - $nonQuery = pdo()->prepare($query); - $nonQuery->bindParam('@id', $docId); - $nonQuery->bindParam('@data', Query::jsonbDocParam($document)); + $nonQuery = pdo()->prepare($query, self::NO_PREPARE); + $nonQuery->bindParam(':id', $docId); + $nonQuery->bindParam(':data', Query::jsonbDocParam($document)); $nonQuery->execute(); } @@ -103,8 +105,8 @@ class Document */ public static function countByContains(string $tableName, array|object $criteria): int { - $query = pdo()->prepare(Query::countByContains($tableName)); - $query->bindParam('@criteria', Query::jsonbDocParam($criteria)); + $query = pdo()->prepare(Query::countByContains($tableName), self::NO_PREPARE); + $query->bindParam(':criteria', Query::jsonbDocParam($criteria)); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); return intval($result['it']); @@ -119,8 +121,8 @@ class Document */ public static function countByJsonPath(string $tableName, string $jsonPath): int { - $query = pdo()->prepare(Query::countByContains($tableName)); - $query->bindParam('@path', $jsonPath); + $query = pdo()->prepare(Query::countByContains($tableName), self::NO_PREPARE); + $query->bindParam(':path', $jsonPath); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); return intval($result['it']); @@ -135,8 +137,8 @@ class Document */ public static function existsById(string $tableName, string $docId): bool { - $query = pdo()->prepare(Query::existsById($tableName)); - $query->bindParam('@id', $docId); + $query = pdo()->prepare(Query::existsById($tableName), self::NO_PREPARE); + $query->bindParam(':id', $docId); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); return boolval($result['it']); @@ -151,8 +153,8 @@ class Document */ public static function existsByContains(string $tableName, array|object $criteria): bool { - $query = pdo()->prepare(Query::existsByContains($tableName)); - $query->bindParam('@criteria', Query::jsonbDocParam($criteria)); + $query = pdo()->prepare(Query::existsByContains($tableName), self::NO_PREPARE); + $query->bindParam(':criteria', Query::jsonbDocParam($criteria)); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); return boolval($result['it']); @@ -167,8 +169,8 @@ class Document */ public static function existsByJsonPath(string $tableName, string $jsonPath): bool { - $query = pdo()->prepare(Query::existsByJsonPath($tableName)); - $query->bindParam('@path', $jsonPath); + $query = pdo()->prepare(Query::existsByJsonPath($tableName), self::NO_PREPARE); + $query->bindParam(':path', $jsonPath); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); return boolval($result['it']); @@ -208,7 +210,7 @@ class Document */ public static function findById(string $tableName, string $docId, string $className): mixed { - $query = pdo()->prepare(Query::findById($tableName)); + $query = pdo()->prepare(Query::findById($tableName), self::NO_PREPARE); $query->bindParam(':id', $docId); $query->execute(); $result = $query->fetch(\PDO::FETCH_ASSOC); @@ -224,8 +226,8 @@ class Document */ private static function queryByContains(string $tableName, array|object $criteria): \PDOStatement { - $query = pdo()->prepare(Query::findByContains($tableName)); - $query->bindParam('@criteria', Query::jsonbDocParam($criteria)); + $query = pdo()->prepare(Query::findByContains($tableName), self::NO_PREPARE); + $query->bindParam(':criteria', Query::jsonbDocParam($criteria)); $query->execute(); return $query; } @@ -267,8 +269,8 @@ class Document */ private static function queryByJsonPath(string $tableName, string $jsonPath): \PDOStatement { - $query = pdo()->prepare(Query::findByJsonPath($tableName)); - $query->bindParam('@path', $jsonPath); + $query = pdo()->prepare(Query::findByJsonPath($tableName), self::NO_PREPARE); + $query->bindParam(':path', $jsonPath); $query->execute(); return $query; } @@ -334,9 +336,9 @@ class Document */ public static function updatePartialByContains(string $tableName, array|object $criteria, array|object $document) { - $query = pdo()->prepare(Query::updatePartialByContains($tableName)); - $query->bindParam('@data', Query::jsonbDocParam($document)); - $query->bindParam('@criteria', Query::jsonbDocParam($criteria)); + $query = pdo()->prepare(Query::updatePartialByContains($tableName), self::NO_PREPARE); + $query->bindParam(':data', Query::jsonbDocParam($document)); + $query->bindParam(':criteria', Query::jsonbDocParam($criteria)); $query->execute(); } @@ -349,9 +351,9 @@ class Document */ public static function updatePartialByJsonPath(string $tableName, string $jsonPath, array|object $document) { - $query = pdo()->prepare(Query::updatePartialByContains($tableName)); - $query->bindParam('@data', Query::jsonbDocParam($document)); - $query->bindParam('@path', $jsonPath); + $query = pdo()->prepare(Query::updatePartialByContains($tableName), self::NO_PREPARE); + $query->bindParam(':data', Query::jsonbDocParam($document)); + $query->bindParam(':path', $jsonPath); $query->execute(); } @@ -374,8 +376,8 @@ class Document */ public static function deleteByContains(string $tableName, array|object $criteria) { - $query = pdo()->prepare(Query::deleteByContains($tableName)); - $query->bindParam('@criteria', Query::jsonbDocParam($criteria)); + $query = pdo()->prepare(Query::deleteByContains($tableName), self::NO_PREPARE); + $query->bindParam(':criteria', Query::jsonbDocParam($criteria)); $query->execute(); } @@ -387,8 +389,8 @@ class Document */ public static function deleteByJsonPath(string $tableName, string $jsonPath) { - $query = pdo()->prepare(Query::deleteByJsonPath($tableName)); - $query->bindParam('@path', $jsonPath); + $query = pdo()->prepare(Query::deleteByJsonPath($tableName), self::NO_PREPARE); + $query->bindParam(':path', $jsonPath); $query->execute(); } @@ -403,16 +405,8 @@ class Document */ private static function createCustomQuery(string $sql, array $params): PDOStatement { - $result = pg_query_params(pgconn(), $sql, $params); - echo "Preparing statement for $sql\n"; - foreach ($params as $name => $value) { - echo "Binding $name to $value\n"; - } - $query = pdo()->prepare($sql); - foreach ($params as $name => $value) { - echo "Binding $name to $value\n"; - $query->bindParam($name, $value); - } + $query = pdo()->prepare($sql, self::NO_PREPARE); + array_walk($params, fn ($value, $name) => $query->bindParam($name, $value)); $query->execute(); return $query; } @@ -428,14 +422,9 @@ class Document */ public static function customList(string $sql, array $params, string $className, callable $mapFunc): array { - $data = pg_query_params(pgconn(), $sql, $params); - $result = []; - if (!$data) return $result; - while ($row = pg_fetch_array($data, mode: PGSQL_ASSOC)) { - array_push($result, $mapFunc($row, $className)); - } - pg_free_result($data); - return $result; + return array_map( + fn ($it) => $mapFunc($it, $className), + Document::createCustomQuery($sql, $params)->fetchAll(\PDO::FETCH_ASSOC)); } /** diff --git a/src/app/documents/Query.php b/src/app/documents/Query.php index 0d6939e..7ec3814 100644 --- a/src/app/documents/Query.php +++ b/src/app/documents/Query.php @@ -25,7 +25,7 @@ class Query */ public static function whereDataContains(string $paramName): string { - return "data @> $paramName"; + return "data @> $paramName::jsonb"; } /** @@ -36,7 +36,7 @@ class Query */ public static function whereJsonPathMatches(string $paramName): string { - return "data @? {$paramName}::jsonpath"; + return "data @?? {$paramName}::jsonpath"; } /** @@ -62,7 +62,7 @@ class Query */ public static function insert(string $tableName): string { - return "INSERT INTO $tableName (id, data) VALUES (@id, @data)"; + return "INSERT INTO $tableName (id, data) VALUES (:id, :data)"; } /** @@ -73,7 +73,7 @@ class Query */ public static function save(string $tableName): string { - return "INSERT INTO $tableName (id, data) VALUES (@id, @data) + return "INSERT INTO $tableName (id, data) VALUES (:id, :data) ON CONFLICT (id) DO UPDATE SET data = EXCLUDED.data"; } @@ -96,7 +96,7 @@ class Query */ public static function countByContains(string $tableName): string { - return "SELECT COUNT(*) AS it FROM $tableName WHERE " . self::whereDataContains('@criteria'); + return sprintf("SELECT COUNT(*) AS it FROM $tableName WHERE %s", self::whereDataContains(':criteria')); } /** @@ -107,7 +107,7 @@ class Query */ public static function countByJsonPath(string $tableName): string { - return "SELECT COUNT(*) AS it FROM $tableName WHERE " . self::whereJsonPathMatches('@path'); + return sprintf("SELECT COUNT(*) AS it FROM $tableName WHERE %s", self::whereJsonPathMatches(':path')); } /** @@ -118,7 +118,7 @@ class Query */ public static function existsById(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE id = @id) AS it"; + return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE id = :id) AS it"; } /** @@ -129,7 +129,7 @@ class Query */ public static function existsByContains(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE " . self::whereDataContains('@criteria') . ' AS it'; + return sprintf("SELECT EXISTS (SELECT 1 FROM $tableName WHERE %s AS it", self::whereDataContains(':criteria')); } /** @@ -140,7 +140,7 @@ class Query */ public static function existsByJsonPath(string $tableName): string { - return "SELECT EXISTS (SELECT 1 FROM $tableName WHERE " . self::whereJsonPathMatches('@path') . ' AS it'; + return sprintf("SELECT EXISTS (SELECT 1 FROM $tableName WHERE %s AS it", self::whereJsonPathMatches(':path')); } /** @@ -151,7 +151,7 @@ class Query */ public static function findById(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE id = :id'; + return sprintf('%s WHERE id = :id', self::selectFromTable($tableName)); } /** @@ -162,7 +162,7 @@ class Query */ public static function findByContains(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE ' . self::whereDataContains('@criteria'); + return sprintf('%s WHERE %s', self::selectFromTable($tableName), self::whereDataContains(':criteria')); } /** @@ -173,7 +173,7 @@ class Query */ public static function findByJsonPath(string $tableName): string { - return self::selectFromTable($tableName) . ' WHERE ' . self::whereJsonPathMatches('@path'); + return sprintf('%s WHERE %s', self::selectFromTable($tableName), self::whereJsonPathMatches(':path')); } /** @@ -184,7 +184,7 @@ class Query */ public static function updateFull(string $tableName): string { - return "UPDATE $tableName SET data = @data WHERE id = @id"; + return "UPDATE $tableName SET data = :data WHERE id = :id"; } /** @@ -195,7 +195,7 @@ class Query */ public static function updatePartialById(string $tableName): string { - return "UPDATE $tableName SET data = data || @data WHERE id = @id"; + return "UPDATE $tableName SET data = data || :data WHERE id = :id"; } /** @@ -206,7 +206,7 @@ class Query */ public static function updatePartialByContains(string $tableName): string { - return "UPDATE $tableName SET data = data || @data WHERE " . self::whereDataContains('@criteria'); + return sprintf("UPDATE $tableName SET data = data || :data WHERE %s", self::whereDataContains(':criteria')); } /** @@ -217,7 +217,7 @@ class Query */ public static function updatePartialByJsonPath(string $tableName): string { - return "UPDATE $tableName SET data = data || @data WHERE " . self::whereJsonPathMatches('@path'); + return sprintf("UPDATE $tableName SET data = data || :data WHERE %s", self::whereJsonPathMatches(':path')); } /** @@ -228,7 +228,7 @@ class Query */ public static function deleteById(string $tableName): string { - return "DELETE FROM $tableName WHERE id = @id"; + return "DELETE FROM $tableName WHERE id = :id"; } /** @@ -239,7 +239,7 @@ class Query */ public static function deleteByContains(string $tableName): string { - return "DELETE FROM $tableName WHERE " . self::whereDataContains('@criteria'); + return sprintf("DELETE FROM $tableName WHERE %s", self::whereDataContains(':criteria')); } /** @@ -250,6 +250,6 @@ class Query */ public static function deleteByJsonPath(string $tableName): string { - return "DELETE FROM $tableName WHERE " . self::whereJsonPathMatches('@path'); + return sprintf("DELETE FROM $tableName WHERE %s", self::whereJsonPathMatches(':path')); } } diff --git a/src/app/documents/functions.php b/src/app/documents/functions.php index 5a93afd..a302a0f 100644 --- a/src/app/documents/functions.php +++ b/src/app/documents/functions.php @@ -13,14 +13,3 @@ if (!function_exists('pdo')) { return Configuration::getConn(); } } -if (!function_exists('pgconn')) { - /** - * Return the active PostgreSQL connection - * - * @return \PgSql\Connection The open PostgreSQL connection - */ - function pgconn() - { - return Configuration::getRawConn(); - } -} diff --git a/src/app/index.php b/src/app/index.php index e30b6d7..cb810a6 100644 --- a/src/app/index.php +++ b/src/app/index.php @@ -5,10 +5,6 @@ require __DIR__ . '/vendor/autoload.php'; use MyPrayerJournal\Data; Data::configure(); -//Data::findFullRequestById('abc', 'def'); -//echo "Returned from req\n"; - -//Data::getAnsweredRequests('abc'); app()->template->config('path', './pages'); app()->template->config('params', [ @@ -37,10 +33,8 @@ function renderPage(string $template, array $params, string $pageTitle) response()->markup(app()->template->render('layout/full', $params)); } -Data::getAnsweredRequests('abc'); app()->get('/', function () { - phpinfo(); - //renderPage('home', [], 'Welcome'); + renderPage('home', [], 'Welcome'); }); app()->get('/legal/privacy-policy', function () {