From ea85823aae337e6c1c8ca7d1ae681e968c824ebf Mon Sep 17 00:00:00 2001 From: darkdef Date: Mon, 21 Feb 2022 21:41:53 +0300 Subject: [PATCH 1/3] Step 2 - partial removing Command::getPdoStatement from other classes --- src/PDO/SchemaPDOMssql.php | 12 +------- tests/CommandTest.php | 59 ++++++++++++++++++++++++++++++++++++++ 2 files changed, 60 insertions(+), 11 deletions(-) diff --git a/src/PDO/SchemaPDOMssql.php b/src/PDO/SchemaPDOMssql.php index e3f4b3076..e095f4019 100644 --- a/src/PDO/SchemaPDOMssql.php +++ b/src/PDO/SchemaPDOMssql.php @@ -972,20 +972,13 @@ private function loadTableConstraints(string $tableName, string $returnType): mi * @throws Exception|InvalidCallException|InvalidConfigException|Throwable * * @return array|false primary key values or false if the command fails. - * - * @todo Remove old version support @darkdef. */ public function insert(string $table, array $columns): bool|array { $command = $this->db->createCommand()->insert($table, $columns); - if (!$command->execute()) { - return false; - } + $inserted = $command->queryOne(); - $isVersion2005orLater = version_compare($this->db->getServerVersion(), '9', '>='); - /** @var array */ - $inserted = $isVersion2005orLater ? $command->getPdoStatement()?->fetch() : []; $tableSchema = $this->getTableSchema($table); $result = []; @@ -1002,9 +995,6 @@ public function insert(string $table, array $columns): bool|array if (isset($inserted[$name])) { /** @var string */ $result[$name] = $inserted[$name]; - } elseif ($tableSchema->getColumns()[$name]->isAutoIncrement()) { - // for a version earlier than 2005 - $result[$name] = $this->getLastInsertID((string) $tableSchema->getSequenceName()); } elseif (isset($columns[$name])) { /** @var string */ $result[$name] = $columns[$name]; diff --git a/tests/CommandTest.php b/tests/CommandTest.php index 2638e8671..9effc3c0b 100644 --- a/tests/CommandTest.php +++ b/tests/CommandTest.php @@ -9,6 +9,8 @@ use Yiisoft\Db\Query\Query; use Yiisoft\Db\TestSupport\TestCommandTrait; +use function trim; + /** * @group mssql * @group upsert @@ -137,6 +139,63 @@ public function testBindParamsNonWhere(string $sql): void $this->assertEquals('Params', $command->queryScalar()); } + public function testBindParamValue(): void + { + $db = $this->getConnection(true); + + // bindParam + $sql = 'INSERT INTO customer(email, name, address) VALUES (:email, :name, :address)'; + $command = $db->createCommand($sql); + $email = 'user4@example.com'; + $name = 'user4'; + $address = 'address4'; + $command->bindParam(':email', $email); + $command->bindParam(':name', $name); + $command->bindParam(':address', $address); + $command->execute(); + + $sql = 'SELECT name FROM customer WHERE email=:email'; + $command = $db->createCommand($sql); + $command->bindParam(':email', $email); + $this->assertEquals($name, $command->queryScalar()); + + $sql = 'INSERT INTO type (int_col, char_col, float_col, blob_col, numeric_col, bool_col) + VALUES (:int_col, :char_col, :float_col, CONVERT([varbinary], :blob_col), :numeric_col, :bool_col)'; + $command = $db->createCommand($sql); + $intCol = 123; + $charCol = 'abc'; + $floatCol = 1.23; + $blobCol = "\x10\x11\x12"; + $numericCol = '1.23'; + $boolCol = false; + $command->bindParam(':int_col', $intCol); + $command->bindParam(':char_col', $charCol); + $command->bindParam(':float_col', $floatCol); + $command->bindParam(':blob_col', $blobCol); + $command->bindParam(':numeric_col', $numericCol); + $command->bindParam(':bool_col', $boolCol); + $this->assertEquals(1, $command->execute()); + + $sql = 'SELECT int_col, char_col, float_col, CONVERT([nvarchar], blob_col) AS blob_col, numeric_col + FROM type'; + $row = $db->createCommand($sql)->queryOne(); + $this->assertEquals($intCol, $row['int_col']); + $this->assertEquals($charCol, trim($row['char_col'])); + $this->assertEquals($floatCol, (float) $row['float_col']); + $this->assertEquals($blobCol, $row['blob_col']); + $this->assertEquals($numericCol, $row['numeric_col']); + + // bindValue + $sql = 'INSERT INTO customer(email, name, address) VALUES (:email, \'user5\', \'address5\')'; + $command = $db->createCommand($sql); + $command->bindValue(':email', 'user5@example.com'); + $command->execute(); + $sql = 'SELECT email FROM customer WHERE name=:name'; + $command = $db->createCommand($sql); + $command->bindValue(':name', 'user5'); + $this->assertEquals('user5@example.com', $command->queryScalar()); + } + /** * Test command getRawSql. * From c9af16d0b95d1edbd09d9ff2294403f9a2850ddd Mon Sep 17 00:00:00 2001 From: darkdef Date: Wed, 23 Feb 2022 23:09:50 +0300 Subject: [PATCH 2/3] Step 2 - partial removing Command::getPdoStatement from other classes --- src/DMLQueryBuilder.php | 25 +++--- src/PDO/CommandPDOMssql.php | 14 +++ src/PDO/SchemaPDOMssql.php | 45 ---------- tests/Provider/QueryBuilderProvider.php | 110 ++++++++++++++++++++---- tests/QueryBuilderTest.php | 16 ++++ tests/SchemaTest.php | 2 +- 6 files changed, 134 insertions(+), 78 deletions(-) diff --git a/src/DMLQueryBuilder.php b/src/DMLQueryBuilder.php index d0d5a8d3a..20eb734ea 100644 --- a/src/DMLQueryBuilder.php +++ b/src/DMLQueryBuilder.php @@ -26,10 +26,8 @@ public function __construct(private QueryBuilderInterface $queryBuilder) /** * @throws Exception|InvalidArgumentException|InvalidConfigException|NotSupportedException */ - public function insert(string $table, QueryInterface|array $columns, array &$params = []): string + public function insertEx(string $table, QueryInterface|array $columns, array &$params = []): string { - $cols = []; - /** * @psalm-var string[] $names * @psalm-var string[] $placeholders @@ -42,18 +40,17 @@ public function insert(string $table, QueryInterface|array $columns, array &$par . ' OUTPUT INSERTED.* INTO @temporary_inserted' . (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : (string) $values); + $cols = []; $tableSchema = $this->queryBuilder->schema()->getTableSchema($table); - - if ($tableSchema !== null) { - foreach ($tableSchema->getColumns() as $column) { - $cols[] = $this->queryBuilder->quoter()->quoteColumnName($column->getName()) . ' ' - . $column->getDbType() - . (in_array( - $column->getDbType(), - ['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary'] - ) ? '(MAX)' : '') - . ' ' . ($column->isAllowNull() ? 'NULL' : ''); - } + $returnColumns = $tableSchema?->getColumns() ?? []; + foreach($returnColumns as $returnColumn) { + $cols[] = $this->queryBuilder->quoter()->quoteColumnName($returnColumn->getName()) . ' ' + . $returnColumn->getDbType() + . (in_array( + $returnColumn->getDbType(), + ['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary'] + ) ? '(MAX)' : '') + . ' ' . ($returnColumn->isAllowNull() ? 'NULL' : ''); } return 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE (' . implode(', ', $cols) . ');' diff --git a/src/PDO/CommandPDOMssql.php b/src/PDO/CommandPDOMssql.php index a9f7d588c..5ee5d266f 100644 --- a/src/PDO/CommandPDOMssql.php +++ b/src/PDO/CommandPDOMssql.php @@ -18,6 +18,20 @@ public function __construct(private ConnectionPDOInterface $db, QueryCache $quer parent::__construct($queryCache); } + /** + * @inheritDoc + */ + public function insertEx(string $table, array $columns): bool|array + { + $params = []; + $sql = $this->queryBuilder()->insertEx($table, $columns, $params); + + $this->setSql($sql)->bindValues($params); + $this->prepare(false); + + return $this->queryOne(); + } + public function queryBuilder(): QueryBuilderInterface { return $this->db->getQueryBuilder(); diff --git a/src/PDO/SchemaPDOMssql.php b/src/PDO/SchemaPDOMssql.php index e095f4019..b438eaa31 100644 --- a/src/PDO/SchemaPDOMssql.php +++ b/src/PDO/SchemaPDOMssql.php @@ -963,51 +963,6 @@ private function loadTableConstraints(string $tableName, string $returnType): mi return $result[$returnType]; } - /** - * Executes the INSERT command, returning primary key values. - * - * @param string $table the table that new rows will be inserted into. - * @param array $columns the column data (name => value) to be inserted into the table. - * - * @throws Exception|InvalidCallException|InvalidConfigException|Throwable - * - * @return array|false primary key values or false if the command fails. - */ - public function insert(string $table, array $columns): bool|array - { - $command = $this->db->createCommand()->insert($table, $columns); - - $inserted = $command->queryOne(); - - $tableSchema = $this->getTableSchema($table); - - $result = []; - - if ($tableSchema !== null) { - $pks = $tableSchema->getPrimaryKey(); - $columnsTable = $tableSchema->getColumns(); - - foreach ($pks as $name) { - /** - * @link https://github.com/yiisoft/yii2/issues/13828 - * @link https://github.com/yiisoft/yii2/issues/17474 - */ - if (isset($inserted[$name])) { - /** @var string */ - $result[$name] = $inserted[$name]; - } elseif (isset($columns[$name])) { - /** @var string */ - $result[$name] = $columns[$name]; - } else { - /** @var mixed */ - $result[$name] = !array_key_exists($name, $columnsTable) ?: $columnsTable[$name]->getDefaultValue(); - } - } - } - - return $result; - } - /** * Create a column schema builder instance giving the type and value precision. * diff --git a/tests/Provider/QueryBuilderProvider.php b/tests/Provider/QueryBuilderProvider.php index f52f0e0fa..0e169f24b 100644 --- a/tests/Provider/QueryBuilderProvider.php +++ b/tests/Provider/QueryBuilderProvider.php @@ -133,6 +133,95 @@ public function deleteProvider(): array } public function insertProvider(): array + { + return [ + 'regular-values' => [ + 'customer', + [ + 'email' => 'test@example.com', + 'name' => 'silverfire', + 'address' => 'Kyiv {{city}}, Ukraine', + 'is_active' => false, + 'related_id' => null, + ], + [], + 'INSERT INTO [customer] ([email], [name], [address], [is_active], [related_id]) VALUES (:qp0, :qp1, :qp2, :qp3, :qp4)', + [ + ':qp0' => 'test@example.com', + ':qp1' => 'silverfire', + ':qp2' => 'Kyiv {{city}}, Ukraine', + ':qp3' => false, + ':qp4' => null, + ], + ], + 'params-and-expressions' => [ + '{{%type}}', + [ + '{{%type}}.[[related_id]]' => null, + '[[time]]' => new Expression('now()'), + ], + [], + 'INSERT INTO {{%type}} ({{%type}}.[[related_id]], [[time]]) VALUES (:qp0, now())', + [ + ':qp0' => null, + ], + ], + 'carry passed params' => [ + 'customer', + [ + 'email' => 'test@example.com', + 'name' => 'sergeymakinen', + 'address' => '{{city}}', + 'is_active' => false, + 'related_id' => null, + 'col' => new Expression('CONCAT(:phFoo, :phBar)', [':phFoo' => 'foo']), + ], + [':phBar' => 'bar'], + 'INSERT INTO [customer] ([email], [name], [address], [is_active], [related_id], [col]) VALUES (:qp1, :qp2, :qp3, :qp4, :qp5, CONCAT(:phFoo, :phBar))', + [ + ':phBar' => 'bar', + ':qp1' => 'test@example.com', + ':qp2' => 'sergeymakinen', + ':qp3' => '{{city}}', + ':qp4' => false, + ':qp5' => null, + ':phFoo' => 'foo', + ], + ], + 'carry passed params (query)' => [ + 'customer', + (new Query($this->getConnection())) + ->select([ + 'email', + 'name', + 'address', + 'is_active', + 'related_id', + ]) + ->from('customer') + ->where([ + 'email' => 'test@example.com', + 'name' => 'sergeymakinen', + 'address' => '{{city}}', + 'is_active' => false, + 'related_id' => null, + 'col' => new Expression('CONCAT(:phFoo, :phBar)', [':phFoo' => 'foo']), + ]), + [':phBar' => 'bar'], + 'INSERT INTO [customer] ([email], [name], [address], [is_active], [related_id]) SELECT [email], [name], [address], [is_active], [related_id] FROM [customer] WHERE ([email]=:qp1) AND ([name]=:qp2) AND ([address]=:qp3) AND ([is_active]=:qp4) AND ([related_id] IS NULL) AND ([col]=CONCAT(:phFoo, :phBar))', + [ + ':phBar' => 'bar', + ':qp1' => 'test@example.com', + ':qp2' => 'sergeymakinen', + ':qp3' => '{{city}}', + ':qp4' => false, + ':phFoo' => 'foo', + ], + ], + ]; + } + + public function insertExProvider(): array { return [ 'regular-values' => [ @@ -302,30 +391,15 @@ public function upsertProvider(): array ], 'values and expressions' => [ - 3 => 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [ts] int NULL, [email] varchar(128)' - . ' , [recovery_email] varchar(128) NULL, [address] text NULL, [status] tinyint , [orders] int ,' - . ' [profile_id] int NULL);' - . 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) OUTPUT INSERTED.*' - . ' INTO @temporary_inserted VALUES (:qp0, now());' - . 'SELECT * FROM @temporary_inserted', + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', ], 'values and expressions with update part' => [ - 3 => 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [ts] int NULL, [email] varchar(128)' - . ' , [recovery_email] varchar(128) NULL, [address] text NULL, [status] tinyint , [orders] int ,' - . ' [profile_id] int NULL);' - . 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) OUTPUT INSERTED.*' - . ' INTO @temporary_inserted VALUES (:qp0, now());' - . 'SELECT * FROM @temporary_inserted', + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', ], 'values and expressions without update part' => [ - 3 => 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [ts] int NULL, [email] varchar(128)' - . ' , [recovery_email] varchar(128) NULL, [address] text NULL, [status] tinyint , [orders] int ,' - . ' [profile_id] int NULL);' - . 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) OUTPUT INSERTED.*' - . ' INTO @temporary_inserted VALUES (:qp0, now());' - . 'SELECT * FROM @temporary_inserted', + 3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())', ], 'query, values and expressions with update part' => [ diff --git a/tests/QueryBuilderTest.php b/tests/QueryBuilderTest.php index 978f138d7..4519d5e2b 100644 --- a/tests/QueryBuilderTest.php +++ b/tests/QueryBuilderTest.php @@ -407,6 +407,22 @@ public function testInsert(string $table, $columns, array $params, string $expec $this->assertSame($expectedParams, $params); } + /** + * @dataProvider \Yiisoft\Db\Mssql\Tests\Provider\QueryBuilderProvider::insertExProvider() + * + * @param string $table + * @param array|ColumnSchema $columns + * @param array $params + * @param string $expectedSQL + * @param array $expectedParams + */ + public function testInsertEx(string $table, $columns, array $params, string $expectedSQL, array $expectedParams): void + { + $db = $this->getConnection(); + $this->assertSame($expectedSQL, $db->getQueryBuilder()->insertEx($table, $columns, $params)); + $this->assertSame($expectedParams, $params); + } + public function testLimit(): void { $db = $this->getConnection(); diff --git a/tests/SchemaTest.php b/tests/SchemaTest.php index f321c588d..d8b1ca49c 100644 --- a/tests/SchemaTest.php +++ b/tests/SchemaTest.php @@ -52,7 +52,7 @@ public function testGetPrimaryKey(): void 'testPKTable', ['id' => SchemaPDOMssql::TYPE_PK, 'bar' => SchemaPDOMssql::TYPE_INTEGER] )->execute(); - $insertResult = $db->getSchema()->insert('testPKTable', ['bar' => 1]); + $insertResult = $db->createCommand()->insertEx('testPKTable', ['bar' => 1]); $selectResult = $db->createCommand('select [id] from [testPKTable] where [bar]=1')->queryOne(); $this->assertEquals($selectResult['id'], $insertResult['id']); } From 7cc4e1f859559405d8f39ff615cc770560823baa Mon Sep 17 00:00:00 2001 From: darkdef Date: Mon, 28 Feb 2022 08:21:08 +0300 Subject: [PATCH 3/3] styleci fix --- src/DMLQueryBuilder.php | 2 +- src/PDO/SchemaPDOMssql.php | 1 - 2 files changed, 1 insertion(+), 2 deletions(-) diff --git a/src/DMLQueryBuilder.php b/src/DMLQueryBuilder.php index 20eb734ea..ce8dcb6a0 100644 --- a/src/DMLQueryBuilder.php +++ b/src/DMLQueryBuilder.php @@ -43,7 +43,7 @@ public function insertEx(string $table, QueryInterface|array $columns, array &$p $cols = []; $tableSchema = $this->queryBuilder->schema()->getTableSchema($table); $returnColumns = $tableSchema?->getColumns() ?? []; - foreach($returnColumns as $returnColumn) { + foreach ($returnColumns as $returnColumn) { $cols[] = $this->queryBuilder->quoter()->quoteColumnName($returnColumn->getName()) . ' ' . $returnColumn->getDbType() . (in_array( diff --git a/src/PDO/SchemaPDOMssql.php b/src/PDO/SchemaPDOMssql.php index b438eaa31..db9ecbe2e 100644 --- a/src/PDO/SchemaPDOMssql.php +++ b/src/PDO/SchemaPDOMssql.php @@ -32,7 +32,6 @@ use function str_replace; use function strcasecmp; use function stripos; -use function version_compare; /** * Schema is the class for retrieving metadata from MS SQL Server databases (version 2008 and above).