diff --git a/CHANGELOG.md b/CHANGELOG.md index 309bb65a..f1545601 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -2,6 +2,7 @@ ## 1.0.2 under development +- Enh #263: Support json type (@Tigrov) - Bug #268: Fix foreign keys: support multiple foreign keys referencing to one table and possible null columns for reference (@Tigrov) ## 1.0.1 July 24, 2023 diff --git a/composer.json b/composer.json index 5f185055..faaac763 100644 --- a/composer.json +++ b/composer.json @@ -24,7 +24,8 @@ "php": "^8.0", "ext-mbstring": "*", "ext-pdo": "*", - "yiisoft/db": "^1.0" + "yiisoft/db": "^1.0", + "yiisoft/json": "^1.0" }, "require-dev": { "ext-json": "*", diff --git a/src/Builder/JsonExpressionBuilder.php b/src/Builder/JsonExpressionBuilder.php new file mode 100644 index 00000000..73ef7c91 --- /dev/null +++ b/src/Builder/JsonExpressionBuilder.php @@ -0,0 +1,55 @@ +getValue(); + + if ($value instanceof QueryInterface) { + [$sql, $params] = $this->queryBuilder->build($value, $params); + + return "($sql)"; + } + + return $this->queryBuilder->bindParam(Json::encode($value), $params); + } +} diff --git a/src/ColumnSchema.php b/src/ColumnSchema.php index 160b94b4..45a886a3 100644 --- a/src/ColumnSchema.php +++ b/src/ColumnSchema.php @@ -4,7 +4,13 @@ namespace Yiisoft\Db\Sqlite; +use JsonException; +use Yiisoft\Db\Expression\ExpressionInterface; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Schema\AbstractColumnSchema; +use Yiisoft\Db\Schema\SchemaInterface; + +use function json_decode; /** * Represents the metadata of a column in a database table for SQLite Server. @@ -32,4 +38,48 @@ */ final class ColumnSchema extends AbstractColumnSchema { + /** + * Converts a value from its PHP representation to a database-specific representation. + * + * If the value is null or an {@see Expression}, it won't be converted. + * + * @param mixed $value The value to be converted. + * + * @return mixed The converted value. + */ + public function dbTypecast(mixed $value): mixed + { + if ($value === null || $value instanceof ExpressionInterface) { + return $value; + } + + if ($this->getType() === SchemaInterface::TYPE_JSON) { + return new JsonExpression($value, $this->getDbType()); + } + + return parent::dbTypecast($value); + } + + /** + * Converts the input value according to {@see phpType} after retrieval from the database. + * + * If the value is null or an {@see Expression}, it won't be converted. + * + * @param mixed $value The value to be converted. + * + * @throws JsonException + * @return mixed The converted value. + */ + public function phpTypecast(mixed $value): mixed + { + if ($value === null) { + return null; + } + + if ($this->getType() === SchemaInterface::TYPE_JSON) { + return json_decode((string) $value, true, 512, JSON_THROW_ON_ERROR); + } + + return parent::phpTypecast($value); + } } diff --git a/src/DQLQueryBuilder.php b/src/DQLQueryBuilder.php index 8c883b8b..753e9504 100644 --- a/src/DQLQueryBuilder.php +++ b/src/DQLQueryBuilder.php @@ -6,12 +6,14 @@ use Yiisoft\Db\Expression\ExpressionBuilderInterface; use Yiisoft\Db\Expression\ExpressionInterface; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Query\Query; use Yiisoft\Db\Query\QueryInterface; use Yiisoft\Db\QueryBuilder\AbstractDQLQueryBuilder; use Yiisoft\Db\QueryBuilder\Condition\InCondition; use Yiisoft\Db\QueryBuilder\Condition\LikeCondition; use Yiisoft\Db\Sqlite\Builder\InConditionBuilder; +use Yiisoft\Db\Sqlite\Builder\JsonExpressionBuilder; use Yiisoft\Db\Sqlite\Builder\LikeConditionBuilder; use function array_filter; @@ -135,6 +137,7 @@ protected function defaultExpressionBuilders(): array return array_merge(parent::defaultExpressionBuilders(), [ LikeCondition::class => LikeConditionBuilder::class, InCondition::class => InConditionBuilder::class, + JsonExpression::class => JsonExpressionBuilder::class, ]); } } diff --git a/src/QueryBuilder.php b/src/QueryBuilder.php index bc8d95d1..3aa810b1 100644 --- a/src/QueryBuilder.php +++ b/src/QueryBuilder.php @@ -42,6 +42,7 @@ final class QueryBuilder extends AbstractQueryBuilder SchemaInterface::TYPE_MONEY => 'decimal(19,4)', SchemaInterface::TYPE_UUID => 'blob(16)', SchemaInterface::TYPE_UUID_PK => 'blob(16) PRIMARY KEY', + SchemaInterface::TYPE_JSON => 'json', ]; public function __construct(QuoterInterface $quoter, SchemaInterface $schema) diff --git a/src/Schema.php b/src/Schema.php index 88dd18bc..ef856721 100644 --- a/src/Schema.php +++ b/src/Schema.php @@ -105,6 +105,7 @@ final class Schema extends AbstractPdoSchema 'time' => self::TYPE_TIME, 'timestamp' => self::TYPE_TIMESTAMP, 'enum' => self::TYPE_STRING, + 'json' => self::TYPE_JSON, ]; public function createColumn(string $type, array|int|string $length = null): ColumnInterface @@ -364,8 +365,13 @@ protected function findColumns(TableSchemaInterface $table): bool { /** @psalm-var ColumnInfo[] $columns */ $columns = $this->getPragmaTableInfo($table->getName()); + $jsonColumns = $this->getJsonColumns($table); foreach ($columns as $info) { + if (in_array($info['name'], $jsonColumns, true)) { + $info['type'] = self::TYPE_JSON; + } + $column = $this->loadColumnSchema($info); $table->column($column->getName(), $column); @@ -734,4 +740,25 @@ protected function getCacheTag(): string { return md5(serialize(array_merge([self::class], $this->generateCacheKey()))); } + + /** + * @throws Throwable + */ + private function getJsonColumns(TableSchemaInterface $table): array + { + $result = []; + /** @psalm-var CheckConstraint[] $checks */ + $checks = $this->getTableChecks((string) $table->getFullName()); + $regexp = '/\bjson_valid\(\s*["`\[]?(.+?)["`\]]?\s*\)/i'; + + foreach ($checks as $check) { + if (preg_match_all($regexp, $check->getExpression(), $matches, PREG_SET_ORDER)) { + foreach ($matches as $match) { + $result[] = $match[1]; + } + } + } + + return $result; + } } diff --git a/tests/ColumnSchemaTest.php b/tests/ColumnSchemaTest.php index 45191562..65187aa5 100644 --- a/tests/ColumnSchemaTest.php +++ b/tests/ColumnSchemaTest.php @@ -4,7 +4,12 @@ namespace Yiisoft\Db\Sqlite\Tests; +use PDO; use PHPUnit\Framework\TestCase; +use Yiisoft\Db\Command\Param; +use Yiisoft\Db\Expression\JsonExpression; +use Yiisoft\Db\Sqlite\ColumnSchema; +use Yiisoft\Db\Schema\SchemaInterface; use Yiisoft\Db\Sqlite\Tests\Support\TestTrait; use Yiisoft\Db\Query\Query; @@ -36,6 +41,8 @@ public function testPhpTypeCast(): void 'timestamp_col' => '2023-07-11 14:50:23', 'bool_col' => false, 'bit_col' => 0b0110_0110, // 102 + 'json_col' => [['a' => 1, 'b' => null, 'c' => [1, 3, 5]]], + 'json_text_col' => (new Query($db))->select(new Param('[1,2,3,"string",null]', PDO::PARAM_STR)), ] ); $command->execute(); @@ -51,6 +58,8 @@ public function testPhpTypeCast(): void $timestampColPhpType = $tableSchema->getColumn('timestamp_col')?->phpTypecast($query['timestamp_col']); $boolColPhpType = $tableSchema->getColumn('bool_col')?->phpTypecast($query['bool_col']); $bitColPhpType = $tableSchema->getColumn('bit_col')?->phpTypecast($query['bit_col']); + $jsonColPhpType = $tableSchema->getColumn('json_col')?->phpTypecast($query['json_col']); + $jsonTextColPhpType = $tableSchema->getColumn('json_text_col')?->phpTypecast($query['json_text_col']); $this->assertSame(1, $intColPhpType); $this->assertSame(str_repeat('x', 100), $charColPhpType); @@ -60,7 +69,19 @@ public function testPhpTypeCast(): void $this->assertSame('2023-07-11 14:50:23', $timestampColPhpType); $this->assertFalse($boolColPhpType); $this->assertSame(0b0110_0110, $bitColPhpType); + $this->assertSame([['a' => 1, 'b' => null, 'c' => [1, 3, 5]]], $jsonColPhpType); + $this->assertSame([1, 2, 3, 'string', null], $jsonTextColPhpType); $db->close(); } + + public function testTypeCastJson(): void + { + $columnSchema = new ColumnSchema('json_col'); + $columnSchema->dbType(SchemaInterface::TYPE_JSON); + $columnSchema->type(SchemaInterface::TYPE_JSON); + + $this->assertSame(['a' => 1], $columnSchema->phpTypeCast('{"a":1}')); + $this->assertEquals(new JsonExpression(['a' => 1], SchemaInterface::TYPE_JSON), $columnSchema->dbTypeCast(['a' => 1])); + } } diff --git a/tests/CommandTest.php b/tests/CommandTest.php index 9d3b3ed2..7f3dbd4d 100644 --- a/tests/CommandTest.php +++ b/tests/CommandTest.php @@ -8,6 +8,7 @@ use Yiisoft\Db\Exception\Exception; use Yiisoft\Db\Exception\InvalidConfigException; use Yiisoft\Db\Exception\NotSupportedException; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Schema\SchemaInterface; use Yiisoft\Db\Sqlite\Tests\Support\TestTrait; use Yiisoft\Db\Tests\Common\CommonCommandTest; @@ -495,4 +496,38 @@ public function testShowDatabases(): void $this->assertSame('sqlite::memory:', $db->getDriver()->getDsn()); $this->assertSame(['main'], $command->showDatabases()); } + + public function testJsonTable(): void + { + $db = $this->getConnection(); + $command = $db->createCommand(); + + if ($db->getTableSchema('json_table', true) !== null) { + $command->dropTable('json_table')->execute(); + } + + $command->createTable('json_table', [ + 'id' => SchemaInterface::TYPE_PK, + 'json_col' => SchemaInterface::TYPE_JSON, + ])->execute(); + + $command->insert('json_table', ['id' => 1, 'json_col' => ['a' => 1, 'b' => 2]])->execute(); + $command->insert('json_table', ['id' => 2, 'json_col' => new JsonExpression(['c' => 3, 'd' => 4])])->execute(); + + $tableSchema = $db->getTableSchema('json_table', true); + $this->assertNotNull($tableSchema); + $this->assertSame('json_col', $tableSchema->getColumn('json_col')->getName()); + $this->assertSame('json', $tableSchema->getColumn('json_col')->getType()); + $this->assertSame('json', $tableSchema->getColumn('json_col')->getDbType()); + + $this->assertSame( + '{"a":1,"b":2}', + $command->setSql('SELECT `json_col` FROM `json_table` WHERE `id`=1')->queryScalar(), + ); + + $this->assertSame( + '{"c":3,"d":4}', + $command->setSql('SELECT `json_col` FROM `json_table` WHERE `id`=2')->queryScalar(), + ); + } } diff --git a/tests/Provider/CommandProvider.php b/tests/Provider/CommandProvider.php index ae807f7f..afdc6f5a 100644 --- a/tests/Provider/CommandProvider.php +++ b/tests/Provider/CommandProvider.php @@ -4,6 +4,7 @@ namespace Yiisoft\Db\Sqlite\Tests\Provider; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Sqlite\Tests\Support\TestTrait; final class CommandProvider extends \Yiisoft\Db\Tests\Provider\CommandProvider @@ -11,4 +12,36 @@ final class CommandProvider extends \Yiisoft\Db\Tests\Provider\CommandProvider use TestTrait; protected static string $driverName = 'sqlite'; + + public static function batchInsert(): array + { + $batchInsert = parent::batchInsert(); + + $batchInsert['batchInsert binds json params'] = [ + '{{%type}}', + ['int_col', 'char_col', 'float_col', 'bool_col', 'json_col'], + [ + [1, 'a', 0.0, true, ['a' => 1, 'b' => true, 'c' => [1, 2, 3]]], + [2, 'b', -1.0, false, new JsonExpression(['d' => 'e', 'f' => false, 'g' => [4, 5, null]])], + ], + 'expected' => 'INSERT INTO `type` (`int_col`, `char_col`, `float_col`, `bool_col`, `json_col`) ' + . 'VALUES (:qp0, :qp1, :qp2, :qp3, :qp4), (:qp5, :qp6, :qp7, :qp8, :qp9)', + 'expectedParams' => [ + ':qp0' => 1, + ':qp1' => 'a', + ':qp2' => 0.0, + ':qp3' => true, + ':qp4' => '{"a":1,"b":true,"c":[1,2,3]}', + + ':qp5' => 2, + ':qp6' => 'b', + ':qp7' => -1.0, + ':qp8' => false, + ':qp9' => '{"d":"e","f":false,"g":[4,5,null]}', + ], + 2, + ]; + + return $batchInsert; + } } diff --git a/tests/Provider/QueryBuilderProvider.php b/tests/Provider/QueryBuilderProvider.php index d81a3dc7..6761ba42 100644 --- a/tests/Provider/QueryBuilderProvider.php +++ b/tests/Provider/QueryBuilderProvider.php @@ -5,6 +5,8 @@ namespace Yiisoft\Db\Sqlite\Tests\Provider; use Yiisoft\Db\Expression\Expression; +use Yiisoft\Db\Expression\JsonExpression; +use Yiisoft\Db\Query\Query; use Yiisoft\Db\QueryBuilder\Condition\InCondition; use Yiisoft\Db\Sqlite\Tests\Support\TestTrait; use Yiisoft\Db\Tests\Support\TraversableObject; @@ -92,6 +94,66 @@ public static function buildCondition(): array 'CONCAT(col1, col2) LIKE :qp0 ESCAPE \'\\\'', [':qp0' => '%b%'], ], + + /* json conditions */ + [ + ['=', 'json_col', new JsonExpression(['type' => 'iron', 'weight' => 15])], + '[[json_col]] = :qp0', [':qp0' => '{"type":"iron","weight":15}'], + ], + 'object with type, that is ignored in SQLite' => [ + ['=', 'json_col', new JsonExpression(['type' => 'iron', 'weight' => 15], 'json')], + '[[json_col]] = :qp0', [':qp0' => '{"type":"iron","weight":15}'], + ], + 'false value' => [ + ['=', 'json_col', new JsonExpression([false])], + '[[json_col]] = :qp0', [':qp0' => '[false]'], + ], + 'null value' => [ + ['=', 'json_col', new JsonExpression(null)], + '[[json_col]] = :qp0', [':qp0' => 'null'], + ], + 'null as array value' => [ + ['=', 'json_col', new JsonExpression([null])], + '[[json_col]] = :qp0', [':qp0' => '[null]'], + ], + 'null as object value' => [ + ['=', 'json_col', new JsonExpression(['nil' => null])], + '[[json_col]] = :qp0', [':qp0' => '{"nil":null}'], + ], + 'query' => [ + [ + '=', + 'json_col', + new JsonExpression((new Query(self::getDb()))->select('params')->from('user')->where(['id' => 1])), + ], + '[[json_col]] = (SELECT [[params]] FROM [[user]] WHERE [[id]]=:qp0)', + [':qp0' => 1], + ], + 'query with type, that is ignored in SQLite' => [ + [ + '=', + 'json_col', + new JsonExpression( + (new Query(self::getDb()))->select('params')->from('user')->where(['id' => 1]), + 'json' + ), + ], + '[[json_col]] = (SELECT [[params]] FROM [[user]] WHERE [[id]]=:qp0)', [':qp0' => 1], + ], + 'nested and combined json expression' => [ + [ + '=', + 'json_col', + new JsonExpression( + new JsonExpression(['a' => 1, 'b' => 2, 'd' => new JsonExpression(['e' => 3])]) + ), + ], + '[[json_col]] = :qp0', [':qp0' => '{"a":1,"b":2,"d":{"e":3}}'], + ], + 'search by property in JSON column' => [ + ['=', new Expression("(json_col->>'$.someKey')"), 42], + "(json_col->>'$.someKey') = :qp0", [':qp0' => 42], + ], ]); } diff --git a/tests/Provider/SchemaProvider.php b/tests/Provider/SchemaProvider.php index 5210b461..b8dee001 100644 --- a/tests/Provider/SchemaProvider.php +++ b/tests/Provider/SchemaProvider.php @@ -222,6 +222,32 @@ public static function columns(): array 'scale' => null, 'defaultValue' => 0b1000_0010, // 130 ], + 'json_col' => [ + 'type' => 'json', + 'dbType' => 'json', + 'phpType' => 'array', + 'primaryKey' => false, + 'allowNull' => false, + 'autoIncrement' => false, + 'enumValues' => null, + 'size' => null, + 'precision' => null, + 'scale' => null, + 'defaultValue' => ['number' => 10], + ], + 'json_text_col' => [ + 'type' => 'json', + 'dbType' => 'json', + 'phpType' => 'array', + 'primaryKey' => false, + 'allowNull' => true, + 'autoIncrement' => false, + 'enumValues' => null, + 'size' => null, + 'precision' => null, + 'scale' => null, + 'defaultValue' => null, + ], ], 'tableName' => 'type', ], diff --git a/tests/QueryBuilderTest.php b/tests/QueryBuilderTest.php index dfe61116..f7934429 100644 --- a/tests/QueryBuilderTest.php +++ b/tests/QueryBuilderTest.php @@ -11,9 +11,11 @@ use Yiisoft\Db\Exception\InvalidConfigException; use Yiisoft\Db\Exception\NotSupportedException; use Yiisoft\Db\Expression\ExpressionInterface; +use Yiisoft\Db\Expression\JsonExpression; use Yiisoft\Db\Query\Query; use Yiisoft\Db\Query\QueryInterface; use Yiisoft\Db\Schema\SchemaInterface; +use Yiisoft\Db\Sqlite\Column; use Yiisoft\Db\Sqlite\Tests\Support\TestTrait; use Yiisoft\Db\Tests\Common\CommonQueryBuilderTest; @@ -737,4 +739,30 @@ public function testUpsertExecute( ): void { parent::testUpsertExecute($table, $insertColumns, $updateColumns); } + + public function testJsonColumn() + { + $qb = $this->getConnection()->getQueryBuilder(); + $columnSchemaBuilder = new Column(SchemaInterface::TYPE_JSON); + + $this->assertSame( + 'ALTER TABLE `json_table` ADD `json_col` json', + $qb->addColumn('json_table', 'json_col', $columnSchemaBuilder->asString()), + ); + + $this->assertSame( + "CREATE TABLE `json_table` (\n\t`json_col` json\n)", + $qb->createTable('json_table', ['json_col' => $columnSchemaBuilder]), + ); + + $this->assertSame( + 'INSERT INTO `json_table` (`json_col`) VALUES (:qp0)', + $qb->insert('json_table', ['json_col' => ['a' => 1, 'b' => 2]]), + ); + + $this->assertSame( + 'INSERT INTO `json_table` (`json_col`) VALUES (:qp0)', + $qb->insert('json_table', ['json_col' => new JsonExpression(['a' => 1, 'b' => 2])]), + ); + } } diff --git a/tests/Support/Fixture/sqlite.sql b/tests/Support/Fixture/sqlite.sql index f54cf7ba..c55b2d4c 100644 --- a/tests/Support/Fixture/sqlite.sql +++ b/tests/Support/Fixture/sqlite.sql @@ -134,7 +134,9 @@ CREATE TABLE "type" ( bool_col tinyint(1) NOT NULL, bool_col2 tinyint(1) DEFAULT '1', ts_default TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, - bit_col BIT(8) NOT NULL DEFAULT 130 -- 0b1000_0010 + bit_col BIT(8) NOT NULL DEFAULT 130, -- 0b1000_0010 + json_col json NOT NULL DEFAULT '{"number":10}', + json_text_col text CHECK(json_text_col IS NULL OR json_valid(json_text_col)) -- for STRICT table ); CREATE TABLE "type_bit" (