From 79cba15dbac896544572259035dc56d961fe4fcc Mon Sep 17 00:00:00 2001 From: Jan Skrasek Date: Thu, 14 Mar 2024 14:55:12 +0100 Subject: [PATCH 1/2] make atLeast/atMost optional boundaries for CountAggregator --- .../Aggregations/CountAggregator.php | 79 ++++++++++++------- .../collection.aggregation.join.phpt | 24 +++++- ...ggregationJoinTest_testCountAggregator.sql | 4 + 3 files changed, 75 insertions(+), 32 deletions(-) create mode 100644 tests/sqls/NextrasTests/Orm/Integration/Collection/CollectionAggregationJoinTest_testCountAggregator.sql diff --git a/src/Collection/Aggregations/CountAggregator.php b/src/Collection/Aggregations/CountAggregator.php index 2190b4fe..5495d31b 100644 --- a/src/Collection/Aggregations/CountAggregator.php +++ b/src/Collection/Aggregations/CountAggregator.php @@ -9,6 +9,7 @@ use Nextras\Orm\Collection\Functions\Result\DbalTableJoin; use Nextras\Orm\Exception\InvalidArgumentException; use function array_filter; +use function array_merge; use function array_pop; use function count; @@ -18,26 +19,18 @@ */ class CountAggregator implements Aggregator { - private int $atLeast; - - private int $atMost; - - /** @var literal-string */ - private string $aggregateKey; - - /** * @param literal-string $aggregateKey */ public function __construct( - int $atLeast, - int $atMost, - string $aggregateKey = 'count', + private readonly ?int $atLeast, + private readonly ?int $atMost, + private readonly string $aggregateKey = 'count', ) { - $this->atLeast = $atLeast; - $this->atMost = $atMost; - $this->aggregateKey = $aggregateKey; + if ($this->atLeast === null && $this->atMost === null) { + throw new InvalidArgumentException("At least one of the limitations (\$atLeast or \$atMost) is required."); + } } @@ -50,7 +43,9 @@ public function getAggregateKey(): string public function aggregateValues(array $values): bool { $count = count(array_filter($values)); - return $count >= $this->atLeast && $count <= $this->atMost; + if ($this->atLeast !== null && $count >= $this->atLeast) return true; + if ($this->atMost !== null && $count <= $this->atMost) return true; + return false; } @@ -85,19 +80,45 @@ public function aggregateExpression( groupByColumns: $join->groupByColumns, ); - return new DbalExpressionResult( - expression: 'COUNT(%table.%column) >= %i AND COUNT(%table.%column) <= %i', - args: [ - $join->toAlias, - $join->groupByColumns[0], - $this->atLeast, - $join->toAlias, - $join->groupByColumns[0], - $this->atMost, - ], - joins: $joins, - groupBy: $expression->groupBy, - isHavingClause: true, - ); + if ($this->atLeast !== null && $this->atMost !== null) { + return new DbalExpressionResult( + expression: 'COUNT(%table.%column) >= %i AND COUNT(%table.%column) <= %i', + args: [ + $join->toAlias, + $join->groupByColumns[0], + $this->atLeast, + $join->toAlias, + $join->groupByColumns[0], + $this->atMost, + ], + joins: $joins, + groupBy: $expression->groupBy, + isHavingClause: true, + ); + } elseif ($this->atMost !== null) { + return new DbalExpressionResult( + expression: 'COUNT(%table.%column) <= %i', + args: [ + $join->toAlias, + $join->groupByColumns[0], + $this->atMost, + ], + joins: $joins, + groupBy: $expression->groupBy, + isHavingClause: true, + ); + } else { + return new DbalExpressionResult( + expression: 'COUNT(%table.%column) >= %i', + args: [ + $join->toAlias, + $join->groupByColumns[0], + $this->atLeast, + ], + joins: $joins, + groupBy: $expression->groupBy, + isHavingClause: true, + ); + } } } diff --git a/tests/cases/integration/Collection/collection.aggregation.join.phpt b/tests/cases/integration/Collection/collection.aggregation.join.phpt index d383f2ab..8027793b 100644 --- a/tests/cases/integration/Collection/collection.aggregation.join.phpt +++ b/tests/cases/integration/Collection/collection.aggregation.join.phpt @@ -61,7 +61,6 @@ class CollectionAggregationJoinTest extends DataTestCase 'books->title' => 'Book 1', 'books->translator->id' => null, ]); - $authors->fetchAll(); Assert::same(0, $authors->count()); Assert::same(0, $authors->countStored()); @@ -74,16 +73,35 @@ class CollectionAggregationJoinTest extends DataTestCase */ $authors = $this->orm->authors->findBy([ ICollection::OR, - new CountAggregator(1, 1), + new CountAggregator(atLeast: 1, atMost: 1), 'books->translator->id!=' => null, 'books->price->cents<' => 100, ]); - $authors->fetchAll(); Assert::same(1, $authors->count()); Assert::same(1, $authors->countStored()); } + public function testCountAggregator(): void + { + $authors = $this->orm->authors->findBy([ + ICollection::AND, + new CountAggregator(atLeast: 2, atMost: null), + 'books->price->cents>=' => 50, + ]); + Assert::same(1, $authors->count()); + Assert::same(1, $authors->countStored()); + + $authors = $this->orm->authors->findBy([ + ICollection::AND, + new CountAggregator(atLeast: null, atMost: 1), + 'books->price->cents>=' => 51, + ]); + Assert::same(2, $authors->count()); + Assert::same(2, $authors->countStored()); + } + + public function testHasValueOrEmptyWithFunctions(): void { /* diff --git a/tests/sqls/NextrasTests/Orm/Integration/Collection/CollectionAggregationJoinTest_testCountAggregator.sql b/tests/sqls/NextrasTests/Orm/Integration/Collection/CollectionAggregationJoinTest_testCountAggregator.sql new file mode 100644 index 00000000..a651421c --- /dev/null +++ b/tests/sqls/NextrasTests/Orm/Integration/Collection/CollectionAggregationJoinTest_testCountAggregator.sql @@ -0,0 +1,4 @@ +SELECT "authors".* FROM "public"."authors" AS "authors" LEFT JOIN "books" AS "books_count" ON (("authors"."id" = "books_count"."author_id") AND "books_count"."price" >= 50) GROUP BY "authors"."id" HAVING ((COUNT("books_count"."id") >= 2)); +SELECT COUNT(*) AS count FROM (SELECT "authors"."id" FROM "public"."authors" AS "authors" LEFT JOIN "books" AS "books_count" ON (("authors"."id" = "books_count"."author_id") AND "books_count"."price" >= 50) GROUP BY "authors"."id" HAVING ((COUNT("books_count"."id") >= 2))) temp; +SELECT "authors".* FROM "public"."authors" AS "authors" LEFT JOIN "books" AS "books_count" ON (("authors"."id" = "books_count"."author_id") AND "books_count"."price" >= 51) GROUP BY "authors"."id" HAVING ((COUNT("books_count"."id") <= 1)); +SELECT COUNT(*) AS count FROM (SELECT "authors"."id" FROM "public"."authors" AS "authors" LEFT JOIN "books" AS "books_count" ON (("authors"."id" = "books_count"."author_id") AND "books_count"."price" >= 51) GROUP BY "authors"."id" HAVING ((COUNT("books_count"."id") <= 1))) temp; From 844a3cffb191574a1d3889d88587ec1d74e08d99 Mon Sep 17 00:00:00 2001 From: Jan Skrasek Date: Thu, 14 Mar 2024 14:32:49 +0100 Subject: [PATCH 2/2] docs: document relationship aggregation [skip ci] [refs #532] --- docs/collection-filtering.md | 89 ++++++++++++++++++++++++++++++------ docs/default.md | 2 +- 2 files changed, 76 insertions(+), 15 deletions(-) diff --git a/docs/collection-filtering.md b/docs/collection-filtering.md index 84d97dcf..da71e41e 100644 --- a/docs/collection-filtering.md +++ b/docs/collection-filtering.md @@ -26,7 +26,7 @@ $orm->books->findBy(['translator->name!=' => 'Jon Snow']); The described syntax may be expanded to support a `OR` logical conjunction. Prepend the `ICollection::OR` operator as a first value of the filtering array: ```php -// finds all books which were authored or translated by one specific person +// finds all books that were authored or translated by one specific person $books = $orm->books->findBy([ ICollection::OR, 'author->name' => 'Jon Snow', @@ -39,7 +39,7 @@ This relationship filtering is designed mainly for has-one relationship. Has-man You may nest the filtering structure; use the same syntax repeatedly: ```php -// find all man older than 10 years and woman younger than 12 years +// find all men older than 10 years and woman younger than 12 years $authors = $orm->author->findBy([ ICollection::OR, [ @@ -58,7 +58,7 @@ $authors = $orm->author->findBy([ The previous example can be shortened because the `AND` operator is the default logical operator. ```php -// find all man older than 10 years and woman younger than 12 years +// find all men older than 10 years and woman younger than 12 years $authors = $orm->author->findBy([ ICollection::OR, [ @@ -83,22 +83,83 @@ Filtering over virtual properties is generally unsupported and provides undefine ```php // finds all users with email hosted on gmail.com -$users->findBy([ - 'emails~' => LikeExpression::endsWith('@gmail.com'), +$authors = $orm->authors->findBy([ + 'email~' => LikeExpression::endsWith('@gmail.com'), ]); ``` -#### Aggregation +#### Relationship Aggregation + +The collection filtering by a relationship was already mentioned earlier. We have described the simple relationship case where the base collection is filtered by a *HasOne relationship. But this may get more complicated with the *HasMany relationships. To do so, we need to aggregate the relationship by using a new instance of the wanted aggregator. Orm comes with these three aggregators: + +- `AnyAggregator`, +- `NoneAggregator`. +- `CountAggregator`, + +The `AnyAggregator` is implicit; whenever you put filter over *hasMany relationship, the filter uses "any" aggregation. To set an aggregator, pass it as a first argument of the filtering expression, but this time, the collection function name is required. The following example looks for authors who have *ANY* book with price > €10. + +```php +use Nextras\Orm\Collection\Aggregations\AnyAggregator; +use Nextras\Orm\Collection\Aggregations\CountAggregator; +use Nextras\Orm\Collection\ICollection; + +$authors = $orm->authors->findBy([ + 'books->price>' => 10, + 'books->currency' => 'eur', +]); + +// same as + +$authors = $orm->authors->findBy([ + ICollection::AND, + new AnyAggregator(), + 'books->price>' => 10, + 'books->currency' => 'eur', +]); +``` + +Swap with `NoneAggregator` to find authors who do not have any book with price > €10. With `CountAggregator` you may limit the number of required aggregated matches. Let's find all authors who have at least two books with price > €10. + +```php +$authors = $orm->authors->findBy([ + ICollection::AND, + new CountAggregator(atLeast: 2, atMost: null), + 'books->price>' => 10, + 'books->currency' => 'eur', +]); +``` + +Aggregators accept an optional to *grouping key* to allow differentiating the joins. So the following example finds those authors who authored `Book 1` with price `€50` AND `Book 2` with price `€150`. + +```php +$authors = $orm->authors->findBy([ + ICollection::AND, + [ + new AnyAggregator('any1'), + 'books->title' => 'Book 1', + 'books->price' => 50, + ], + [ + new AnyAggregator('any2'), + 'books->title' => 'Book 2', + 'books->price' => 150, + ], +]); +``` + +If those aggregations were not separated, then none of the entries would match because the book's title could not be `Book 1` and `Book 2` at the same time. + +#### Property Aggregation Aggregation functions can be used for both collection filtering and sorting. They are based on [collection functions | collection-functions] -- a general approach for custom collection modification. Orm brings these prepared aggregation functions: -- CountAggregateFunction -- SumAggregateFunction -- AvgAggregateFunction -- MinAggregateFunction -- MaxAggregateFunction +- `CountAggregateFunction` +- `SumAggregateFunction` +- `AvgAggregateFunction` +- `MinAggregateFunction` +- `MaxAggregateFunction` All those functions are implemented both for Dbal and Array collections, and they are registered in a repository as commonly provided collection functions. @@ -112,7 +173,7 @@ $authorsCollection->orderBy( ); ``` -In the example we sort the collection of authors by the count of their books, i.e. authors with the least books will be at the beginning. The example allows the same "property expression" you use for filtering. You can reverse the ordering: +In the example, we sort the collection of authors by the count of their books, i.e., authors with the fewest books will be at the beginning. The example allows the same "property expression" you use for filtering. You can reverse the ordering: ```php use Nextras\Orm\Collection\Functions\CountAggregateFunction; @@ -124,7 +185,7 @@ $authorsCollection->orderBy( ); ``` -Filtering by an aggregation requires a little more. Let's filter the collection by authors who have written more than 2 books. Using `CountAggregationFunction` itself won’t be enough. You need to compare its result with the wanted number, `2` this time. To do so, use built-in `Compare*Function`. Choose function depending on the wanted operator. The function takes a property expression on the left, and a value to compare (on the right). +Filtering by an aggregation requires a little more. Let's filter the collection by authors who have written more than two books. Using `CountAggregationFunction` itself won’t be enough. You need to compare its result with the wanted number, `2` this time. To do so, use built-in `Compare*Function`. Choose function depending on the wanted operator. The function takes a property expression on the left, and a value to compare (on the right). ```php use Nextras\Orm\Collection\Functions\CompareGreaterThanFunction; @@ -143,7 +204,7 @@ $authorsCollection->findBy( ); ``` -You can nest these function calls together. This approach is very powerful and flexible, though, sometimes quite verbose. To ease this issue you may create your own wrappers (not included in Orm!). +You can nest these function calls together. This approach is very powerful and flexible, though, sometimes quite verbose. To ease this issue, you may create your own wrappers (not included in Orm!). ```php class Aggregate { diff --git a/docs/default.md b/docs/default.md index 229b4c8f..79a09866 100644 --- a/docs/default.md +++ b/docs/default.md @@ -38,7 +38,7 @@ Let's create some new entities $author = new Author(); $author->name = 'Jon Snow'; $author->born = 'yesterday'; -$author->mail = 'snow@wall.st'; +$author->email = 'snow@wall.st'; $publisher = new Publisher(); $publisher->name = '7K publisher';