2bf999a91c5f791f7caf2c1e3ca90d361e837d48
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / DBI / SQLServer.pm
1 package SQL::Translator::Parser::DBI::SQLServer;
2
3 # -------------------------------------------------------------------
4 # $Id$
5 # -------------------------------------------------------------------
6 # Copyright (C) 2002-2009 SQLFairy Authors
7 #
8 # This program is free software; you can redistribute it and/or
9 # modify it under the terms of the GNU General Public License as
10 # published by the Free Software Foundation; version 2.
11 #
12 # This program is distributed in the hope that it will be useful, but
13 # WITHOUT ANY WARRANTY; without even the implied warranty of
14 # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the GNU
15 # General Public License for more details.
16 #
17 # You should have received a copy of the GNU General Public License
18 # along with this program; if not, write to the Free Software
19 # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
20 # 02111-1307  USA
21 # -------------------------------------------------------------------
22
23 =head1 NAME
24
25 SQL::Translator::Parser::DBI::SQLServer - parser for SQL Server through DBD::ODBC
26
27 =head1 SYNOPSIS
28
29 See SQL::Translator::Parser::DBI.
30
31 =head1 DESCRIPTION
32
33 Uses DBI Catalog Methods.
34
35 =cut
36
37 use strict;
38 use DBI;
39 use SQL::Translator::Schema;
40 use Data::Dumper;
41
42 use vars qw[ $DEBUG @EXPORT_OK ];
43 $DEBUG   = 0 unless defined $DEBUG;
44
45 no strict 'refs';
46
47 # -------------------------------------------------------------------
48 sub parse {
49     my ( $tr, $dbh ) = @_;
50
51     if ($dbh->{FetchHashKeyName} ne 'NAME_uc') {
52         warn "setting dbh attribute {FetchHashKeyName} to NAME_uc";
53         $dbh->{FetchHashKeyName} = 'NAME_uc';
54     }
55
56     if ($dbh->{ChopBlanks} != 1) {
57         warn "setting dbh attribute {ChopBlanks} to 1";
58         $dbh->{ChopBlanks} = 1;
59     }
60
61     my $schema = $tr->schema;
62
63     my ($sth, @tables, $columns);
64     my $stuff;
65
66     ### Columns
67
68     # it is much quicker to slurp back everything all at once rather
69     # than make repeated calls
70
71     $sth = $dbh->column_info(undef, undef, undef, undef);
72
73
74     foreach my $c (@{$sth->fetchall_arrayref({})}) {
75         $columns
76             ->{$c->{TABLE_CAT}}
77                 ->{$c->{TABLE_SCHEM}}
78                     ->{$c->{TABLE_NAME}}
79                         ->{columns}
80                             ->{$c->{COLUMN_NAME}}= $c;
81     }
82
83     ### Tables and views
84
85     # Get a list of the tables and views.
86     $sth = $dbh->table_info();
87     @tables   = @{$sth->fetchall_arrayref({})};
88
89     my $h = $dbh->selectall_arrayref(q{
90 SELECT o.name, colid,c.text
91   FROM syscomments c
92   JOIN sysobjects o
93     ON c.id = o.id
94  WHERE o.type ='V'
95 ORDER BY o.name,
96          c.colid
97 }
98 );
99
100     # View text
101     # I had always thought there was something 'hard' about
102     # reconstructing text from syscomments ..
103     # this seems to work fine and is certainly not complicated!
104
105     foreach (@{$h}) {
106         $stuff->{view}->{$_->[0]}->{text} .= $_->[2];
107     }
108
109     #### objects with indexes.
110     map {
111         $stuff->{indexes}->{$_->[0]}++
112             if defined;
113     } @{$dbh->selectall_arrayref("SELECT DISTINCT object_name(id)
114                                     FROM sysindexes
115                                    WHERE indid > 0 and indid < 255 and
116                                          name not like '_WA_Sys%'")};
117
118     ## slurp objects
119     map {
120         $stuff->{$_->[1]}->{$_->[0]} = $_;
121     } @{$dbh->selectall_arrayref("SELECT name,type, id FROM sysobjects")};
122
123
124     ### Procedures
125
126     # This gets legitimate procedures by used the 'supported' API: sp_stored_procedures
127     map {
128         my $n = $_->{PROCEDURE_NAME};
129         $n =~ s/;\d+$//;        # Ignore versions for now
130         $_->{name} = $n;
131         $stuff->{procedures}->{$n} = $_;
132     } values %{$dbh->selectall_hashref("sp_stored_procedures", 'PROCEDURE_NAME')};
133
134
135     # And this blasts in the text of 'legit' stored procedures.  Do
136     # this rather than calling sp_helptext in a loop.
137
138     $h = $dbh->selectall_arrayref(q{
139 SELECT o.name, colid,c.text
140   FROM syscomments c
141   JOIN sysobjects o
142     ON c.id = o.id
143  WHERE o.type in ('P', 'FN', 'TF', 'IF')
144 }
145 );
146
147     foreach (@{$h}) {
148         $stuff->{procedures}->{$_->[0]}->{text} .= $_->[2]
149             if (defined($stuff->{procedures}->{$_->[0]}));
150     }
151
152     ### Defaults
153     ### Rules
154     ### Bind Defaults
155     ### Bind Rules
156
157     ### Triggers
158     # Since the 'target' of the trigger is defined in the text, we will
159     # just create them independently for now rather than associating them
160     # with a table.
161
162     $h = $dbh->selectall_arrayref(q{
163 SELECT o.name, colid,c.text
164   FROM syscomments c
165   JOIN sysobjects o
166     ON c.id = o.id
167   JOIN sysobjects o1
168     ON (o.id = o1.instrig OR o.id = o1.deltrig or o.id = o1.updtrig)
169  WHERE o.type ='TR'
170 ORDER BY o.name,
171          c.colid
172 }
173 );
174     foreach (@{$h}) {
175         $stuff->{triggers}->{$_->[0]}->{text} .= $_->[2];
176     }
177
178     ### References
179     ### Keys
180
181     ### Types
182     # Not sure what to do with these?
183     $stuff->{type_info_all} = $dbh->type_info_all;
184
185     ### Tables
186     # According to the DBI docs, these can be
187
188     # "TABLE"
189     # "VIEW"
190     # "SYSTEM TABLE"
191     # "GLOBAL TEMPORARY",
192     # "LOCAL TEMPORARY"
193     # "ALIAS"
194     # "SYNONYM"
195
196     foreach my $table_info (@tables) {
197         next
198             unless (defined($table_info->{TABLE_TYPE}));
199
200         if ($table_info->{TABLE_TYPE} eq "TABLE") {
201             my $table = $schema->add_table(
202                                            name =>
203 $table_info->{TABLE_NAME},
204                                            type =>
205 $table_info->{TABLE_TYPE},
206                                           ) || die $schema->error;
207
208             # find the associated columns
209
210             my $cols =
211                 $columns->{$table_info->{TABLE_CAT}}
212                     ->{$table_info->{TABLE_SCHEM}}
213                         ->{$table_info->{TABLE_NAME}}
214                             ->{columns};
215
216             foreach my $c (values %{$cols}) {
217                                 my $is_auto_increment = $c->{TYPE_NAME} =~ s#(\(\))? identity##i;
218                 my $f = $table->add_field(
219                                           name        => $c->{COLUMN_NAME},
220                                           data_type   => $c->{TYPE_NAME},
221                                           order       => $c->{ORDINAL_POSITION},
222                                           size        => $c->{COLUMN_SIZE},
223                                          ) || die $table->error;
224                 $f->is_nullable($c->{NULLABLE} == 1);
225                 $f->is_auto_increment($is_auto_increment);
226                 if ( defined $c->{COLUMN_DEF}) {
227                         $c->{COLUMN_DEF} =~ s#\('?(.*?)'?\)#$1#;
228                         $f->default_value($c->{COLUMN_DEF});
229                 }
230             }
231
232             # add in primary key
233             my $h = $dbh->selectall_hashref("sp_pkeys
234 $table_info->{TABLE_NAME}", 'COLUMN_NAME');
235             if (scalar keys %{$h} >= 1) {
236                 my @c = map {
237                     $_->{COLUMN_NAME}
238                 } sort {
239                     $a->{KEY_SEQ} <=> $b->{KEY_SEQ}
240                 } values %{$h};
241
242                 $table->primary_key(@c)
243                     if (scalar @c);
244             }
245
246             # add in foreign keys
247             $h = $dbh->selectall_hashref("sp_fkeys NULL,
248 \@fktable_name = '$table_info->{TABLE_NAME}'", 'FK_NAME');
249                         foreach my $fk ( values %{$h} ) {
250                                 my $constraint = $table->add_constraint( name => $fk->{FK_NAME},
251                                         fields => [$fk->{FKCOLUMN_NAME}],
252                                 );
253                                 $constraint->type("FOREIGN_KEY");
254                                 $constraint->on_delete(
255                                         $fk->{DELETE_RULE} == 0 ? "CASCADE" :
256                                         $fk->{DELETE_RULE} == 1 ? "NO ACTION" : "SET_NULL"
257                                 );
258                                 $constraint->on_update(
259                                         $fk->{UPDATE_RULE} == 0 ? "CASCADE" :
260                                         $fk->{UPDATE_RULE} == 1 ? "NO ACTION" : "SET_NULL"
261                                 );
262                                 $constraint->reference_table($fk->{PKTABLE_NAME});
263                         }
264
265             # add in any indexes ... how do we tell if the index has
266             # already been created as part of a primary key or other
267             # constraint?
268
269             if (defined($stuff->{indexes}->{$table_info->{TABLE_NAME}})){
270                 my $h = $dbh->selectall_hashref("sp_helpindex
271 $table_info->{TABLE_NAME}", 'INDEX_NAME');
272                 foreach (values %{$h}) {
273                     my $fields = $_->{'INDEX_KEYS'};
274                     $fields =~ s/\s*//g;
275                     my $i = $table->add_index(
276                                               name   =>
277 $_->{INDEX_NAME},
278                                               fields => $fields,
279                                              );
280                     if ($_->{'INDEX_DESCRIPTION'} =~ /unique/i) {
281                         $i->type('unique');
282
283                         # we could make this a primary key if there
284                         # isn't already one defined and if there
285                         # aren't any nullable columns in thisindex.
286
287                         if (!defined($table->primary_key())) {
288                             $table->primary_key($fields)
289                                 unless grep {
290                                     $table->get_field($_)->is_nullable()
291                                 } split(/,\s*/, $fields);
292                         }
293                     }
294                 }
295             }
296         } elsif ($table_info->{TABLE_TYPE} eq 'VIEW') {
297                 next if $table_info->{TABLE_NAME} eq 'sysconstraints'
298                         || $table_info->{TABLE_NAME} eq 'syssegments';
299                 next if !$stuff->{view}->{$table_info->{TABLE_NAME}}->{text};
300             my $view =  $schema->add_view(
301                                           name =>
302 $table_info->{TABLE_NAME},
303                                           );
304
305
306             my $cols =
307                 $columns->{$table_info->{TABLE_CAT}}
308                     ->{$table_info->{TABLE_SCHEM}}
309                         ->{$table_info->{TABLE_NAME}}
310                             ->{columns};
311
312             $view->fields(map {
313                 $_->{COLUMN_NAME}
314             } sort {
315                 $a->{ORDINAL_POSITION} <=> $b->{ORDINAL_POSITION}
316                 } values %{$cols}
317                          );
318
319             $view->sql($stuff->{view}->{$table_info->{TABLE_NAME}}->{text})
320                 if (defined($stuff->{view}->{$table_info->{TABLE_NAME}}->{text}));
321         }
322     }
323
324     foreach my $p (values %{$stuff->{procedures}}) {
325         next if !$p->{text};
326         my $proc = $schema->add_procedure(
327                                name      => $p->{name},
328                                owner     => $p->{PROCEDURE_OWNER},
329                                comments  => $p->{REMARKS},
330                                sql       => $p->{text},
331                                );
332
333     }
334
335     ### Permissions
336     ### Groups
337     ### Users
338     ### Aliases
339     ### Logins
340     return 1;
341 }
342
343 1;
344
345 # -------------------------------------------------------------------
346
347 =pod
348
349 =head1 AUTHOR
350
351 Chris Hilton E<lt>chris@dctank.comE<gt> - Bulk of code from
352 DBI-Sybase parser, I just tweaked it for SQLServer. Thanks.
353
354 =head1 SEE ALSO
355
356 DBI, DBD::ODBC, SQL::Translator::Schema.
357
358 =cut