Schema.php 13.4 KB
Newer Older
1 2 3 4 5 6 7 8 9 10 11 12
<?php
/**
 * @link http://www.yiiframework.com/
 * @copyright Copyright (c) 2008 Yii Software LLC
 * @license http://www.yiiframework.com/license/
 */

namespace yii\db\mssql;

use yii\db\ColumnSchema;

/**
13
 * Schema is the class for retrieving metadata from a MS SQL Server databases (version 2008 and above).
14 15 16 17 18 19
 *
 * @author Timur Ruziev <resurtm@gmail.com>
 * @since 2.0
 */
class Schema extends \yii\db\Schema
{
20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102
    /**
     * @var string the default schema used for the current session.
     */
    public $defaultSchema = 'dbo';
    /**
     * @var array mapping from physical column types (keys) to abstract column types (values)
     */
    public $typeMap = [
        // exact numbers
        'bigint' => self::TYPE_BIGINT,
        'numeric' => self::TYPE_DECIMAL,
        'bit' => self::TYPE_SMALLINT,
        'smallint' => self::TYPE_SMALLINT,
        'decimal' => self::TYPE_DECIMAL,
        'smallmoney' => self::TYPE_MONEY,
        'int' => self::TYPE_INTEGER,
        'tinyint' => self::TYPE_SMALLINT,
        'money' => self::TYPE_MONEY,

        // approximate numbers
        'float' => self::TYPE_FLOAT,
        'real' => self::TYPE_FLOAT,

        // date and time
        'date' => self::TYPE_DATE,
        'datetimeoffset' => self::TYPE_DATETIME,
        'datetime2' => self::TYPE_DATETIME,
        'smalldatetime' => self::TYPE_DATETIME,
        'datetime' => self::TYPE_DATETIME,
        'time' => self::TYPE_TIME,

        // character strings
        'char' => self::TYPE_STRING,
        'varchar' => self::TYPE_STRING,
        'text' => self::TYPE_TEXT,

        // unicode character strings
        'nchar' => self::TYPE_STRING,
        'nvarchar' => self::TYPE_STRING,
        'ntext' => self::TYPE_TEXT,

        // binary strings
        'binary' => self::TYPE_BINARY,
        'varbinary' => self::TYPE_BINARY,
        'image' => self::TYPE_BINARY,

        // other data types
        // 'cursor' type cannot be used with tables
        'timestamp' => self::TYPE_TIMESTAMP,
        'hierarchyid' => self::TYPE_STRING,
        'uniqueidentifier' => self::TYPE_STRING,
        'sql_variant' => self::TYPE_STRING,
        'xml' => self::TYPE_STRING,
        'table' => self::TYPE_STRING,
    ];

    /**
     * @inheritdoc
     */
    public function createSavepoint($name)
    {
        $this->db->createCommand("SAVE TRANSACTION $name")->execute();
    }

    /**
     * @inheritdoc
     */
    public function releaseSavepoint($name)
    {
        // does nothing as MSSQL does not support this
    }

    /**
     * @inheritdoc
     */
    public function rollBackSavepoint($name)
    {
        $this->db->createCommand("ROLLBACK TRANSACTION $name")->execute();
    }

    /**
     * Quotes a table name for use in a query.
     * A simple table name has no schema prefix.
103
     * @param string $name table name.
104 105 106 107 108 109 110 111 112 113
     * @return string the properly quoted table name.
     */
    public function quoteSimpleTableName($name)
    {
        return strpos($name, '[') === false ? "[{$name}]" : $name;
    }

    /**
     * Quotes a column name for use in a query.
     * A simple column name has no prefix.
114
     * @param string $name column name.
115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132
     * @return string the properly quoted column name.
     */
    public function quoteSimpleColumnName($name)
    {
        return strpos($name, '[') === false && $name !== '*' ? "[{$name}]" : $name;
    }

    /**
     * Creates a query builder for the MSSQL database.
     * @return QueryBuilder query builder interface.
     */
    public function createQueryBuilder()
    {
        return new QueryBuilder($this->db);
    }

    /**
     * Loads the metadata for the specified table.
133
     * @param string $name table name
134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152
     * @return TableSchema|null driver dependent table metadata. Null if the table does not exist.
     */
    public function loadTableSchema($name)
    {
        $table = new TableSchema();
        $this->resolveTableNames($table, $name);
        $this->findPrimaryKeys($table);
        if ($this->findColumns($table)) {
            $this->findForeignKeys($table);

            return $table;
        } else {
            return null;
        }
    }

    /**
     * Resolves the table name and schema name (if any).
     * @param TableSchema $table the table metadata object
153
     * @param string $name the table name
154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178
     */
    protected function resolveTableNames($table, $name)
    {
        $parts = explode('.', str_replace(['[', ']'], '', $name));
        $partCount = count($parts);
        if ($partCount == 3) {
            // catalog name, schema name and table name passed
            $table->catalogName = $parts[0];
            $table->schemaName = $parts[1];
            $table->name = $parts[2];
            $table->fullName = $table->catalogName . '.' . $table->schemaName . '.' . $table->name;
        } elseif ($partCount == 2) {
            // only schema name and table name passed
            $table->schemaName = $parts[0];
            $table->name = $parts[1];
            $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
        } else {
            // only table name passed
            $table->schemaName = $this->defaultSchema;
            $table->fullName = $table->name = $parts[0];
        }
    }

    /**
     * Loads the column information into a [[ColumnSchema]] object.
179
     * @param array $info column information
180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223
     * @return ColumnSchema the column schema object
     */
    protected function loadColumnSchema($info)
    {
        $column = new ColumnSchema();

        $column->name = $info['column_name'];
        $column->allowNull = $info['is_nullable'] == 'YES';
        $column->dbType = $info['data_type'];
        $column->enumValues = []; // mssql has only vague equivalents to enum
        $column->isPrimaryKey = null; // primary key will be determined in findColumns() method
        $column->autoIncrement = $info['is_identity'] == 1;
        $column->unsigned = stripos($column->dbType, 'unsigned') !== false;
        $column->comment = $info['comment'] === null ? '' : $info['comment'];

        $column->type = self::TYPE_STRING;
        if (preg_match('/^(\w+)(?:\(([^\)]+)\))?/', $column->dbType, $matches)) {
            $type = $matches[1];
            if (isset($this->typeMap[$type])) {
                $column->type = $this->typeMap[$type];
            }
            if (!empty($matches[2])) {
                $values = explode(',', $matches[2]);
                $column->size = $column->precision = (int) $values[0];
                if (isset($values[1])) {
                    $column->scale = (int) $values[1];
                }
                if ($column->size === 1 && ($type === 'tinyint' || $type === 'bit')) {
                    $column->type = 'boolean';
                } elseif ($type === 'bit') {
                    if ($column->size > 32) {
                        $column->type = 'bigint';
                    } elseif ($column->size === 32) {
                        $column->type = 'integer';
                    }
                }
            }
        }

        $column->phpType = $this->getColumnPhpType($column);

        if ($info['column_default'] == '(NULL)') {
            $info['column_default'] = null;
        }
224
        if (!$column->isPrimaryKey && ($column->type !== 'timestamp' || $info['column_default'] !== 'CURRENT_TIMESTAMP')) {
225 226 227 228 229 230 231 232
            $column->defaultValue = $column->typecast($info['column_default']);
        }

        return $column;
    }

    /**
     * Collects the metadata of table columns.
233 234
     * @param TableSchema $table the table metadata
     * @return boolean whether the table exists in the database
235 236 237
     */
    protected function findColumns($table)
    {
Alexander Makarov committed
238
        $columnsTableName = 'INFORMATION_SCHEMA.COLUMNS';
239 240 241 242 243 244 245 246 247 248 249
        $whereSql = "[t1].[table_name] = '{$table->name}'";
        if ($table->catalogName !== null) {
            $columnsTableName = "{$table->catalogName}.{$columnsTableName}";
            $whereSql .= " AND [t1].[table_catalog] = '{$table->catalogName}'";
        }
        if ($table->schemaName !== null) {
            $whereSql .= " AND [t1].[table_schema] = '{$table->schemaName}'";
        }
        $columnsTableName = $this->quoteTableName($columnsTableName);

        $sql = <<<SQL
250
SELECT
251 252 253
    [t1].[column_name], [t1].[is_nullable], [t1].[data_type], [t1].[column_default],
    COLUMNPROPERTY(OBJECT_ID([t1].[table_schema] + '.' + [t1].[table_name]), [t1].[column_name], 'IsIdentity') AS is_identity,
    CONVERT(VARCHAR, [t2].[value]) AS comment
254 255
FROM {$columnsTableName} AS [t1]
LEFT OUTER JOIN [sys].[extended_properties] AS [t2] ON
256 257 258 259 260
    [t1].[ordinal_position] = [t2].[minor_id] AND
    OBJECT_NAME([t2].[major_id]) = [t1].[table_name] AND
    [t2].[class] = 1 AND
    [t2].[class_desc] = 'OBJECT_OR_COLUMN' AND
    [t2].[name] = 'MS_Description'
261 262 263
WHERE {$whereSql}
SQL;

264 265
        try {
            $columns = $this->db->createCommand($sql)->queryAll();
266 267 268
            if (empty($columns)) {
                return false;
            }
269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294
        } catch (\Exception $e) {
            return false;
        }
        foreach ($columns as $column) {
            $column = $this->loadColumnSchema($column);
            foreach ($table->primaryKey as $primaryKey) {
                if (strcasecmp($column->name, $primaryKey) === 0) {
                    $column->isPrimaryKey = true;
                    break;
                }
            }
            if ($column->isPrimaryKey && $column->autoIncrement) {
                $table->sequenceName = '';
            }
            $table->columns[$column->name] = $column;
        }

        return true;
    }

    /**
     * Collects the primary key column details for the given table.
     * @param TableSchema $table the table metadata
     */
    protected function findPrimaryKeys($table)
    {
Alexander Makarov committed
295 296
        $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
        $tableConstraintsTableName = 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
297 298 299 300 301 302 303 304
        if ($table->catalogName !== null) {
            $keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
            $tableConstraintsTableName = $table->catalogName . '.' . $tableConstraintsTableName;
        }
        $keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);
        $tableConstraintsTableName = $this->quoteTableName($tableConstraintsTableName);

        $sql = <<<SQL
305
SELECT
306
    [kcu].[column_name] AS [field_name]
307 308
FROM {$keyColumnUsageTableName} AS [kcu]
LEFT JOIN {$tableConstraintsTableName} AS [tc] ON
309 310
    [kcu].[table_name] = [tc].[table_name] AND
    [kcu].[constraint_name] = [tc].[constraint_name]
311
WHERE
312 313 314
    [tc].[constraint_type] = 'PRIMARY KEY' AND
    [kcu].[table_name] = :tableName AND
    [kcu].[table_schema] = :schemaName
315 316
SQL;

317 318 319 320 321 322 323 324 325 326 327
        $table->primaryKey = $this->db
            ->createCommand($sql, [':tableName' => $table->name, ':schemaName' => $table->schemaName])
            ->queryColumn();
    }

    /**
     * Collects the foreign key column details for the given table.
     * @param TableSchema $table the table metadata
     */
    protected function findForeignKeys($table)
    {
Alexander Makarov committed
328 329
        $referentialConstraintsTableName = 'INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS';
        $keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
330 331 332 333 334 335 336 337 338 339
        if ($table->catalogName !== null) {
            $referentialConstraintsTableName = $table->catalogName . '.' . $referentialConstraintsTableName;
            $keyColumnUsageTableName = $table->catalogName . '.' . $keyColumnUsageTableName;
        }
        $referentialConstraintsTableName = $this->quoteTableName($referentialConstraintsTableName);
        $keyColumnUsageTableName = $this->quoteTableName($keyColumnUsageTableName);

        // please refer to the following page for more details:
        // http://msdn2.microsoft.com/en-us/library/aa175805(SQL.80).aspx
        $sql = <<<SQL
340
SELECT
341 342 343
    [kcu1].[column_name] AS [fk_column_name],
    [kcu2].[table_name] AS [uq_table_name],
    [kcu2].[column_name] AS [uq_column_name]
344 345
FROM {$referentialConstraintsTableName} AS [rc]
JOIN {$keyColumnUsageTableName} AS [kcu1] ON
346 347 348
    [kcu1].[constraint_catalog] = [rc].[constraint_catalog] AND
    [kcu1].[constraint_schema] = [rc].[constraint_schema] AND
    [kcu1].[constraint_name] = [rc].[constraint_name]
349
JOIN {$keyColumnUsageTableName} AS [kcu2] ON
350 351 352 353
    [kcu2].[constraint_catalog] = [rc].[constraint_catalog] AND
    [kcu2].[constraint_schema] = [rc].[constraint_schema] AND
    [kcu2].[constraint_name] = [rc].[constraint_name] AND
    [kcu2].[ordinal_position] = [kcu1].[ordinal_position]
354
WHERE [kcu1].[table_name] = :tableName
355 356
SQL;

357 358 359 360 361 362 363 364 365
        $rows = $this->db->createCommand($sql, [':tableName' => $table->name])->queryAll();
        $table->foreignKeys = [];
        foreach ($rows as $row) {
            $table->foreignKeys[] = [$row['uq_table_name'], $row['fk_column_name'] => $row['uq_column_name']];
        }
    }

    /**
     * Returns all table names in the database.
366 367
     * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
     * @return array all table names in the database. The names have NO schema name prefix.
368 369 370 371 372 373 374 375
     */
    protected function findTableNames($schema = '')
    {
        if ($schema === '') {
            $schema = $this->defaultSchema;
        }

        $sql = <<<SQL
Qiang Xue committed
376
SELECT [t].[table_name]
Alexander Makarov committed
377
FROM [INFORMATION_SCHEMA].[TABLES] AS [t]
378
WHERE [t].[table_schema] = :schema AND [t].[table_type] = 'BASE TABLE'
379 380
SQL;

381 382
        return $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
    }
383
}