File: MSSQL.pm

package info (click to toggle)
libdbix-class-schema-loader-perl 0.07000-1
  • links: PTS, VCS
  • area: main
  • in suites: squeeze
  • size: 868 kB
  • ctags: 447
  • sloc: perl: 7,851; makefile: 4
file content (310 lines) | stat: -rw-r--r-- 9,446 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
package DBIx::Class::Schema::Loader::DBI::MSSQL;

use strict;
use warnings;
use base 'DBIx::Class::Schema::Loader::DBI::Sybase::Common';
use Carp::Clan qw/^DBIx::Class/;
use Class::C3;

our $VERSION = '0.07000';

=head1 NAME

DBIx::Class::Schema::Loader::DBI::MSSQL - DBIx::Class::Schema::Loader::DBI MSSQL Implementation.

=head1 DESCRIPTION

Base driver for Microsoft SQL Server, used by
L<DBIx::Class::Schema::Loader::DBI::Sybase::Microsoft_SQL_Server> for support
via L<DBD::Sybase> and
L<DBIx::Class::Schema::Loader::DBI::ODBC::Microsoft_SQL_Server> for support via
L<DBD::ODBC>.

See L<DBIx::Class::Schema::Loader> and L<DBIx::Class::Schema::Loader::Base> for
usage information.

=head1 CASE SENSITIVITY

Most MSSQL databases use C<CI> (case-insensitive) collation, for this reason
generated column names are lower-cased as this makes them easier to work with
in L<DBIx::Class>.

We attempt to detect the database collation at startup, and set the column
lowercasing behavior accordingly, as lower-cased column names do not work on
case-sensitive databases.

To manually control case-sensitive mode, put:

    preserve_case => 1|0

in your Loader options.

See L<preserve_case|DBIx::Class::Schema::Loader::Base/preserve_case>.

B<NOTE:> this option used to be called C<case_sensitive_collation>, but has
been renamed to a more generic option.

=cut

sub _setup {
    my $self = shift;

    $self->next::method(@_);

    return if defined $self->preserve_case;

    my $dbh = $self->schema->storage->dbh;

    # We use the sys.databases query for the general case, and fallback to
    # databasepropertyex() if for some reason sys.databases is not available,
    # which does not work over DBD::ODBC with unixODBC+FreeTDS.
    #
    # XXX why does databasepropertyex() not work over DBD::ODBC ?
    #
    # more on collations here: http://msdn.microsoft.com/en-us/library/ms143515.aspx
    my ($collation_name) =
           eval { $dbh->selectrow_array('SELECT collation_name FROM sys.databases WHERE name = DB_NAME()') }
        || eval { $dbh->selectrow_array("SELECT CAST(databasepropertyex(DB_NAME(), 'Collation') AS VARCHAR)") };

    if (not $collation_name) {
        warn <<'EOF';

WARNING: MSSQL Collation detection failed. Defaulting to case-insensitive mode.
Override the 'preserve_case' attribute in your Loader options if needed.

See 'preserve_case' in
perldoc DBIx::Class::Schema::Loader::Base
EOF
        $self->preserve_case(0);
        return;
    }

    my $case_sensitive = $collation_name =~ /_(?:CS|BIN2?)(?:_|\z)/;

    $self->preserve_case($case_sensitive ? 1 : 0);
}

sub _tables_list {
    my ($self, $opts) = @_;

    my $dbh = $self->schema->storage->dbh;
    my $sth = $dbh->prepare(<<'EOF');
SELECT t.table_name
FROM INFORMATION_SCHEMA.TABLES t
WHERE t.table_schema = ?
EOF
    $sth->execute($self->db_schema);

    my @tables = map @$_, @{ $sth->fetchall_arrayref };

    return $self->_filter_tables(\@tables, $opts);
}

sub _table_pk_info {
    my ($self, $table) = @_;
    my $dbh = $self->schema->storage->dbh;
    my $sth = $dbh->prepare(qq{sp_pkeys '$table'});
    $sth->execute;

    my @keydata;

    while (my $row = $sth->fetchrow_hashref) {
        push @keydata, $self->_lc($row->{COLUMN_NAME});
    }

    return \@keydata;
}

sub _table_fk_info {
    my ($self, $table) = @_;

    my ($local_cols, $remote_cols, $remote_table, @rels, $sth);
    my $dbh = $self->schema->storage->dbh;
    eval {
        $sth = $dbh->prepare(qq{sp_fkeys \@fktable_name = '$table'});
        $sth->execute;
    };

    while (my $row = eval { $sth->fetchrow_hashref }) {
        my $fk = $row->{FK_NAME};
        push @{$local_cols->{$fk}}, $self->_lc($row->{FKCOLUMN_NAME});
        push @{$remote_cols->{$fk}}, $self->_lc($row->{PKCOLUMN_NAME});
        $remote_table->{$fk} = $row->{PKTABLE_NAME};
    }

    foreach my $fk (keys %$remote_table) {
        push @rels, {
                      local_columns => \@{$local_cols->{$fk}},
                      remote_columns => \@{$remote_cols->{$fk}},
                      remote_table => $remote_table->{$fk},
                    };

    }
    return \@rels;
}

sub _table_uniq_info {
    my ($self, $table) = @_;

    my $dbh = $self->schema->storage->dbh;
    local $dbh->{FetchHashKeyName} = 'NAME_lc';

    my $sth = $dbh->prepare(qq{
SELECT ccu.constraint_name, ccu.column_name
FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE ccu
JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc on (ccu.constraint_name = tc.constraint_name)
JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE kcu on (ccu.constraint_name = kcu.constraint_name and ccu.column_name = kcu.column_name)
wHERE ccu.table_name = @{[ $dbh->quote($table) ]} AND constraint_type = 'UNIQUE' ORDER BY kcu.ordinal_position
    });
    $sth->execute;
    my $constraints;
    while (my $row = $sth->fetchrow_hashref) {
        my $name = $row->{constraint_name};
        my $col  = $self->_lc($row->{column_name});
        push @{$constraints->{$name}}, $col;
    }

    my @uniqs = map { [ $_ => $constraints->{$_} ] } keys %$constraints;
    return \@uniqs;
}

sub _columns_info_for {
    my $self    = shift;
    my ($table) = @_;

    my $result = $self->next::method(@_);

    while (my ($col, $info) = each %$result) {
        my $dbh = $self->schema->storage->dbh;

# find identities
        my $sth = $dbh->prepare(qq{
SELECT column_name 
FROM INFORMATION_SCHEMA.COLUMNS
WHERE columnproperty(object_id(@{[ $dbh->quote($table) ]}, 'U'), @{[ $dbh->quote($col) ]}, 'IsIdentity') = 1
AND table_name = @{[ $dbh->quote($table) ]} AND column_name = @{[ $dbh->quote($col) ]}
        });
        if (eval { $sth->execute; $sth->fetchrow_array }) {
            $info->{is_auto_increment} = 1;
            $info->{data_type} =~ s/\s*identity//i;
            delete $info->{size};
        }

# fix types
        if ($info->{data_type} eq 'int') {
            $info->{data_type} = 'integer';
        }
        elsif ($info->{data_type} eq 'timestamp') {
            $info->{inflate_datetime} = 0;
        }
        elsif ($info->{data_type} =~ /^(?:numeric|decimal)\z/) {
            if (ref($info->{size}) && $info->{size}[0] == 18 && $info->{size}[1] == 0) {
                delete $info->{size};
            }
        }
        elsif ($info->{data_type} eq 'float') {
            $info->{data_type} = 'double precision';
        }
        elsif ($info->{data_type} =~ /^(?:small)?datetime\z/) {
            # fixup for DBD::Sybase
            if ($info->{default_value} && $info->{default_value} eq '3') {
                delete $info->{default_value};
            }
        }
        elsif ($info->{data_type} eq 'datetimeoffset') {
            $info->{size} = {
                26 => 0,
                28 => 1,
                29 => 2,
                30 => 3,
                31 => 4,
                32 => 5,
                33 => 6,
                34 => 7,
            }->{$info->{size}};

            delete $info->{size} if $info->{size} == 7;
        }
        elsif ($info->{data_type} eq 'datetime2') {
            $info->{size} = {
                19 => 0,
                21 => 1,
                22 => 2,
                23 => 3,
                24 => 4,
                25 => 5,
                26 => 6,
                27 => 7,
            }->{$info->{size}};

            delete $info->{size} if $info->{size} == 7;
        }
        elsif ($info->{data_type} eq 'time') {
            $info->{size} = {
                 8 => 0,
                10 => 1,
                11 => 2,
                12 => 3,
                13 => 4,
                14 => 5,
                15 => 6,
                16 => 7,
            }->{$info->{size}};

            delete $info->{size} if $info->{size} == 7;
        }

        if ($info->{data_type} !~ /^(?:n?char|n?varchar|binary|varbinary|numeric|decimal|float|datetime(?:2|offset)|time)\z/) {
            delete $info->{size};
        }

# get default
        $sth = $dbh->prepare(qq{
SELECT column_default
FROM INFORMATION_SCHEMA.COLUMNS
wHERE table_name = @{[ $dbh->quote($table) ]} AND column_name = @{[ $dbh->quote($col) ]}
        });
        my ($default) = eval { $sth->execute; $sth->fetchrow_array };

        if (defined $default) {
            # strip parens
            $default =~ s/^\( (.*) \)\z/$1/x;

            # Literal strings are in ''s, numbers are in ()s (in some versions of
            # MSSQL, in others they are unquoted) everything else is a function.
            $info->{default_value} =
                $default =~ /^['(] (.*) [)']\z/x ? $1 :
                    $default =~ /^\d/ ? $default : \$default;

            if ((eval { lc ${ $info->{default_value} } }||'') eq 'getdate()') {
                ${ $info->{default_value} } = 'current_timestamp';

                my $getdate = 'getdate()';
                $info->{original}{default_value} = \$getdate;
            }
        }
    }

    return $result;
}

=head1 SEE ALSO

L<DBIx::Class::Schema::Loader::DBI::Sybase::Microsoft_SQL_Server>,
L<DBIx::Class::Schema::Loader::DBI::ODBC::Microsoft_SQL_Server>,
L<DBIx::Class::Schema::Loader>, L<DBIx::Class::Schema::Loader::Base>,
L<DBIx::Class::Schema::Loader::DBI>

=head1 AUTHOR

See L<DBIx::Class::Schema::Loader/AUTHOR> and L<DBIx::Class::Schema::Loader/CONTRIBUTORS>.

=head1 LICENSE

This library is free software; you can redistribute it and/or modify it under
the same terms as Perl itself.

=cut

1;
# vim:et sts=4 sw=4 tw=0: