diff --git a/CHANGELOG.md b/CHANGELOG.md
index c10eeb0..1e78dbf 100644
--- a/CHANGELOG.md
+++ b/CHANGELOG.md
@@ -58,6 +58,7 @@
- Enh #350: Adapt to `Like` changes in `yiisoft/db` package (@vjik)
- Enh #352: Support column's collation (@Tigrov)
- New #358: Add `Connection::getColumnBuilderClass()` method (@Tigrov)
+- New #357: Implement `ArrayMergeBuilder`, `LongestBuilder` and `ShortestBuilder` classes (@Tigrov)
## 1.3.0 March 21, 2024
diff --git a/psalm.xml b/psalm.xml
index 6461f99..4570fdb 100644
--- a/psalm.xml
+++ b/psalm.xml
@@ -19,5 +19,6 @@
+
diff --git a/src/Builder/ArrayMergeBuilder.php b/src/Builder/ArrayMergeBuilder.php
new file mode 100644
index 0000000..22883d1
--- /dev/null
+++ b/src/Builder/ArrayMergeBuilder.php
@@ -0,0 +1,75 @@
+
+ */
+final class ArrayMergeBuilder extends MultiOperandFunctionBuilder
+{
+ private const DEFAULT_OPERAND_TYPE = '';
+
+ /**
+ * Builds a SQL expression which merges arrays from the given {@see ArrayMerge} object.
+ *
+ * @param ArrayMerge $expression The expression to build.
+ * @param array $params The parameters to bind.
+ *
+ * @return string The SQL expression.
+ */
+ protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
+ {
+ $selects = [];
+ $operandType = $this->buildOperandType($expression->getType());
+
+ foreach ($expression->getOperands() as $operand) {
+ $builtOperand = $this->buildOperand($operand, $params);
+ $selects[] = "SELECT value FROM JSON_TABLE($builtOperand, '$[*]' COLUMNS(value $operandType PATH '$'))";
+ }
+
+ return '(SELECT JSON_ARRAYAGG(value) AS value FROM (' . implode(' UNION ', $selects) . '))';
+ }
+
+ private function buildOperandType(string|ColumnInterface $type): string
+ {
+ if (is_string($type)) {
+ return $type === '' ? self::DEFAULT_OPERAND_TYPE : rtrim($type, '[]');
+ }
+
+ if ($type instanceof AbstractArrayColumn) {
+ if ($type->getDimension() > 1) {
+ return self::DEFAULT_OPERAND_TYPE;
+ }
+
+ $type = $type->getColumn();
+
+ if ($type === null) {
+ return self::DEFAULT_OPERAND_TYPE;
+ }
+ }
+
+ return $this->queryBuilder->getColumnDefinitionBuilder()->buildType($type);
+ }
+}
diff --git a/src/Builder/LongestBuilder.php b/src/Builder/LongestBuilder.php
new file mode 100644
index 0000000..4a95303
--- /dev/null
+++ b/src/Builder/LongestBuilder.php
@@ -0,0 +1,47 @@
+
+ */
+final class LongestBuilder extends MultiOperandFunctionBuilder
+{
+ /**
+ * Builds a SQL expression to represent the function which returns the longest string.
+ *
+ * @param Greatest $expression The expression to build.
+ * @param array $params The parameters to bind.
+ *
+ * @return string The SQL expression.
+ */
+ protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
+ {
+ $selects = [];
+
+ foreach ($expression->getOperands() as $operand) {
+ $selects[] = 'SELECT ' . $this->buildOperand($operand, $params) . ' AS value FROM DUAL';
+ }
+
+ $unions = implode(' UNION ', $selects);
+
+ return "(SELECT value FROM ($unions) ORDER BY LENGTH(value) DESC FETCH FIRST 1 ROWS ONLY)";
+ }
+}
diff --git a/src/Builder/ShortestBuilder.php b/src/Builder/ShortestBuilder.php
new file mode 100644
index 0000000..145413a
--- /dev/null
+++ b/src/Builder/ShortestBuilder.php
@@ -0,0 +1,46 @@
+
+ */
+final class ShortestBuilder extends MultiOperandFunctionBuilder
+{
+ /**
+ * Builds a SQL expression to represent the function which returns the shortest string.
+ *
+ * @param Shortest $expression The expression to build.
+ * @param array $params The parameters to bind.
+ *
+ * @return string The SQL expression.
+ */
+ protected function buildFromExpression(MultiOperandFunction $expression, array &$params): string
+ {
+ $selects = [];
+
+ foreach ($expression->getOperands() as $operand) {
+ $selects[] = 'SELECT ' . $this->buildOperand($operand, $params) . ' AS value FROM DUAL';
+ }
+
+ $unions = implode(' UNION ', $selects);
+
+ return "(SELECT value FROM ($unions) ORDER BY LENGTH(value) ASC FETCH FIRST 1 ROWS ONLY)";
+ }
+}
diff --git a/src/DQLQueryBuilder.php b/src/DQLQueryBuilder.php
index c82659b..e1cd532 100644
--- a/src/DQLQueryBuilder.php
+++ b/src/DQLQueryBuilder.php
@@ -5,8 +5,14 @@
namespace Yiisoft\Db\Oracle;
use Yiisoft\Db\Expression\ExpressionInterface;
+use Yiisoft\Db\Expression\Function\ArrayMerge;
+use Yiisoft\Db\Expression\Function\Longest;
+use Yiisoft\Db\Expression\Function\Shortest;
+use Yiisoft\Db\Oracle\Builder\ArrayMergeBuilder;
use Yiisoft\Db\Oracle\Builder\InBuilder;
use Yiisoft\Db\Oracle\Builder\LikeBuilder;
+use Yiisoft\Db\Oracle\Builder\LongestBuilder;
+use Yiisoft\Db\Oracle\Builder\ShortestBuilder;
use Yiisoft\Db\Query\Query;
use Yiisoft\Db\QueryBuilder\AbstractDQLQueryBuilder;
use Yiisoft\Db\QueryBuilder\Condition\In;
@@ -89,6 +95,9 @@ protected function defaultExpressionBuilders(): array
NotIn::class => InBuilder::class,
Like::class => LikeBuilder::class,
NotLike::class => LikeBuilder::class,
+ ArrayMerge::class => ArrayMergeBuilder::class,
+ Longest::class => LongestBuilder::class,
+ Shortest::class => ShortestBuilder::class,
];
}
}
diff --git a/tests/Provider/QueryBuilderProvider.php b/tests/Provider/QueryBuilderProvider.php
index a7ec4a7..4436c19 100644
--- a/tests/Provider/QueryBuilderProvider.php
+++ b/tests/Provider/QueryBuilderProvider.php
@@ -10,7 +10,9 @@
use Yiisoft\Db\Constant\PseudoType;
use Yiisoft\Db\Constant\ReferentialAction;
use Yiisoft\Db\Constraint\ForeignKey;
+use Yiisoft\Db\Expression\ArrayExpression;
use Yiisoft\Db\Expression\Expression;
+use Yiisoft\Db\Expression\Function\ArrayMerge;
use Yiisoft\Db\Expression\Param;
use Yiisoft\Db\Oracle\Column\ColumnBuilder;
use Yiisoft\Db\Oracle\Tests\Support\TestTrait;
@@ -453,4 +455,78 @@ public static function delete(): array
$values['base'][2] = 'DELETE FROM "user" WHERE ("is_enabled" = \'0\') AND ("power" = WRONG_POWER())';
return $values;
}
+
+ public static function lengthBuilder(): array
+ {
+ $data = parent::lengthBuilder();
+
+ $data['query'][1] = "LENGTH((SELECT 'four' FROM DUAL))";
+
+ return $data;
+ }
+
+ public static function multiOperandFunctionClasses(): array
+ {
+ return [
+ ...parent::multiOperandFunctionClasses(),
+ ArrayMerge::class => [ArrayMerge::class],
+ ];
+ }
+
+ public static function multiOperandFunctionBuilder(): array
+ {
+ $data = parent::multiOperandFunctionBuilder();
+
+ $data['Greatest with 4 operands'][2] = 'GREATEST(1, 1.5, 1 + 2, (SELECT 10 FROM DUAL))';
+ $data['Least with 4 operands'][2] = 'LEAST(1, 1.5, 1 + 2, (SELECT 10 FROM DUAL))';
+ $data['Longest with 2 operands'][2] = << [
+ ArrayMerge::class,
+ ["'[1,2,3]'"],
+ "('[1,2,3]')",
+ [1, 2, 3],
+ ],
+ 'ArrayMerge with 2 operands' => [
+ ArrayMerge::class,
+ ["'[1,2,3]'", $stringParam],
+ '(SELECT JSON_ARRAYAGG(value) AS value FROM ('
+ . "SELECT value FROM JSON_TABLE('[1,2,3]', '$[*]' COLUMNS(value PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE(:qp0, '$[*]' COLUMNS(value PATH '$'))))",
+ [1, 2, 3, 4, 5],
+ [':qp0' => $stringParam],
+ ],
+ 'ArrayMerge with 4 operands' => [
+ ArrayMerge::class,
+ ["'[1,2,3]'", [5, 6, 7], $stringParam, self::getDb()->select(new ArrayExpression([9, 10]))],
+ '(SELECT JSON_ARRAYAGG(value) AS value FROM ('
+ . "SELECT value FROM JSON_TABLE('[1,2,3]', '$[*]' COLUMNS(value PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE(:qp0, '$[*]' COLUMNS(value PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE(:qp1, '$[*]' COLUMNS(value PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE((SELECT :qp2 FROM DUAL), '$[*]' COLUMNS(value PATH '$'))"
+ . '))',
+ [1, 2, 3, 4, 5, 6, 7, 9, 10],
+ [
+ ':qp0' => new Param('[5,6,7]', DataType::STRING),
+ ':qp1' => $stringParam,
+ ':qp2' => new Param('[9,10]', DataType::STRING),
+ ],
+ ],
+ ];
+ }
}
diff --git a/tests/QueryBuilderTest.php b/tests/QueryBuilderTest.php
index 4c20585..258dad0 100644
--- a/tests/QueryBuilderTest.php
+++ b/tests/QueryBuilderTest.php
@@ -6,17 +6,30 @@
use PHPUnit\Framework\Attributes\DataProvider;
use PHPUnit\Framework\Attributes\DataProviderExternal;
+use PHPUnit\Framework\Attributes\TestWith;
+use Yiisoft\Db\Constant\DataType;
use Yiisoft\Db\Exception\Exception;
use InvalidArgumentException;
use Yiisoft\Db\Exception\NotSupportedException;
+use Yiisoft\Db\Expression\ArrayExpression;
use Yiisoft\Db\Expression\CaseExpression;
use Yiisoft\Db\Expression\ExpressionInterface;
+use Yiisoft\Db\Expression\Function\ArrayMerge;
+use Yiisoft\Db\Expression\Param;
use Yiisoft\Db\Oracle\Tests\Provider\QueryBuilderProvider;
use Yiisoft\Db\Oracle\Tests\Support\TestTrait;
use Yiisoft\Db\Query\Query;
use Yiisoft\Db\Query\QueryInterface;
+use Yiisoft\Db\Schema\Column\ArrayColumn;
use Yiisoft\Db\Schema\Column\ColumnInterface;
+use Yiisoft\Db\Schema\Column\IntegerColumn;
use Yiisoft\Db\Tests\Common\CommonQueryBuilderTest;
+use Yiisoft\Db\Tests\Support\Assert;
+
+use function json_decode;
+use function sort;
+
+use const SORT_NUMERIC;
/**
* @group oracle
@@ -579,4 +592,78 @@ public function testCaseExpressionBuilder(
): void {
parent::testCaseExpressionBuilder($case, $expectedSql, $expectedParams, $expectedResult);
}
+
+ #[DataProviderExternal(QueryBuilderProvider::class, 'lengthBuilder')]
+ public function testLengthBuilder(
+ string|ExpressionInterface $operand,
+ string $expectedSql,
+ int $expectedResult,
+ array $expectedParams = [],
+ ): void {
+ parent::testLengthBuilder($operand, $expectedSql, $expectedResult, $expectedParams);
+ }
+
+ #[DataProviderExternal(QueryBuilderProvider::class, 'multiOperandFunctionBuilder')]
+ public function testMultiOperandFunctionBuilder(
+ string $class,
+ array $operands,
+ string $expectedSql,
+ array|string|int $expectedResult,
+ array $expectedParams = [],
+ ): void {
+ parent::testMultiOperandFunctionBuilder($class, $operands, $expectedSql, $expectedResult, $expectedParams);
+ }
+
+ #[DataProviderExternal(QueryBuilderProvider::class, 'multiOperandFunctionClasses')]
+ public function testMultiOperandFunctionBuilderWithoutOperands(string $class): void
+ {
+ parent::testMultiOperandFunctionBuilderWithoutOperands($class);
+ }
+
+ #[TestWith(['int[]', 'int', '[1,2,3,4,5,6,7,9,10]'])]
+ #[TestWith([new IntegerColumn(), 'number(10)', '[1,2,3,4,5,6,7,9,10]'])]
+ #[TestWith([new ArrayColumn(), '', '["1","2","3","4","5","6","7","9","10"]'])]
+ #[TestWith([new ArrayColumn(column: new IntegerColumn()), 'number(10)', '[1,2,3,4,5,6,7,9,10]'])]
+ public function testMultiOperandFunctionBuilderWithType(
+ string|ColumnInterface $type,
+ string $operandType,
+ string $expectedResult,
+ ): void {
+ $db = $this->getConnection();
+ $qb = $db->getQueryBuilder();
+
+ $stringParam = new Param('[3,4,5]', DataType::STRING);
+ $arrayMerge = (new ArrayMerge(
+ "'[1,2,3]'",
+ [5, 6, 7],
+ $stringParam,
+ self::getDb()->select(new ArrayExpression([9, 10])),
+ ))->type($type);
+ $params = [];
+
+ $this->assertSame(
+ '(SELECT JSON_ARRAYAGG(value) AS value FROM ('
+ . "SELECT value FROM JSON_TABLE('[1,2,3]', '$[*]' COLUMNS(value $operandType PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE(:qp0, '$[*]' COLUMNS(value $operandType PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE(:qp1, '$[*]' COLUMNS(value $operandType PATH '$'))"
+ . " UNION SELECT value FROM JSON_TABLE((SELECT :qp2 FROM DUAL), '$[*]' COLUMNS(value $operandType PATH '$'))"
+ . '))',
+ $qb->buildExpression($arrayMerge, $params)
+ );
+ Assert::arraysEquals(
+ [
+ ':qp0' => new Param('[5,6,7]', DataType::STRING),
+ ':qp1' => $stringParam,
+ ':qp2' => new Param('[9,10]', DataType::STRING),
+ ],
+ $params,
+ );
+
+ $result = $db->select($arrayMerge)->scalar();
+ $result = json_decode($result);
+ sort($result, SORT_NUMERIC);
+ $expectedResult = json_decode($expectedResult);
+
+ $this->assertSame($expectedResult, $result);
+ }
}