From: Cedric Carree Date: Tue, 22 Nov 2011 11:34:27 +0000 (+0100) Subject: get Postgres table and column descriptions X-Git-Tag: v0.11011~81 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=fd52d7dda57e532e5624ad4a512c939639d038b0;p=dbsrgits%2FSQL-Translator.git get Postgres table and column descriptions patch submitted by Andrew Pam --- diff --git a/Changes b/Changes index bd65b9e..db1fc00 100644 --- a/Changes +++ b/Changes @@ -1,5 +1,6 @@ * Correct Data Type in SQLT::Parser::DBI::PostgreSQL (patch from Andrew Pam) * Fix index issue in SQLT::Parser::DBI::PostgreSQL +* Add column and table comments in SQLT::Parser::DBI::PostgreSQL(patch from Andrew Pam) # ---------------------------------------------------------- # 0.11010 2011-10-05 diff --git a/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm b/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm index f01f1b2..a6d5cf5 100644 --- a/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm +++ b/lib/SQL/Translator/Parser/DBI/PostgreSQL.pm @@ -56,9 +56,11 @@ sub parse { my $column_select = $dbh->prepare( "SELECT a.attname, format_type(t.oid, a.atttypmod) as typname, a.attnum, - a.atttypmod as length, a.attnotnull, a.atthasdef, d.adsrc - FROM pg_type t,pg_attribute a - LEFT JOIN pg_attrdef d ON (d.adrelid = a.attrelid AND a.attnum = d.adnum) + a.atttypmod as length, a.attnotnull, a.atthasdef, ad.adsrc, + d.description + FROM pg_type t, pg_attribute a + LEFT JOIN pg_attrdef ad ON (ad.adrelid = a.attrelid AND a.attnum = ad.adnum) + LEFT JOIN pg_description d ON (a.attrelid=d.objoid AND a.attnum=d.objsubid) WHERE a.attrelid=? AND attnum>0 AND a.atttypid=t.oid ORDER BY a.attnum" @@ -77,7 +79,10 @@ sub parse { ); my $table_select = $dbh->prepare( - "SELECT oid,relname FROM pg_class WHERE relnamespace IN + "SELECT c.oid, c.relname, d.description + FROM pg_class c + LEFT JOIN pg_description d ON c.oid=d.objoid AND d.objsubid=0 + WHERE relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname='public') AND relkind='r';" ); @@ -127,12 +132,13 @@ ORDER BY 1; my $table_name = $$tablehash{'relname'}; my $table_oid = $$tablehash{'oid'}; - my $table = $schema->add_table( name => $table_name, #what is type? type => $table_info->{TABLE_TYPE}, ) || die $schema->error; + $table->comments($$tablehash{'description'}) if $$tablehash{'description'}; + $column_select->execute($table_oid); while (my $columnhash = $column_select->fetchrow_hashref ) { @@ -150,6 +156,7 @@ ORDER BY 1; $col->{size} = [$$columnhash{'length'}] if $$columnhash{'length'}>0 && $$columnhash{'length'}<=0xFFFF; $col->{is_nullable} = $$columnhash{'attnotnull'} ? 0 : 1; + $col->comments($$columnhash{'description'}) if $$columnhash{'description'}; } $index_select->execute($table_oid); diff --git a/t/66-postgres-dbi-parser.t b/t/66-postgres-dbi-parser.t index 0483a54..f3d88c9 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(56, 'SQL::Translator::Parser::DBI::PostgreSQL'); + maybe_plan(60, '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'", 55; + skip "No connection to test db. DBI says '$err'", 59; } ok($dbh, "dbh setup correctly"); @@ -46,6 +46,9 @@ my $sql = q[ f_last text ); + comment on table sqlt_test1 is 'this is a comment on the first table'; + comment on column sqlt_test1.f_text is 'this is a comment on a field of the first table'; + create index sqlt_test1_f_last_idx on sqlt_test1 (f_last); create table sqlt_test2 ( @@ -79,6 +82,7 @@ my @tables = $schema->get_tables; my $t1 = $schema->get_table("sqlt_test1"); is( $t1->name, 'sqlt_test1', 'Table sqlt_test1 exists' ); +is( $t1->comments, 'this is a comment on the first table', 'First table has a comment'); my @t1_fields = $t1->get_fields; is( scalar @t1_fields, 4, '4 fields in sqlt_test1' ); @@ -101,6 +105,7 @@ is( $f2->size, 259, 'Size is "259"' ); is( $f2->default_value, undef, 'Default value is undefined' ); is( $f2->is_primary_key, 0, 'Field is not PK' ); is( $f2->is_auto_increment, 0, 'Field is not auto increment' ); +is( $f2->comments, '', 'There is no comment on the second field'); my $f3 = shift @t1_fields; is( $f3->name, 'f_text', 'Third field is "f_text"' ); @@ -110,6 +115,7 @@ is( $f3->size, 0, 'Size is 0' ); 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' ); +is( $f3->comments, 'this is a comment on a field of the first table', 'There is a comment on the third field'); my $f4 = shift @t1_fields; is( $f4->name, 'f_last', 'Fouth field is "f_last"' ); @@ -124,6 +130,7 @@ is( $f4->is_auto_increment, 0, 'Field is not auto increment' ); my $t2 = $schema->get_table("sqlt_test2"); is( $t2->name, 'sqlt_test2', 'Table sqlt_test2 exists' ); +is( $t2->comments, undef, 'No comment on table sqlt_test2'); my @t2_fields = $t2->get_fields; is( scalar @t2_fields, 3, '3 fields in sqlt_test2' );