From: Cedric Carree Date: Tue, 22 Nov 2011 10:15:10 +0000 (+0100) Subject: Fix index issue in Parser::DBI::PostgreSQL X-Git-Tag: v0.11011~82 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=c601ca5da1eabe59d4dd09b9265923573fb72ec6;p=dbsrgits%2FSQL-Translator.git Fix index issue in Parser::DBI::PostgreSQL pg_index.indkey does not necessaraly matches the id of the columns_name array. It happens when a column is dropped after the table was created. --- diff --git a/Changes b/Changes index ec55465..bd65b9e 100644 --- a/Changes +++ b/Changes @@ -1,4 +1,5 @@ * Correct Data Type in SQLT::Parser::DBI::PostgreSQL (patch from Andrew Pam) +* Fix index issue in SQLT::Parser::DBI::PostgreSQL # ---------------------------------------------------------- # 0.11010 2011-10-05 diff --git a/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm b/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm index a6dc3e8..f01f1b2 100644 --- a/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm +++ b/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm @@ -66,6 +66,10 @@ sub parse { my $index_select = $dbh->prepare( "SELECT oid, c.relname, i.indkey, i.indnatts, i.indisunique, + ARRAY(SELECT a.attname + FROM pg_attribute a + WHERE a.attrelid=i.indrelid AND a.attnum = ANY(i.indkey) + ) AS attname, i.indisprimary, pg_get_indexdef(oid) AS create_string FROM pg_class c,pg_index i WHERE c.relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname='public') AND c.relkind='i' @@ -170,11 +174,9 @@ ORDER BY 1; $type = NORMAL; } + my @column_ids = split /\s+/, $$indexhash{'indkey'}; - my @columns; - foreach my $col (@column_ids) { - push @columns, $column_names[($col - 1)]; - } + my @columns = split /\s+/, $$indexhash{'attname'}; $table->add_index( name => $$indexhash{'relname'}, diff --git a/t/66-postgres-dbi-parser.t b/t/66-postgres-dbi-parser.t index a37050c..0483a54 100644 --- a/t/66-postgres-dbi-parser.t +++ b/t/66-postgres-dbi-parser.t @@ -8,7 +8,7 @@ use SQL::Translator::Schema::Constants; use Test::SQL::Translator qw(maybe_plan table_ok); BEGIN { - maybe_plan(49, 'SQL::Translator::Parser::DBI::PostgreSQL'); + maybe_plan(56, 'SQL::Translator::Parser::DBI::PostgreSQL'); SQL::Translator::Parser::DBI::PostgreSQL->import('parse'); } @@ -26,7 +26,7 @@ my $dbh = eval { SKIP: { if (my $err = ($@ || $DBI::err )) { chomp $err; - skip "No connection to test db. DBI says '$err'", 48; + skip "No connection to test db. DBI says '$err'", 55; } ok($dbh, "dbh setup correctly"); @@ -41,9 +41,12 @@ my $sql = q[ create table sqlt_test1 ( f_serial serial NOT NULL primary key, f_varchar character varying(255), - f_text text default 'FOO' + f_text text default 'FOO', + f_to_drop integer, + f_last text ); + create index sqlt_test1_f_last_idx on sqlt_test1 (f_last); create table sqlt_test2 ( f_id integer NOT NULL, @@ -57,6 +60,11 @@ my $sql = q[ name text, price numeric ); + + -- drop a column, to not have a linear id + -- When the table t_test1 is created, f_last get id 5 but + -- after this drop, there is only 4 columns. + alter table sqlt_test1 drop column f_to_drop; ]; $| = 1; @@ -73,7 +81,7 @@ my $t1 = $schema->get_table("sqlt_test1"); is( $t1->name, 'sqlt_test1', 'Table sqlt_test1 exists' ); my @t1_fields = $t1->get_fields; -is( scalar @t1_fields, 3, '3 fields in sqlt_test1' ); +is( scalar @t1_fields, 4, '4 fields in sqlt_test1' ); my $f1 = shift @t1_fields; is( $f1->name, 'f_serial', 'First field is "f_serial"' ); @@ -103,6 +111,15 @@ is( $f3->default_value, "'FOO'::text", 'Default value is "FOO"' ); is( $f3->is_primary_key, 0, 'Field is not PK' ); is( $f3->is_auto_increment, 0, 'Field is not auto increment' ); +my $f4 = shift @t1_fields; +is( $f4->name, 'f_last', 'Fouth field is "f_last"' ); +is( $f4->data_type, 'text', 'Field is a text' ); +is( $f4->is_nullable, 1, 'Field can be null' ); +is( $f4->size, 0, 'Size is 0' ); +is( $f4->default_value, undef, 'No default value' ); +is( $f4->is_primary_key, 0, 'Field is not PK' ); +is( $f4->is_auto_increment, 0, 'Field is not auto increment' ); + #TODO: no 'NOT NULL' constraint not set my $t2 = $schema->get_table("sqlt_test2");