1 | <?php |
||
2 | |||
3 | declare(strict_types=1); |
||
4 | |||
5 | namespace Yiisoft\Db\Mssql; |
||
6 | |||
7 | use JsonException; |
||
8 | use Yiisoft\Db\Constraint\Constraint; |
||
9 | use Yiisoft\Db\Exception\Exception; |
||
10 | use Yiisoft\Db\Exception\InvalidArgumentException; |
||
11 | use Yiisoft\Db\Exception\InvalidConfigException; |
||
12 | use Yiisoft\Db\Exception\NotSupportedException; |
||
13 | use Yiisoft\Db\Expression\Expression; |
||
14 | use Yiisoft\Db\Query\QueryInterface; |
||
15 | use Yiisoft\Db\QueryBuilder\AbstractDMLQueryBuilder; |
||
16 | |||
17 | use function array_flip; |
||
18 | use function array_intersect_key; |
||
19 | use function implode; |
||
20 | use function in_array; |
||
21 | |||
22 | /** |
||
23 | * Implements a DML (Data Manipulation Language) SQL statements for MSSQL Server. |
||
24 | */ |
||
25 | final class DMLQueryBuilder extends AbstractDMLQueryBuilder |
||
26 | { |
||
27 | /** |
||
28 | * @throws Exception |
||
29 | * @throws InvalidArgumentException |
||
30 | * @throws InvalidConfigException |
||
31 | * @throws NotSupportedException |
||
32 | */ |
||
33 | 14 | public function insertWithReturningPks(string $table, QueryInterface|array $columns, array &$params = []): string |
|
34 | { |
||
35 | 14 | $tableSchema = $this->schema->getTableSchema($table); |
|
36 | 14 | $primaryKeys = $tableSchema?->getPrimaryKey(); |
|
37 | |||
38 | 14 | if (empty($primaryKeys)) { |
|
39 | 1 | return $this->insert($table, $columns, $params); |
|
40 | } |
||
41 | |||
42 | 13 | $createdCols = []; |
|
43 | 13 | $insertedCols = []; |
|
44 | 13 | $returnColumns = array_intersect_key($tableSchema?->getColumns() ?? [], array_flip($primaryKeys)); |
|
45 | |||
46 | 13 | foreach ($returnColumns as $returnColumn) { |
|
47 | 13 | $dbType = $returnColumn->getDbType(); |
|
48 | |||
49 | 13 | if (in_array($dbType, ['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary'], true)) { |
|
50 | $dbType .= '(MAX)'; |
||
51 | 13 | } elseif ($dbType === 'timestamp') { |
|
52 | $dbType = $returnColumn->isAllowNull() ? 'varbinary(8)' : 'binary(8)'; |
||
53 | } |
||
54 | |||
55 | 13 | $quotedName = $this->quoter->quoteColumnName($returnColumn->getName()); |
|
56 | 13 | $createdCols[] = $quotedName . ' ' . (string) $dbType . ' ' . ($returnColumn->isAllowNull() ? 'NULL' : ''); |
|
57 | 13 | $insertedCols[] = 'INSERTED.' . $quotedName; |
|
58 | } |
||
59 | |||
60 | 13 | [$names, $placeholders, $values, $params] = $this->prepareInsertValues($table, $columns, $params); |
|
61 | |||
62 | 13 | $sql = 'INSERT INTO ' . $this->quoter->quoteTableName($table) |
|
63 | 13 | . (!empty($names) ? ' (' . implode(', ', $names) . ')' : '') |
|
64 | 13 | . ' OUTPUT ' . implode(',', $insertedCols) . ' INTO @temporary_inserted' |
|
65 | 13 | . (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : ' ' . $values); |
|
66 | |||
67 | 13 | return 'SET NOCOUNT ON;DECLARE @temporary_inserted TABLE (' . implode(', ', $createdCols) . ');' |
|
68 | 13 | . $sql . ';SELECT * FROM @temporary_inserted;'; |
|
69 | } |
||
70 | |||
71 | /** |
||
72 | * @throws InvalidArgumentException |
||
73 | */ |
||
74 | 5 | public function resetSequence(string $table, int|string $value = null): string |
|
75 | { |
||
76 | 5 | $tableSchema = $this->schema->getTableSchema($table); |
|
77 | |||
78 | 5 | if ($tableSchema === null) { |
|
79 | 1 | throw new InvalidArgumentException("Table not found: '$table'."); |
|
80 | } |
||
81 | |||
82 | 4 | $sequenceName = $tableSchema->getSequenceName(); |
|
83 | |||
84 | 4 | if ($sequenceName === null) { |
|
85 | 1 | throw new InvalidArgumentException("There is not sequence associated with table '$table'.'"); |
|
86 | } |
||
87 | |||
88 | 3 | $tableName = $this->quoter->quoteTableName($table); |
|
89 | |||
90 | 3 | if ($value === null) { |
|
91 | 3 | return "DBCC CHECKIDENT ('$tableName', RESEED, 0) WITH NO_INFOMSGS;DBCC CHECKIDENT ('$tableName', RESEED)"; |
|
92 | } |
||
93 | |||
94 | 1 | return "DBCC CHECKIDENT ('$tableName', RESEED, $value)"; |
|
95 | } |
||
96 | |||
97 | /** |
||
98 | * @throws Exception |
||
99 | * @throws InvalidArgumentException |
||
100 | * @throws InvalidConfigException |
||
101 | * @throws JsonException |
||
102 | * @throws NotSupportedException |
||
103 | */ |
||
104 | 37 | public function upsert( |
|
105 | string $table, |
||
106 | QueryInterface|array $insertColumns, |
||
107 | bool|array $updateColumns, |
||
108 | array &$params = [] |
||
109 | ): string { |
||
110 | /** @psalm-var Constraint[] $constraints */ |
||
111 | 37 | $constraints = []; |
|
112 | |||
113 | 37 | [$uniqueNames, $insertNames, $updateNames] = $this->prepareUpsertColumns( |
|
114 | 37 | $table, |
|
115 | 37 | $insertColumns, |
|
116 | 37 | $updateColumns, |
|
117 | 37 | $constraints |
|
118 | 37 | ); |
|
119 | |||
120 | 37 | if (empty($uniqueNames)) { |
|
121 | 2 | return $this->insert($table, $insertColumns, $params); |
|
122 | } |
||
123 | |||
124 | 35 | $onCondition = ['or']; |
|
125 | 35 | $quotedTableName = $this->quoter->quoteTableName($table); |
|
126 | |||
127 | 35 | foreach ($constraints as $constraint) { |
|
128 | 35 | $constraintCondition = ['and']; |
|
129 | 35 | $columnNames = (array) $constraint->getColumnNames(); |
|
130 | |||
131 | /** @psalm-var string[] $columnNames */ |
||
132 | 35 | foreach ($columnNames as $name) { |
|
133 | 35 | $quotedName = $this->quoter->quoteColumnName($name); |
|
134 | 35 | $constraintCondition[] = "$quotedTableName.$quotedName=[EXCLUDED].$quotedName"; |
|
135 | } |
||
136 | |||
137 | 35 | $onCondition[] = $constraintCondition; |
|
138 | } |
||
139 | |||
140 | 35 | $on = $this->queryBuilder->buildCondition($onCondition, $params); |
|
141 | |||
142 | 35 | [, $placeholders, $values, $params] = $this->prepareInsertValues($table, $insertColumns, $params); |
|
143 | |||
144 | 35 | $mergeSql = 'MERGE ' . $quotedTableName . ' WITH (HOLDLOCK) USING (' |
|
145 | 35 | . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : $values) |
|
146 | 35 | . ') AS [EXCLUDED] (' . implode(', ', $insertNames) . ') ' . "ON ($on)"; |
|
147 | |||
148 | 35 | $insertValues = []; |
|
149 | |||
150 | 35 | foreach ($insertNames as $quotedName) { |
|
151 | 35 | $insertValues[] = '[EXCLUDED].' . $quotedName; |
|
152 | } |
||
153 | |||
154 | 35 | $insertSql = 'INSERT (' . implode(', ', $insertNames) . ') VALUES (' . implode(', ', $insertValues) . ')'; |
|
155 | |||
156 | 35 | if ($updateColumns === false || $updateNames === []) { |
|
0 ignored issues
–
show
introduced
by
![]() |
|||
157 | /** there are no columns to update */ |
||
158 | 14 | return "$mergeSql WHEN NOT MATCHED THEN $insertSql;"; |
|
159 | } |
||
160 | |||
161 | 21 | if ($updateColumns === true) { |
|
0 ignored issues
–
show
|
|||
162 | 10 | $updateColumns = []; |
|
163 | |||
164 | /** @psalm-var string[] $updateNames */ |
||
165 | 10 | foreach ($updateNames as $quotedName) { |
|
166 | 10 | $updateColumns[$quotedName] = new Expression('[EXCLUDED].' . $quotedName); |
|
167 | } |
||
168 | } |
||
169 | |||
170 | 21 | [$updates, $params] = $this->prepareUpdateSets($table, $updateColumns, $params); |
|
171 | |||
172 | 21 | return "$mergeSql WHEN MATCHED THEN UPDATE SET " . implode(', ', $updates) |
|
173 | 21 | . " WHEN NOT MATCHED THEN $insertSql;"; |
|
174 | } |
||
175 | } |
||
176 |