From 3a060238be3fdb323cd1fa94412fa8cff405ecf5 Mon Sep 17 00:00:00 2001 From: Sergei Tigrov Date: Thu, 4 Jul 2024 09:55:35 +0700 Subject: [PATCH] Add array and json overlaps conditions (#855) --- CHANGELOG.md | 1 + docs/guide/en/query/where.md | 34 ++++++-- src/QueryBuilder/AbstractDQLQueryBuilder.php | 2 + .../Condition/AbstractOverlapsCondition.php | 84 +++++++++++++++++++ .../Condition/ArrayOverlapsCondition.php | 12 +++ .../AbstractOverlapsConditionBuilder.php | 28 +++++++ .../Interface/OverlapsConditionInterface.php | 23 +++++ .../Interface/SimpleConditionInterface.php | 3 +- .../Condition/JsonOverlapsCondition.php | 12 +++ tests/AbstractQueryBuilderTest.php | 53 ++++++++++++ tests/Provider/QueryBuilderProvider.php | 23 +++++ 11 files changed, 268 insertions(+), 7 deletions(-) create mode 100644 src/QueryBuilder/Condition/AbstractOverlapsCondition.php create mode 100644 src/QueryBuilder/Condition/ArrayOverlapsCondition.php create mode 100644 src/QueryBuilder/Condition/Builder/AbstractOverlapsConditionBuilder.php create mode 100644 src/QueryBuilder/Condition/Interface/OverlapsConditionInterface.php create mode 100644 src/QueryBuilder/Condition/JsonOverlapsCondition.php diff --git a/CHANGELOG.md b/CHANGELOG.md index 3e751ee24..677a5e190 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -29,6 +29,7 @@ - Chg #846: Remove `SchemaInterface::isReadQuery()` and `AbstractSchema::isReadQuery()` methods (@Tigrov) - Chg #847: Remove `SchemaInterface::getRawTableName()` and `AbstractSchema::getRawTableName()` methods (@Tigrov) - Enh #852: Add method chaining for column classes (@Tigrov) +- Enh #855: Add array and JSON overlaps conditions (@Tigrov) ## 1.3.0 March 21, 2024 diff --git a/docs/guide/en/query/where.md b/docs/guide/en/query/where.md index d351cd0de..a2812097a 100644 --- a/docs/guide/en/query/where.md +++ b/docs/guide/en/query/where.md @@ -211,7 +211,7 @@ Similar to the `not like` operator except that `OR` is used to concatenate the ` Requires one operand which must be an instance of `Yiisoft\Db\Query\Query` representing the sub-query. It will build an `EXISTS` (sub-query) expression. -## not exists +### not exists Similar to the `exists` operator and builds a `NOT EXISTS` (sub-query) expression. @@ -237,6 +237,28 @@ $query->where(['=', $column, $value]); // $value is safe, but $column name won't be encoded! ``` +### array overlaps + +Checks if the first array contains at least one element from the second array. Currently supported only by PostgreSQL +and equals to `&&` operator. + +Requires two operands: + +- Operator 1 should be a column name of an array type or DB expression returning an array; +- Operator 2 should be an array, iterator or DB expression returning an array. + +For example, `['array overlaps', 'ids', [1, 2, 3]]` will generate `"ids"::text[] && ARRAY[1,2,3]::text[]`. + +### JSON overlaps + +Checks if the JSON contains at least one element from the array. Currently supported only by PostgreSQL, MySQL and +SQLite. + +Requires two operands: + +- Operator 1 should be a column name of a JSON type or DB expression returning a JSON; +- Operator 2 should be an array, iterator or DB expression returning an array. + ## Object format Object format is most powerful yet the most complex way to define conditions. @@ -272,10 +294,12 @@ Conversion from operator format into object format is performed according to `Yiisoft\Db\QueryBuilder\AbstractDQLQueryBuilder::conditionClasses` property that maps operator names to representative class names. -- `AND`, `OR` => `Yiisoft\Db\QueryBuilder\Condition\ConjunctionCondition`. -- `NOT` => `Yiisoft\Db\QueryBuilder\Condition\NotCondition`. -- `IN`, `NOT IN` => `Yiisoft\Db\QueryBuilder\Condition\InCondition`. -- `BETWEEN`, `NOT BETWEEN` => `Yiisoft\Db\QueryBuilder\Condition\BetweenCondition`. +- `AND`, `OR` => `Yiisoft\Db\QueryBuilder\Condition\ConjunctionCondition`; +- `NOT` => `Yiisoft\Db\QueryBuilder\Condition\NotCondition`; +- `IN`, `NOT IN` => `Yiisoft\Db\QueryBuilder\Condition\InCondition`; +- `BETWEEN`, `NOT BETWEEN` => `Yiisoft\Db\QueryBuilder\Condition\BetweenCondition`; +- `ARRAY OVERLAPS` => `Yiisoft\Db\QueryBuilder\Condition\ArrayOverlapsCondition`; +- `JSON OVERLAPS` => `Yiisoft\Db\QueryBuilder\Condition\JsonOverlapsCondition`. ## Appending conditions diff --git a/src/QueryBuilder/AbstractDQLQueryBuilder.php b/src/QueryBuilder/AbstractDQLQueryBuilder.php index 9119ffa7d..d423bc317 100644 --- a/src/QueryBuilder/AbstractDQLQueryBuilder.php +++ b/src/QueryBuilder/AbstractDQLQueryBuilder.php @@ -496,6 +496,8 @@ protected function defaultConditionClasses(): array 'OR NOT LIKE' => Condition\LikeCondition::class, 'EXISTS' => Condition\ExistsCondition::class, 'NOT EXISTS' => Condition\ExistsCondition::class, + 'ARRAY OVERLAPS' => Condition\ArrayOverlapsCondition::class, + 'JSON OVERLAPS' => Condition\JsonOverlapsCondition::class, ]; } diff --git a/src/QueryBuilder/Condition/AbstractOverlapsCondition.php b/src/QueryBuilder/Condition/AbstractOverlapsCondition.php new file mode 100644 index 000000000..ffa6e474a --- /dev/null +++ b/src/QueryBuilder/Condition/AbstractOverlapsCondition.php @@ -0,0 +1,84 @@ +column; + } + + public function getValues(): iterable|ExpressionInterface + { + return $this->values; + } + + /** + * Creates a condition based on the given operator and operands. + * + * @throws InvalidArgumentException If the number of operands isn't 2. + */ + public static function fromArrayDefinition(string $operator, array $operands): static + { + if (!isset($operands[0], $operands[1])) { + throw new InvalidArgumentException("Operator \"$operator\" requires two operands."); + } + + /** @psalm-suppress UnsafeInstantiation */ + return new static( + self::validateColumn($operator, $operands[0]), + self::validateValues($operator, $operands[1]) + ); + } + + /** + * Validates the given column to be string or `ExpressionInterface`. + * + * @throws InvalidArgumentException If the column isn't a string or `ExpressionInterface`. + */ + private static function validateColumn(string $operator, mixed $column): string|ExpressionInterface + { + if (is_string($column) || $column instanceof ExpressionInterface) { + return $column; + } + + throw new InvalidArgumentException( + "Operator \"$operator\" requires column to be string or ExpressionInterface." + ); + } + + /** + * Validates the given values to be `iterable` or `ExpressionInterface`. + * + * @throws InvalidArgumentException If the values aren't an `iterable` or `ExpressionInterface`. + */ + private static function validateValues(string $operator, mixed $values): iterable|ExpressionInterface + { + if (is_iterable($values) || $values instanceof ExpressionInterface) { + return $values; + } + + throw new InvalidArgumentException( + "Operator \"$operator\" requires values to be iterable or ExpressionInterface." + ); + } +} diff --git a/src/QueryBuilder/Condition/ArrayOverlapsCondition.php b/src/QueryBuilder/Condition/ArrayOverlapsCondition.php new file mode 100644 index 000000000..7c215b578 --- /dev/null +++ b/src/QueryBuilder/Condition/ArrayOverlapsCondition.php @@ -0,0 +1,12 @@ +queryBuilder->buildExpression($column); + } + + return $this->queryBuilder->quoter()->quoteColumnName($column); + } +} diff --git a/src/QueryBuilder/Condition/Interface/OverlapsConditionInterface.php b/src/QueryBuilder/Condition/Interface/OverlapsConditionInterface.php new file mode 100644 index 000000000..e110a428f --- /dev/null +++ b/src/QueryBuilder/Condition/Interface/OverlapsConditionInterface.php @@ -0,0 +1,23 @@ +getConnection(); + $qb = $db->getQueryBuilder(); + + $condition = $qb->createConditionFromArray(['array overlaps', 'column', [1, 2, 3]]); + + $this->assertInstanceOf(ArrayOverlapsCondition::class, $condition); + $this->assertSame('column', $condition->getColumn()); + $this->assertSame([1, 2, 3], $condition->getValues()); + + $condition = $qb->createConditionFromArray(['json overlaps', 'column', [1, 2, 3]]); + + $this->assertInstanceOf(JsonOverlapsCondition::class, $condition); + $this->assertSame('column', $condition->getColumn()); + $this->assertSame([1, 2, 3], $condition->getValues()); + } + + public function testCreateOverlapsConditionFromArrayWithInvalidOperandsCount(): void + { + $db = $this->getConnection(); + $qb = $db->getQueryBuilder(); + + $this->expectException(InvalidArgumentException::class); + $this->expectExceptionMessage('Operator "JSON OVERLAPS" requires two operands.'); + + $qb->createConditionFromArray(['json overlaps', 'column']); + } + + public function testCreateOverlapsConditionFromArrayWithInvalidColumn(): void + { + $db = $this->getConnection(); + $qb = $db->getQueryBuilder(); + + $this->expectException(InvalidArgumentException::class); + $this->expectExceptionMessage('Operator "JSON OVERLAPS" requires column to be string or ExpressionInterface.'); + + $qb->createConditionFromArray(['json overlaps', ['column'], [1, 2, 3]]); + } + + public function testCreateOverlapsConditionFromArrayWithInvalidValues(): void + { + $db = $this->getConnection(); + $qb = $db->getQueryBuilder(); + + $this->expectException(InvalidArgumentException::class); + $this->expectExceptionMessage('Operator "JSON OVERLAPS" requires values to be iterable or ExpressionInterface.'); + + $qb->createConditionFromArray(['json overlaps', 'column', 1]); + } + /** * @dataProvider \Yiisoft\Db\Tests\Provider\QueryBuilderProvider::createIndex */ diff --git a/tests/Provider/QueryBuilderProvider.php b/tests/Provider/QueryBuilderProvider.php index 9c350bd9a..6529ad3f9 100644 --- a/tests/Provider/QueryBuilderProvider.php +++ b/tests/Provider/QueryBuilderProvider.php @@ -4,9 +4,11 @@ namespace Yiisoft\Db\Tests\Provider; +use ArrayIterator; use Yiisoft\Db\Command\DataType; use Yiisoft\Db\Command\Param; use Yiisoft\Db\Expression\Expression; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Query\Query; use Yiisoft\Db\QueryBuilder\Condition\BetweenColumnsCondition; use Yiisoft\Db\QueryBuilder\Condition\InCondition; @@ -1538,4 +1540,25 @@ public static function columnTypes(): array [new Column('string(100)')], ]; } + + public static function overlapsCondition(): array + { + return [ + [[], 0], + [[0], 0], + [[1], 1], + [[4], 1], + [[3], 2], + [[0, 1], 1], + [[1, 2], 1], + [[1, 4], 2], + [[0, 1, 2, 3, 4, 5, 6], 2], + [[6, 7, 8, 9], 0], + [new ArrayIterator([0, 1, 2, 7]), 1], + 'null' => [[null], 1], + 'expression' => [new Expression("'[0,1,2,7]'"), 1], + 'json expression' => [new JsonExpression([0,1,2,7]), 1], + 'query expression' => [(new Query(static::getDb()))->select(new JsonExpression([0,1,2,7])), 1], + ]; + } }