diff --git a/src/Database/Table/GroupedSelection.php b/src/Database/Table/GroupedSelection.php index 8ef9c77f2..6b6f46147 100644 --- a/src/Database/Table/GroupedSelection.php +++ b/src/Database/Table/GroupedSelection.php @@ -96,7 +96,7 @@ public function order(string $columns, ...$params) /** * @return mixed */ - public function aggregation(string $function) + public function aggregation(string $function, string $groupFunction = null) { $aggregation = &$this->getRefTable($refPath)->aggregation[$refPath . $function . $this->sqlBuilder->getSelectQueryHash($this->getPreviousAccessedColumns())]; @@ -105,12 +105,21 @@ public function aggregation(string $function) $selection = $this->createSelectionInstance(); $selection->getSqlBuilder()->importConditions($this->getSqlBuilder()); - $selection->select($function); - $selection->select("$this->name.$this->column"); - $selection->group("$this->name.$this->column"); - foreach ($selection as $row) { - $aggregation[$row[$this->column]] = $row; + if ($groupFunction && $selection->getSqlBuilder()->importGroupConditions($this->getSqlBuilder())) { + $selection->select("$function AS aggregate, $this->name.$this->column AS groupname"); + $selection->group($selection->getSqlBuilder()->getGroup() . ", $this->name.$this->column"); + $query = "SELECT $groupFunction(aggregate) AS groupaggregate, groupname FROM (" . $selection->getSql() . ') AS aggregates GROUP BY groupname'; + foreach ($this->context->query($query, ...$selection->getSqlBuilder()->getParameters()) as $row) { + $aggregation[$row->groupname] = $row; + } + } else { + $selection->select($function); + $selection->select("$this->name.$this->column"); + $selection->group("$this->name.$this->column"); + foreach ($selection as $row) { + $aggregation[$row[$this->column]] = $row; + } } } diff --git a/src/Database/Table/Selection.php b/src/Database/Table/Selection.php index de726f85d..74463a63f 100644 --- a/src/Database/Table/Selection.php +++ b/src/Database/Table/Selection.php @@ -473,13 +473,19 @@ public function alias(string $tableChain, string $alias) * @param string $function select call in "FUNCTION(column)" format * @return mixed */ - public function aggregation(string $function) + public function aggregation(string $function, string $groupFunction = null) { $selection = $this->createSelectionInstance(); $selection->getSqlBuilder()->importConditions($this->getSqlBuilder()); - $selection->select($function); - foreach ($selection->fetch() as $val) { - return $val; + if ($groupFunction && $selection->getSqlBuilder()->importGroupConditions($this->getSqlBuilder())) { + $selection->select("$function AS aggregate"); + $query = "SELECT $groupFunction(aggregate) AS groupaggregate FROM (" . $selection->getSql() . ') AS aggregates'; + return $this->context->query($query, ...$selection->getSqlBuilder()->getParameters())->fetch()->groupaggregate; + } else { + $selection->select($function); + foreach ($selection->fetch() as $val) { + return $val; + } } } @@ -494,7 +500,7 @@ public function count(string $column = null): int $this->execute(); return count($this->data); } - return (int) $this->aggregation("COUNT($column)"); + return (int) $this->aggregation("COUNT($column)", 'SUM'); } @@ -504,7 +510,7 @@ public function count(string $column = null): int */ public function min(string $column) { - return $this->aggregation("MIN($column)"); + return $this->aggregation("MIN($column)", 'MIN'); } @@ -514,7 +520,7 @@ public function min(string $column) */ public function max(string $column) { - return $this->aggregation("MAX($column)"); + return $this->aggregation("MAX($column)", 'MAX'); } @@ -524,7 +530,7 @@ public function max(string $column) */ public function sum(string $column) { - return $this->aggregation("SUM($column)"); + return $this->aggregation("SUM($column)", 'SUM'); } diff --git a/src/Database/Table/SqlBuilder.php b/src/Database/Table/SqlBuilder.php index 03ab12e1d..be0e56ae5 100644 --- a/src/Database/Table/SqlBuilder.php +++ b/src/Database/Table/SqlBuilder.php @@ -256,6 +256,19 @@ public function importConditions(self $builder): void } + public function importGroupConditions(self $builder): bool + { + if ($builder->having) { + $this->group = $builder->group; + $this->having = $builder->having; + $this->parameters['group'] = $builder->parameters['group']; + $this->parameters['having'] = $builder->parameters['having']; + return true; + } + return false; + } + + /********************* SQL selectors ****************d*g**/ diff --git a/tests/Database/Explorer/Explorer.aggregation.phpt b/tests/Database/Explorer/Explorer.aggregation.phpt index b45fa73e5..3aa6518c6 100644 --- a/tests/Database/Explorer/Explorer.aggregation.phpt +++ b/tests/Database/Explorer/Explorer.aggregation.phpt @@ -41,3 +41,54 @@ test('', function () use ($explorer) { Assert::count(2, $authors); Assert::same(2, $authors->count('DISTINCT author.id')); // SELECT COUNT(DISTINCT author.id) FROM `author` INNER JOIN `book` ON `author`.`id` = `book`.`author_id` WHERE (`book`.`translator_id` IS NOT NULL) }); + + +test('', function () use ($explorer) { + $authors = $explorer->table('book')->group('book.id')->having('COUNT(DISTINCT :book_tag.tag_id) < 2'); // SELECT `author`.* FROM `author` INNER JOIN `book` ON `author`.`id` = `book`.`author_id` WHERE (`book`.`translator_id` IS NOT NULL) GROUP BY `author`.`id` + Assert::count(2, $authors); + Assert::same(2, $authors->count('DISTINCT author.id')); // SELECT COUNT(DISTINCT author.id) FROM `author` INNER JOIN `book` ON `author`.`id` = `book`.`author_id` WHERE (`book`.`translator_id` IS NOT NULL) +}); + + +test('', function () use ($explorer) { + $bookTags = []; + foreach ($explorer->table('book') as $book) { + $book_tags = $book->related('book_tag'); + $bookTags[$book->title] = $book_tags->count('DISTINCT tag.id'); + } + + Assert::same([ + '1001 tipu a triku pro PHP' => 2, + 'JUSH' => 1, + 'Nette' => 1, + 'Dibi' => 2, + ], $bookTags); +}); + + +test('', function () use ($explorer) { + $bookTags = []; + foreach ($explorer->table('book')->group('book.id, book.title')->having('COUNT(DISTINCT :book_tag.tag_id) < 2') as $book) { + $book_tags = $book->related('book_tag'); + $bookTags[$book->title] = $book_tags->count('DISTINCT tag.id'); + } + + Assert::same([ + 'JUSH' => 1, + 'Nette' => 1, + ], $bookTags); +}); + +test('', function () use ($explorer) { + $bookTags = []; + foreach ($explorer->table('author') as $author) { + $books = $author->related('book'); + $bookTags[$author->name] = $books->group('book.id')->having('COUNT(DISTINCT :book_tag.tag_id) < 2')->count('DISTINCT book.id'); + } + + Assert::same([ + 'Jakub Vrana' => 1, + 'David Grudl' => 1, + 'Geek' => 0, + ], $bookTags); +});