Browse Source

Bug #17597: PostgreSQL 12 and partitioned tables support (batyrmastyr)

* yiisoft#17597, pg_constraint.consrc removed in Postgres 12

* yiisoft#17597, load schema for partitioned tables (introduced in Postgres 10)

* messed up with issue number

* #yiisoft#17597 Postgres 12 support, support GENERATED AS IDENTITY columns

* uncleared FileCache leads to falsy failures on subsequent test runs

* moved .sql for postgres 10 and 12 to separate files, added ResetSequence test for GENERATED AS IDENTITY column
tags/2.0.29
Evgeny 5 years ago committed by Alexander Makarov
parent
commit
09eacd8dc1
  1. 3
      framework/CHANGELOG.md
  2. 6
      framework/db/pgsql/ColumnSchema.php
  3. 26
      framework/db/pgsql/Schema.php
  4. 2
      tests/data/postgres.sql
  5. 6
      tests/data/postgres10.sql
  6. 19
      tests/data/postgres12.sql
  7. 4
      tests/framework/db/CommandTest.php
  8. 21
      tests/framework/db/pgsql/QueryBuilderTest.php
  9. 48
      tests/framework/db/pgsql/SchemaTest.php

3
framework/CHANGELOG.md

@ -4,9 +4,10 @@ Yii Framework 2 Change Log
2.0.29 under development
------------------------
- Bug #17602: `EmailValidator` with `checkDNS=true` throws `ErrorException` on bad domains on Alpine (batyrmastyr)
- Enh #17607: Added Yii version 3 DI config compatibility (hiqsol)
- Bug #17573: `EmailValidator` with `checkDNS=true` throws `ErrorException` on bad domains on Alpine (batyrmastyr)
- Bug #17606: Fix error in `AssetBundle` when a disabled bundle with custom init() was still published (onmotion)
- Bug #17597: PostgreSQL 12 and partitioned tables support (batyrmastyr)
2.0.28 October 08, 2019
-----------------------

6
framework/db/pgsql/ColumnSchema.php

@ -50,6 +50,12 @@ class ColumnSchema extends \yii\db\ColumnSchema
*/
public $deserializeArrayColumnToArrayExpression = true;
/**
* @var string name of associated sequence if column is auto-incremental
* @since 2.0.29
*/
public $sequenceName;
/**
* {@inheritdoc}

26
framework/db/pgsql/Schema.php

@ -176,7 +176,7 @@ SQL;
SELECT c.relname AS table_name
FROM pg_class c
INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f')
WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f', 'p')
ORDER BY c.relname
SQL;
return $this->db->createCommand($sql, [':schemaName' => $schema])->queryColumn();
@ -463,6 +463,12 @@ SQL;
{
$tableName = $this->db->quoteValue($table->name);
$schemaName = $this->db->quoteValue($table->schemaName);
$orIdentity = '';
if (version_compare($this->db->serverVersion, '12.0', '>=')) {
$orIdentity = 'OR attidentity != \'\'';
}
$sql = <<<SQL
SELECT
d.nspname AS table_schema,
@ -475,7 +481,8 @@ SELECT
a.atttypmod AS modifier,
a.attnotnull = false AS is_nullable,
CAST(pg_get_expr(ad.adbin, ad.adrelid) AS varchar) AS column_default,
coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) AS is_autoinc,
coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) {$orIdentity} AS is_autoinc,
pg_get_serial_sequence(quote_ident(d.nspname) || '.' || quote_ident(c.relname), a.attname) AS sequence_name,
CASE WHEN COALESCE(td.typtype, tb.typtype, t.typtype) = 'e'::char
THEN array_to_string((SELECT array_agg(enumlabel) FROM pg_enum WHERE enumtypid = COALESCE(td.oid, tb.oid, a.atttypid))::varchar[], ',')
ELSE NULL
@ -518,7 +525,7 @@ FROM
LEFT JOIN pg_namespace d ON d.oid = c.relnamespace
LEFT JOIN pg_constraint ct ON ct.conrelid = c.oid AND ct.contype = 'p'
WHERE
a.attnum > 0 AND t.typname != ''
a.attnum > 0 AND t.typname != '' AND NOT a.attisdropped
AND c.relname = {$tableName}
AND d.nspname = {$schemaName}
ORDER BY
@ -536,8 +543,8 @@ SQL;
$table->columns[$column->name] = $column;
if ($column->isPrimaryKey) {
$table->primaryKey[] = $column->name;
if ($table->sequenceName === null && preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) {
$table->sequenceName = preg_replace(['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], '', $column->defaultValue);
if ($table->sequenceName === null) {
$table->sequenceName = $column->sequenceName;
}
$column->defaultValue = null;
} elseif ($column->defaultValue) {
@ -586,6 +593,13 @@ SQL;
$column->scale = $info['numeric_scale'];
$column->size = $info['size'] === null ? null : (int) $info['size'];
$column->dimension = (int)$info['dimension'];
// pg_get_serial_sequence() doesn't track DEFAULT value change. GENERATED BY IDENTITY columns always have null default value
if (isset($column->defaultValue) && preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) {
$column->sequenceName = preg_replace(['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], '', $column->defaultValue);
} elseif (isset($info['sequence_name'])) {
$column->sequenceName = $this->resolveTableName($info['sequence_name'])->fullName;
}
if (isset($this->typeMap[$column->dbType])) {
$column->type = $this->typeMap[$column->dbType];
} else {
@ -641,7 +655,7 @@ SELECT
"fa"."attname" AS "foreign_column_name",
"c"."confupdtype" AS "on_update",
"c"."confdeltype" AS "on_delete",
"c"."consrc" AS "check_expr"
pg_get_constraintdef("c"."oid") AS "check_expr"
FROM "pg_class" AS "tc"
INNER JOIN "pg_namespace" AS "tcns"
ON "tcns"."oid" = "tc"."relnamespace"

2
tests/data/postgres.sql

@ -7,6 +7,7 @@
DROP TABLE IF EXISTS "composite_fk" CASCADE;
DROP TABLE IF EXISTS "order_item" CASCADE;
DROP TABLE IF EXISTS "item" CASCADE;
DROP SEQUENCE IF EXISTS "item_id_seq_2" CASCADE;
DROP TABLE IF EXISTS "order_item_with_null_fk" CASCADE;
DROP TABLE IF EXISTS "order" CASCADE;
DROP TABLE IF EXISTS "order_with_null_fk" CASCADE;
@ -79,6 +80,7 @@ CREATE TABLE "item" (
name varchar(128) NOT NULL,
category_id integer NOT NULL references "category"(id) on UPDATE CASCADE on DELETE CASCADE
);
CREATE SEQUENCE "item_id_seq_2";
CREATE TABLE "order" (
id serial not null primary key,

6
tests/data/postgres10.sql

@ -0,0 +1,6 @@
DROP TABLE IF EXISTS "partitioned" CASCADE;
CREATE TABLE "partitioned" (
city_id int not null,
logdate date not null
) PARTITION BY RANGE ("logdate");

19
tests/data/postgres12.sql

@ -0,0 +1,19 @@
DROP TABLE IF EXISTS "generated" CASCADE;
DROP TABLE IF EXISTS "item_12" CASCADE;
CREATE TABLE "generated" (
id_always int GENERATED ALWAYS AS IDENTITY,
id_primary int GENERATED ALWAYS AS IDENTITY primary key,
id_default int GENERATED BY DEFAULT AS IDENTITY
);
CREATE TABLE "item_12" (
id int GENERATED ALWAYS AS IDENTITY primary key,
name varchar(128) NOT NULL,
category_id integer NOT NULL references "category"(id) on UPDATE CASCADE on DELETE CASCADE
);
INSERT INTO "item_12" (name, category_id) VALUES ('Agile Web Application Development with Yii1.1 and PHP5', 1);
INSERT INTO "item_12" (name, category_id) VALUES ('Yii 1.1 Application Development Cookbook', 1);
INSERT INTO "item_12" (name, category_id) VALUES ('Ice Age', 2);
INSERT INTO "item_12" (name, category_id) VALUES ('Toy Story', 2);

4
tests/framework/db/CommandTest.php

@ -8,7 +8,7 @@
namespace yiiunit\framework\db;
use ArrayObject;
use yii\caching\FileCache;
use yii\caching\ArrayCache;
use yii\db\Connection;
use yii\db\DataReader;
use yii\db\Exception;
@ -1252,7 +1252,7 @@ SQL;
{
$db = $this->getConnection();
$db->enableQueryCache = true;
$db->queryCache = new FileCache(['cachePath' => '@yiiunit/runtime/cache']);
$db->queryCache = new ArrayCache();
$command = $db->createCommand('SELECT [[name]] FROM {{customer}} WHERE [[id]] = :id');
$this->assertEquals('user1', $command->bindValue(':id', 1)->queryScalar());

21
tests/framework/db/pgsql/QueryBuilderTest.php

@ -261,6 +261,27 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
$this->assertEquals($expected, $sql);
}
public function testResetSequencePostgres12()
{
if (version_compare($this->getConnection(false)->getServerVersion(), '12.0', '<')) {
$this->markTestSkipped('PostgreSQL < 12.0 does not support GENERATED AS IDENTITY columns.');
}
$config = $this->database;
unset($config['fixture']);
$this->prepareDatabase($config, realpath(__DIR__.'/../../../data') . '/postgres12.sql');
$qb = $this->getQueryBuilder(false);
$expected = "SELECT SETVAL('\"item_12_id_seq\"',(SELECT COALESCE(MAX(\"id\"),0) FROM \"item_12\")+1,false)";
$sql = $qb->resetSequence('item_12');
$this->assertEquals($expected, $sql);
$expected = "SELECT SETVAL('\"item_12_id_seq\"',4,false)";
$sql = $qb->resetSequence('item_12', 4);
$this->assertEquals($expected, $sql);
}
public function upsertProvider()
{
$concreteData = [

48
tests/framework/db/pgsql/SchemaTest.php

@ -204,6 +204,52 @@ class SchemaTest extends \yiiunit\framework\db\SchemaTest
$this->assertFalse($table->getColumn('default_false')->defaultValue);
}
public function testSequenceName()
{
$connection = $this->getConnection();
$sequenceName = $connection->schema->getTableSchema('item')->sequenceName;
$connection->createCommand('ALTER TABLE "item" ALTER COLUMN "id" SET DEFAULT nextval(\'item_id_seq_2\')')->execute();
$connection->schema->refreshTableSchema('item');
$this->assertEquals('item_id_seq_2', $connection->schema->getTableSchema('item')->sequenceName);
$connection->createCommand('ALTER TABLE "item" ALTER COLUMN "id" SET DEFAULT nextval(\'' . $sequenceName . '\')')->execute();
$connection->schema->refreshTableSchema('item');
$this->assertEquals($sequenceName, $connection->schema->getTableSchema('item')->sequenceName);
}
public function testGeneratedValues()
{
if (version_compare($this->getConnection(false)->getServerVersion(), '12.0', '<')) {
$this->markTestSkipped('PostgreSQL < 12.0 does not support GENERATED AS IDENTITY columns.');
}
$config = $this->database;
unset($config['fixture']);
$this->prepareDatabase($config, realpath(__DIR__.'/../../../data') . '/postgres12.sql');
$table = $this->getConnection(false)->schema->getTableSchema('generated');
$this->assertTrue($table->getColumn('id_always')->autoIncrement);
$this->assertTrue($table->getColumn('id_primary')->autoIncrement);
$this->assertTrue($table->getColumn('id_primary')->isPrimaryKey);
$this->assertTrue($table->getColumn('id_default')->autoIncrement);
}
public function testPartitionedTable()
{
if (version_compare($this->getConnection(false)->getServerVersion(), '10.0', '<')) {
$this->markTestSkipped('PostgreSQL < 10.0 does not support PARTITION BY clause.');
}
$config = $this->database;
unset($config['fixture']);
$this->prepareDatabase($config, realpath(__DIR__.'/../../../data') . '/postgres10.sql');
$this->assertNotNull($this->getConnection(false)->schema->getTableSchema('partitioned'));
}
public function testFindSchemaNames()
{
$schema = $this->getConnection()->schema;
@ -295,7 +341,7 @@ class SchemaTest extends \yiiunit\framework\db\SchemaTest
public function constraintsProvider()
{
$result = parent::constraintsProvider();
$result['1: check'][2][0]->expression = '(("C_check")::text <> \'\'::text)';
$result['1: check'][2][0]->expression = 'CHECK ((("C_check")::text <> \'\'::text))';
$result['3: foreign key'][2][0]->foreignSchemaName = 'public';
$result['3: index'][2] = [];

Loading…
Cancel
Save