From e4da4b3a78e933c93f85443aecb3086031afd76c Mon Sep 17 00:00:00 2001 From: Your Name Date: Thu, 20 Nov 2025 15:04:27 +0300 Subject: [PATCH] Add JSON aggregate support for HasMany references Features: - JSON aggregate fields for HasMany references with 'aggregate' => 'json' - Multiple expression types: strings, callables, Expressionable objects - Dot notation for join field references (e.g., 'person.first_name') - Custom field output names in aggregates - Support for nested joins in JSON aggregates - Database-specific implementations for all supported engines Database support: - MySQL: JSON_ARRAYAGG, json_object (5.7.8+) - SQLite: json_group_array, json_object - PostgreSQL: json_agg, json_build_object - Oracle: JSON_ARRAYAGG, json_object - MSSQL: json_array, json_object API: ```php $ref = $movie->hasMany('reviews', ['model' => [Review::class]]); $ref->addField('reviews_json', [ 'aggregate' => 'json', 'fields' => [ 'rating', 'comment', 'reviewer' ], ]); ``` --- composer.json | 2 +- src/Model/Join.php | 9 ++ src/Persistence/Sql/Mssql/Query.php | 20 ++++ src/Persistence/Sql/Mysql/Query.php | 27 +++++ src/Persistence/Sql/Oracle/Query.php | 19 +++ src/Persistence/Sql/Postgresql/Query.php | 19 +++ src/Persistence/Sql/Query.php | 3 + src/Persistence/Sql/Sqlite/Query.php | 20 ++++ src/Reference/HasMany.php | 86 ++++++++++++++ tests/ReferenceSqlTest.php | 140 +++++++++++++++++++++++ 10 files changed, 344 insertions(+), 1 deletion(-) diff --git a/composer.json b/composer.json index e370ced688..aa2b1c25e0 100644 --- a/composer.json +++ b/composer.json @@ -16,7 +16,7 @@ "oracle", "postgresql" ], - "version": "dev-develop", + "version": "6.0.x-dev", "authors": [ { "name": "Romans Malinovskis", diff --git a/src/Model/Join.php b/src/Model/Join.php index de64424a0b..b435e9888c 100644 --- a/src/Model/Join.php +++ b/src/Model/Join.php @@ -110,6 +110,15 @@ public function __construct(string $foreignTable) } } + /** + * Used internally for JSON aggregate field resolution with dot notation + * We need this to prevent using slow ReflectionClass. + */ + public function getForeignTable(): string + { + return $this->foreignTable; + } + /** * @internal should be not used outside atk4/data, for Migrator only */ diff --git a/src/Persistence/Sql/Mssql/Query.php b/src/Persistence/Sql/Mssql/Query.php index ba3d62866c..b4c7578e7f 100644 --- a/src/Persistence/Sql/Mssql/Query.php +++ b/src/Persistence/Sql/Mssql/Query.php @@ -6,6 +6,7 @@ use Atk4\Data\Exception; use Atk4\Data\Field; +use Atk4\Data\Persistence\Sql\Expression as BaseExpression; use Atk4\Data\Persistence\Sql\Expressionable; use Atk4\Data\Persistence\Sql\Query as BaseQuery; use Atk4\Data\Persistence\Sql\RawExpression; @@ -263,6 +264,25 @@ public function jsonTable(Expressionable $json, array $columns, string $rowsPath return $query; } + /** + * @param array $keyValuePairs + */ + public function fxJsonObject(array $keyValuePairs): BaseExpression + { + $parts = []; + foreach ($keyValuePairs as $key => $value) { + $parts[] = new RawExpression($this->escapeStringLiteral($key)); + $parts[] = $value; + } + + return $this->expr('json_object(' . implode(', ', array_fill(0, count($parts), '[]')) . ')', $parts); + } + + public function jsonArrayAgg(Expressionable $expr): BaseExpression + { + return $this->expr('json_array([])', [$expr]); + } + #[\Override] public function exists() { diff --git a/src/Persistence/Sql/Mysql/Query.php b/src/Persistence/Sql/Mysql/Query.php index 6d31c44ce5..1c1958382b 100644 --- a/src/Persistence/Sql/Mysql/Query.php +++ b/src/Persistence/Sql/Mysql/Query.php @@ -87,6 +87,33 @@ public function fxJsonArray(array $values) ]); } + /** + * @param array $keyValuePairs + */ + public function fxJsonObject(array $keyValuePairs): BaseExpression + { + if (!Connection::isServerMariaDb($this->connection) && version_compare($this->connection->getServerVersion(), '5.7.8') < 0) { + throw new \Exception('JSON_OBJECT requires MySQL 5.7.8+'); + } + + $parts = []; + foreach ($keyValuePairs as $key => $value) { + $parts[] = new RawExpression($this->escapeStringLiteral($key)); + $parts[] = $value; + } + + return $this->expr('json_object(' . implode(', ', array_fill(0, count($parts), '[]')) . ')', $parts); + } + + public function jsonArrayAgg(Expressionable $expr): BaseExpression + { + if (!Connection::isServerMariaDb($this->connection) && version_compare($this->connection->getServerVersion(), '5.7.8') < 0) { + throw new \Exception('JSON_ARRAYAGG requires MySQL 5.7.8+'); + } + + return $this->expr('json_arrayagg([])', [$expr]); + } + /** * @return ($forJsonValue is true ? array{string, string, string|null} : string) */ diff --git a/src/Persistence/Sql/Oracle/Query.php b/src/Persistence/Sql/Oracle/Query.php index 2ff8ac51b5..d0902822c8 100644 --- a/src/Persistence/Sql/Oracle/Query.php +++ b/src/Persistence/Sql/Oracle/Query.php @@ -311,6 +311,25 @@ public function exists() ); } + /** + * @param array $keyValuePairs + */ + public function fxJsonObject(array $keyValuePairs): BaseExpression + { + $parts = []; + foreach ($keyValuePairs as $key => $value) { + $parts[] = new RawExpression($this->escapeStringLiteral($key)); + $parts[] = $value; + } + + return $this->expr('json_object(' . implode(', ', array_fill(0, count($parts), '[]')) . ')', $parts); + } + + public function jsonArrayAgg(Expressionable $expr): BaseExpression + { + return $this->expr('json_arrayagg([])', [$expr]); + } + #[\Override] protected function _execute(?object $connection, bool $fromExecuteStatement) { diff --git a/src/Persistence/Sql/Postgresql/Query.php b/src/Persistence/Sql/Postgresql/Query.php index 3d43826ebd..ef78905c83 100644 --- a/src/Persistence/Sql/Postgresql/Query.php +++ b/src/Persistence/Sql/Postgresql/Query.php @@ -227,4 +227,23 @@ public function jsonTable(Expressionable $json, array $columns, string $rowsPath return $query; } + + /** + * @param array $keyValuePairs + */ + public function fxJsonObject(array $keyValuePairs): BaseExpression + { + $parts = []; + foreach ($keyValuePairs as $key => $value) { + $parts[] = new RawExpression($this->escapeStringLiteral($key)); + $parts[] = $value; + } + + return $this->expr('json_build_object(' . implode(', ', array_fill(0, count($parts), '[]')) . ')', $parts); + } + + public function jsonArrayAgg(Expressionable $expr): BaseExpression + { + return $this->expr('json_agg([])', [$expr]); + } } diff --git a/src/Persistence/Sql/Query.php b/src/Persistence/Sql/Query.php index 89ff499d13..63c75c2b36 100644 --- a/src/Persistence/Sql/Query.php +++ b/src/Persistence/Sql/Query.php @@ -6,6 +6,9 @@ /** * Perform query operation on SQL server (such as select, insert, delete, etc). + * + * @method Expression fxJsonObject(array $keyValuePairs) + * @method Expression jsonArrayAgg(Expressionable $expr) */ abstract class Query extends Expression { diff --git a/src/Persistence/Sql/Sqlite/Query.php b/src/Persistence/Sql/Sqlite/Query.php index f973cd2218..2a043c17f7 100644 --- a/src/Persistence/Sql/Sqlite/Query.php +++ b/src/Persistence/Sql/Sqlite/Query.php @@ -5,6 +5,7 @@ namespace Atk4\Data\Persistence\Sql\Sqlite; use Atk4\Data\Persistence\Sql\ExecuteException; +use Atk4\Data\Persistence\Sql\Expression as BaseExpression; use Atk4\Data\Persistence\Sql\Expressionable; use Atk4\Data\Persistence\Sql\Query as BaseQuery; use Atk4\Data\Persistence\Sql\RawExpression; @@ -172,6 +173,25 @@ public function fxJsonArray(array $values) ]); } + /** + * @param array $keyValuePairs + */ + public function fxJsonObject(array $keyValuePairs): BaseExpression + { + $parts = []; + foreach ($keyValuePairs as $key => $value) { + $parts[] = new RawExpression($this->escapeStringLiteral($key)); + $parts[] = $value; + } + + return $this->expr('json_object(' . implode(', ', array_fill(0, count($parts), '[]')) . ')', $parts); + } + + public function jsonArrayAgg(Expressionable $expr): BaseExpression + { + return $this->expr('json_group_array([])', [$expr]); + } + #[\Override] public function fxJsonValue(Expressionable $json, string $path, string $type, ?Expressionable $jsonRootType = null) { diff --git a/src/Reference/HasMany.php b/src/Reference/HasMany.php index 634023b2ea..67103be41e 100644 --- a/src/Reference/HasMany.php +++ b/src/Reference/HasMany.php @@ -8,6 +8,8 @@ use Atk4\Data\Exception; use Atk4\Data\Field; use Atk4\Data\Model; +use Atk4\Data\Model\Join; +use Atk4\Data\Persistence\Sql\Expressionable; use Atk4\Data\Reference; class HasMany extends Reference @@ -155,6 +157,90 @@ public function addField(string $fieldName, array $defaults = []): Field $fx = function () use ($defaults, $field) { return $this->refLink()->action('fx0', [$defaults['aggregate'], $field]); }; + } elseif ($defaults['aggregate'] === 'json') { + if (!isset($defaults['fields'])) { + throw new Exception('JSON aggregate requires "fields" parameter with array of field names'); + } + + $jsonFields = $defaults['fields']; + unset($defaults['fields']); // Remove from field defaults + + $fx = function () use ($jsonFields) { + $theirModel = $this->refLink(); + $query = $theirModel->action('select', [[]]); + + // Helper to resolve field reference with dot notation support + $resolveField = static function ($fieldRef) use ($theirModel, $query) { + if (is_string($fieldRef) && str_contains($fieldRef, '.')) { + // Dot notation: 'join.field' - resolve from join + [$joinName, $fieldName] = explode('.', $fieldRef, 2); + + // Find the join by iterating through model's joins + $join = null; + foreach ($theirModel->elements as $element) { + if ($element instanceof Join) { + if ($element->getForeignTable() === $joinName) { + $join = $element; + + break; + } + } + } + + if (!$join) { + throw (new Exception('Join not found for field reference')) + ->addMoreInfo('field', $fieldRef) + ->addMoreInfo('join', $joinName); + } + + // Get field from join's foreign table + // The field is qualified as joinAlias.fieldName in the query + $joinAlias = $join->foreignAlias ?? ('_' . $joinName); + + return $query->expr($joinAlias . '.' . $fieldName); + } + + // Regular field reference + return $theirModel->getField($fieldRef); + }; + + $jsonPairs = []; + foreach ($jsonFields as $key => $fieldSpec) { + // Determine output key name + if (is_int($key)) { + // No custom name - auto-generate from field spec + if (is_string($fieldSpec) && str_contains($fieldSpec, '.')) { + // Strip join prefix: 'person.first_name' -> 'first_name' + $jsonKey = explode('.', $fieldSpec, 2)[1]; + } else { + $jsonKey = is_string($fieldSpec) ? $fieldSpec : $key; + } + } else { + // Custom name provided + $jsonKey = $key; + } + + if (is_string($fieldSpec)) { + $jsonPairs[$jsonKey] = $resolveField($fieldSpec); + } elseif ($fieldSpec instanceof Expressionable) { + $jsonPairs[$jsonKey] = $fieldSpec; + } elseif (is_callable($fieldSpec)) { + $jsonPairs[$jsonKey] = $fieldSpec($query, $resolveField); + } elseif (is_array($fieldSpec) && isset($fieldSpec['expr'])) { + if (is_callable($fieldSpec['expr'])) { + $jsonPairs[$jsonKey] = $fieldSpec['expr']($query, $resolveField); + } else { + $resolvedArgs = array_map($resolveField, $fieldSpec['args'] ?? []); + $jsonPairs[$jsonKey] = $query->expr($fieldSpec['expr'], $resolvedArgs); + } + } + } + + $jsonObj = $query->fxJsonObject($jsonPairs); + $jsonAgg = $query->jsonArrayAgg($jsonObj); + + return $theirModel->action('field', [$jsonAgg]); + }; } else { $fx = function () use ($defaults, $field) { $args = [$defaults['aggregate'], $field]; diff --git a/tests/ReferenceSqlTest.php b/tests/ReferenceSqlTest.php index dfbb71863f..85a8bdc587 100644 --- a/tests/ReferenceSqlTest.php +++ b/tests/ReferenceSqlTest.php @@ -1032,4 +1032,144 @@ public function testHasOneReferenceType(): void $orderUserRef->addField('some_other_number', null, ['type' => 'string']); self::assertSame('string', $order->getField('some_other_number')->type); } + + public function testJsonAggregateField(): void + { + $this->setDb([ + 'author' => [ + ['id' => 1, 'name' => 'John'], + ['id' => 2, 'name' => 'Jane'], + ], + 'book' => [ + ['id' => 1, 'author_id' => 1, 'title' => 'Book 1', 'year' => 2020], + ['id' => 2, 'author_id' => 1, 'title' => 'Book 2', 'year' => 2021], + ['id' => 3, 'author_id' => 2, 'title' => 'Book 3', 'year' => 2019], + ], + ]); + + $author = new Model($this->db, ['table' => 'author']); + $author->addField('name'); + + $book = new Model($this->db, ['table' => 'book']); + $book->addField('author_id', ['type' => 'bigint']); + $book->addField('title'); + $book->addField('year', ['type' => 'integer']); + + // Model instance works when not using joins + $author->hasMany('Books', ['model' => $book]) + ->addField('books_json', [ + 'aggregate' => 'json', + 'fields' => ['id', 'title', 'year'], + 'type' => 'json', + ]); + + $john = $author->load(1); + self::assertSame([ + ['id' => 1, 'title' => 'Book 1', 'year' => 2020], + ['id' => 2, 'title' => 'Book 2', 'year' => 2021], + ], $john->get('books_json')); + + $jane = $author->load(2); + self::assertSame([ + ['id' => 3, 'title' => 'Book 3', 'year' => 2019], + ], $jane->get('books_json')); + } + + public function testJsonAggregateWithJoins(): void + { + $this->setDb([ + 'author' => [ + ['id' => 1, 'name' => 'John', 'country' => 'US'], + ['id' => 2, 'name' => 'Jane', 'country' => 'UK'], + ], + 'book' => [ + ['id' => 1, 'author_id' => 1, 'title' => 'Book 1'], + ['id' => 2, 'author_id' => 1, 'title' => 'Book 2'], + ], + ]); + + $author = new Model($this->db, ['table' => 'author']); + $author->addField('name'); + $author->addField('country'); + + // Closure allows aggregation on joined tables + $author->hasMany('Books', ['model' => static function ($persistence) { + $book = new Model($persistence, ['table' => 'book']); + $book->addField('author_id', ['type' => 'bigint']); + $book->addField('title'); + $book->join('author'); + // Json aggregation with dot notation allows skipping addField() calls for joined tables. + // Without dot notation, you must add all fields required in the aggregation, + // doing the same job twice. This is prone to errors and not low-code. + + return $book; + }]) + ->addField('books_with_author_json', [ + 'aggregate' => 'json', + 'fields' => [ + 'book_id' => 'id', // Field from book table: new_field_name => original_field_name + 'book_title' => 'title', // Field from book table + 'author.name', // Dot notation: reference joined field without addField(), shortened to 'name' + 'author.country', // Dot notation: same, shortened to 'country' + ], + 'type' => 'json', + ]); + + $john = $author->load(1); + self::assertSame([ + ['book_id' => 1, 'book_title' => 'Book 1', 'name' => 'John', 'country' => 'US'], + ['book_id' => 2, 'book_title' => 'Book 2', 'name' => 'John', 'country' => 'US'], + ], $john->get('books_with_author_json')); + } + + public function testJsonAggregateExpressionTypes(): void + { + $this->setDb([ + 'author' => [ + ['id' => 1, 'name' => 'John'], + ], + 'book' => [ + ['id' => 1, 'author_id' => 1, 'title' => 'Book A'], + ], + ]); + + $author = new Model($this->db, ['table' => 'author']); + $author->addField('name'); + + $bookModel = static function ($persistence) { + $book = new Model($persistence, ['table' => 'book']); + $book->addField('author_id', ['type' => 'bigint']); + $book->addField('title'); + $book->join('author'); + + return $book; + }; + + $author->hasMany('Books1', ['model' => $bookModel]) + ->addField('books_expr', [ + 'aggregate' => 'json', + 'fields' => ['info' => ['expr' => "CONCAT([], ' by ', [])", 'args' => ['title', 'author.name']]], + 'type' => 'json', + ]); + + $author->hasMany('Books2', ['model' => $bookModel]) + ->addField('books_callable', [ + 'aggregate' => 'json', + 'fields' => ['info' => static fn ($q, $r) => $q->fxConcat($r('title'), ' by ', $r('author.name'))], + 'type' => 'json', + ]); + + $author->hasMany('Books3', ['model' => $bookModel]) + ->addField('books_callable_array', [ + 'aggregate' => 'json', + 'fields' => ['info' => ['expr' => static fn ($q, $r) => $q->fxConcat($r('title'), ' by ', $r('author.name'))]], + 'type' => 'json', + ]); + + $author = $author->loadAny(); + + self::assertSame([['info' => 'Book A by John']], $author->get('books_expr')); + self::assertSame([['info' => 'Book A by John']], $author->get('books_callable')); + self::assertSame([['info' => 'Book A by John']], $author->get('books_callable_array')); + } }