Skip to content
Merged
Show file tree
Hide file tree
Changes from all 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
40 changes: 25 additions & 15 deletions src/DMLQueryBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -46,27 +46,37 @@ public function insertEx(string $table, QueryInterface|array $columns, array &$p
*/
[$names, $placeholders, $values, $params] = $this->prepareInsertValues($table, $columns, $params);

$sql = 'INSERT INTO '
. $this->quoter->quoteTableName($table)
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
. ' OUTPUT INSERTED.* INTO @temporary_inserted'
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : (string) $values);

$cols = [];
$createdCols = $insertedCols = [];
$tableSchema = $this->schema->getTableSchema($table);
$returnColumns = $tableSchema?->getColumns() ?? [];
foreach ($returnColumns as $returnColumn) {
$cols[] = $this->quoter->quoteColumnName($returnColumn->getName()) . ' '
. $returnColumn->getDbType()
. (in_array(
$returnColumn->getDbType(),
['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary']
) ? '(MAX)' : '')
. ' ' . ($returnColumn->isAllowNull() ? 'NULL' : '');
if ($returnColumn->isComputed()) {
continue;
}

$dbType = $returnColumn->getDbType();
if (in_array($dbType, ['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary'])) {
$dbType .= '(MAX)';
}
if ($returnColumn->getDbType() === Schema::TYPE_TIMESTAMP) {
$dbType = $returnColumn->isAllowNull() ? 'varbinary(8)' : 'binary(8)';
}

$quotedName = $this->quoter->quoteColumnName($returnColumn->getName());
$createdCols[] = $quotedName . ' ' . $dbType . ' ' . ($returnColumn->isAllowNull() ? 'NULL' : '');
$insertedCols[] = 'INSERTED.' . $quotedName;
}

return 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE (' . implode(', ', $cols) . ');'
. $sql . ';SELECT * FROM @temporary_inserted';
$sql = 'INSERT INTO '
. $this->quoter->quoteTableName($table)
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
. ' OUTPUT ' . implode(',', $insertedCols) . ' INTO @temporary_inserted'
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : (string) $values);


return 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE (' . implode(', ', $createdCols) . ');'
. $sql . ';SELECT * FROM @temporary_inserted;';
}

/**
Expand Down
2 changes: 2 additions & 0 deletions src/Schema.php
Original file line number Diff line number Diff line change
Expand Up @@ -394,6 +394,7 @@ protected function loadColumnSchema(array $info): ColumnSchemaInterface
$column->enumValues([]); // mssql has only vague equivalents to enum
$column->primaryKey(false); // primary key will be determined in findColumns() method
$column->autoIncrement($info['is_identity'] === '1');
$column->computed((bool)$info['is_computed']);
$column->unsigned(stripos($column->getDbType(), 'unsigned') !== false);
$column->comment($info['comment'] ?? '');
$column->type(self::TYPE_STRING);
Expand Down Expand Up @@ -482,6 +483,7 @@ protected function findColumns(TableSchemaInterface $table): bool
END AS 'data_type',
[t1].[column_default],
COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsComputed') AS is_computed,
(
SELECT CONVERT(VARCHAR, [t2].[value])
FROM [sys].[extended_properties] AS [t2]
Expand Down
69 changes: 68 additions & 1 deletion tests/CommandTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,9 @@

namespace Yiisoft\Db\Mssql\Tests;

use Throwable;
use Yiisoft\Db\Exception\InvalidArgumentException;
use Yiisoft\Db\Expression\Expression;
use Yiisoft\Db\Mssql\Schema;
use Yiisoft\Db\Query\Query;
use Yiisoft\Db\TestSupport\TestCommandTrait;
Expand Down Expand Up @@ -248,7 +250,7 @@ public function testInsertSelectFailed(mixed $invalidSelectColumns): void
/**
* @dataProvider \Yiisoft\Db\Mssql\Tests\Provider\CommandProvider::dataInsertVarbinary
*
* @throws \Throwable
* @throws Throwable
* @throws \Yiisoft\Db\Exception\Exception
* @throws \Yiisoft\Db\Exception\InvalidConfigException
*/
Expand Down Expand Up @@ -276,4 +278,69 @@ public function testUpsert(array $firstData, array $secondData): void
$this->assertEquals(1, $db->createCommand('SELECT COUNT(*) FROM {{T_upsert}}')->queryScalar());
$this->performAndCompareUpsertResult($db, $secondData);
}

/**
* @throws Throwable
*/
public function testInsertExWithComputedColumn(): void
{
$db = $this->getConnection(true);

$sql = 'CREATE OR ALTER FUNCTION TESTFUNC(@Number INT)
RETURNS VARCHAR(15)
AS
BEGIN
RETURN (SELECT TRY_CONVERT(VARCHAR(15),@Number))
END';
$db->createCommand($sql)->execute();

$sql = 'ALTER TABLE [dbo].[test_trigger] ADD [computed_column] AS dbo.TESTFUNC([ID])';
$db->createCommand($sql)->execute();

$insertedString = 'test';

$transaction = $db->beginTransaction();
$result = $db->createCommand()->insertEx('test_trigger', ['stringcol' => $insertedString]);
$transaction->commit();

$this->assertIsArray($result);
$this->assertEquals($insertedString, $result['stringcol']);
$this->assertEquals(1, $result['id']);
}

/**
* @throws Throwable
*/
public function testInsertExWithRowVersionColumn(): void
{
$db = $this->getConnection(true);

$sql = 'ALTER TABLE [dbo].[test_trigger] ADD [RV] rowversion';
$db->createCommand($sql)->execute();

$insertedString = 'test';
$result = $db->createCommand()->insertEx('test_trigger', ['stringcol' => $insertedString]);

$this->assertIsArray($result);
$this->assertEquals($insertedString, $result['stringcol']);
$this->assertEquals(1, $result['id']);
}

/**
* @throws Throwable
*/
public function testInsertExWithRowVersionNullColumn(): void
{
$db = $this->getConnection(true);

$sql = 'ALTER TABLE [dbo].[test_trigger] ADD [RV] rowversion NULL';
$db->createCommand($sql)->execute();

$insertedString = 'test';
$result = $db->createCommand()->insertEx('test_trigger', ['stringcol' => $insertedString, 'RV' => new Expression('DEFAULT')]);

$this->assertIsArray($result);
$this->assertEquals($insertedString, $result['stringcol']);
$this->assertEquals(1, $result['id']);
}
}
17 changes: 9 additions & 8 deletions tests/Provider/QueryBuilderProvider.php
Original file line number Diff line number Diff line change
Expand Up @@ -224,8 +224,9 @@ public function insertExProvider(): array
],
[],
$this->replaceQuotes('SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [email] varchar(128) , [name] varchar(128) NULL, [address] text NULL, [status] int NULL, [profile_id] int NULL);' .
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]]) OUTPUT INSERTED.* INTO @temporary_inserted VALUES (:qp0, :qp1, :qp2, :qp3, :qp4);' .
'SELECT * FROM @temporary_inserted'),
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]]) OUTPUT INSERTED.[id],INSERTED.[email],INSERTED.[name],INSERTED.[address],INSERTED.[status],INSERTED.[profile_id] ' .
'INTO @temporary_inserted VALUES (:qp0, :qp1, :qp2, :qp3, :qp4);' .
'SELECT * FROM @temporary_inserted;'),
[
':qp0' => 'test@example.com',
':qp1' => 'silverfire',
Expand All @@ -242,8 +243,8 @@ public function insertExProvider(): array
],
[],
'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([int_col] int , [int_col2] int NULL, [tinyint_col] tinyint NULL, [smallint_col] smallint NULL, [char_col] char(100) , [char_col2] varchar(100) NULL, [char_col3] text NULL, [float_col] decimal , [float_col2] float NULL, [blob_col] varbinary(MAX) NULL, [numeric_col] decimal NULL, [time] datetime , [bool_col] tinyint , [bool_col2] tinyint NULL);' .
'INSERT INTO {{%type}} ({{%type}}.[[related_id]], [[time]]) OUTPUT INSERTED.* INTO @temporary_inserted VALUES (:qp0, now());' .
'SELECT * FROM @temporary_inserted',
'INSERT INTO {{%type}} ({{%type}}.[[related_id]], [[time]]) OUTPUT INSERTED.[int_col],INSERTED.[int_col2],INSERTED.[tinyint_col],INSERTED.[smallint_col],INSERTED.[char_col],INSERTED.[char_col2],INSERTED.[char_col3],INSERTED.[float_col],INSERTED.[float_col2],INSERTED.[blob_col],INSERTED.[numeric_col],INSERTED.[time],INSERTED.[bool_col],INSERTED.[bool_col2] INTO @temporary_inserted VALUES (:qp0, now());' .
'SELECT * FROM @temporary_inserted;',
[
':qp0' => null,
],
Expand All @@ -260,8 +261,8 @@ public function insertExProvider(): array
],
[':phBar' => 'bar'],
$this->replaceQuotes('SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [email] varchar(128) , [name] varchar(128) NULL, [address] text NULL, [status] int NULL, [profile_id] int NULL);' .
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]], [[col]]) OUTPUT INSERTED.* INTO @temporary_inserted VALUES (:qp1, :qp2, :qp3, :qp4, :qp5, CONCAT(:phFoo, :phBar));' .
'SELECT * FROM @temporary_inserted'),
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]], [[col]]) OUTPUT INSERTED.[id],INSERTED.[email],INSERTED.[name],INSERTED.[address],INSERTED.[status],INSERTED.[profile_id] INTO @temporary_inserted VALUES (:qp1, :qp2, :qp3, :qp4, :qp5, CONCAT(:phFoo, :phBar));' .
'SELECT * FROM @temporary_inserted;'),
[
':phBar' => 'bar',
':qp1' => 'test@example.com',
Expand Down Expand Up @@ -293,8 +294,8 @@ public function insertExProvider(): array
]),
[':phBar' => 'bar'],
$this->replaceQuotes('SET NOCOUNT ON;DECLARE @temporary_inserted TABLE ([id] int , [email] varchar(128) , [name] varchar(128) NULL, [address] text NULL, [status] int NULL, [profile_id] int NULL);' .
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]]) OUTPUT INSERTED.* INTO @temporary_inserted 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));' .
'SELECT * FROM @temporary_inserted'),
'INSERT INTO [[customer]] ([[email]], [[name]], [[address]], [[is_active]], [[related_id]]) OUTPUT INSERTED.[id],INSERTED.[email],INSERTED.[name],INSERTED.[address],INSERTED.[status],INSERTED.[profile_id] INTO @temporary_inserted 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));' .
'SELECT * FROM @temporary_inserted;'),
[
':phBar' => 'bar',
':qp1' => 'test@example.com',
Expand Down