1: <?php
2: 3: 4: 5: 6: 7: 8: 9: 10:
11:
12: 13: 14: 15: 16: 17: 18:
19: class CMssqlSchema extends CDbSchema
20: {
21: const DEFAULT_SCHEMA='dbo';
22:
23: 24: 25: 26:
27: public $columnTypes=array(
28: 'pk' => 'int IDENTITY PRIMARY KEY',
29: 'bigpk' => 'bigint IDENTITY PRIMARY KEY',
30: 'string' => 'varchar(255)',
31: 'text' => 'text',
32: 'integer' => 'int',
33: 'bigint' => 'bigint',
34: 'float' => 'float',
35: 'decimal' => 'decimal',
36: 'datetime' => 'datetime',
37: 'timestamp' => 'timestamp',
38: 'time' => 'time',
39: 'date' => 'date',
40: 'binary' => 'binary',
41: 'boolean' => 'bit',
42: );
43:
44: 45: 46: 47: 48: 49: 50:
51: public function quoteSimpleTableName($name)
52: {
53: return '['.$name.']';
54: }
55:
56: 57: 58: 59: 60: 61: 62:
63: public function quoteSimpleColumnName($name)
64: {
65: return '['.$name.']';
66: }
67:
68: 69: 70: 71: 72: 73: 74: 75:
76: public function compareTableNames($name1,$name2)
77: {
78: $name1=str_replace(array('[',']'),'',$name1);
79: $name2=str_replace(array('[',']'),'',$name2);
80: return parent::compareTableNames(strtolower($name1),strtolower($name2));
81: }
82:
83: 84: 85: 86: 87: 88: 89: 90: 91: 92:
93: public function resetSequence($table,$value=null)
94: {
95: if($table->sequenceName===null)
96: return;
97: if($value!==null)
98: $value=(int)($value)-1;
99: else
100: $value=(int)$this->getDbConnection()
101: ->createCommand("SELECT MAX([{$table->primaryKey}]) FROM {$table->rawName}")
102: ->queryScalar();
103: $name=strtr($table->rawName,array('['=>'',']'=>''));
104: $this->getDbConnection()
105: ->createCommand("DBCC CHECKIDENT ('$name',RESEED,$value)")
106: ->execute();
107: }
108:
109: private $_normalTables=array();
110: 111: 112: 113: 114: 115:
116: public function checkIntegrity($check=true,$schema='')
117: {
118: $enable=$check ? 'CHECK' : 'NOCHECK';
119: if(!isset($this->_normalTables[$schema]))
120: $this->_normalTables[$schema]=$this->findTableNames($schema,false);
121: $db=$this->getDbConnection();
122: foreach($this->_normalTables[$schema] as $tableName)
123: {
124: $tableName=$this->quoteTableName($tableName);
125: $db->createCommand("ALTER TABLE $tableName $enable CONSTRAINT ALL")->execute();
126: }
127: }
128:
129: 130: 131: 132: 133:
134: protected function loadTable($name)
135: {
136: $table=new CMssqlTableSchema;
137: $this->resolveTableNames($table,$name);
138:
139: $table->primaryKey=$this->findPrimaryKey($table);
140: $table->foreignKeys=$this->findForeignKeys($table);
141: if($this->findColumns($table))
142: {
143: return $table;
144: }
145: else
146: return null;
147: }
148:
149: 150: 151: 152: 153:
154: protected function resolveTableNames($table,$name)
155: {
156: $parts=explode('.',str_replace(array('[',']'),'',$name));
157: if(($c=count($parts))==3)
158: {
159:
160: $table->catalogName=$parts[0];
161: $table->schemaName=$parts[1];
162: $table->name=$parts[2];
163: $table->rawName=$this->quoteTableName($table->catalogName).'.'.$this->quoteTableName($table->schemaName).'.'.$this->quoteTableName($table->name);
164: }
165: elseif ($c==2)
166: {
167:
168: $table->name=$parts[1];
169: $table->schemaName=$parts[0];
170: $table->rawName=$this->quoteTableName($table->schemaName).'.'.$this->quoteTableName($table->name);
171: }
172: else
173: {
174:
175:
176: $table->name=$parts[0];
177: $table->schemaName=self::DEFAULT_SCHEMA;
178: $table->rawName=$this->quoteTableName($table->schemaName).'.'.$this->quoteTableName($table->name);
179: }
180: }
181:
182: 183: 184: 185: 186:
187: protected function findPrimaryKey($table)
188: {
189: $kcu='INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
190: $tc='INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
191: if (isset($table->catalogName))
192: {
193: $kcu=$table->catalogName.'.'.$kcu;
194: $tc=$table->catalogName.'.'.$tc;
195: }
196:
197: $sql = <<<EOD
198: SELECT k.column_name field_name
199: FROM {$this->quoteTableName($kcu)} k
200: LEFT JOIN {$this->quoteTableName($tc)} c
201: ON k.table_name = c.table_name
202: AND k.constraint_name = c.constraint_name
203: WHERE c.constraint_type ='PRIMARY KEY'
204: AND k.table_name = :table
205: AND k.table_schema = :schema
206: EOD;
207: $command = $this->getDbConnection()->createCommand($sql);
208: $command->bindValue(':table', $table->name);
209: $command->bindValue(':schema', $table->schemaName);
210: $primary=$command->queryColumn();
211: switch (count($primary))
212: {
213: case 0:
214: $primary=null;
215: break;
216: case 1:
217: $primary=$primary[0];
218: break;
219: }
220: return $primary;
221: }
222:
223: 224: 225: 226: 227:
228: protected function findForeignKeys($table)
229: {
230: $rc='INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS';
231: $kcu='INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
232: if (isset($table->catalogName))
233: {
234: $kcu=$table->catalogName.'.'.$kcu;
235: $rc=$table->catalogName.'.'.$rc;
236: }
237:
238:
239: $sql = <<<EOD
240: SELECT
241: KCU1.CONSTRAINT_NAME AS 'FK_CONSTRAINT_NAME'
242: , KCU1.TABLE_NAME AS 'FK_TABLE_NAME'
243: , KCU1.COLUMN_NAME AS 'FK_COLUMN_NAME'
244: , KCU1.ORDINAL_POSITION AS 'FK_ORDINAL_POSITION'
245: , KCU2.CONSTRAINT_NAME AS 'UQ_CONSTRAINT_NAME'
246: , KCU2.TABLE_NAME AS 'UQ_TABLE_NAME'
247: , KCU2.COLUMN_NAME AS 'UQ_COLUMN_NAME'
248: , KCU2.ORDINAL_POSITION AS 'UQ_ORDINAL_POSITION'
249: FROM {$this->quoteTableName($rc)} RC
250: JOIN {$this->quoteTableName($kcu)} KCU1
251: ON KCU1.CONSTRAINT_CATALOG = RC.CONSTRAINT_CATALOG
252: AND KCU1.CONSTRAINT_SCHEMA = RC.CONSTRAINT_SCHEMA
253: AND KCU1.CONSTRAINT_NAME = RC.CONSTRAINT_NAME
254: JOIN {$this->quoteTableName($kcu)} KCU2
255: ON KCU2.CONSTRAINT_CATALOG =
256: RC.UNIQUE_CONSTRAINT_CATALOG
257: AND KCU2.CONSTRAINT_SCHEMA =
258: RC.UNIQUE_CONSTRAINT_SCHEMA
259: AND KCU2.CONSTRAINT_NAME =
260: RC.UNIQUE_CONSTRAINT_NAME
261: AND KCU2.ORDINAL_POSITION = KCU1.ORDINAL_POSITION
262: WHERE KCU1.TABLE_NAME = :table
263: EOD;
264: $command = $this->getDbConnection()->createCommand($sql);
265: $command->bindValue(':table', $table->name);
266: $fkeys=array();
267: foreach($command->queryAll() as $info)
268: {
269: $fkeys[$info['FK_COLUMN_NAME']]=array($info['UQ_TABLE_NAME'],$info['UQ_COLUMN_NAME'],);
270:
271: }
272: return $fkeys;
273: }
274:
275:
276: 277: 278: 279: 280:
281: protected function findColumns($table)
282: {
283: $columnsTable="INFORMATION_SCHEMA.COLUMNS";
284: $where=array();
285: $where[]="t1.TABLE_NAME='".$table->name."'";
286: if (isset($table->catalogName))
287: {
288: $where[]="t1.TABLE_CATALOG='".$table->catalogName."'";
289: $columnsTable = $table->catalogName.'.'.$columnsTable;
290: }
291: if (isset($table->schemaName))
292: $where[]="t1.TABLE_SCHEMA='".$table->schemaName."'";
293:
294: $sql="SELECT t1.*, columnproperty(object_id(t1.table_schema+'.'+t1.table_name), t1.column_name, 'IsIdentity') AS IsIdentity, ".
295: "CONVERT(VARCHAR, t2.value) AS Comment FROM ".$this->quoteTableName($columnsTable)." AS t1 ".
296: "LEFT OUTER JOIN sys.extended_properties AS t2 ON t1.ORDINAL_POSITION = t2.minor_id AND ".
297: "object_name(t2.major_id) = t1.TABLE_NAME AND t2.class=1 AND t2.class_desc='OBJECT_OR_COLUMN' AND t2.name='MS_Description' ".
298: "WHERE ".join(' AND ',$where);
299: try
300: {
301: $columns=$this->getDbConnection()->createCommand($sql)->queryAll();
302: if(empty($columns))
303: return false;
304: }
305: catch(Exception $e)
306: {
307: return false;
308: }
309:
310: foreach($columns as $column)
311: {
312: $c=$this->createColumn($column);
313: if (is_array($table->primaryKey))
314: $c->isPrimaryKey=in_array($c->name, $table->primaryKey);
315: else
316: $c->isPrimaryKey=strcasecmp($c->name,$table->primaryKey)===0;
317:
318: $c->isForeignKey=isset($table->foreignKeys[$c->name]);
319: $table->columns[$c->name]=$c;
320: if ($c->autoIncrement && $table->sequenceName===null)
321: $table->sequenceName=$table->name;
322: }
323: return true;
324: }
325:
326: 327: 328: 329: 330:
331: protected function createColumn($column)
332: {
333: $c=new CMssqlColumnSchema;
334: $c->name=$column['COLUMN_NAME'];
335: $c->rawName=$this->quoteColumnName($c->name);
336: $c->allowNull=$column['IS_NULLABLE']=='YES';
337: if ($column['NUMERIC_PRECISION_RADIX']!==null)
338: {
339:
340: $c->size=$c->precision=$column['NUMERIC_PRECISION']!==null?(int)$column['NUMERIC_PRECISION']:null;
341: $c->scale=$column['NUMERIC_SCALE']!==null?(int)$column['NUMERIC_SCALE']:null;
342: }
343: elseif ($column['DATA_TYPE']=='image' || $column['DATA_TYPE']=='text')
344: $c->size=$c->precision=null;
345: else
346: $c->size=$c->precision=($column['CHARACTER_MAXIMUM_LENGTH']!== null)?(int)$column['CHARACTER_MAXIMUM_LENGTH']:null;
347: $c->autoIncrement=$column['IsIdentity']==1;
348: $c->comment=$column['Comment']===null ? '' : $column['Comment'];
349:
350: $c->init($column['DATA_TYPE'],$column['COLUMN_DEFAULT']);
351: return $c;
352: }
353:
354: 355: 356: 357: 358: 359: 360:
361: protected function findTableNames($schema='',$includeViews=true)
362: {
363: if($schema==='')
364: $schema=self::DEFAULT_SCHEMA;
365: if($includeViews)
366: $condition="TABLE_TYPE in ('BASE TABLE','VIEW')";
367: else
368: $condition="TABLE_TYPE='BASE TABLE'";
369: $sql=<<<EOD
370: SELECT TABLE_NAME FROM [INFORMATION_SCHEMA].[TABLES]
371: WHERE TABLE_SCHEMA=:schema AND $condition
372: EOD;
373: $command=$this->getDbConnection()->createCommand($sql);
374: $command->bindParam(":schema", $schema);
375: $rows=$command->queryAll();
376: $names=array();
377: foreach ($rows as $row)
378: {
379: if ($schema == self::DEFAULT_SCHEMA)
380: $names[]=$row['TABLE_NAME'];
381: else
382: $names[]=$schema.'.'.$row['TABLE_NAME'];
383: }
384:
385: return $names;
386: }
387:
388: 389: 390: 391: 392:
393: protected function createCommandBuilder()
394: {
395: return new CMssqlCommandBuilder($this);
396: }
397:
398: 399: 400: 401: 402: 403: 404:
405: public function renameTable($table, $newName)
406: {
407: return "sp_rename '$table', '$newName'";
408: }
409:
410: 411: 412: 413: 414: 415: 416: 417:
418: public function renameColumn($table, $name, $newName)
419: {
420: return "sp_rename '$table.$name', '$newName', 'COLUMN'";
421: }
422:
423: 424: 425: 426: 427: 428: 429: 430: 431: 432:
433: public function alterColumn($table, $column, $type)
434: {
435: $type=$this->getColumnType($type);
436: $sql='ALTER TABLE ' . $this->quoteTableName($table) . ' ALTER COLUMN '
437: . $this->quoteColumnName($column) . ' '
438: . $this->getColumnType($type);
439: return $sql;
440: }
441: }
442: