584b2543a718b16a42ed6d234c3e20f62eefba7d
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / DBI / PostgreSQL.pm
1 package SQL::Translator::Parser::DBI::PostgreSQL;
2
3 =head1 NAME
4
5 SQL::Translator::Parser::DBI::PostgreSQL - parser for DBD::Pg
6
7 =head1 SYNOPSIS
8
9 See SQL::Translator::Parser::DBI.
10
11 =head1 DESCRIPTION
12
13 Uses DBI to query PostgreSQL system tables to determine schema structure.
14
15 =cut
16
17 use strict;
18 use DBI;
19 use Data::Dumper;
20 use SQL::Translator::Schema::Constants;
21
22 use vars qw[ $DEBUG $VERSION @EXPORT_OK ];
23 $VERSION = '1.59';
24 $DEBUG   = 0 unless defined $DEBUG;
25
26 my $actions = {c => 'cascade',
27                r => 'restrict',
28                a => 'no action',
29                n => 'set null',
30                d => 'set default',
31            };
32
33 sub parse {
34     my ( $tr, $dbh ) = @_;
35
36     my $schema = $tr->schema;
37
38     my $column_select = $dbh->prepare(
39       "SELECT a.attname, format_type(t.oid, a.atttypmod) as typname, a.attnum,
40               a.atttypmod as length, a.attnotnull, a.atthasdef, ad.adsrc,
41               d.description
42        FROM pg_type t, pg_attribute a
43        LEFT JOIN pg_attrdef ad ON (ad.adrelid = a.attrelid AND a.attnum = ad.adnum)
44        LEFT JOIN pg_description d ON (a.attrelid=d.objoid AND a.attnum=d.objsubid)
45        WHERE a.attrelid=? AND attnum>0
46          AND a.atttypid=t.oid
47        ORDER BY a.attnum"
48     );
49
50     my $index_select  = $dbh->prepare(
51       "SELECT oid, c.relname, i.indkey, i.indnatts, i.indisunique,
52               ARRAY(SELECT a.attname
53                   FROM pg_attribute a
54                   WHERE a.attrelid=i.indrelid AND a.attnum = ANY(i.indkey)
55               ) AS attname,
56               i.indisprimary, pg_get_indexdef(oid) AS create_string
57        FROM pg_class c,pg_index i
58        WHERE c.relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname='public') AND c.relkind='i'
59          AND c.oid=i.indexrelid AND i.indrelid=?"
60     );
61
62     my $table_select  = $dbh->prepare(
63       "SELECT c.oid, c.relname, d.description
64        FROM pg_class c
65        LEFT JOIN pg_description d ON c.oid=d.objoid AND d.objsubid=0
66        WHERE relnamespace IN
67           (SELECT oid FROM pg_namespace WHERE nspname='public')
68           AND relkind='r';"
69     );
70
71     my $fk_select = $dbh->prepare(
72         q/
73 SELECT r.conname,
74        c.relname,
75        d.relname AS frelname,
76        r.conkey,
77        ARRAY(SELECT column_name::varchar
78                FROM information_schema.columns
79               WHERE ordinal_position = ANY  (r.conkey)
80                 AND table_schema = n.nspname
81                 AND table_name   =   c.relname ) AS fields,
82        r.confkey,
83        ARRAY(SELECT column_name::varchar
84                FROM information_schema.columns
85               WHERE ordinal_position = ANY  (r.confkey)
86                 AND table_schema =   n.nspname
87                 AND table_name   =   d.relname ) AS reference_fields,
88        r.confupdtype,
89        r.confdeltype,
90        r.confmatchtype
91
92 FROM pg_catalog.pg_constraint r
93
94 JOIN pg_catalog.pg_class c
95   ON c.oid = r.conrelid
96  AND r.contype = 'f'
97
98 JOIN pg_catalog.pg_class d
99   ON d.oid = r.confrelid
100
101 JOIN pg_catalog.pg_namespace n
102   ON n.oid = c.relnamespace
103
104 WHERE pg_catalog.pg_table_is_visible(c.oid)
105   AND n.nspname = ?
106   AND c.relname = ?
107 ORDER BY 1;
108         /) or die "Can't prepare: $@";
109
110     $table_select->execute();
111
112     while ( my $tablehash = $table_select->fetchrow_hashref ) {
113
114         my $table_name = $$tablehash{'relname'};
115         my $table_oid  = $$tablehash{'oid'};
116         my $table = $schema->add_table(
117                                        name => $table_name,
118               #what is type?               type => $table_info->{TABLE_TYPE},
119                                           ) || die $schema->error;
120
121         $table->comments($$tablehash{'description'}) if $$tablehash{'description'};
122
123         $column_select->execute($table_oid);
124
125         while (my $columnhash = $column_select->fetchrow_hashref ) {
126
127             #data_type seems to not be populated; perhaps there needs to
128             #be a mapping of query output to reserved constants in sqlt?
129
130             my $col = $table->add_field(
131                               name        => $$columnhash{'attname'},
132                               default_value => $$columnhash{'adsrc'},
133                               data_type   => $$columnhash{'typname'},
134                               order       => $$columnhash{'attnum'},
135                              ) || die $table->error;
136
137             $col->{size} = [$$columnhash{'length'}]
138                 if $$columnhash{'length'}>0 && $$columnhash{'length'}<=0xFFFF;
139             $col->{is_nullable} = $$columnhash{'attnotnull'} ? 0 : 1;
140             $col->comments($$columnhash{'description'}) if $$columnhash{'description'};
141         }
142
143         $index_select->execute($table_oid);
144
145         my @column_names = $table->field_names();
146         while (my $indexhash = $index_select->fetchrow_hashref ) {
147               #don't deal with function indexes at the moment
148             next if ($$indexhash{'indkey'} eq ''
149                      or !defined($$indexhash{'indkey'}) );
150
151             my $type;
152             if      ($$indexhash{'indisprimary'}) {
153                 $type = UNIQUE; #PRIMARY_KEY;
154
155                 #tell sqlt that this is the primary key:
156                 my $col_name=$column_names[($$indexhash{'indkey'} - 1)];
157                 $table->get_field($col_name)->{is_primary_key}=1;
158
159             } elsif ($$indexhash{'indisunique'}) {
160                 $type = UNIQUE;
161             } else {
162                 $type = NORMAL;
163             }
164
165
166             my @column_ids = split /\s+/, $$indexhash{'indkey'};
167             my @columns = split /\s+/, $$indexhash{'attname'};
168
169             $table->add_index(
170                               name         => $$indexhash{'relname'},
171                               type         => $type,
172                               fields       => \@columns,
173                              ) || die $table->error;
174         }
175
176         $fk_select->execute('public',$table_name) or die "Can't execute: $@";
177         my $fkeys = $fk_select->fetchall_arrayref({});
178         $DEBUG and print Dumper $fkeys;
179         for my $con (@$fkeys){
180             my $con_name         = $con->{conname};
181             my $fields           = $con->{fields};
182             my $reference_fields = $con->{reference_fields};
183             my $reference_table  = $con->{frelname};
184             my $on_upd           = $con->{confupdtype};
185             my $on_del           = $con->{confdeltype};
186             $table->add_constraint(
187                                    name   => $con_name,
188                                    type   => 'foreign_key',
189                                    fields =>  $fields,
190                                    reference_fields => $reference_fields,
191                                    reference_table => $reference_table,
192                                    on_delete  => $actions->{$on_upd},
193                                    on_update  => $actions->{$on_del},
194                                );
195         }
196     }
197
198
199     return 1;
200 }
201
202 1;
203
204 # -------------------------------------------------------------------
205 # Time is a waste of money.
206 # Oscar Wilde
207 # -------------------------------------------------------------------
208
209 =pod
210
211 =head1 AUTHOR
212
213 Scott Cain E<lt>cain@cshl.eduE<gt>, previous author:
214 Paul Harrington E<lt>harringp@deshaw.comE<gt>.
215
216 =head1 SEE ALSO
217
218 SQL::Translator, DBD::Pg.
219
220 =cut