You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

380 lines
13KB

  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\mssql;
  8. use yii\db\ColumnSchema;
  9. /**
  10. * Schema is the class for retrieving metadata from a MS SQL Server databases (version 2008 and above).
  11. *
  12. * @author Timur Ruziev <resurtm@gmail.com>
  13. * @since 2.0
  14. */
  15. class Schema extends \yii\db\Schema
  16. {
  17. /**
  18. * @var string the default schema used for the current session.
  19. */
  20. public $defaultSchema = 'dbo';
  21. /**
  22. * @var array mapping from physical column types (keys) to abstract column types (values)
  23. */
  24. public $typeMap = [
  25. // exact numbers
  26. 'bigint' => self::TYPE_BIGINT,
  27. 'numeric' => self::TYPE_DECIMAL,
  28. 'bit' => self::TYPE_SMALLINT,
  29. 'smallint' => self::TYPE_SMALLINT,
  30. 'decimal' => self::TYPE_DECIMAL,
  31. 'smallmoney' => self::TYPE_MONEY,
  32. 'int' => self::TYPE_INTEGER,
  33. 'tinyint' => self::TYPE_SMALLINT,
  34. 'money' => self::TYPE_MONEY,
  35. // approximate numbers
  36. 'float' => self::TYPE_FLOAT,
  37. 'double' => self::TYPE_DOUBLE,
  38. 'real' => self::TYPE_FLOAT,
  39. // date and time
  40. 'date' => self::TYPE_DATE,
  41. 'datetimeoffset' => self::TYPE_DATETIME,
  42. 'datetime2' => self::TYPE_DATETIME,
  43. 'smalldatetime' => self::TYPE_DATETIME,
  44. 'datetime' => self::TYPE_DATETIME,
  45. 'time' => self::TYPE_TIME,
  46. // character strings
  47. 'char' => self::TYPE_STRING,
  48. 'varchar' => self::TYPE_STRING,
  49. 'text' => self::TYPE_TEXT,
  50. // unicode character strings
  51. 'nchar' => self::TYPE_STRING,
  52. 'nvarchar' => self::TYPE_STRING,
  53. 'ntext' => self::TYPE_TEXT,
  54. // binary strings
  55. 'binary' => self::TYPE_BINARY,
  56. 'varbinary' => self::TYPE_BINARY,
  57. 'image' => self::TYPE_BINARY,
  58. // other data types
  59. // 'cursor' type cannot be used with tables
  60. 'timestamp' => self::TYPE_TIMESTAMP,
  61. 'hierarchyid' => self::TYPE_STRING,
  62. 'uniqueidentifier' => self::TYPE_STRING,
  63. 'sql_variant' => self::TYPE_STRING,
  64. 'xml' => self::TYPE_STRING,
  65. 'table' => self::TYPE_STRING,
  66. ];
  67. /**
  68. * @inheritdoc
  69. */
  70. public function createSavepoint($name)
  71. {
  72. $this->db->createCommand("SAVE TRANSACTION $name")->execute();
  73. }
  74. /**
  75. * @inheritdoc
  76. */
  77. public function releaseSavepoint($name)
  78. {
  79. // does nothing as MSSQL does not support this
  80. }
  81. /**
  82. * @inheritdoc
  83. */
  84. public function rollBackSavepoint($name)
  85. {
  86. $this->db->createCommand("ROLLBACK TRANSACTION $name")->execute();
  87. }
  88. /**
  89. * Quotes a table name for use in a query.
  90. * A simple table name has no schema prefix.
  91. * @param string $name table name.
  92. * @return string the properly quoted table name.
  93. */
  94. public function quoteSimpleTableName($name)
  95. {
  96. return strpos($name, '[') === false ? "[{$name}]" : $name;
  97. }
  98. /**
  99. * Quotes a column name for use in a query.
  100. * A simple column name has no prefix.
  101. * @param string $name column name.
  102. * @return string the properly quoted column name.
  103. */
  104. public function quoteSimpleColumnName($name)
  105. {
  106. return strpos($name, '[') === false && $name !== '*' ? "[{$name}]" : $name;
  107. }
  108. /**
  109. * Creates a query builder for the MSSQL database.
  110. * @return QueryBuilder query builder interface.
  111. */
  112. public function createQueryBuilder()
  113. {
  114. return new QueryBuilder($this->db);
  115. }
  116. /**
  117. * Loads the metadata for the specified table.
  118. * @param string $name table name
  119. * @return TableSchema|null driver dependent table metadata. Null if the table does not exist.
  120. */
  121. public function loadTableSchema($name)
  122. {
  123. $table = new TableSchema();
  124. $this->resolveTableNames($table, $name);
  125. $this->findPrimaryKeys($table);
  126. if ($this->findColumns($table)) {
  127. $this->findForeignKeys($table);
  128. return $table;
  129. } else {
  130. return null;
  131. }
  132. }
  133. /**
  134. * Resolves the table name and schema name (if any).
  135. * @param TableSchema $table the table metadata object
  136. * @param string $name the table name
  137. */
  138. protected function resolveTableNames($table, $name)
  139. {
  140. $parts = explode('.', str_replace(['[', ']'], '', $name));
  141. $partCount = count($parts);
  142. if ($partCount == 3) {
  143. // catalog name, schema name and table name passed
  144. $table->catalogName = $parts[0];
  145. $table->schemaName = $parts[1];
  146. $table->name = $parts[2];
  147. $table->fullName = $table->catalogName . '.' . $table->schemaName . '.' . $table->name;
  148. } elseif ($partCount == 2) {
  149. // only schema name and table name passed
  150. $table->schemaName = $parts[0];
  151. $table->name = $parts[1];
  152. $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
  153. } else {
  154. // only table name passed
  155. $table->schemaName = $this->defaultSchema;
  156. $table->fullName = $table->name = $parts[0];
  157. }
  158. }
  159. /**
  160. * Loads the column information into a [[ColumnSchema]] object.
  161. * @param array $info column information
  162. * @return ColumnSchema the column schema object
  163. */
  164. protected function loadColumnSchema($info)
  165. {
  166. $column = $this->createColumnSchema();
  167. $column->name = $info['column_name'];
  168. $column->allowNull = $info['is_nullable'] == 'YES';
  169. $column->dbType = $info['data_type'];
  170. $column->enumValues = []; // mssql has only vague equivalents to enum
  171. $column->isPrimaryKey = null; // primary key will be determined in findColumns() method
  172. $column->autoIncrement = $info['is_identity'] == 1;
  173. $column->unsigned = stripos($column->dbType, 'unsigned') !== false;
  174. $column->comment = $info['comment'] === null ? '' : $info['comment'];
  175. $column->type = self::TYPE_STRING;
  176. if (preg_match('/^(\w+)(?:\(([^\)]+)\))?/', $column->dbType, $matches)) {
  177. $type = $matches[1];
  178. if (isset($this->typeMap[$type])) {
  179. $column->type = $this->typeMap[$type];
  180. }
  181. if (!empty($matches[2])) {
  182. $values = explode(',', $matches[2]);
  183. $column->size = $column->precision = (int) $values[0];
  184. if (isset($values[1])) {
  185. $column->scale = (int) $values[1];
  186. }
  187. if ($column->size === 1 && ($type === 'tinyint' || $type === 'bit')) {
  188. $column->type = 'boolean';
  189. } elseif ($type === 'bit') {
  190. if ($column->size > 32) {
  191. $column->type = 'bigint';
  192. } elseif ($column->size === 32) {
  193. $column->type = 'integer';
  194. }
  195. }
  196. }
  197. }
  198. $column->phpType = $this->getColumnPhpType($column);
  199. if ($info['column_default'] == '(NULL)') {
  200. $info['column_default'] = null;
  201. }
  202. if (!$column->isPrimaryKey && ($column->type !== 'timestamp' || $info['column_default'] !== 'CURRENT_TIMESTAMP')) {
  203. $column->defaultValue = $column->phpTypecast($info['column_default']);
  204. }
  205. return $column;
  206. }
  207. /**
  208. * Collects the metadata of table columns.
  209. * @param TableSchema $table the table metadata
  210. * @return boolean whether the table exists in the database
  211. */
  212. protected function findColumns($table)
  213. {
  214. $columnsTableName = 'INFORMATION_SCHEMA.COLUMNS';
  215. $whereSql = "[t1].[table_name] = '{$table->name}'";
  216. if ($table->catalogName !== null) {
  217. $columnsTableName = "{$table->catalogName}.{$columnsTableName}";
  218. $whereSql .= " AND [t1].[table_catalog] = '{$table->catalogName}'";
  219. }
  220. if ($table->schemaName !== null) {
  221. $whereSql .= " AND [t1].[table_schema] = '{$table->schemaName}'";
  222. }
  223. $columnsTableName = $this->quoteTableName($columnsTableName);
  224. $sql = <<<SQL
  225. SELECT
  226. [t1].[column_name], [t1].[is_nullable], [t1].[data_type], [t1].[column_default],
  227. COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
  228. CONVERT(VARCHAR, [t2].[value]) AS comment
  229. FROM {$columnsTableName} AS [t1]
  230. LEFT OUTER JOIN [sys].[extended_properties] AS [t2] ON
  231. [t2].[minor_id] = COLUMNPROPERTY(OBJECT_ID([t1].[TABLE_SCHEMA] + '.' + [t1].[TABLE_NAME]), [t1].[COLUMN_NAME], 'ColumnID') AND
  232. OBJECT_NAME([t2].[major_id]) = [t1].[table_name] AND
  233. [t2].[class] = 1 AND
  234. [t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
  235. [t2].[name] = 'MS_Description'
  236. WHERE {$whereSql}
  237. SQL;
  238. try {
  239. $columns = $this->db->createCommand($sql)->queryAll();
  240. if (empty($columns)) {
  241. return false;
  242. }
  243. } catch (\Exception $e) {
  244. return false;
  245. }
  246. foreach ($columns as $column) {
  247. $column = $this->loadColumnSchema($column);
  248. foreach ($table->primaryKey as $primaryKey) {
  249. if (strcasecmp($column->name, $primaryKey) === 0) {
  250. $column->isPrimaryKey = true;
  251. break;
  252. }
  253. }
  254. if ($column->isPrimaryKey && $column->autoIncrement) {
  255. $table->sequenceName = '';
  256. }
  257. $table->columns[$column->name] = $column;
  258. }
  259. return true;
  260. }
  261. /**
  262. * Collects the primary key column details for the given table.
  263. * @param TableSchema $table the table metadata
  264. */
  265. protected function findPrimaryKeys($table)
  266. {
  267. $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
  268. $tableConstraintsTableName = 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
  269. if ($table->catalogName !== null) {
  270. $keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
  271. $tableConstraintsTableName = $table->catalogName . '.' . $tableConstraintsTableName;
  272. }
  273. $keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);
  274. $tableConstraintsTableName = $this->quoteTableName($tableConstraintsTableName);
  275. $sql = <<<SQL
  276. SELECT
  277. [kcu].[column_name] AS [field_name]
  278. FROM {$keyColumnUsageTableName} AS [kcu]
  279. LEFT JOIN {$tableConstraintsTableName} AS [tc] ON
  280. [kcu].[table_name] = [tc].[table_name] AND
  281. [kcu].[constraint_name] = [tc].[constraint_name]
  282. WHERE
  283. [tc].[constraint_type] = 'PRIMARY KEY' AND
  284. [kcu].[table_name] = :tableName AND
  285. [kcu].[table_schema] = :schemaName
  286. SQL;
  287. $table->primaryKey = $this->db
  288. ->createCommand($sql, [':tableName' => $table->name, ':schemaName' => $table->schemaName])
  289. ->queryColumn();
  290. }
  291. /**
  292. * Collects the foreign key column details for the given table.
  293. * @param TableSchema $table the table metadata
  294. */
  295. protected function findForeignKeys($table)
  296. {
  297. $referentialConstraintsTableName = 'INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS';
  298. $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
  299. if ($table->catalogName !== null) {
  300. $referentialConstraintsTableName = $table->catalogName . '.' . $referentialConstraintsTableName;
  301. $keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
  302. }
  303. $referentialConstraintsTableName = $this->quoteTableName($referentialConstraintsTableName);
  304. $keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);
  305. // please refer to the following page for more details:
  306. // http://msdn2.microsoft.com/en-us/library/aa175805(SQL.80).aspx
  307. $sql = <<<SQL
  308. SELECT
  309. [kcu1].[column_name] AS [fk_column_name],
  310. [kcu2].[table_name] AS [uq_table_name],
  311. [kcu2].[column_name] AS [uq_column_name]
  312. FROM {$referentialConstraintsTableName} AS [rc]
  313. JOIN {$keyColumnUsageTableName} AS [kcu1] ON
  314. [kcu1].[constraint_catalog] = [rc].[constraint_catalog] AND
  315. [kcu1].[constraint_schema] = [rc].[constraint_schema] AND
  316. [kcu1].[constraint_name] = [rc].[constraint_name]
  317. JOIN {$keyColumnUsageTableName} AS [kcu2] ON
  318. [kcu2].[constraint_catalog] = [rc].[constraint_catalog] AND
  319. [kcu2].[constraint_schema] = [rc].[constraint_schema] AND
  320. [kcu2].[constraint_name] = [rc].[unique_constraint_name] AND
  321. [kcu2].[ordinal_position] = [kcu1].[ordinal_position]
  322. WHERE [kcu1].[table_name] = :tableName
  323. SQL;
  324. $rows = $this->db->createCommand($sql, [':tableName' => $table->name])->queryAll();
  325. $table->foreignKeys = [];
  326. foreach ($rows as $row) {
  327. $table->foreignKeys[] = [$row['uq_table_name'], $row['fk_column_name'] => $row['uq_column_name']];
  328. }
  329. }
  330. /**
  331. * Returns all table names in the database.
  332. * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
  333. * @return array all table names in the database. The names have NO schema name prefix.
  334. */
  335. protected function findTableNames($schema = '')
  336. {
  337. if ($schema === '') {
  338. $schema = $this->defaultSchema;
  339. }
  340. $sql = <<<SQL
  341. SELECT [t].[table_name]
  342. FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
  343. WHERE [t].[table_schema] = :schema AND [t].[table_type] = 'BASE TABLE'
  344. SQL;
  345. return $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
  346. }
  347. }