Tab/WS crusade
[dbsrgits/SQL-Translator.git] / t / 66-postgres-dbi-parser.t
CommitLineData
122353c5 1#!/usr/bin/perl
2# vim: set ft=perl:
3
4use strict;
5use Test::More;
6use SQL::Translator;
7use SQL::Translator::Schema::Constants;
8use Test::SQL::Translator qw(maybe_plan table_ok);
9
10BEGIN {
fd52d7dd 11 maybe_plan(60, 'SQL::Translator::Parser::DBI::PostgreSQL');
122353c5 12 SQL::Translator::Parser::DBI::PostgreSQL->import('parse');
13}
14
15use_ok('SQL::Translator::Parser::DBI::PostgreSQL');
16
17my @dsn =
18 $ENV{DBICTEST_PG_DSN} ? @ENV{ map { "DBICTEST_PG_$_" } qw/DSN USER PASS/ }
19: $ENV{DBI_DSN} ? @ENV{ map { "DBI_$_" } qw/DSN USER PASS/ }
20: ( "dbi:Pg:dbname=postgres", '', '' );
21
22my $dbh = eval {
23 DBI->connect(@dsn, {AutoCommit => 1, RaiseError=>1,PrintError => 1} );
24};
25
26SKIP: {
27 if (my $err = ($@ || $DBI::err )) {
28 chomp $err;
fd52d7dd 29 skip "No connection to test db. DBI says '$err'", 59;
122353c5 30 }
31
32 ok($dbh, "dbh setup correctly");
33 $dbh->do('SET client_min_messages=WARNING');
34
35my $t = SQL::Translator->new( trace => 0 );
36my $sql = q[
37 drop table if exists sqlt_test2;
38 drop table if exists sqlt_test1;
39 drop table if exists sqlt_products_1;
40
41 create table sqlt_test1 (
42 f_serial serial NOT NULL primary key,
a23f9a9d 43 f_varchar character varying(255),
c601ca5d 44 f_text text default 'FOO',
45 f_to_drop integer,
46 f_last text
122353c5 47 );
48
fd52d7dd 49 comment on table sqlt_test1 is 'this is a comment on the first table';
50 comment on column sqlt_test1.f_text is 'this is a comment on a field of the first table';
51
c601ca5d 52 create index sqlt_test1_f_last_idx on sqlt_test1 (f_last);
122353c5 53
54 create table sqlt_test2 (
55 f_id integer NOT NULL,
56 f_int smallint,
57 primary key (f_id),
58 f_fk1 integer NOT NULL references sqlt_test1 (f_serial)
59 );
60
61 CREATE TABLE sqlt_products_1 (
62 product_no integer,
63 name text,
64 price numeric
65 );
c601ca5d 66
aee4b66e 67 -- drop a column, to not have a linear id
c601ca5d 68 -- When the table t_test1 is created, f_last get id 5 but
69 -- after this drop, there is only 4 columns.
70 alter table sqlt_test1 drop column f_to_drop;
122353c5 71];
72
73$| = 1;
74
75$dbh->do($sql);
76
77my $data = SQL::Translator::Parser::DBI::PostgreSQL::parse( $t, $dbh );
78my $schema = $t->schema;
79
80isa_ok( $schema, 'SQL::Translator::Schema', 'Schema object' );
81my @tables = $schema->get_tables;
82
83my $t1 = $schema->get_table("sqlt_test1");
84is( $t1->name, 'sqlt_test1', 'Table sqlt_test1 exists' );
fd52d7dd 85is( $t1->comments, 'this is a comment on the first table', 'First table has a comment');
122353c5 86
87my @t1_fields = $t1->get_fields;
c601ca5d 88is( scalar @t1_fields, 4, '4 fields in sqlt_test1' );
122353c5 89
90my $f1 = shift @t1_fields;
91is( $f1->name, 'f_serial', 'First field is "f_serial"' );
a23f9a9d 92is( $f1->data_type, 'integer', 'Field is an integer' );
122353c5 93is( $f1->is_nullable, 0, 'Field cannot be null' );
94is( $f1->default_value, "nextval('sqlt_test1_f_serial_seq'::regclass)", 'Default value is nextval()' );
95is( $f1->is_primary_key, 1, 'Field is PK' );
96#FIXME: not set to auto-increment? maybe we can guess auto-increment behavior by looking at the default_value (i.e. it call function nextval() )
97#is( $f1->is_auto_increment, 1, 'Field is auto increment' );
98
99my $f2 = shift @t1_fields;
100is( $f2->name, 'f_varchar', 'Second field is "f_varchar"' );
a23f9a9d 101is( $f2->data_type, 'character varying(255)', 'Field is a character varying(255)' );
122353c5 102is( $f2->is_nullable, 1, 'Field can be null' );
103#FIXME: should not be 255?
104is( $f2->size, 259, 'Size is "259"' );
105is( $f2->default_value, undef, 'Default value is undefined' );
106is( $f2->is_primary_key, 0, 'Field is not PK' );
107is( $f2->is_auto_increment, 0, 'Field is not auto increment' );
fd52d7dd 108is( $f2->comments, '', 'There is no comment on the second field');
122353c5 109
110my $f3 = shift @t1_fields;
111is( $f3->name, 'f_text', 'Third field is "f_text"' );
112is( $f3->data_type, 'text', 'Field is a text' );
113is( $f3->is_nullable, 1, 'Field can be null' );
114is( $f3->size, 0, 'Size is 0' );
115is( $f3->default_value, "'FOO'::text", 'Default value is "FOO"' );
116is( $f3->is_primary_key, 0, 'Field is not PK' );
117is( $f3->is_auto_increment, 0, 'Field is not auto increment' );
fd52d7dd 118is( $f3->comments, 'this is a comment on a field of the first table', 'There is a comment on the third field');
122353c5 119
c601ca5d 120my $f4 = shift @t1_fields;
121is( $f4->name, 'f_last', 'Fouth field is "f_last"' );
122is( $f4->data_type, 'text', 'Field is a text' );
123is( $f4->is_nullable, 1, 'Field can be null' );
124is( $f4->size, 0, 'Size is 0' );
125is( $f4->default_value, undef, 'No default value' );
126is( $f4->is_primary_key, 0, 'Field is not PK' );
127is( $f4->is_auto_increment, 0, 'Field is not auto increment' );
128
122353c5 129#TODO: no 'NOT NULL' constraint not set
130
131my $t2 = $schema->get_table("sqlt_test2");
132is( $t2->name, 'sqlt_test2', 'Table sqlt_test2 exists' );
fd52d7dd 133is( $t2->comments, undef, 'No comment on table sqlt_test2');
122353c5 134
135my @t2_fields = $t2->get_fields;
136is( scalar @t2_fields, 3, '3 fields in sqlt_test2' );
137
138my $t2_f1 = shift @t2_fields;
139is( $t2_f1->name, 'f_id', 'First field is "f_id"' );
a23f9a9d 140is( $t2_f1->data_type, 'integer', 'Field is an integer' );
122353c5 141is( $t2_f1->is_nullable, 0, 'Field cannot be null' );
142is( $t2_f1->size, 0, 'Size is "0"' );
143is( $t2_f1->default_value, undef, 'Default value is undefined' );
144is( $t2_f1->is_primary_key, 1, 'Field is PK' );
145
146my $t2_f2= shift @t2_fields;
147is( $t2_f2->name, 'f_int', 'Third field is "f_int"' );
a23f9a9d 148is( $t2_f2->data_type, 'smallint', 'Field is an smallint' );
122353c5 149is( $t2_f2->is_nullable, 1, 'Field can be null' );
150is( $t2_f2->size, 0, 'Size is "0"' );
151is( $t2_f2->default_value, undef, 'Default value is undefined' );
152is( $t2_f2->is_primary_key, 0, 'Field is not PK' );
153
154my $t2_f3 = shift @t2_fields;
155is( $t2_f3->name, 'f_fk1', 'Third field is "f_fk1"' );
a23f9a9d 156is( $t2_f3->data_type, 'integer', 'Field is an integer' );
122353c5 157is( $t2_f3->is_nullable, 0, 'Field cannot be null' );
158is( $t2_f3->size, 0, 'Size is "0"' );
159is( $t2_f3->default_value, undef, 'Default value is undefined' );
160is( $t2_f3->is_primary_key, 0, 'Field is not PK' );
161is( $t2_f3->is_foreign_key, 1, 'Field is a FK' );
162my $fk_ref1 = $t2_f3->foreign_key_reference;
163isa_ok( $fk_ref1, 'SQL::Translator::Schema::Constraint', 'FK' );
164is( $fk_ref1->reference_table, 'sqlt_test1', 'FK is to "sqlt_test1" table' );
165
166my @t2_constraints = $t2->get_constraints;
167is( scalar @t2_constraints, 1, "One constraint on table" );
168
169my $t2_c1 = shift @t2_constraints;
170is( $t2_c1->type, FOREIGN_KEY, "Constraint is a FK" );
171
172$dbh->disconnect;
173} # end of SKIP block
174
175END {
176 if ($dbh) {
177 for (
178 'drop table if exists sqlt_test2',
179 'drop table if exists sqlt_test1',
180 'drop table if exists sqlt_products_1',
181 ) {
182 eval { $dbh->do($_) };
183 }
184 }
185}