Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add json overlaps condition builder #350

Merged
merged 5 commits into from
Jul 4, 2024
Merged
Show file tree
Hide file tree
Changes from 4 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@
for type casting performance. Related with yiisoft/db#752 (@Tigrov)
- Chg #348: Replace call of `SchemaInterface::getRawTableName()` to `QuoterInterface::getRawTableName()` (@Tigrov)
- Enh #349: Add method chaining for column classes (@Tigrov)
- Enh #350: Add array and json overlaps condition builders (@Tigrov)

## 1.3.0 March 21, 2024

Expand Down
47 changes: 47 additions & 0 deletions src/Builder/ArrayOverlapsConditionBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
<?php

declare(strict_types=1);

namespace Yiisoft\Db\Pgsql\Builder;

use Yiisoft\Db\Exception\Exception;
use Yiisoft\Db\Exception\InvalidArgumentException;
use Yiisoft\Db\Exception\InvalidConfigException;
use Yiisoft\Db\Exception\NotSupportedException;
use Yiisoft\Db\Expression\ArrayExpression;
use Yiisoft\Db\Expression\ExpressionInterface;
use Yiisoft\Db\Expression\JsonExpression;
use Yiisoft\Db\QueryBuilder\Condition\ArrayOverlapsCondition;
use Yiisoft\Db\QueryBuilder\Condition\Builder\AbstractOverlapsConditionBuilder;

/**
* Builds expressions for {@see ArrayOverlapsCondition} for PostgreSQL Server.
*/
final class ArrayOverlapsConditionBuilder extends AbstractOverlapsConditionBuilder
{
/**
* Build SQL for {@see ArrayOverlapsCondition}.
*
* @param ArrayOverlapsCondition $expression the {@see ArrayOverlapsCondition} to be built.
*
* @throws Exception
* @throws InvalidArgumentException
* @throws InvalidConfigException
* @throws NotSupportedException
*/
public function build(ExpressionInterface $expression, array &$params = []): string
{
$column = $this->prepareColumn($expression->getColumn());
$values = $expression->getValues();

if ($values instanceof JsonExpression) {
$values = new ArrayExpression($values->getValue());
} elseif (!$values instanceof ExpressionInterface) {
$values = new ArrayExpression($values);
}

$values = $this->queryBuilder->buildExpression($values, $params);

return "$column::text[] && $values::text[]";
}
}
47 changes: 47 additions & 0 deletions src/Builder/JsonOverlapsConditionBuilder.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
<?php

declare(strict_types=1);

namespace Yiisoft\Db\Pgsql\Builder;

use Yiisoft\Db\Exception\Exception;
use Yiisoft\Db\Exception\InvalidArgumentException;
use Yiisoft\Db\Exception\InvalidConfigException;
use Yiisoft\Db\Exception\NotSupportedException;
use Yiisoft\Db\Expression\ArrayExpression;
use Yiisoft\Db\Expression\ExpressionInterface;
use Yiisoft\Db\Expression\JsonExpression;
use Yiisoft\Db\QueryBuilder\Condition\Builder\AbstractOverlapsConditionBuilder;
use Yiisoft\Db\QueryBuilder\Condition\JsonOverlapsCondition;

/**
* Builds expressions for {@see JsonOverlapsCondition} for PostgreSQL Server.
*/
final class JsonOverlapsConditionBuilder extends AbstractOverlapsConditionBuilder
{
/**
* Build SQL for {@see JsonOverlapsCondition}.
*
* @param JsonOverlapsCondition $expression the {@see JsonOverlapsCondition} to be built.
*
* @throws Exception
* @throws InvalidArgumentException
* @throws InvalidConfigException
* @throws NotSupportedException
*/
public function build(ExpressionInterface $expression, array &$params = []): string
{
$column = $this->prepareColumn($expression->getColumn());
$values = $expression->getValues();

if ($values instanceof JsonExpression) {
$values = new ArrayExpression($values->getValue());
} elseif (!$values instanceof ExpressionInterface) {
$values = new ArrayExpression($values);
}

$values = $this->queryBuilder->buildExpression($values, $params);

return "ARRAY(SELECT jsonb_array_elements_text($column::jsonb)) && $values::text[]";
}
}
6 changes: 6 additions & 0 deletions src/DQLQueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -9,10 +9,14 @@
use Yiisoft\Db\Expression\ExpressionBuilderInterface;
use Yiisoft\Db\Expression\JsonExpression;
use Yiisoft\Db\Pgsql\Builder\ArrayExpressionBuilder;
use Yiisoft\Db\Pgsql\Builder\ArrayOverlapsConditionBuilder;
use Yiisoft\Db\Pgsql\Builder\JsonOverlapsConditionBuilder;
use Yiisoft\Db\Pgsql\Builder\StructuredExpressionBuilder;
use Yiisoft\Db\Pgsql\Builder\ExpressionBuilder;
use Yiisoft\Db\Pgsql\Builder\JsonExpressionBuilder;
use Yiisoft\Db\QueryBuilder\AbstractDQLQueryBuilder;
use Yiisoft\Db\QueryBuilder\Condition\ArrayOverlapsCondition;
use Yiisoft\Db\QueryBuilder\Condition\JsonOverlapsCondition;
use Yiisoft\Db\QueryBuilder\Condition\LikeCondition;

use function array_merge;
Expand Down Expand Up @@ -52,7 +56,9 @@ protected function defaultExpressionBuilders(): array
{
return array_merge(parent::defaultExpressionBuilders(), [
ArrayExpression::class => ArrayExpressionBuilder::class,
ArrayOverlapsCondition::class => ArrayOverlapsConditionBuilder::class,
JsonExpression::class => JsonExpressionBuilder::class,
JsonOverlapsCondition::class => JsonOverlapsConditionBuilder::class,
StructuredExpression::class => StructuredExpressionBuilder::class,
Expression::class => ExpressionBuilder::class,
]);
Expand Down
46 changes: 0 additions & 46 deletions tests/CommandTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,6 @@
use Yiisoft\Db\Exception\Exception;
use Yiisoft\Db\Exception\InvalidConfigException;
use Yiisoft\Db\Exception\NotSupportedException;
use Yiisoft\Db\Expression\JsonExpression;
use Yiisoft\Db\Pgsql\Connection;
use Yiisoft\Db\Pgsql\Dsn;
use Yiisoft\Db\Pgsql\Driver;
Expand Down Expand Up @@ -182,51 +181,6 @@ public function testDropDefaultValue(): void
$db->close();
}

/**
* @throws Exception
* @throws InvalidConfigException
* @throws Throwable
*
* {@link https://github.com/yiisoft/yii2/issues/15827}
*/
public function testIssue15827(): void
{
$db = $this->getConnection();

$command = $db->createCommand();
$inserted = $command->insert(
'{{array_and_json_types}}',
[
'jsonb_col' => new JsonExpression(['Solution date' => '13.01.2011']),
],
)->execute();

$this->assertSame(1, $inserted);

$found = $command->setSql(
<<<SQL
SELECT *
FROM [[array_and_json_types]]
WHERE [[jsonb_col]] @> '{"Some not existing key": "random value"}'
SQL,
)->execute();

$this->assertSame(0, $found);

$found = $command->setSql(
<<<SQL
SELECT *
FROM [[array_and_json_types]]
WHERE [[jsonb_col]] @> '{"Solution date": "13.01.2011"}'
SQL,
)->execute();

$this->assertSame(1, $found);
$this->assertSame(1, $command->delete('{{array_and_json_types}}')->execute());

$db->close();
}

/**
* @dataProvider \Yiisoft\Db\Pgsql\Tests\Provider\CommandProvider::rawSql
*
Expand Down
13 changes: 13 additions & 0 deletions tests/Provider/QueryBuilderProvider.php
Original file line number Diff line number Diff line change
Expand Up @@ -523,4 +523,17 @@ public static function upsert(): array

return $upsert;
}

public static function overlapsCondition(): array
{
$data = parent::overlapsCondition();

$data['null'][1] = 0;
$data['expression'][0] = new Expression("'{0,1,2,7}'");
$data['query expression'][0] = (new Query(self::getDb()))->select(new ArrayExpression([0,1,2,7]));
$data[] = [new Expression('ARRAY[0,1,2,7]'), 1];
$data[] = [new ArrayExpression([0,1,2,7]), 1];

return $data;
}
}
102 changes: 102 additions & 0 deletions tests/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -10,10 +10,14 @@
use Yiisoft\Db\Exception\IntegrityException;
use Yiisoft\Db\Exception\InvalidConfigException;
use Yiisoft\Db\Exception\NotSupportedException;
use Yiisoft\Db\Expression\Expression;
use Yiisoft\Db\Expression\ExpressionInterface;
use Yiisoft\Db\Pgsql\Column;
use Yiisoft\Db\Pgsql\Tests\Support\TestTrait;
use Yiisoft\Db\Query\Query;
use Yiisoft\Db\Query\QueryInterface;
use Yiisoft\Db\QueryBuilder\Condition\ArrayOverlapsCondition;
use Yiisoft\Db\QueryBuilder\Condition\JsonOverlapsCondition;
use Yiisoft\Db\Schema\SchemaInterface;
use Yiisoft\Db\Tests\Common\CommonQueryBuilderTest;

Expand Down Expand Up @@ -681,4 +685,102 @@ public function testSelectScalar(array|bool|float|int|string $columns, string $e
{
parent::testSelectScalar($columns, $expected);
}

public function testArrayOverlapsConditionBuilder(): void
{
$db = $this->getConnection();
$qb = $db->getQueryBuilder();

$params = [];
$sql = $qb->buildExpression(new ArrayOverlapsCondition('column', [1, 2, 3]), $params);

$this->assertSame('"column"::text[] && ARRAY[:qp0, :qp1, :qp2]::text[]', $sql);
$this->assertSame([':qp0' => 1, ':qp1' => 2, ':qp2' => 3], $params);

// Test column as Expression
$params = [];
$sql = $qb->buildExpression(new ArrayOverlapsCondition(new Expression('column'), [1, 2, 3]), $params);

$this->assertSame('column::text[] && ARRAY[:qp0, :qp1, :qp2]::text[]', $sql);
$this->assertSame([':qp0' => 1, ':qp1' => 2, ':qp2' => 3], $params);

$db->close();
}

public function testJsonOverlapsConditionBuilder(): void
{
$db = $this->getConnection();
$qb = $db->getQueryBuilder();

$params = [];
$sql = $qb->buildExpression(new JsonOverlapsCondition('column', [1, 2, 3]), $params);

$this->assertSame(
'ARRAY(SELECT jsonb_array_elements_text("column"::jsonb)) && ARRAY[:qp0, :qp1, :qp2]::text[]',
$sql
);
$this->assertSame([':qp0' => 1, ':qp1' => 2, ':qp2' => 3], $params);

$db->close();
}

/** @dataProvider \Yiisoft\Db\Pgsql\Tests\Provider\QueryBuilderProvider::overlapsCondition */
public function testOverlapsCondition(iterable|ExpressionInterface $values, int $expectedCount): void
{
$db = $this->getConnection();
$query = new Query($db);

$count = $query
->from('array_and_json_types')
->where(new ArrayOverlapsCondition('intarray_col', $values))
->count();

$this->assertSame($expectedCount, $count);

$count = $query
->from('array_and_json_types')
->where(new JsonOverlapsCondition('json_col', $values))
->count();

$this->assertSame($expectedCount, $count);

$count = $query
->from('array_and_json_types')
->where(new JsonOverlapsCondition('jsonb_col', $values))
->count();

$this->assertSame($expectedCount, $count);

$db->close();
}

/** @dataProvider \Yiisoft\Db\Pgsql\Tests\Provider\QueryBuilderProvider::overlapsCondition */
public function testOverlapsConditionOperator(iterable|ExpressionInterface $values, int $expectedCount): void
{
$db = $this->getConnection();
$query = new Query($db);

$count = $query
->from('array_and_json_types')
->where(['array overlaps', 'intarray_col', $values])
->count();

$this->assertSame($expectedCount, $count);

$count = $query
->from('array_and_json_types')
->where(['json overlaps', 'json_col', $values])
->count();

$this->assertSame($expectedCount, $count);

$count = $query
->from('array_and_json_types')
->where(['json overlaps', 'jsonb_col', $values])
->count();

$this->assertSame($expectedCount, $count);

$db->close();
}
}
4 changes: 4 additions & 0 deletions tests/Support/Fixture/pgsql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -357,6 +357,10 @@ CREATE TABLE "array_and_json_types" (
jsonarray_col JSON[]
);

INSERT INTO "array_and_json_types" (intarray_col, json_col, jsonb_col) VALUES (null, null, null);
INSERT INTO "array_and_json_types" (intarray_col, json_col, jsonb_col) VALUES ('{1,2,3,null}', '[1,2,3,null]', '[1,2,3,null]');
INSERT INTO "array_and_json_types" (intarray_col, json_col, jsonb_col) VALUES ('{3,4,5}', '[3,4,5]', '[3,4,5]');

CREATE TABLE "T_constraints_1"
(
"C_id" INT NOT NULL PRIMARY KEY,
Expand Down
9 changes: 9 additions & 0 deletions tests/Support/TestTrait.php
Original file line number Diff line number Diff line change
Expand Up @@ -64,4 +64,13 @@ protected function setFixture(string $fixture): void
{
$this->fixture = $fixture;
}

public static function setUpBeforeClass(): void
{
$db = self::getDb();

DbHelper::loadFixture($db, __DIR__ . '/Fixture/pgsql.sql');

$db->close();
}
}
Loading