CPgsqlSchema.php 13.3 KB
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 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 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 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 179 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 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 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 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424
<?php
/**
 * CPgsqlSchema class file.
 *
 * @author Qiang Xue <qiang.xue@gmail.com>
 * @link http://www.yiiframework.com/
 * @copyright Copyright &copy; 2008-2011 Yii Software LLC
 * @license http://www.yiiframework.com/license/
 */

/**
 * CPgsqlSchema is the class for retrieving metadata information from a PostgreSQL database.
 *
 * @author Qiang Xue <qiang.xue@gmail.com>
 * @version $Id$
 * @package system.db.schema.pgsql
 * @since 1.0
 */
class CPgsqlSchema extends CDbSchema
{
	const DEFAULT_SCHEMA='public';

	/**
	 * @var array the abstract column types mapped to physical column types.
	 * @since 1.1.6
	 */
    public $columnTypes=array(
        'pk' => 'serial NOT NULL PRIMARY KEY',
        'string' => 'character varying (255)',
        'text' => 'text',
        'integer' => 'integer',
        'float' => 'double precision',
        'decimal' => 'numeric',
        'datetime' => 'timestamp',
        'timestamp' => 'timestamp',
        'time' => 'time',
        'date' => 'date',
        'binary' => 'bytea',
        'boolean' => 'boolean',
		'money' => 'decimal(19,4)',
    );

	private $_sequences=array();

	/**
	 * Quotes a table name for use in a query.
	 * A simple table name does not schema prefix.
	 * @param string $name table name
	 * @return string the properly quoted table name
	 * @since 1.1.6
	 */
	public function quoteSimpleTableName($name)
	{
		return '"'.$name.'"';
	}

	/**
	 * Resets the sequence value of a table's primary key.
	 * The sequence will be reset such that the primary key of the next new row inserted
	 * will have the specified value or 1.
	 * @param CDbTableSchema $table the table schema whose primary key sequence will be reset
	 * @param mixed $value the value for the primary key of the next new row inserted. If this is not set,
	 * the next new row's primary key will have a value 1.
	 * @since 1.1
	 */
	public function resetSequence($table,$value=null)
	{
		if($table->sequenceName!==null)
		{
			$seq='"'.$table->sequenceName.'"';
			if(strpos($seq,'.')!==false)
				$seq=str_replace('.','"."',$seq);
			if($value===null)
				$value="(SELECT COALESCE(MAX(\"{$table->primaryKey}\"),0) FROM {$table->rawName}) + 1";
			else
				$value=(int)$value;
			$this->getDbConnection()->createCommand("SELECT SETVAL('$seq', $value, false)")->execute();
		}
	}

	/**
	 * Enables or disables integrity check.
	 * @param boolean $check whether to turn on or off the integrity check.
	 * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
	 * @since 1.1
	 */
	public function checkIntegrity($check=true,$schema='')
	{
		$enable=$check ? 'ENABLE' : 'DISABLE';
		$tableNames=$this->getTableNames($schema);
		$db=$this->getDbConnection();
		foreach($tableNames as $tableName)
		{
			$tableName='"'.$tableName.'"';
			if(strpos($tableName,'.')!==false)
				$tableName=str_replace('.','"."',$tableName);
			$db->createCommand("ALTER TABLE $tableName $enable TRIGGER ALL")->execute();
		}
	}

	/**
	 * Loads the metadata for the specified table.
	 * @param string $name table name
	 * @return CDbTableSchema driver dependent table metadata.
	 */
	protected function loadTable($name)
	{
		$table=new CPgsqlTableSchema;
		$this->resolveTableNames($table,$name);
		if(!$this->findColumns($table))
			return null;
		$this->findConstraints($table);

		if(is_string($table->primaryKey) && isset($this->_sequences[$table->rawName.'.'.$table->primaryKey]))
			$table->sequenceName=$this->_sequences[$table->rawName.'.'.$table->primaryKey];
		else if(is_array($table->primaryKey))
		{
			foreach($table->primaryKey as $pk)
			{
				if(isset($this->_sequences[$table->rawName.'.'.$pk]))
				{
					$table->sequenceName=$this->_sequences[$table->rawName.'.'.$pk];
					break;
				}
			}
		}

		return $table;
	}

	/**
	 * Generates various kinds of table names.
	 * @param CPgsqlTableSchema $table the table instance
	 * @param string $name the unquoted table name
	 */
	protected function resolveTableNames($table,$name)
	{
		$parts=explode('.',str_replace('"','',$name));
		if(isset($parts[1]))
		{
			$schemaName=$parts[0];
			$tableName=$parts[1];
		}
		else
		{
			$schemaName=self::DEFAULT_SCHEMA;
			$tableName=$parts[0];
		}

		$table->name=$tableName;
		$table->schemaName=$schemaName;
		if($schemaName===self::DEFAULT_SCHEMA)
			$table->rawName=$this->quoteTableName($tableName);
		else
			$table->rawName=$this->quoteTableName($schemaName).'.'.$this->quoteTableName($tableName);
	}

	/**
	 * Collects the table column metadata.
	 * @param CPgsqlTableSchema $table the table metadata
	 * @return boolean whether the table exists in the database
	 */
	protected function findColumns($table)
	{
		$sql=<<<EOD
SELECT a.attname, LOWER(format_type(a.atttypid, a.atttypmod)) AS type, d.adsrc, a.attnotnull, a.atthasdef
FROM pg_attribute a LEFT JOIN pg_attrdef d ON a.attrelid = d.adrelid AND a.attnum = d.adnum
WHERE a.attnum > 0 AND NOT a.attisdropped
	AND a.attrelid = (SELECT oid FROM pg_catalog.pg_class WHERE relname=:table
		AND relnamespace = (SELECT oid FROM pg_catalog.pg_namespace WHERE nspname = :schema))
ORDER BY a.attnum
EOD;
		$command=$this->getDbConnection()->createCommand($sql);
		$command->bindValue(':table',$table->name);
		$command->bindValue(':schema',$table->schemaName);

		if(($columns=$command->queryAll())===array())
			return false;

		foreach($columns as $column)
		{
			$c=$this->createColumn($column);
			$table->columns[$c->name]=$c;

			if(stripos($column['adsrc'],'nextval')===0 && preg_match('/nextval\([^\']*\'([^\']+)\'[^\)]*\)/i',$column['adsrc'],$matches))
			{
				if(strpos($matches[1],'.')!==false || $table->schemaName===self::DEFAULT_SCHEMA)
					$this->_sequences[$table->rawName.'.'.$c->name]=$matches[1];
				else
					$this->_sequences[$table->rawName.'.'.$c->name]=$table->schemaName.'.'.$matches[1];
				$c->autoIncrement=true;
			}
		}
		return true;
	}

	/**
	 * Creates a table column.
	 * @param array $column column metadata
	 * @return CDbColumnSchema normalized column metadata
	 */
	protected function createColumn($column)
	{
		$c=new CPgsqlColumnSchema;
		$c->name=$column['attname'];
		$c->rawName=$this->quoteColumnName($c->name);
		$c->allowNull=!$column['attnotnull'];
		$c->isPrimaryKey=false;
		$c->isForeignKey=false;

		$c->init($column['type'],$column['atthasdef'] ? $column['adsrc'] : null);

		return $c;
	}

	/**
	 * Collects the primary and foreign key column details for the given table.
	 * @param CPgsqlTableSchema $table the table metadata
	 */
	protected function findConstraints($table)
	{
		$sql=<<<EOD
SELECT conname, consrc, contype, indkey FROM (
	SELECT
		conname,
		CASE WHEN contype='f' THEN
			pg_catalog.pg_get_constraintdef(oid)
		ELSE
			'CHECK (' || consrc || ')'
		END AS consrc,
		contype,
		conrelid AS relid,
		NULL AS indkey
	FROM
		pg_catalog.pg_constraint
	WHERE
		contype IN ('f', 'c')
	UNION ALL
	SELECT
		pc.relname,
		NULL,
		CASE WHEN indisprimary THEN
				'p'
		ELSE
				'u'
		END,
		pi.indrelid,
		indkey
	FROM
		pg_catalog.pg_class pc,
		pg_catalog.pg_index pi
	WHERE
		pc.oid=pi.indexrelid
		AND EXISTS (
			SELECT 1 FROM pg_catalog.pg_depend d JOIN pg_catalog.pg_constraint c
			ON (d.refclassid = c.tableoid AND d.refobjid = c.oid)
			WHERE d.classid = pc.tableoid AND d.objid = pc.oid AND d.deptype = 'i' AND c.contype IN ('u', 'p')
	)
) AS sub
WHERE relid = (SELECT oid FROM pg_catalog.pg_class WHERE relname=:table
	AND relnamespace = (SELECT oid FROM pg_catalog.pg_namespace
	WHERE nspname=:schema))
EOD;
		$command=$this->getDbConnection()->createCommand($sql);
		$command->bindValue(':table',$table->name);
		$command->bindValue(':schema',$table->schemaName);
		foreach($command->queryAll() as $row)
		{
			if($row['contype']==='p') // primary key
				$this->findPrimaryKey($table,$row['indkey']);
			else if($row['contype']==='f') // foreign key
				$this->findForeignKey($table,$row['consrc']);
		}
	}

	/**
	 * Collects primary key information.
	 * @param CPgsqlTableSchema $table the table metadata
	 * @param string $indices pgsql primary key index list
	 */
	protected function findPrimaryKey($table,$indices)
	{
		$indices=implode(', ',preg_split('/\s+/',$indices));
		$sql=<<<EOD
SELECT attnum, attname FROM pg_catalog.pg_attribute WHERE
	attrelid=(
		SELECT oid FROM pg_catalog.pg_class WHERE relname=:table AND relnamespace=(
			SELECT oid FROM pg_catalog.pg_namespace WHERE nspname=:schema
		)
	)
    AND attnum IN ({$indices})
EOD;
		$command=$this->getDbConnection()->createCommand($sql);
		$command->bindValue(':table',$table->name);
		$command->bindValue(':schema',$table->schemaName);
		foreach($command->queryAll() as $row)
		{
			$name=$row['attname'];
			if(isset($table->columns[$name]))
			{
				$table->columns[$name]->isPrimaryKey=true;
				if($table->primaryKey===null)
					$table->primaryKey=$name;
				else if(is_string($table->primaryKey))
					$table->primaryKey=array($table->primaryKey,$name);
				else
					$table->primaryKey[]=$name;
			}
		}
	}

	/**
	 * Collects foreign key information.
	 * @param CPgsqlTableSchema $table the table metadata
	 * @param string $src pgsql foreign key definition
	 */
	protected function findForeignKey($table,$src)
	{
		$matches=array();
		$brackets='\(([^\)]+)\)';
		$pattern="/FOREIGN\s+KEY\s+{$brackets}\s+REFERENCES\s+([^\(]+){$brackets}/i";
		if(preg_match($pattern,str_replace('"','',$src),$matches))
		{
			$keys=preg_split('/,\s+/', $matches[1]);
			$tableName=$matches[2];
			$fkeys=preg_split('/,\s+/', $matches[3]);
			foreach($keys as $i=>$key)
			{
				$table->foreignKeys[$key]=array($tableName,$fkeys[$i]);
				if(isset($table->columns[$key]))
					$table->columns[$key]->isForeignKey=true;
			}
		}
	}

	/**
	 * Returns all table names in the database.
	 * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
	 * If not empty, the returned table names will be prefixed with the schema name.
	 * @return array all table names in the database.
	 */
	protected function findTableNames($schema='')
	{
		if($schema==='')
			$schema=self::DEFAULT_SCHEMA;
		$sql=<<<EOD
SELECT table_name, table_schema FROM information_schema.tables
WHERE table_schema=:schema AND table_type='BASE TABLE'
EOD;
		$command=$this->getDbConnection()->createCommand($sql);
		$command->bindParam(':schema',$schema);
		$rows=$command->queryAll();
		$names=array();
		foreach($rows as $row)
		{
			if($schema===self::DEFAULT_SCHEMA)
				$names[]=$row['table_name'];
			else
				$names[]=$row['table_schema'].'.'.$row['table_name'];
		}
		return $names;
	}

	/**
	 * Builds a SQL statement for renaming a DB table.
	 * @param string $table the table to be renamed. The name will be properly quoted by the method.
	 * @param string $newName the new table name. The name will be properly quoted by the method.
	 * @return string the SQL statement for renaming a DB table.
	 * @since 1.1.6
	 */
	public function renameTable($table, $newName)
	{
		return 'ALTER TABLE ' . $this->quoteTableName($table) . ' RENAME TO ' . $this->quoteTableName($newName);
	}

	/**
	 * Builds a SQL statement for adding a new DB column.
	 * @param string $table the table that the new column will be added to. The table name will be properly quoted by the method.
	 * @param string $column the name of the new column. The name will be properly quoted by the method.
	 * @param string $type the column type. The {@link getColumnType} method will be invoked to convert abstract column type (if any)
	 * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL.
	 * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'.
	 * @return string the SQL statement for adding a new column.
	 * @since 1.1.6
	 */
	public function addColumn($table, $column, $type)
	{
		$type=$this->getColumnType($type);
		$sql='ALTER TABLE ' . $this->quoteTableName($table)
			. ' ADD COLUMN ' . $this->quoteColumnName($column) . ' '
			. $this->getColumnType($type);
		return $sql;
	}

	/**
	 * Builds a SQL statement for changing the definition of a column.
	 * @param string $table the table whose column is to be changed. The table name will be properly quoted by the method.
	 * @param string $column the name of the column to be changed. The name will be properly quoted by the method.
	 * @param string $type the new column type. The {@link getColumnType} method will be invoked to convert abstract column type (if any)
	 * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL.
	 * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'.
	 * @return string the SQL statement for changing the definition of a column.
	 * @since 1.1.6
	 */
	public function alterColumn($table, $column, $type)
	{
		$type=$this->getColumnType($type);
		$sql='ALTER TABLE ' . $this->quoteTableName($table) . ' ALTER COLUMN '
			. $this->quoteColumnName($column) . ' TYPE ' . $this->getColumnType($type);
		return $sql;
	}

	/**
	 * Builds a SQL statement for dropping an index.
	 * @param string $name the name of the index to be dropped. The name will be properly quoted by the method.
	 * @param string $table the table whose index is to be dropped. The name will be properly quoted by the method.
	 * @return string the SQL statement for dropping an index.
	 * @since 1.1.6
	 */
	public function dropIndex($name, $table)
	{
		return 'DROP INDEX '.$this->quoteTableName($name);
	}
}