Schema.php 28 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827
  1. <?php
  2. /**
  3. * @link https://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license https://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\mssql;
  8. use Yii;
  9. use yii\db\CheckConstraint;
  10. use yii\db\Constraint;
  11. use yii\db\ConstraintFinderInterface;
  12. use yii\db\ConstraintFinderTrait;
  13. use yii\db\DefaultValueConstraint;
  14. use yii\db\ForeignKeyConstraint;
  15. use yii\db\IndexConstraint;
  16. use yii\db\ViewFinderTrait;
  17. use yii\helpers\ArrayHelper;
  18. /**
  19. * Schema is the class for retrieving metadata from MS SQL Server databases (version 2008 and above).
  20. *
  21. * @author Timur Ruziev <resurtm@gmail.com>
  22. * @since 2.0
  23. */
  24. class Schema extends \yii\db\Schema implements ConstraintFinderInterface
  25. {
  26. use ViewFinderTrait;
  27. use ConstraintFinderTrait;
  28. /**
  29. * {@inheritdoc}
  30. */
  31. public $columnSchemaClass = 'yii\db\mssql\ColumnSchema';
  32. /**
  33. * @var string the default schema used for the current session.
  34. */
  35. public $defaultSchema = 'dbo';
  36. /**
  37. * @var array mapping from physical column types (keys) to abstract column types (values)
  38. */
  39. public $typeMap = [
  40. // exact numbers
  41. 'bigint' => self::TYPE_BIGINT,
  42. 'numeric' => self::TYPE_DECIMAL,
  43. 'bit' => self::TYPE_SMALLINT,
  44. 'smallint' => self::TYPE_SMALLINT,
  45. 'decimal' => self::TYPE_DECIMAL,
  46. 'smallmoney' => self::TYPE_MONEY,
  47. 'int' => self::TYPE_INTEGER,
  48. 'tinyint' => self::TYPE_TINYINT,
  49. 'money' => self::TYPE_MONEY,
  50. // approximate numbers
  51. 'float' => self::TYPE_FLOAT,
  52. 'double' => self::TYPE_DOUBLE,
  53. 'real' => self::TYPE_FLOAT,
  54. // date and time
  55. 'date' => self::TYPE_DATE,
  56. 'datetimeoffset' => self::TYPE_DATETIME,
  57. 'datetime2' => self::TYPE_DATETIME,
  58. 'smalldatetime' => self::TYPE_DATETIME,
  59. 'datetime' => self::TYPE_DATETIME,
  60. 'time' => self::TYPE_TIME,
  61. // character strings
  62. 'char' => self::TYPE_CHAR,
  63. 'varchar' => self::TYPE_STRING,
  64. 'text' => self::TYPE_TEXT,
  65. // unicode character strings
  66. 'nchar' => self::TYPE_CHAR,
  67. 'nvarchar' => self::TYPE_STRING,
  68. 'ntext' => self::TYPE_TEXT,
  69. // binary strings
  70. 'binary' => self::TYPE_BINARY,
  71. 'varbinary' => self::TYPE_BINARY,
  72. 'image' => self::TYPE_BINARY,
  73. // other data types
  74. // 'cursor' type cannot be used with tables
  75. 'timestamp' => self::TYPE_TIMESTAMP,
  76. 'hierarchyid' => self::TYPE_STRING,
  77. 'uniqueidentifier' => self::TYPE_STRING,
  78. 'sql_variant' => self::TYPE_STRING,
  79. 'xml' => self::TYPE_STRING,
  80. 'table' => self::TYPE_STRING,
  81. ];
  82. /**
  83. * {@inheritdoc}
  84. */
  85. protected $tableQuoteCharacter = ['[', ']'];
  86. /**
  87. * {@inheritdoc}
  88. */
  89. protected $columnQuoteCharacter = ['[', ']'];
  90. /**
  91. * Resolves the table name and schema name (if any).
  92. * @param string $name the table name
  93. * @return TableSchema resolved table, schema, etc. names.
  94. */
  95. protected function resolveTableName($name)
  96. {
  97. $resolvedName = new TableSchema();
  98. $parts = $this->getTableNameParts($name);
  99. $partCount = count($parts);
  100. if ($partCount === 4) {
  101. // server name, catalog name, schema name and table name passed
  102. $resolvedName->catalogName = $parts[1];
  103. $resolvedName->schemaName = $parts[2];
  104. $resolvedName->name = $parts[3];
  105. $resolvedName->fullName = $resolvedName->catalogName . '.' . $resolvedName->schemaName . '.' . $resolvedName->name;
  106. } elseif ($partCount === 3) {
  107. // catalog name, schema name and table name passed
  108. $resolvedName->catalogName = $parts[0];
  109. $resolvedName->schemaName = $parts[1];
  110. $resolvedName->name = $parts[2];
  111. $resolvedName->fullName = $resolvedName->catalogName . '.' . $resolvedName->schemaName . '.' . $resolvedName->name;
  112. } elseif ($partCount === 2) {
  113. // only schema name and table name passed
  114. $resolvedName->schemaName = $parts[0];
  115. $resolvedName->name = $parts[1];
  116. $resolvedName->fullName = ($resolvedName->schemaName !== $this->defaultSchema ? $resolvedName->schemaName . '.' : '') . $resolvedName->name;
  117. } else {
  118. // only table name passed
  119. $resolvedName->schemaName = $this->defaultSchema;
  120. $resolvedName->fullName = $resolvedName->name = $parts[0];
  121. }
  122. return $resolvedName;
  123. }
  124. /**
  125. * {@inheritDoc}
  126. * @param string $name
  127. * @return array
  128. * @since 2.0.22
  129. */
  130. protected function getTableNameParts($name)
  131. {
  132. $parts = [$name];
  133. preg_match_all('/([^.\[\]]+)|\[([^\[\]]+)\]/', $name, $matches);
  134. if (isset($matches[0]) && is_array($matches[0]) && !empty($matches[0])) {
  135. $parts = $matches[0];
  136. }
  137. $parts = str_replace(['[', ']'], '', $parts);
  138. return $parts;
  139. }
  140. /**
  141. * {@inheritdoc}
  142. * @see https://docs.microsoft.com/en-us/sql/relational-databases/system-catalog-views/sys-database-principals-transact-sql
  143. */
  144. protected function findSchemaNames()
  145. {
  146. static $sql = <<<'SQL'
  147. SELECT [s].[name]
  148. FROM [sys].[schemas] AS [s]
  149. INNER JOIN [sys].[database_principals] AS [p] ON [p].[principal_id] = [s].[principal_id]
  150. WHERE [p].[is_fixed_role] = 0 AND [p].[sid] IS NOT NULL
  151. ORDER BY [s].[name] ASC
  152. SQL;
  153. return $this->db->createCommand($sql)->queryColumn();
  154. }
  155. /**
  156. * {@inheritdoc}
  157. */
  158. protected function findTableNames($schema = '')
  159. {
  160. if ($schema === '') {
  161. $schema = $this->defaultSchema;
  162. }
  163. $sql = <<<'SQL'
  164. SELECT [t].[table_name]
  165. FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
  166. WHERE [t].[table_schema] = :schema AND [t].[table_type] IN ('BASE TABLE', 'VIEW')
  167. ORDER BY [t].[table_name]
  168. SQL;
  169. return $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
  170. }
  171. /**
  172. * {@inheritdoc}
  173. */
  174. protected function loadTableSchema($name)
  175. {
  176. $table = new TableSchema();
  177. $this->resolveTableNames($table, $name);
  178. $this->findPrimaryKeys($table);
  179. if ($this->findColumns($table)) {
  180. $this->findForeignKeys($table);
  181. return $table;
  182. }
  183. return null;
  184. }
  185. /**
  186. * {@inheritdoc}
  187. */
  188. protected function getSchemaMetadata($schema, $type, $refresh)
  189. {
  190. $metadata = [];
  191. $methodName = 'getTable' . ucfirst($type);
  192. $tableNames = array_map(function ($table) {
  193. return $this->quoteSimpleTableName($table);
  194. }, $this->getTableNames($schema, $refresh));
  195. foreach ($tableNames as $name) {
  196. if ($schema !== '') {
  197. $name = $schema . '.' . $name;
  198. }
  199. $tableMetadata = $this->$methodName($name, $refresh);
  200. if ($tableMetadata !== null) {
  201. $metadata[] = $tableMetadata;
  202. }
  203. }
  204. return $metadata;
  205. }
  206. /**
  207. * {@inheritdoc}
  208. */
  209. protected function loadTablePrimaryKey($tableName)
  210. {
  211. return $this->loadTableConstraints($tableName, 'primaryKey');
  212. }
  213. /**
  214. * {@inheritdoc}
  215. */
  216. protected function loadTableForeignKeys($tableName)
  217. {
  218. return $this->loadTableConstraints($tableName, 'foreignKeys');
  219. }
  220. /**
  221. * {@inheritdoc}
  222. */
  223. protected function loadTableIndexes($tableName)
  224. {
  225. static $sql = <<<'SQL'
  226. SELECT
  227. [i].[name] AS [name],
  228. [iccol].[name] AS [column_name],
  229. [i].[is_unique] AS [index_is_unique],
  230. [i].[is_primary_key] AS [index_is_primary]
  231. FROM [sys].[indexes] AS [i]
  232. INNER JOIN [sys].[index_columns] AS [ic]
  233. ON [ic].[object_id] = [i].[object_id] AND [ic].[index_id] = [i].[index_id]
  234. INNER JOIN [sys].[columns] AS [iccol]
  235. ON [iccol].[object_id] = [ic].[object_id] AND [iccol].[column_id] = [ic].[column_id]
  236. WHERE [i].[object_id] = OBJECT_ID(:fullName)
  237. ORDER BY [ic].[key_ordinal] ASC
  238. SQL;
  239. $resolvedName = $this->resolveTableName($tableName);
  240. $indexes = $this->db->createCommand($sql, [
  241. ':fullName' => $resolvedName->fullName,
  242. ])->queryAll();
  243. $indexes = $this->normalizePdoRowKeyCase($indexes, true);
  244. $indexes = ArrayHelper::index($indexes, null, 'name');
  245. $result = [];
  246. foreach ($indexes as $name => $index) {
  247. $result[] = new IndexConstraint([
  248. 'isPrimary' => (bool)$index[0]['index_is_primary'],
  249. 'isUnique' => (bool)$index[0]['index_is_unique'],
  250. 'name' => $name,
  251. 'columnNames' => ArrayHelper::getColumn($index, 'column_name'),
  252. ]);
  253. }
  254. return $result;
  255. }
  256. /**
  257. * {@inheritdoc}
  258. */
  259. protected function loadTableUniques($tableName)
  260. {
  261. return $this->loadTableConstraints($tableName, 'uniques');
  262. }
  263. /**
  264. * {@inheritdoc}
  265. */
  266. protected function loadTableChecks($tableName)
  267. {
  268. return $this->loadTableConstraints($tableName, 'checks');
  269. }
  270. /**
  271. * {@inheritdoc}
  272. */
  273. protected function loadTableDefaultValues($tableName)
  274. {
  275. return $this->loadTableConstraints($tableName, 'defaults');
  276. }
  277. /**
  278. * {@inheritdoc}
  279. */
  280. public function createSavepoint($name)
  281. {
  282. $this->db->createCommand("SAVE TRANSACTION $name")->execute();
  283. }
  284. /**
  285. * {@inheritdoc}
  286. */
  287. public function releaseSavepoint($name)
  288. {
  289. // does nothing as MSSQL does not support this
  290. }
  291. /**
  292. * {@inheritdoc}
  293. */
  294. public function rollBackSavepoint($name)
  295. {
  296. $this->db->createCommand("ROLLBACK TRANSACTION $name")->execute();
  297. }
  298. /**
  299. * Creates a query builder for the MSSQL database.
  300. * @return QueryBuilder query builder interface.
  301. */
  302. public function createQueryBuilder()
  303. {
  304. return Yii::createObject(QueryBuilder::className(), [$this->db]);
  305. }
  306. /**
  307. * Resolves the table name and schema name (if any).
  308. * @param TableSchema $table the table metadata object
  309. * @param string $name the table name
  310. */
  311. protected function resolveTableNames($table, $name)
  312. {
  313. $parts = $this->getTableNameParts($name);
  314. $partCount = count($parts);
  315. if ($partCount === 4) {
  316. // server name, catalog name, schema name and table name passed
  317. $table->catalogName = $parts[1];
  318. $table->schemaName = $parts[2];
  319. $table->name = $parts[3];
  320. $table->fullName = $table->catalogName . '.' . $table->schemaName . '.' . $table->name;
  321. } elseif ($partCount === 3) {
  322. // catalog name, schema name and table name passed
  323. $table->catalogName = $parts[0];
  324. $table->schemaName = $parts[1];
  325. $table->name = $parts[2];
  326. $table->fullName = $table->catalogName . '.' . $table->schemaName . '.' . $table->name;
  327. } elseif ($partCount === 2) {
  328. // only schema name and table name passed
  329. $table->schemaName = $parts[0];
  330. $table->name = $parts[1];
  331. $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
  332. } else {
  333. // only table name passed
  334. $table->schemaName = $this->defaultSchema;
  335. $table->fullName = $table->name = $parts[0];
  336. }
  337. }
  338. /**
  339. * Loads the column information into a [[ColumnSchema]] object.
  340. * @param array $info column information
  341. * @return ColumnSchema the column schema object
  342. */
  343. protected function loadColumnSchema($info)
  344. {
  345. $isVersion2017orLater = version_compare($this->db->getSchema()->getServerVersion(), '14', '>=');
  346. $column = $this->createColumnSchema();
  347. $column->name = $info['column_name'];
  348. $column->allowNull = $info['is_nullable'] === 'YES';
  349. $column->dbType = $info['data_type'];
  350. $column->enumValues = []; // mssql has only vague equivalents to enum
  351. $column->isPrimaryKey = null; // primary key will be determined in findColumns() method
  352. $column->autoIncrement = $info['is_identity'] == 1;
  353. $column->isComputed = (bool)$info['is_computed'];
  354. $column->unsigned = stripos($column->dbType, 'unsigned') !== false;
  355. $column->comment = $info['comment'] === null ? '' : $info['comment'];
  356. $column->type = self::TYPE_STRING;
  357. if (preg_match('/^(\w+)(?:\(([^\)]+)\))?/', $column->dbType, $matches)) {
  358. $type = $matches[1];
  359. if (isset($this->typeMap[$type])) {
  360. $column->type = $this->typeMap[$type];
  361. }
  362. if ($isVersion2017orLater && $type === 'bit') {
  363. $column->type = 'boolean';
  364. }
  365. if (!empty($matches[2])) {
  366. $values = explode(',', $matches[2]);
  367. $column->size = $column->precision = (int) $values[0];
  368. if (isset($values[1])) {
  369. $column->scale = (int) $values[1];
  370. }
  371. if ($isVersion2017orLater === false) {
  372. if ($column->size === 1 && ($type === 'tinyint' || $type === 'bit')) {
  373. $column->type = 'boolean';
  374. } elseif ($type === 'bit') {
  375. if ($column->size > 32) {
  376. $column->type = 'bigint';
  377. } elseif ($column->size === 32) {
  378. $column->type = 'integer';
  379. }
  380. }
  381. }
  382. }
  383. }
  384. $column->phpType = $this->getColumnPhpType($column);
  385. if ($info['column_default'] === '(NULL)') {
  386. $info['column_default'] = null;
  387. }
  388. if (!$column->isPrimaryKey && ($column->type !== 'timestamp' || $info['column_default'] !== 'CURRENT_TIMESTAMP')) {
  389. $column->defaultValue = $column->defaultPhpTypecast($info['column_default']);
  390. }
  391. return $column;
  392. }
  393. /**
  394. * Collects the metadata of table columns.
  395. * @param TableSchema $table the table metadata
  396. * @return bool whether the table exists in the database
  397. */
  398. protected function findColumns($table)
  399. {
  400. $columnsTableName = 'INFORMATION_SCHEMA.COLUMNS';
  401. $whereSql = '[t1].[table_name] = ' . $this->db->quoteValue($table->name);
  402. if ($table->catalogName !== null) {
  403. $columnsTableName = "{$table->catalogName}.{$columnsTableName}";
  404. $whereSql .= " AND [t1].[table_catalog] = '{$table->catalogName}'";
  405. }
  406. if ($table->schemaName !== null) {
  407. $whereSql .= " AND [t1].[table_schema] = '{$table->schemaName}'";
  408. }
  409. $columnsTableName = $this->quoteTableName($columnsTableName);
  410. $sql = <<<SQL
  411. SELECT
  412. [t1].[column_name],
  413. [t1].[is_nullable],
  414. CASE WHEN [t1].[data_type] IN ('char','varchar','nchar','nvarchar','binary','varbinary') THEN
  415. CASE WHEN [t1].[character_maximum_length] = NULL OR [t1].[character_maximum_length] = -1 THEN
  416. [t1].[data_type]
  417. ELSE
  418. [t1].[data_type] + '(' + LTRIM(RTRIM(CONVERT(CHAR,[t1].[character_maximum_length]))) + ')'
  419. END
  420. ELSE
  421. [t1].[data_type]
  422. END AS 'data_type',
  423. [t1].[column_default],
  424. COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
  425. COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsComputed') AS is_computed,
  426. (
  427. SELECT CONVERT(VARCHAR, [t2].[value])
  428. FROM [sys].[extended_properties] AS [t2]
  429. WHERE
  430. [t2].[class] = 1 AND
  431. [t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
  432. [t2].[name] = 'MS_Description' AND
  433. [t2].[major_id] = OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[table_name]) AND
  434. [t2].[minor_id] = COLUMNPROPERTY(OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[TABLE_NAME]), [t1].[COLUMN_NAME], 'ColumnID')
  435. ) as comment
  436. FROM {$columnsTableName} AS [t1]
  437. WHERE {$whereSql}
  438. SQL;
  439. try {
  440. $columns = $this->db->createCommand($sql)->queryAll();
  441. if (empty($columns)) {
  442. return false;
  443. }
  444. } catch (\Exception $e) {
  445. return false;
  446. }
  447. foreach ($columns as $column) {
  448. $column = $this->loadColumnSchema($column);
  449. foreach ($table->primaryKey as $primaryKey) {
  450. if (strcasecmp($column->name, $primaryKey) === 0) {
  451. $column->isPrimaryKey = true;
  452. break;
  453. }
  454. }
  455. if ($column->isPrimaryKey && $column->autoIncrement) {
  456. $table->sequenceName = '';
  457. }
  458. $table->columns[$column->name] = $column;
  459. }
  460. return true;
  461. }
  462. /**
  463. * Collects the constraint details for the given table and constraint type.
  464. * @param TableSchema $table
  465. * @param string $type either PRIMARY KEY or UNIQUE
  466. * @return array each entry contains index_name and field_name
  467. * @since 2.0.4
  468. */
  469. protected function findTableConstraints($table, $type)
  470. {
  471. $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
  472. $tableConstraintsTableName = 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
  473. if ($table->catalogName !== null) {
  474. $keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
  475. $tableConstraintsTableName = $table->catalogName . '.' . $tableConstraintsTableName;
  476. }
  477. $keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);
  478. $tableConstraintsTableName = $this->quoteTableName($tableConstraintsTableName);
  479. $sql = <<<SQL
  480. SELECT
  481. [kcu].[constraint_name] AS [index_name],
  482. [kcu].[column_name] AS [field_name]
  483. FROM {$keyColumnUsageTableName} AS [kcu]
  484. LEFT JOIN {$tableConstraintsTableName} AS [tc] ON
  485. [kcu].[table_schema] = [tc].[table_schema] AND
  486. [kcu].[table_name] = [tc].[table_name] AND
  487. [kcu].[constraint_name] = [tc].[constraint_name]
  488. WHERE
  489. [tc].[constraint_type] = :type AND
  490. [kcu].[table_name] = :tableName AND
  491. [kcu].[table_schema] = :schemaName
  492. SQL;
  493. return $this->db
  494. ->createCommand($sql, [
  495. ':tableName' => $table->name,
  496. ':schemaName' => $table->schemaName,
  497. ':type' => $type,
  498. ])
  499. ->queryAll();
  500. }
  501. /**
  502. * Collects the primary key column details for the given table.
  503. * @param TableSchema $table the table metadata
  504. */
  505. protected function findPrimaryKeys($table)
  506. {
  507. $result = [];
  508. foreach ($this->findTableConstraints($table, 'PRIMARY KEY') as $row) {
  509. $result[] = $row['field_name'];
  510. }
  511. $table->primaryKey = $result;
  512. }
  513. /**
  514. * Collects the foreign key column details for the given table.
  515. * @param TableSchema $table the table metadata
  516. */
  517. protected function findForeignKeys($table)
  518. {
  519. $object = $table->name;
  520. if ($table->schemaName !== null) {
  521. $object = $table->schemaName . '.' . $object;
  522. }
  523. if ($table->catalogName !== null) {
  524. $object = $table->catalogName . '.' . $object;
  525. }
  526. // please refer to the following page for more details:
  527. // http://msdn2.microsoft.com/en-us/library/aa175805(SQL.80).aspx
  528. $sql = <<<'SQL'
  529. SELECT
  530. [fk].[name] AS [fk_name],
  531. [cp].[name] AS [fk_column_name],
  532. OBJECT_NAME([fk].[referenced_object_id]) AS [uq_table_name],
  533. [cr].[name] AS [uq_column_name]
  534. FROM
  535. [sys].[foreign_keys] AS [fk]
  536. INNER JOIN [sys].[foreign_key_columns] AS [fkc] ON
  537. [fk].[object_id] = [fkc].[constraint_object_id]
  538. INNER JOIN [sys].[columns] AS [cp] ON
  539. [fk].[parent_object_id] = [cp].[object_id] AND
  540. [fkc].[parent_column_id] = [cp].[column_id]
  541. INNER JOIN [sys].[columns] AS [cr] ON
  542. [fk].[referenced_object_id] = [cr].[object_id] AND
  543. [fkc].[referenced_column_id] = [cr].[column_id]
  544. WHERE
  545. [fk].[parent_object_id] = OBJECT_ID(:object)
  546. SQL;
  547. $rows = $this->db->createCommand($sql, [
  548. ':object' => $object,
  549. ])->queryAll();
  550. $table->foreignKeys = [];
  551. foreach ($rows as $row) {
  552. if (!isset($table->foreignKeys[$row['fk_name']])) {
  553. $table->foreignKeys[$row['fk_name']][] = $row['uq_table_name'];
  554. }
  555. $table->foreignKeys[$row['fk_name']][$row['fk_column_name']] = $row['uq_column_name'];
  556. }
  557. }
  558. /**
  559. * {@inheritdoc}
  560. */
  561. protected function findViewNames($schema = '')
  562. {
  563. if ($schema === '') {
  564. $schema = $this->defaultSchema;
  565. }
  566. $sql = <<<'SQL'
  567. SELECT [t].[table_name]
  568. FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
  569. WHERE [t].[table_schema] = :schema AND [t].[table_type] = 'VIEW'
  570. ORDER BY [t].[table_name]
  571. SQL;
  572. return $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
  573. }
  574. /**
  575. * Returns all unique indexes for the given table.
  576. *
  577. * Each array element is of the following structure:
  578. *
  579. * ```php
  580. * [
  581. * 'IndexName1' => ['col1' [, ...]],
  582. * 'IndexName2' => ['col2' [, ...]],
  583. * ]
  584. * ```
  585. *
  586. * @param TableSchema $table the table metadata
  587. * @return array all unique indexes for the given table.
  588. * @since 2.0.4
  589. */
  590. public function findUniqueIndexes($table)
  591. {
  592. $result = [];
  593. foreach ($this->findTableConstraints($table, 'UNIQUE') as $row) {
  594. $result[$row['index_name']][] = $row['field_name'];
  595. }
  596. return $result;
  597. }
  598. /**
  599. * Loads multiple types of constraints and returns the specified ones.
  600. * @param string $tableName table name.
  601. * @param string $returnType return type:
  602. * - primaryKey
  603. * - foreignKeys
  604. * - uniques
  605. * - checks
  606. * - defaults
  607. * @return mixed constraints.
  608. */
  609. private function loadTableConstraints($tableName, $returnType)
  610. {
  611. static $sql = <<<'SQL'
  612. SELECT
  613. [o].[name] AS [name],
  614. COALESCE([ccol].[name], [dcol].[name], [fccol].[name], [kiccol].[name]) AS [column_name],
  615. RTRIM([o].[type]) AS [type],
  616. OBJECT_SCHEMA_NAME([f].[referenced_object_id]) AS [foreign_table_schema],
  617. OBJECT_NAME([f].[referenced_object_id]) AS [foreign_table_name],
  618. [ffccol].[name] AS [foreign_column_name],
  619. [f].[update_referential_action_desc] AS [on_update],
  620. [f].[delete_referential_action_desc] AS [on_delete],
  621. [c].[definition] AS [check_expr],
  622. [d].[definition] AS [default_expr]
  623. FROM (SELECT OBJECT_ID(:fullName) AS [object_id]) AS [t]
  624. INNER JOIN [sys].[objects] AS [o]
  625. ON [o].[parent_object_id] = [t].[object_id] AND [o].[type] IN ('PK', 'UQ', 'C', 'D', 'F')
  626. LEFT JOIN [sys].[check_constraints] AS [c]
  627. ON [c].[object_id] = [o].[object_id]
  628. LEFT JOIN [sys].[columns] AS [ccol]
  629. ON [ccol].[object_id] = [c].[parent_object_id] AND [ccol].[column_id] = [c].[parent_column_id]
  630. LEFT JOIN [sys].[default_constraints] AS [d]
  631. ON [d].[object_id] = [o].[object_id]
  632. LEFT JOIN [sys].[columns] AS [dcol]
  633. ON [dcol].[object_id] = [d].[parent_object_id] AND [dcol].[column_id] = [d].[parent_column_id]
  634. LEFT JOIN [sys].[key_constraints] AS [k]
  635. ON [k].[object_id] = [o].[object_id]
  636. LEFT JOIN [sys].[index_columns] AS [kic]
  637. ON [kic].[object_id] = [k].[parent_object_id] AND [kic].[index_id] = [k].[unique_index_id]
  638. LEFT JOIN [sys].[columns] AS [kiccol]
  639. ON [kiccol].[object_id] = [kic].[object_id] AND [kiccol].[column_id] = [kic].[column_id]
  640. LEFT JOIN [sys].[foreign_keys] AS [f]
  641. ON [f].[object_id] = [o].[object_id]
  642. LEFT JOIN [sys].[foreign_key_columns] AS [fc]
  643. ON [fc].[constraint_object_id] = [o].[object_id]
  644. LEFT JOIN [sys].[columns] AS [fccol]
  645. ON [fccol].[object_id] = [fc].[parent_object_id] AND [fccol].[column_id] = [fc].[parent_column_id]
  646. LEFT JOIN [sys].[columns] AS [ffccol]
  647. ON [ffccol].[object_id] = [fc].[referenced_object_id] AND [ffccol].[column_id] = [fc].[referenced_column_id]
  648. ORDER BY [kic].[key_ordinal] ASC, [fc].[constraint_column_id] ASC
  649. SQL;
  650. $resolvedName = $this->resolveTableName($tableName);
  651. $constraints = $this->db->createCommand($sql, [
  652. ':fullName' => $resolvedName->fullName,
  653. ])->queryAll();
  654. $constraints = $this->normalizePdoRowKeyCase($constraints, true);
  655. $constraints = ArrayHelper::index($constraints, null, ['type', 'name']);
  656. $result = [
  657. 'primaryKey' => null,
  658. 'foreignKeys' => [],
  659. 'uniques' => [],
  660. 'checks' => [],
  661. 'defaults' => [],
  662. ];
  663. foreach ($constraints as $type => $names) {
  664. foreach ($names as $name => $constraint) {
  665. switch ($type) {
  666. case 'PK':
  667. $result['primaryKey'] = new Constraint([
  668. 'name' => $name,
  669. 'columnNames' => ArrayHelper::getColumn($constraint, 'column_name'),
  670. ]);
  671. break;
  672. case 'F':
  673. $result['foreignKeys'][] = new ForeignKeyConstraint([
  674. 'name' => $name,
  675. 'columnNames' => ArrayHelper::getColumn($constraint, 'column_name'),
  676. 'foreignSchemaName' => $constraint[0]['foreign_table_schema'],
  677. 'foreignTableName' => $constraint[0]['foreign_table_name'],
  678. 'foreignColumnNames' => ArrayHelper::getColumn($constraint, 'foreign_column_name'),
  679. 'onDelete' => str_replace('_', '', $constraint[0]['on_delete']),
  680. 'onUpdate' => str_replace('_', '', $constraint[0]['on_update']),
  681. ]);
  682. break;
  683. case 'UQ':
  684. $result['uniques'][] = new Constraint([
  685. 'name' => $name,
  686. 'columnNames' => ArrayHelper::getColumn($constraint, 'column_name'),
  687. ]);
  688. break;
  689. case 'C':
  690. $result['checks'][] = new CheckConstraint([
  691. 'name' => $name,
  692. 'columnNames' => ArrayHelper::getColumn($constraint, 'column_name'),
  693. 'expression' => $constraint[0]['check_expr'],
  694. ]);
  695. break;
  696. case 'D':
  697. $result['defaults'][] = new DefaultValueConstraint([
  698. 'name' => $name,
  699. 'columnNames' => ArrayHelper::getColumn($constraint, 'column_name'),
  700. 'value' => $constraint[0]['default_expr'],
  701. ]);
  702. break;
  703. }
  704. }
  705. }
  706. foreach ($result as $type => $data) {
  707. $this->setTableMetadata($tableName, $type, $data);
  708. }
  709. return $result[$returnType];
  710. }
  711. /**
  712. * {@inheritdoc}
  713. */
  714. public function quoteColumnName($name)
  715. {
  716. if (preg_match('/^\[.*\]$/', $name)) {
  717. return $name;
  718. }
  719. return parent::quoteColumnName($name);
  720. }
  721. /**
  722. * Retrieving inserted data from a primary key request of type uniqueidentifier (for SQL Server 2005 or later)
  723. * {@inheritdoc}
  724. */
  725. public function insert($table, $columns)
  726. {
  727. $command = $this->db->createCommand()->insert($table, $columns);
  728. if (!$command->execute()) {
  729. return false;
  730. }
  731. $isVersion2005orLater = version_compare($this->db->getSchema()->getServerVersion(), '9', '>=');
  732. $inserted = $isVersion2005orLater ? $command->pdoStatement->fetch() : [];
  733. $tableSchema = $this->getTableSchema($table);
  734. $result = [];
  735. foreach ($tableSchema->primaryKey as $name) {
  736. // @see https://github.com/yiisoft/yii2/issues/13828 & https://github.com/yiisoft/yii2/issues/17474
  737. if (isset($inserted[$name])) {
  738. $result[$name] = $inserted[$name];
  739. } elseif ($tableSchema->columns[$name]->autoIncrement) {
  740. // for a version earlier than 2005
  741. $result[$name] = $this->getLastInsertID($tableSchema->sequenceName);
  742. } elseif (isset($columns[$name])) {
  743. $result[$name] = $columns[$name];
  744. } else {
  745. $result[$name] = $tableSchema->columns[$name]->defaultValue;
  746. }
  747. }
  748. return $result;
  749. }
  750. /**
  751. * {@inheritdoc}
  752. */
  753. public function createColumnSchemaBuilder($type, $length = null)
  754. {
  755. return Yii::createObject(ColumnSchemaBuilder::className(), [$type, $length, $this->db]);
  756. }
  757. }