. */ namespace Doctrine\DBAL\Platforms; use Doctrine\DBAL\Schema\TableDiff; /** * PostgreSqlPlatform. * * @since 2.0 * @author Roman Borschel * @author Lukas Smith (PEAR MDB2 library) * @author Benjamin Eberlei */ class PostgreSqlPlatform extends AbstractPlatform { /** * Returns part of a string. * * Note: Not SQL92, but common functionality. * * @param string $value the target $value the string or the string column. * @param int $from extract from this characeter. * @param int $len extract this amount of characters. * @return string sql that extracts part of a string. * @override */ public function getSubstringExpression($value, $from, $len = null) { if ($len === null) { return 'SUBSTR(' . $value . ', ' . $from . ')'; } else { return 'SUBSTR(' . $value . ', ' . $from . ', ' . $len . ')'; } } /** * Returns the SQL string to return the current system date and time. * * @return string */ public function getNowExpression() { return 'LOCALTIMESTAMP(0)'; } /** * regexp * * @return string the regular expression operator * @override */ public function getRegexpExpression() { return 'SIMILAR TO'; } /** * returns the position of the first occurrence of substring $substr in string $str * * @param string $substr literal string to find * @param string $str literal string * @param int $pos position to start at, beginning of string by default * @return integer */ public function getLocateExpression($str, $substr, $startPos = false) { if ($startPos !== false) { $str = $this->getSubstringExpression($str, $startPos); return 'CASE WHEN (POSITION('.$substr.' IN '.$str.') = 0) THEN 0 ELSE (POSITION('.$substr.' IN '.$str.') + '.($startPos-1).') END'; } else { return 'POSITION('.$substr.' IN '.$str.')'; } } /** * parses a literal boolean value and returns * proper sql equivalent * * @param string $value boolean value to be parsed * @return string parsed boolean value */ /*public function parseBoolean($value) { return $value; }*/ /** * Whether the platform supports sequences. * Postgres has native support for sequences. * * @return boolean */ public function supportsSequences() { return true; } /** * Whether the platform supports database schemas. * * @return boolean */ public function supportsSchemas() { return true; } /** * Whether the platform supports identity columns. * Postgres supports these through the SERIAL keyword. * * @return boolean */ public function supportsIdentityColumns() { return true; } /** * Whether the platform prefers sequences for ID generation. * * @return boolean */ public function prefersSequences() { return true; } public function getListDatabasesSql() { return 'SELECT datname FROM pg_database'; } public function getListSequencesSql($database) { return "SELECT relname FROM pg_class WHERE relkind = 'S' AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname NOT LIKE 'pg_%' AND nspname != 'information_schema')"; } public function getListTablesSql() { return "SELECT c.relname AS table_name FROM pg_class c, pg_user u WHERE c.relowner = u.usesysid AND c.relkind = 'r' AND NOT EXISTS (SELECT 1 FROM pg_views WHERE viewname = c.relname) AND c.relname !~ '^(pg_|sql_)' UNION SELECT c.relname AS table_name FROM pg_class c WHERE c.relkind = 'r' AND NOT EXISTS (SELECT 1 FROM pg_views WHERE viewname = c.relname) AND NOT EXISTS (SELECT 1 FROM pg_user WHERE usesysid = c.relowner) AND c.relname !~ '^pg_'"; } public function getListViewsSql($database) { return 'SELECT viewname, definition FROM pg_views'; } public function getListTableForeignKeysSql($table, $database = null) { return "SELECT r.conname, pg_catalog.pg_get_constraintdef(r.oid, true) as condef FROM pg_catalog.pg_constraint r WHERE r.conrelid = ( SELECT c.oid FROM pg_catalog.pg_class c LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace WHERE c.relname = '" . $table . "' AND pg_catalog.pg_table_is_visible(c.oid) ) AND r.contype = 'f'"; } public function getCreateViewSql($name, $sql) { return 'CREATE VIEW ' . $name . ' AS ' . $sql; } public function getDropViewSql($name) { return 'DROP VIEW '. $name; } public function getListTableConstraintsSql($table) { return "SELECT relname FROM pg_class WHERE oid IN ( SELECT indexrelid FROM pg_index, pg_class WHERE pg_class.relname = '$table' AND pg_class.oid = pg_index.indrelid AND (indisunique = 't' OR indisprimary = 't') )"; } /** * @license New BSD License * @link http://ezcomponents.org/docs/api/trunk/DatabaseSchema/ezcDbSchemaPgsqlReader.html * @param string $table * @return string */ public function getListTableIndexesSql($table) { return "SELECT relname, pg_index.indisunique, pg_index.indisprimary, pg_index.indkey, pg_index.indrelid FROM pg_class, pg_index WHERE oid IN ( SELECT indexrelid FROM pg_index, pg_class WHERE pg_class.relname='$table' AND pg_class.oid=pg_index.indrelid ) AND pg_index.indexrelid = oid"; } public function getListTableColumnsSql($table) { return "SELECT a.attnum, a.attname AS field, t.typname AS type, format_type(a.atttypid, a.atttypmod) AS complete_type, a.attnotnull AS isnotnull, (SELECT 't' FROM pg_index WHERE c.oid = pg_index.indrelid AND pg_index.indkey[0] = a.attnum AND pg_index.indisprimary = 't' ) AS pri, (SELECT pg_attrdef.adsrc FROM pg_attrdef WHERE c.oid = pg_attrdef.adrelid AND pg_attrdef.adnum=a.attnum ) AS default FROM pg_attribute a, pg_class c, pg_type t WHERE c.relname = '$table' AND a.attnum > 0 AND a.attrelid = c.oid AND a.atttypid = t.oid ORDER BY a.attnum"; } /** * create a new database * * @param string $name name of the database that should be created * @throws PDOException * @return void * @override */ public function getCreateDatabaseSql($name) { return 'CREATE DATABASE ' . $name; } /** * drop an existing database * * @param string $name name of the database that should be dropped * @throws PDOException * @access public */ public function getDropDatabaseSql($name) { return 'DROP DATABASE ' . $name; } /** * getAdvancedForeignKeyOptions * Return the FOREIGN KEY query section dealing with non-standard options * as MATCH, INITIALLY DEFERRED, ON UPDATE, ... * * @param \Doctrine\DBAL\Schema\ForeignKeyConstraint $foreignKey foreign key definition * @return string * @override */ public function getAdvancedForeignKeyOptionsSql(\Doctrine\DBAL\Schema\ForeignKeyConstraint $foreignKey) { $query = ''; if ($foreignKey->hasOption('match')) { $query .= ' MATCH ' . $foreignKey->getOption('match'); } $query .= parent::getAdvancedForeignKeyOptionsSql($foreignKey); if ($foreignKey->hasOption('deferrable') && $foreignKey->getOption('deferrable') !== false) { $query .= ' DEFERRABLE'; } else { $query .= ' NOT DEFERRABLE'; } if ($foreignKey->hasOption('feferred') && $foreignKey->getOption('feferred') !== false) { $query .= ' INITIALLY DEFERRED'; } else { $query .= ' INITIALLY IMMEDIATE'; } return $query; } /** * generates the sql for altering an existing table on postgresql * * @param string $name name of the table that is intended to be changed. * @param array $changes associative array that contains the details of each type * * @param boolean $check indicates whether the function should just check if the DBMS driver * can perform the requested table alterations if the value is true or * actually perform them otherwise. * @see Doctrine_Export::alterTable() * @return array * @override */ public function getAlterTableSql(TableDiff $diff) { $sql = array(); foreach ($diff->addedColumns as $column) { $query = 'ADD ' . $this->getColumnDeclarationSql($column->getName(), $column->toArray()); $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } foreach ($diff->removedColumns as $column) { $query = 'DROP ' . $column->getName(); $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } foreach ($diff->changedColumns AS $columnDiff) { $oldColumnName = $columnDiff->oldColumnName; $column = $columnDiff->column; if ($columnDiff->hasChanged('type')) { $type = $column->getType(); // here was a server version check before, but DBAL API does not support this anymore. $query = 'ALTER ' . $oldColumnName . ' TYPE ' . $type->getSqlDeclaration($column->toArray(), $this); $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } if ($columnDiff->hasChanged('default')) { $query = 'ALTER ' . $oldColumnName . ' SET ' . $this->getDefaultValueDeclarationSql($column->toArray()); $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } if ($columnDiff->hasChanged('notnull')) { $query = 'ALTER ' . $oldColumnName . ' ' . ($column->getNotNull() ? 'SET' : 'DROP') . ' NOT NULL'; $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } } foreach ($diff->renamedColumns as $oldColumnName => $column) { $sql[] = 'ALTER TABLE ' . $diff->name . ' RENAME COLUMN ' . $oldColumnName . ' TO ' . $column->getName(); } if ($diff->newName !== false) { $sql[] = 'ALTER TABLE ' . $diff->name . ' RENAME TO ' . $diff->newName; } $sql = array_merge($sql, $this->_getAlterTableIndexForeignKeySql($diff)); return $sql; } /** * Gets the SQL to create a sequence on this platform. * * @param \Doctrine\DBAL\Schema\Sequence $sequence * @throws DoctrineException */ public function getCreateSequenceSql(\Doctrine\DBAL\Schema\Sequence $sequence) { return 'CREATE SEQUENCE ' . $sequence->getName() . ' INCREMENT BY ' . $sequence->getAllocationSize() . ' MINVALUE ' . $sequence->getInitialValue() . ' START ' . $sequence->getInitialValue(); } /** * Drop existing sequence * @param \Doctrine\DBAL\Schema\Sequence $sequence * @return string */ public function getDropSequenceSql($sequence) { if ($sequence instanceof \Doctrine\DBAL\Schema\Sequence) { $sequence = $sequence->getName(); } return 'DROP SEQUENCE ' . $sequence; } /** * @param ForeignKeyConstraint|string $foreignKey * @param Table|string $table * @return string */ public function getDropForeignKeySql($foreignKey, $table) { return $this->getDropConstraintSql($foreignKey, $table); } /** * Gets the SQL used to create a table. * * @param unknown_type $tableName * @param array $columns * @param array $options * @return unknown */ protected function _getCreateTableSql($tableName, array $columns, array $options = array()) { $queryFields = $this->getColumnDeclarationListSql($columns); if (isset($options['primary']) && ! empty($options['primary'])) { $keyColumns = array_unique(array_values($options['primary'])); $queryFields .= ', PRIMARY KEY(' . implode(', ', $keyColumns) . ')'; } $query = 'CREATE TABLE ' . $tableName . ' (' . $queryFields . ')'; $sql[] = $query; if (isset($options['indexes']) && ! empty($options['indexes'])) { foreach ($options['indexes'] AS $index) { $sql[] = $this->getCreateIndexSql($index, $tableName); } } if (isset($options['foreignKeys'])) { foreach ((array) $options['foreignKeys'] as $definition) { $sql[] = $this->getCreateForeignKeySql($definition, $tableName); } } return $sql; } /** * Postgres wants boolean values converted to the strings 'true'/'false'. * * @param array $item * @override */ public function convertBooleans($item) { if (is_array($item)) { foreach ($item as $key => $value) { if (is_bool($value) || is_numeric($item)) { $item[$key] = ($value) ? 'true' : 'false'; } } } else { if (is_bool($item) || is_numeric($item)) { $item = ($item) ? 'true' : 'false'; } } return $item; } public function getSequenceNextValSql($sequenceName) { return "SELECT NEXTVAL('" . $sequenceName . "')"; } public function getSetTransactionIsolationSql($level) { return 'SET SESSION CHARACTERISTICS AS TRANSACTION ISOLATION LEVEL ' . $this->_getTransactionIsolationLevelSql($level); } /** * @override */ public function getBooleanTypeDeclarationSql(array $field) { return 'BOOLEAN'; } /** * @override */ public function getIntegerTypeDeclarationSql(array $field) { if ( ! empty($field['autoincrement'])) { return 'SERIAL'; } return 'INT'; } /** * @override */ public function getBigIntTypeDeclarationSql(array $field) { if ( ! empty($field['autoincrement'])) { return 'BIGSERIAL'; } return 'BIGINT'; } /** * @override */ public function getSmallIntTypeDeclarationSql(array $field) { return 'SMALLINT'; } /** * @override */ public function getDateTimeTypeDeclarationSql(array $fieldDeclaration) { return 'TIMESTAMP(0) WITH TIME ZONE'; } /** * @override */ public function getDateTypeDeclarationSql(array $fieldDeclaration) { return 'DATE'; } /** * @override */ public function getTimeTypeDeclarationSql(array $fieldDeclaration) { return 'TIME'; } /** * @override */ protected function _getCommonIntegerTypeDeclarationSql(array $columnDef) { return ''; } /** * Gets the SQL snippet used to declare a VARCHAR column on the MySql platform. * * @params array $field * @override */ public function getVarcharTypeDeclarationSql(array $field) { if ( ! isset($field['length'])) { if (array_key_exists('default', $field)) { $field['length'] = $this->getVarcharMaxLength(); } else { $field['length'] = false; } } $length = ($field['length'] <= $this->getVarcharMaxLength()) ? $field['length'] : false; $fixed = (isset($field['fixed'])) ? $field['fixed'] : false; return $fixed ? ($length ? 'CHAR(' . $length . ')' : 'CHAR(255)') : ($length ? 'VARCHAR(' . $length . ')' : 'TEXT'); } /** @override */ public function getClobTypeDeclarationSql(array $field) { return 'TEXT'; } /** * Get the platform name for this instance * * @return string */ public function getName() { return 'postgresql'; } /** * Gets the character casing of a column in an SQL result set. * * PostgreSQL returns all column names in SQL result sets in lowercase. * * @param string $column The column name for which to get the correct character casing. * @return string The column name in the character casing used in SQL result sets. */ public function getSqlResultCasing($column) { return strtolower($column); } public function getDateTimeFormatString() { return 'Y-m-d H:i:sO'; } /** * Get the insert sql for an empty insert statement * * @param string $tableName * @param string $identifierColumnName * @return string $sql */ public function getEmptyIdentityInsertSql($quotedTableName, $quotedIdentifierColumnName) { return 'INSERT INTO ' . $quotedTableName . ' (' . $quotedIdentifierColumnName . ') VALUES (DEFAULT)'; } /** * @inheritdoc */ public function getTruncateTableSql($tableName, $cascade = false) { return 'TRUNCATE '.$tableName.' '.($cascade)?'CASCADE':''; } }