PostgreSqlPlatform.php 31.8 KB
Newer Older
1
<?php
2 3 4 5 6 7 8 9 10 11 12 13 14 15
/*
 * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
 * "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
 * LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
 * A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
 * OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,
 * SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT
 * LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
 * DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
 * THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
 * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
 * OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
 *
 * This software consists of voluntary contributions made by many individuals
Benjamin Eberlei's avatar
Benjamin Eberlei committed
16
 * and is licensed under the MIT license. For more information, see
17 18
 * <http://www.doctrine-project.org>.
 */
19

20
namespace Doctrine\DBAL\Platforms;
21

Steve Müller's avatar
Steve Müller committed
22 23
use Doctrine\DBAL\Schema\Column;
use Doctrine\DBAL\Schema\ColumnDiff;
24
use Doctrine\DBAL\Schema\Identifier;
25
use Doctrine\DBAL\Schema\Index;
jeroendedauw's avatar
jeroendedauw committed
26
use Doctrine\DBAL\Schema\Sequence;
Benjamin Morel's avatar
Benjamin Morel committed
27
use Doctrine\DBAL\Schema\TableDiff;
Steve Müller's avatar
Steve Müller committed
28 29
use Doctrine\DBAL\Types\BinaryType;
use Doctrine\DBAL\Types\BlobType;
30

31 32 33
/**
 * PostgreSqlPlatform.
 *
Benjamin Morel's avatar
Benjamin Morel committed
34
 * @since  2.0
35 36
 * @author Roman Borschel <roman@code-factory.org>
 * @author Lukas Smith <smith@pooteeweet.org> (PEAR MDB2 library)
37
 * @author Benjamin Eberlei <kontakt@beberlei.de>
Benjamin Morel's avatar
Benjamin Morel committed
38
 * @todo   Rename: PostgreSQLPlatform
39
 */
40
class PostgreSqlPlatform extends AbstractPlatform
41
{
42 43 44 45 46
    /**
     * @var bool
     */
    private $useBooleanTrueFalseStrings = true;

47 48 49 50
    /**
     * @var array PostgreSQL booleans literals
     */
    private $booleanLiterals = array(
51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67
        'true' => array(
            't',
            'true',
            'y',
            'yes',
            'on',
            '1'
        ),
        'false' => array(
            'f',
            'false',
            'n',
            'no',
            'off',
            '0'
        )
    );
68

69 70 71 72 73 74 75 76 77 78 79 80 81
    /**
     * PostgreSQL has different behavior with some drivers
     * with regard to how booleans have to be handled.
     *
     * Enables use of 'true'/'false' or otherwise 1 and 0 instead.
     *
     * @param bool $flag
     */
    public function setUseBooleanTrueFalseStrings($flag)
    {
        $this->useBooleanTrueFalseStrings = (bool)$flag;
    }

82
    /**
83
     * {@inheritDoc}
84
     */
85
    public function getSubstringExpression($value, $from, $length = null)
86
    {
87
        if ($length === null) {
88
            return 'SUBSTRING(' . $value . ' FROM ' . $from . ')';
89
        }
90

91
        return 'SUBSTRING(' . $value . ' FROM ' . $from . ' FOR ' . $length . ')';
92 93 94
    }

    /**
95
     * {@inheritDoc}
96 97 98 99 100 101 102
     */
    public function getNowExpression()
    {
        return 'LOCALTIMESTAMP(0)';
    }

    /**
103
     * {@inheritDoc}
104 105 106 107 108
     */
    public function getRegexpExpression()
    {
        return 'SIMILAR TO';
    }
109 110

    /**
111
     * {@inheritDoc}
112 113 114 115 116
     */
    public function getLocateExpression($str, $substr, $startPos = false)
    {
        if ($startPos !== false) {
            $str = $this->getSubstringExpression($str, $startPos);
117

118 119
            return 'CASE WHEN (POSITION('.$substr.' IN '.$str.') = 0) THEN 0 ELSE (POSITION('.$substr.' IN '.$str.') + '.($startPos-1).') END';
        }
120 121

        return 'POSITION('.$substr.' IN '.$str.')';
122
    }
123

124
    /**
125
     * {@inheritdoc}
126
     */
127
    protected function getDateArithmeticIntervalExpression($date, $operator, $interval, $unit)
128
    {
129 130 131 132
        if (self::DATE_INTERVAL_UNIT_QUARTER === $unit) {
            $interval *= 3;
            $unit = self::DATE_INTERVAL_UNIT_MONTH;
        }
133

134
        return "(" . $date ." " . $operator . " (" . $interval . " || ' " . $unit . "')::interval)";
135 136
    }

137 138 139
    /**
     * {@inheritDoc}
     */
140
    public function getDateDiffExpression($date1, $date2)
141
    {
142
        return '(DATE(' . $date1 . ')-DATE(' . $date2 . '))';
143
    }
144

145
    /**
146
     * {@inheritDoc}
romanb's avatar
romanb committed
147 148 149 150 151
     */
    public function supportsSequences()
    {
        return true;
    }
152

153
    /**
154
     * {@inheritDoc}
155 156 157 158 159
     */
    public function supportsSchemas()
    {
        return true;
    }
160

161 162 163 164 165 166 167 168
    /**
     * {@inheritdoc}
     */
    public function getDefaultSchemaName()
    {
        return 'public';
    }

romanb's avatar
romanb committed
169
    /**
170
     * {@inheritDoc}
romanb's avatar
romanb committed
171 172 173 174 175
     */
    public function supportsIdentityColumns()
    {
        return true;
    }
176

177
    /**
178
     * {@inheritdoc}
179 180 181 182 183 184
     */
    public function supportsPartialIndexes()
    {
        return true;
    }

185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200
    /**
     * {@inheritdoc}
     */
    public function usesSequenceEmulatedIdentityColumns()
    {
        return true;
    }

    /**
     * {@inheritdoc}
     */
    public function getIdentitySequenceName($tableName, $columnName)
    {
        return $tableName . '_' . $columnName . '_seq';
    }

201 202 203
    /**
     * {@inheritDoc}
     */
204 205 206 207
    public function supportsCommentOnStatement()
    {
        return true;
    }
208

romanb's avatar
romanb committed
209
    /**
210
     * {@inheritDoc}
romanb's avatar
romanb committed
211 212 213 214 215
     */
    public function prefersSequences()
    {
        return true;
    }
216

217 218 219 220 221 222 223 224
    /**
     * {@inheritDoc}
     */
    public function hasNativeGuidType()
    {
        return true;
    }

Benjamin Morel's avatar
Benjamin Morel committed
225 226 227
    /**
     * {@inheritDoc}
     */
228
    public function getListDatabasesSQL()
229 230 231
    {
        return 'SELECT datname FROM pg_database';
    }
232

233 234 235 236 237 238 239 240
    /**
     * {@inheritDoc}
     */
    public function getListNamespacesSQL()
    {
        return "SELECT nspname FROM pg_namespace WHERE nspname NOT LIKE 'pg_%' AND nspname != 'information_schema'";
    }

Benjamin Morel's avatar
Benjamin Morel committed
241 242 243
    /**
     * {@inheritDoc}
     */
244
    public function getListSequencesSQL($database)
245 246
    {
        return "SELECT
247
                    c.relname, n.nspname AS schemaname
248
                FROM
249
                   pg_class c, pg_namespace n
250
                WHERE relkind = 'S' AND n.oid = c.relnamespace AND
251
                    (n.nspname NOT LIKE 'pg_%' AND n.nspname != 'information_schema')";
252
    }
253

Benjamin Morel's avatar
Benjamin Morel committed
254 255 256
    /**
     * {@inheritDoc}
     */
257
    public function getListTablesSQL()
258
    {
259
        return "SELECT quote_ident(tablename) AS table_name, schemaname AS schema_name
jsor's avatar
jsor committed
260
                FROM pg_tables WHERE schemaname NOT LIKE 'pg_%' AND schemaname != 'information_schema' AND tablename != 'geometry_columns' AND tablename != 'spatial_ref_sys'";
261
    }
262

263 264 265
    /**
     * {@inheritDoc}
     */
266
    public function getListViewsSQL($database)
267
    {
268
        return 'SELECT quote_ident(viewname) as viewname, schemaname, definition FROM pg_views';
269
    }
270

Benjamin Morel's avatar
Benjamin Morel committed
271 272 273
    /**
     * {@inheritDoc}
     */
274
    public function getListTableForeignKeysSQL($table, $database = null)
275
    {
276
        return "SELECT quote_ident(r.conname) as conname, pg_catalog.pg_get_constraintdef(r.oid, true) as condef
277 278 279 280
                  FROM pg_catalog.pg_constraint r
                  WHERE r.conrelid =
                  (
                      SELECT c.oid
281
                      FROM pg_catalog.pg_class c, pg_catalog.pg_namespace n
282
                      WHERE " .$this->getTableWhereClause($table) ." AND n.oid = c.relnamespace
283 284 285 286
                  )
                  AND r.contype = 'f'";
    }

Benjamin Morel's avatar
Benjamin Morel committed
287 288 289
    /**
     * {@inheritDoc}
     */
290
    public function getCreateViewSQL($name, $sql)
291 292 293 294
    {
        return 'CREATE VIEW ' . $name . ' AS ' . $sql;
    }

Benjamin Morel's avatar
Benjamin Morel committed
295 296 297
    /**
     * {@inheritDoc}
     */
298
    public function getDropViewSQL($name)
299 300 301 302
    {
        return 'DROP VIEW '. $name;
    }

Benjamin Morel's avatar
Benjamin Morel committed
303 304 305
    /**
     * {@inheritDoc}
     */
306
    public function getListTableConstraintsSQL($table)
307
    {
308 309 310
        $table = new Identifier($table);
        $table = $table->getName();

311
        return "SELECT
312
                    quote_ident(relname) as relname
313 314 315 316 317
                FROM
                    pg_class
                WHERE oid IN (
                    SELECT indexrelid
                    FROM pg_index, pg_class
318
                    WHERE pg_class.relname = '$table'
319 320 321 322
                        AND pg_class.oid = pg_index.indrelid
                        AND (indisunique = 't' OR indisprimary = 't')
                        )";
    }
323

324
    /**
325 326
     * {@inheritDoc}
     *
327 328 329
     * @license New BSD License
     * @link http://ezcomponents.org/docs/api/trunk/DatabaseSchema/ezcDbSchemaPgsqlReader.html
     */
330
    public function getListTableIndexesSQL($table, $currentDatabase = null)
331
    {
332
        return "SELECT quote_ident(relname) as relname, pg_index.indisunique, pg_index.indisprimary,
333 334
                       pg_index.indkey, pg_index.indrelid,
                       TRIM(BOTH '()' FROM pg_get_expr(indpred, indrelid)) AS where
335 336
                 FROM pg_class, pg_index
                 WHERE oid IN (
337
                    SELECT indexrelid
338 339
                    FROM pg_index si, pg_class sc, pg_namespace sn
                    WHERE " . $this->getTableWhereClause($table, 'sc', 'sn')." AND sc.oid=si.indrelid AND sc.relnamespace = sn.oid
340
                 ) AND pg_index.indexrelid = oid";
341
    }
342

343 344 345 346
    /**
     * @param string $table
     * @param string $classAlias
     * @param string $namespaceAlias
347
     *
348 349
     * @return string
     */
350 351
    private function getTableWhereClause($table, $classAlias = 'c', $namespaceAlias = 'n')
    {
352
        $whereClause = $namespaceAlias.".nspname NOT IN ('pg_catalog', 'information_schema', 'pg_toast') AND ";
353 354
        if (strpos($table, ".") !== false) {
            list($schema, $table) = explode(".", $table);
355
            $schema = "'" . $schema . "'";
356
        } else {
357
            $schema = "ANY(string_to_array((select replace(replace(setting,'\"\$user\"',user),' ','') from pg_catalog.pg_settings where name = 'search_path'),','))";
358
        }
359 360 361

        $table = new Identifier($table);
        $whereClause .= "$classAlias.relname = '" . $table->getName() . "' AND $namespaceAlias.nspname = $schema";
362

363 364 365
        return $whereClause;
    }

Benjamin Morel's avatar
Benjamin Morel committed
366 367 368
    /**
     * {@inheritDoc}
     */
369
    public function getListTableColumnsSQL($table, $database = null)
370 371 372
    {
        return "SELECT
                    a.attnum,
373
                    quote_ident(a.attname) AS field,
374 375
                    t.typname AS type,
                    format_type(a.atttypid, a.atttypmod) AS complete_type,
376
                    (SELECT t1.typname FROM pg_catalog.pg_type t1 WHERE t1.oid = t.typbasetype) AS domain_type,
377 378
                    (SELECT format_type(t2.typbasetype, t2.typtypmod) FROM
                      pg_catalog.pg_type t2 WHERE t2.typtype = 'd' AND t2.oid = a.atttypid) AS domain_complete_type,
379 380 381 382 383 384 385
                    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,
386
                    (SELECT pg_get_expr(adbin, adrelid)
387 388 389
                     FROM pg_attrdef
                     WHERE c.oid = pg_attrdef.adrelid
                        AND pg_attrdef.adnum=a.attnum
390 391
                    ) AS default,
                    (SELECT pg_description.description
392
                        FROM pg_description WHERE pg_description.objoid = c.oid AND a.attnum = pg_description.objsubid
393 394
                    ) AS comment
                    FROM pg_attribute a, pg_class c, pg_type t, pg_namespace n
395
                    WHERE ".$this->getTableWhereClause($table, 'c', 'n') ."
396 397 398
                        AND a.attnum > 0
                        AND a.attrelid = c.oid
                        AND a.atttypid = t.oid
399
                        AND n.oid = c.relnamespace
400 401
                    ORDER BY a.attnum";
    }
402

403
    /**
404
     * {@inheritDoc}
405
     */
406
    public function getCreateDatabaseSQL($name)
407
    {
408
        return 'CREATE DATABASE ' . $name;
409
    }
410

411
    /**
412
     * {@inheritDoc}
413
     */
414
    public function getAdvancedForeignKeyOptionsSQL(\Doctrine\DBAL\Schema\ForeignKeyConstraint $foreignKey)
415 416
    {
        $query = '';
417

418 419
        if ($foreignKey->hasOption('match')) {
            $query .= ' MATCH ' . $foreignKey->getOption('match');
420
        }
421

422
        $query .= parent::getAdvancedForeignKeyOptionsSQL($foreignKey);
423

424
        if ($foreignKey->hasOption('deferrable') && $foreignKey->getOption('deferrable') !== false) {
425 426 427 428
            $query .= ' DEFERRABLE';
        } else {
            $query .= ' NOT DEFERRABLE';
        }
429

430 431 432
        if (($foreignKey->hasOption('feferred') && $foreignKey->getOption('feferred') !== false)
            || ($foreignKey->hasOption('deferred') && $foreignKey->getOption('deferred') !== false)
        ) {
433 434 435 436
            $query .= ' INITIALLY DEFERRED';
        } else {
            $query .= ' INITIALLY IMMEDIATE';
        }
437

438 439
        return $query;
    }
440

441
    /**
442
     * {@inheritDoc}
443
     */
444
    public function getAlterTableSQL(TableDiff $diff)
445
    {
446
        $sql = array();
447
        $commentsSQL = array();
448
        $columnSql = array();
449 450

        foreach ($diff->addedColumns as $column) {
451 452
            if ($this->onSchemaAlterTableAddColumn($column, $diff, $columnSql)) {
                continue;
453 454
            }

455
            $query = 'ADD ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray());
456
            $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
457 458
            if ($comment = $this->getColumnComment($column)) {
                $commentsSQL[] = $this->getCommentOnColumnSQL($diff->name, $column->getName(), $comment);
459
            }
460 461
        }

462
        foreach ($diff->removedColumns as $column) {
463 464
            if ($this->onSchemaAlterTableRemoveColumn($column, $diff, $columnSql)) {
                continue;
465 466
            }

467
            $query = 'DROP ' . $column->getQuotedName($this);
468
            $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
469 470
        }

471
        foreach ($diff->changedColumns as $columnDiff) {
472
            /** @var $columnDiff \Doctrine\DBAL\Schema\ColumnDiff */
473 474
            if ($this->onSchemaAlterTableChangeColumn($columnDiff, $diff, $columnSql)) {
                continue;
475 476
            }

Steve Müller's avatar
Steve Müller committed
477 478 479 480
            if ($this->isUnchangedBinaryColumn($columnDiff)) {
                continue;
            }

481
            $oldColumnName = $columnDiff->getOldColumnName()->getQuotedName($this);
482
            $column = $columnDiff->column;
483

484
            if ($columnDiff->hasChanged('type') || $columnDiff->hasChanged('precision') || $columnDiff->hasChanged('scale')) {
485
                $type = $column->getType();
486

487 488
                // here was a server version check before, but DBAL API does not support this anymore.
                $query = 'ALTER ' . $oldColumnName . ' TYPE ' . $type->getSqlDeclaration($column->toArray(), $this);
489
                $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
490
            }
491

492
            if ($columnDiff->hasChanged('default') || $columnDiff->hasChanged('type')) {
493 494 495 496
                $defaultClause = null === $column->getDefault()
                    ? ' DROP DEFAULT'
                    : ' SET' . $this->getDefaultValueDeclarationSQL($column->toArray());
                $query = 'ALTER ' . $oldColumnName . $defaultClause;
497
                $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
498
            }
499

500 501
            if ($columnDiff->hasChanged('notnull')) {
                $query = 'ALTER ' . $oldColumnName . ' ' . ($column->getNotNull() ? 'SET' : 'DROP') . ' NOT NULL';
502
                $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
503
            }
504

505 506 507
            if ($columnDiff->hasChanged('autoincrement')) {
                if ($column->getAutoincrement()) {
                    // add autoincrement
508
                    $seqName = $this->getIdentitySequenceName($diff->name, $oldColumnName);
509 510

                    $sql[] = "CREATE SEQUENCE " . $seqName;
511
                    $sql[] = "SELECT setval('" . $seqName . "', (SELECT MAX(" . $oldColumnName . ") FROM " . $diff->getName()->getQuotedName($this) . "))";
512
                    $query = "ALTER " . $oldColumnName . " SET DEFAULT nextval('" . $seqName . "')";
513
                    $sql[] = "ALTER TABLE " . $diff->getName()->getQuotedName($this) . " " . $query;
514 515 516
                } else {
                    // Drop autoincrement, but do NOT drop the sequence. It might be re-used by other tables or have
                    $query = "ALTER " . $oldColumnName . " " . "DROP DEFAULT";
517
                    $sql[] = "ALTER TABLE " . $diff->getName()->getQuotedName($this) . " " . $query;
518 519
                }
            }
520

521 522 523 524 525 526
            if ($columnDiff->hasChanged('comment')) {
                $commentsSQL[] = $this->getCommentOnColumnSQL(
                    $diff->name,
                    $column->getName(),
                    $this->getColumnComment($column)
                );
527
            }
528 529

            if ($columnDiff->hasChanged('length')) {
530
                $query = 'ALTER ' . $oldColumnName . ' TYPE ' . $column->getType()->getSqlDeclaration($column->toArray(), $this);
531
                $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' ' . $query;
532
            }
533 534
        }

535
        foreach ($diff->renamedColumns as $oldColumnName => $column) {
536 537
            if ($this->onSchemaAlterTableRenameColumn($oldColumnName, $column, $diff, $columnSql)) {
                continue;
538 539
            }

540 541 542 543
            $oldColumnName = new Identifier($oldColumnName);

            $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) .
                ' RENAME COLUMN ' . $oldColumnName->getQuotedName($this) . ' TO ' . $column->getQuotedName($this);
544 545
        }

546 547
        $tableSql = array();

548
        if ( ! $this->onSchemaAlterTable($diff, $tableSql)) {
549
            if ($diff->newName !== false) {
550
                $sql[] = 'ALTER TABLE ' . $diff->getName()->getQuotedName($this) . ' RENAME TO ' . $diff->getNewName()->getQuotedName($this);
551 552
            }

553
            $sql = array_merge($this->getPreAlterTableIndexForeignKeySQL($diff), $sql, $this->getPostAlterTableIndexForeignKeySQL($diff), $commentsSQL);
554 555
        }

556
        return array_merge($sql, $tableSql, $columnSql);
557
    }
558

Steve Müller's avatar
Steve Müller committed
559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599
    /**
     * Checks whether a given column diff is a logically unchanged binary type column.
     *
     * Used to determine whether a column alteration for a binary type column can be skipped.
     * Doctrine's {@link \Doctrine\DBAL\Types\BinaryType} and {@link \Doctrine\DBAL\Types\BlobType}
     * are mapped to the same database column type on this platform as this platform
     * does not have a native VARBINARY/BINARY column type. Therefore the {@link \Doctrine\DBAL\Schema\Comparator}
     * might detect differences for binary type columns which do not have to be propagated
     * to database as there actually is no difference at database level.
     *
     * @param ColumnDiff $columnDiff The column diff to check against.
     *
     * @return boolean True if the given column diff is an unchanged binary type column, false otherwise.
     */
    private function isUnchangedBinaryColumn(ColumnDiff $columnDiff)
    {
        $columnType = $columnDiff->column->getType();

        if ( ! $columnType instanceof BinaryType && ! $columnType instanceof BlobType) {
            return false;
        }

        $fromColumn = $columnDiff->fromColumn instanceof Column ? $columnDiff->fromColumn : null;

        if ($fromColumn) {
            $fromColumnType = $fromColumn->getType();

            if ( ! $fromColumnType instanceof BinaryType && ! $fromColumnType instanceof BlobType) {
                return false;
            }

            return count(array_diff($columnDiff->changedProperties, array('type', 'length', 'fixed'))) === 0;
        }

        if ($columnDiff->hasChanged('type')) {
            return false;
        }

        return count(array_diff($columnDiff->changedProperties, array('length', 'fixed'))) === 0;
    }

600 601 602 603 604
    /**
     * {@inheritdoc}
     */
    protected function getRenameIndexSQL($oldIndexName, Index $index, $tableName)
    {
605 606 607 608 609
        if (strpos($tableName, '.') !== false) {
            list($schema) = explode('.', $tableName);
            $oldIndexName = $schema . '.' . $oldIndexName;
        }

610 611 612
        return array('ALTER INDEX ' . $oldIndexName . ' RENAME TO ' . $index->getQuotedName($this));
    }

613 614 615 616 617
    /**
     * {@inheritdoc}
     */
    public function getCommentOnColumnSQL($tableName, $columnName, $comment)
    {
618
        $comment = $comment === null ? 'NULL' : $this->quoteStringLiteral($comment);
619 620 621 622

        return "COMMENT ON COLUMN $tableName.$columnName IS $comment";
    }

623
    /**
624
     * {@inheritDoc}
625
     */
jeroendedauw's avatar
jeroendedauw committed
626
    public function getCreateSequenceSQL(Sequence $sequence)
627
    {
628
        return 'CREATE SEQUENCE ' . $sequence->getQuotedName($this) .
629
               ' INCREMENT BY ' . $sequence->getAllocationSize() .
630
               ' MINVALUE ' . $sequence->getInitialValue() .
631 632
               ' START ' . $sequence->getInitialValue() .
               $this->getSequenceCacheSQL($sequence);
633
    }
634

635 636 637
    /**
     * {@inheritDoc}
     */
jeroendedauw's avatar
jeroendedauw committed
638
    public function getAlterSequenceSQL(Sequence $sequence)
639
    {
640
        return 'ALTER SEQUENCE ' . $sequence->getQuotedName($this) .
641 642 643 644 645 646 647
               ' INCREMENT BY ' . $sequence->getAllocationSize() .
               $this->getSequenceCacheSQL($sequence);
    }

    /**
     * Cache definition for sequences
     *
jeroendedauw's avatar
jeroendedauw committed
648 649
     * @param Sequence $sequence
     *
650 651
     * @return string
     */
jeroendedauw's avatar
jeroendedauw committed
652
    private function getSequenceCacheSQL(Sequence $sequence)
653 654 655 656 657 658
    {
        if ($sequence->getCache() > 1) {
            return ' CACHE ' . $sequence->getCache();
        }

        return '';
659
    }
660

661
    /**
662
     * {@inheritDoc}
663
     */
664
    public function getDropSequenceSQL($sequence)
665
    {
jeroendedauw's avatar
jeroendedauw committed
666
        if ($sequence instanceof Sequence) {
667
            $sequence = $sequence->getQuotedName($this);
668
        }
669
        return 'DROP SEQUENCE ' . $sequence . ' CASCADE';
670
    }
671

672 673 674 675 676 677 678 679
    /**
     * {@inheritDoc}
     */
    public function getCreateSchemaSQL($schemaName)
    {
        return 'CREATE SCHEMA ' . $schemaName;
    }

680
    /**
681
     * {@inheritDoc}
682
     */
683
    public function getDropForeignKeySQL($foreignKey, $table)
684
    {
685
        return $this->getDropConstraintSQL($foreignKey, $table);
686
    }
687

688
    /**
689
     * {@inheritDoc}
690
     */
691
    protected function _getCreateTableSQL($tableName, array $columns, array $options = array())
692
    {
693
        $queryFields = $this->getColumnDeclarationListSQL($columns);
694 695

        if (isset($options['primary']) && ! empty($options['primary'])) {
696
            $keyColumns = array_unique(array_values($options['primary']));
697 698 699
            $queryFields .= ', PRIMARY KEY(' . implode(', ', $keyColumns) . ')';
        }

700
        $query = 'CREATE TABLE ' . $tableName . ' (' . $queryFields . ')';
701 702 703 704

        $sql[] = $query;

        if (isset($options['indexes']) && ! empty($options['indexes'])) {
705
            foreach ($options['indexes'] as $index) {
706
                $sql[] = $this->getCreateIndexSQL($index, $tableName);
707 708 709 710
            }
        }

        if (isset($options['foreignKeys'])) {
711
            foreach ((array) $options['foreignKeys'] as $definition) {
712
                $sql[] = $this->getCreateForeignKeySQL($definition, $tableName);
713 714 715 716 717
            }
        }

        return $sql;
    }
718

719 720 721 722 723 724 725 726 727 728 729
    /**
     * Converts a single boolean value.
     *
     * First converts the value to its native PHP boolean type
     * and passes it to the given callback function to be reconverted
     * into any custom representation.
     *
     * @param mixed    $value    The value to convert.
     * @param callable $callback The callback function to use for converting the real boolean value.
     *
     * @return mixed
jeroendedauw's avatar
jeroendedauw committed
730
     * @throws \UnexpectedValueException
731 732 733 734 735 736 737 738 739 740 741
     */
    private function convertSingleBooleanValue($value, $callback)
    {
        if (null === $value) {
            return $callback(false);
        }

        if (is_bool($value) || is_numeric($value)) {
            return $callback($value ? true : false);
        }

742 743 744 745 746 747 748 749 750 751 752 753 754
        if (!is_string($value)) {
            return $callback(true);
        }

        /**
         * Better safe than sorry: http://php.net/in_array#106319
         */
        if (in_array(trim(strtolower($value)), $this->booleanLiterals['false'], true)) {
            return $callback(false);
        }

        if (in_array(trim(strtolower($value)), $this->booleanLiterals['true'], true)) {
            return $callback(true);
755 756
        }

757
        throw new \UnexpectedValueException("Unrecognized boolean literal '${value}'");
758 759 760 761 762 763 764 765 766
    }

    /**
     * Converts one or multiple boolean values.
     *
     * First converts the value(s) to their native PHP boolean type
     * and passes them to the given callback function to be reconverted
     * into any custom representation.
     *
767 768
     * @param mixed $item        The value(s) to convert.
     * @param callable $callback The callback function to use for converting the real boolean value(s).
769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784
     *
     * @return mixed
     */
    private function doConvertBooleans($item, $callback)
    {
        if (is_array($item)) {
            foreach ($item as $key => $value) {
                $item[$key] = $this->convertSingleBooleanValue($value, $callback);
            }

            return $item;
        }

        return $this->convertSingleBooleanValue($item, $callback);
    }

785
    /**
786
     * {@inheritDoc}
787
     *
788
     * Postgres wants boolean values converted to the strings 'true'/'false'.
789
     */
790
    public function convertBooleans($item)
791
    {
792
        if ( ! $this->useBooleanTrueFalseStrings) {
793
            return parent::convertBooleans($item);
794 795
        }

796 797 798 799
        return $this->doConvertBooleans(
            $item,
            function ($boolean) {
                return true === $boolean ? 'true' : 'false';
800
            }
801
        );
802 803 804 805 806
    }

    /**
     * {@inheritDoc}
     */
807
    public function convertBooleansToDatabaseValue($item)
808
    {
809
        if ( ! $this->useBooleanTrueFalseStrings) {
810
            return parent::convertBooleansToDatabaseValue($item);
811 812
        }

813 814 815 816 817 818
        return $this->doConvertBooleans(
            $item,
            function ($boolean) {
                return (int) $boolean;
            }
        );
819
    }
820 821
    
    /**
822 823
     * {@inheritDoc}
     */
824 825
    public function convertFromBoolean($item)
    {
826
        if (in_array(strtolower($item), $this->booleanLiterals['false'], true)) {
827
            return false;
828 829 830
        } 
          
        return parent::convertFromBoolean($item);
831
    }
832

Benjamin Morel's avatar
Benjamin Morel committed
833 834 835
    /**
     * {@inheritDoc}
     */
836
    public function getSequenceNextValSQL($sequenceName)
837 838 839
    {
        return "SELECT NEXTVAL('" . $sequenceName . "')";
    }
840

841 842 843
    /**
     * {@inheritDoc}
     */
844
    public function getSetTransactionIsolationSQL($level)
romanb's avatar
romanb committed
845 846
    {
        return 'SET SESSION CHARACTERISTICS AS TRANSACTION ISOLATION LEVEL '
847
                . $this->_getTransactionIsolationLevelSQL($level);
romanb's avatar
romanb committed
848
    }
849

850
    /**
851
     * {@inheritDoc}
852
     */
853
    public function getBooleanTypeDeclarationSQL(array $field)
854 855 856
    {
        return 'BOOLEAN';
    }
857 858

    /**
859
     * {@inheritDoc}
860
     */
861
    public function getIntegerTypeDeclarationSQL(array $field)
862 863 864 865
    {
        if ( ! empty($field['autoincrement'])) {
            return 'SERIAL';
        }
866

867 868 869 870
        return 'INT';
    }

    /**
871
     * {@inheritDoc}
872
     */
873
    public function getBigIntTypeDeclarationSQL(array $field)
874 875 876 877 878 879 880 881
    {
        if ( ! empty($field['autoincrement'])) {
            return 'BIGSERIAL';
        }
        return 'BIGINT';
    }

    /**
882
     * {@inheritDoc}
883
     */
884
    public function getSmallIntTypeDeclarationSQL(array $field)
885 886 887 888
    {
        return 'SMALLINT';
    }

rivaros's avatar
rivaros committed
889
    /**
890
     * {@inheritDoc}
rivaros's avatar
rivaros committed
891
     */
892
    public function getGuidTypeDeclarationSQL(array $field)
rivaros's avatar
rivaros committed
893 894 895 896
    {
        return 'UUID';
    }

897
    /**
898
     * {@inheritDoc}
899
     */
900
    public function getDateTimeTypeDeclarationSQL(array $fieldDeclaration)
901 902 903 904 905
    {
        return 'TIMESTAMP(0) WITHOUT TIME ZONE';
    }

    /**
906
     * {@inheritDoc}
907
     */
908
    public function getDateTimeTzTypeDeclarationSQL(array $fieldDeclaration)
909
    {
910 911
        return 'TIMESTAMP(0) WITH TIME ZONE';
    }
912

913
    /**
914
     * {@inheritDoc}
915
     */
916
    public function getDateTypeDeclarationSQL(array $fieldDeclaration)
917 918
    {
        return 'DATE';
919 920
    }

921
    /**
922
     * {@inheritDoc}
923
     */
924
    public function getTimeTypeDeclarationSQL(array $fieldDeclaration)
925
    {
926
        return 'TIME(0) WITHOUT TIME ZONE';
927 928
    }

929 930 931 932 933 934 935 936
    /**
     * {@inheritDoc}
     */
    public function getGuidExpression()
    {
        return 'UUID_GENERATE_V4()';
    }

937
    /**
938
     * {@inheritDoc}
939
     */
940
    protected function _getCommonIntegerTypeDeclarationSQL(array $columnDef)
941 942 943 944 945
    {
        return '';
    }

    /**
946
     * {@inheritDoc}
947
     */
948
    protected function getVarcharTypeDeclarationSQLSnippet($length, $fixed)
949 950
    {
        return $fixed ? ($length ? 'CHAR(' . $length . ')' : 'CHAR(255)')
951
                : ($length ? 'VARCHAR(' . $length . ')' : 'VARCHAR(255)');
952
    }
953

Steve Müller's avatar
Steve Müller committed
954 955 956 957 958 959 960 961
    /**
     * {@inheritdoc}
     */
    protected function getBinaryTypeDeclarationSQLSnippet($length, $fixed)
    {
        return 'BYTEA';
    }

962 963 964
    /**
     * {@inheritDoc}
     */
965
    public function getClobTypeDeclarationSQL(array $field)
966 967 968
    {
        return 'TEXT';
    }
969 970

    /**
971
     * {@inheritDoc}
972 973 974 975 976
     */
    public function getName()
    {
        return 'postgresql';
    }
977

978
    /**
979
     * {@inheritDoc}
980
     *
981 982
     * PostgreSQL returns all column names in SQL result sets in lowercase.
     */
983
    public function getSQLResultCasing($column)
984 985 986
    {
        return strtolower($column);
    }
987

988 989 990
    /**
     * {@inheritDoc}
     */
991
    public function getDateTimeTzFormatString()
992
    {
993 994
        return 'Y-m-d H:i:sO';
    }
995 996

    /**
997
     * {@inheritDoc}
998
     */
999
    public function getEmptyIdentityInsertSQL($quotedTableName, $quotedIdentifierColumnName)
1000 1001 1002
    {
        return 'INSERT INTO ' . $quotedTableName . ' (' . $quotedIdentifierColumnName . ') VALUES (DEFAULT)';
    }
1003 1004

    /**
1005
     * {@inheritDoc}
1006
     */
1007
    public function getTruncateTableSQL($tableName, $cascade = false)
1008
    {
1009
        return 'TRUNCATE '.$tableName.' '.(($cascade)?'CASCADE':'');
1010
    }
1011

1012 1013 1014
    /**
     * {@inheritDoc}
     */
1015 1016 1017 1018
    public function getReadLockSQL()
    {
        return 'FOR SHARE';
    }
1019

1020 1021 1022
    /**
     * {@inheritDoc}
     */
1023 1024 1025
    protected function initializeDoctrineTypeMappings()
    {
        $this->doctrineTypeMapping = array(
1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044
            'smallint'      => 'smallint',
            'int2'          => 'smallint',
            'serial'        => 'integer',
            'serial4'       => 'integer',
            'int'           => 'integer',
            'int4'          => 'integer',
            'integer'       => 'integer',
            'bigserial'     => 'bigint',
            'serial8'       => 'bigint',
            'bigint'        => 'bigint',
            'int8'          => 'bigint',
            'bool'          => 'boolean',
            'boolean'       => 'boolean',
            'text'          => 'text',
            'varchar'       => 'string',
            'interval'      => 'string',
            '_varchar'      => 'string',
            'char'          => 'string',
            'bpchar'        => 'string',
1045
            'inet'          => 'string',
1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061
            'date'          => 'date',
            'datetime'      => 'datetime',
            'timestamp'     => 'datetime',
            'timestamptz'   => 'datetimetz',
            'time'          => 'time',
            'timetz'        => 'time',
            'float'         => 'float',
            'float4'        => 'float',
            'float8'        => 'float',
            'double'        => 'float',
            'double precision' => 'float',
            'real'          => 'float',
            'decimal'       => 'decimal',
            'money'         => 'decimal',
            'numeric'       => 'decimal',
            'year'          => 'date',
1062
            'uuid'          => 'guid',
1063
            'bytea'         => 'blob',
1064 1065
        );
    }
1066

1067 1068 1069
    /**
     * {@inheritDoc}
     */
1070 1071 1072 1073
    public function getVarcharMaxLength()
    {
        return 65535;
    }
1074

Steve Müller's avatar
Steve Müller committed
1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090
    /**
     * {@inheritdoc}
     */
    public function getBinaryMaxLength()
    {
        return 0;
    }

    /**
     * {@inheritdoc}
     */
    public function getBinaryDefaultLength()
    {
        return 0;
    }

1091 1092 1093
    /**
     * {@inheritDoc}
     */
1094 1095 1096 1097
    protected function getReservedKeywordsClass()
    {
        return 'Doctrine\DBAL\Platforms\Keywords\PostgreSQLKeywords';
    }
1098 1099

    /**
1100
     * {@inheritDoc}
1101 1102 1103 1104 1105
     */
    public function getBlobTypeDeclarationSQL(array $field)
    {
        return 'BYTEA';
    }
1106
}