1 package DBIx::Class::Storage::DBI::MSSQL;
7 DBIx::Class::Storage::DBI::UniqueIdentifier
8 DBIx::Class::Storage::DBI::IdentityInsert
13 use List::Util 'first';
16 __PACKAGE__->mk_group_accessors(simple => qw/
17 _identity _identity_method _no_scope_identity_query
20 __PACKAGE__->sql_maker_class('DBIx::Class::SQLMaker::MSSQL');
22 __PACKAGE__->sql_quote_char([qw/[ ]/]);
24 __PACKAGE__->datetime_parser_type (
25 'DBIx::Class::Storage::DBI::MSSQL::DateTime::Format'
28 __PACKAGE__->new_guid('NEWID()');
30 sub _prep_for_execute {
32 my ($op, $ident, $args) = @_;
34 # cast MONEY values properly
35 if ($op eq 'insert' || $op eq 'update') {
36 my $fields = $args->[0];
38 my $colinfo = $ident->columns_info([keys %$fields]);
40 for my $col (keys %$fields) {
41 # $ident is a result source object with INSERT/UPDATE ops
43 $colinfo->{$col}{data_type}
45 $colinfo->{$col}{data_type} =~ /^money\z/i
47 my $val = $fields->{$col};
48 $fields->{$col} = \['CAST(? AS MONEY)', [ $col => $val ]];
53 my ($sql, $bind) = $self->next::method (@_);
55 # SELECT SCOPE_IDENTITY only works within a statement scope. We
56 # must try to always use this particular idiom frist, as it is the
57 # only one that guarantees retrieving the correct id under high
58 # concurrency. When this fails we will fall back to whatever secondary
59 # retrieval method is specified in _identity_method, but at this
60 # point we don't have many guarantees we will get what we expected.
61 # http://msdn.microsoft.com/en-us/library/ms190315.aspx
62 # http://davidhayden.com/blog/dave/archive/2006/01/17/2736.aspx
63 if ($self->_perform_autoinc_retrieval and not $self->_no_scope_identity_query) {
64 $sql .= "\nSELECT SCOPE_IDENTITY()";
74 # always list ctx - we need the $sth
75 my ($rv, $sth, @bind) = $self->next::method(@_);
77 if ($self->_perform_autoinc_retrieval) {
79 # attempt to bring back the result of SELECT SCOPE_IDENTITY() we tacked
80 # on in _prep_for_execute above
83 # we didn't even try on ftds
84 unless ($self->_no_scope_identity_query) {
85 ($identity) = try { $sth->fetchrow_array };
89 # SCOPE_IDENTITY failed, but we can do something else
90 if ( (! $identity) && $self->_identity_method) {
91 ($identity) = $self->_dbh->selectrow_array(
92 'select ' . $self->_identity_method
96 $self->_identity($identity);
99 return wantarray ? ($rv, $sth, @bind) : $rv;
102 sub last_insert_id { shift->_identity }
105 # MSSQL is retarded wrt ordered subselects. One needs to add a TOP
106 # to *all* subqueries, but one also *can't* use TOP 100 PERCENT
107 # http://sqladvice.com/forums/permalink/18496/22931/ShowThread.aspx#22931
109 sub _select_args_to_query {
112 my ($sql, $prep_bind, @rest) = $self->next::method (@_);
114 # see if this is an ordered subquery
117 $sql !~ /^ \s* SELECT \s+ TOP \s+ \d+ \s+ /xi
119 scalar $self->_extract_order_criteria ($attrs->{order_by})
121 $self->throw_exception(
122 'An ordered subselect encountered - this is not safe! Please see "Ordered Subselects" in DBIx::Class::Storage::DBI::MSSQL
123 ') unless $attrs->{unsafe_subselect_ok};
124 my $max = $self->sql_maker->__max_int;
125 $sql =~ s/^ \s* SELECT \s/SELECT TOP $max /xi;
129 ? ($sql, $prep_bind, @rest)
130 : \[ "($sql)", @$prep_bind ]
135 # savepoint syntax is the same as in Sybase ASE
137 sub _exec_svp_begin {
138 my ($self, $name) = @_;
140 $self->_dbh->do("SAVE TRANSACTION $name");
143 # A new SAVE TRANSACTION with the same name releases the previous one.
144 sub _exec_svp_release { 1 }
146 sub _exec_svp_rollback {
147 my ($self, $name) = @_;
149 $self->_dbh->do("ROLLBACK TRANSACTION $name");
152 sub sqlt_type { 'SQLServer' }
154 sub sql_limit_dialect {
157 my $supports_rno = 0;
159 if (exists $self->_server_info->{normalized_dbms_version}) {
160 $supports_rno = 1 if $self->_server_info->{normalized_dbms_version} >= 9;
163 # User is connecting via DBD::Sybase and has no permission to run
164 # stored procedures like xp_msver, or version detection failed for some
166 # So, we use a query to check if RNO is implemented.
168 $self->_get_dbh->selectrow_array('SELECT row_number() OVER (ORDER BY rand())');
173 return $supports_rno ? 'RowNumberOver' : 'Top';
179 my $dbh = $self->_dbh or return 0;
181 local $dbh->{RaiseError} = 1;
182 local $dbh->{PrintError} = 0;
185 $dbh->do('select 1');
192 package # hide from PAUSE
193 DBIx::Class::Storage::DBI::MSSQL::DateTime::Format;
195 my $datetime_format = '%Y-%m-%d %H:%M:%S.%3N'; # %F %T
196 my $smalldatetime_format = '%Y-%m-%d %H:%M:%S';
198 my ($datetime_parser, $smalldatetime_parser);
202 require DateTime::Format::Strptime;
203 $datetime_parser ||= DateTime::Format::Strptime->new(
204 pattern => $datetime_format,
207 return $datetime_parser->parse_datetime(shift);
210 sub format_datetime {
212 require DateTime::Format::Strptime;
213 $datetime_parser ||= DateTime::Format::Strptime->new(
214 pattern => $datetime_format,
217 return $datetime_parser->format_datetime(shift);
220 sub parse_smalldatetime {
222 require DateTime::Format::Strptime;
223 $smalldatetime_parser ||= DateTime::Format::Strptime->new(
224 pattern => $smalldatetime_format,
227 return $smalldatetime_parser->parse_datetime(shift);
230 sub format_smalldatetime {
232 require DateTime::Format::Strptime;
233 $smalldatetime_parser ||= DateTime::Format::Strptime->new(
234 pattern => $smalldatetime_format,
237 return $smalldatetime_parser->format_datetime(shift);
244 DBIx::Class::Storage::DBI::MSSQL - Base Class for Microsoft SQL Server support
249 This is the base class for Microsoft SQL Server support, used by
250 L<DBIx::Class::Storage::DBI::ODBC::Microsoft_SQL_Server> and
251 L<DBIx::Class::Storage::DBI::Sybase::Microsoft_SQL_Server>.
253 =head1 IMPLEMENTATION NOTES
255 =head2 IDENTITY information
257 Microsoft SQL Server supports three methods of retrieving the IDENTITY
258 value for inserted row: IDENT_CURRENT, @@IDENTITY, and SCOPE_IDENTITY().
259 SCOPE_IDENTITY is used here because it is the safest. However, it must
260 be called is the same execute statement, not just the same connection.
262 So, this implementation appends a SELECT SCOPE_IDENTITY() statement
263 onto each INSERT to accommodate that requirement.
265 C<SELECT @@IDENTITY> can also be used by issuing:
267 $self->_identity_method('@@identity');
269 it will only be used if SCOPE_IDENTITY() fails.
271 This is more dangerous, as inserting into a table with an on insert trigger that
272 inserts into another table with an identity will give erroneous results on
273 recent versions of SQL Server.
275 =head2 identity insert
277 Be aware that we have tried to make things as simple as possible for our users.
278 For MSSQL that means that when a user tries to create a row, while supplying an
279 explicit value for an autoincrementing column, we will try to issue the
280 appropriate database call to make this possible, namely C<SET IDENTITY_INSERT
281 $table_name ON>. Unfortunately this operation in MSSQL requires the
282 C<db_ddladmin> privilege, which is normally not included in the standard
285 =head2 Ordered Subselects
287 If you attempted the following query (among many others) in Microsoft SQL
291 prefetch => 'relation',
296 You may be surprised to receive an exception. The reason for this is a quirk
297 in the MSSQL engine itself, and sadly doesn't have a sensible workaround due
298 to the way DBIC is built. DBIC can do truly wonderful things with the aid of
299 subselects, and does so automatically when necessary. The list of situations
300 when a subselect is necessary is long and still changes often, so it can not
301 be exhaustively enumerated here. The general rule of thumb is a joined
302 L<has_many|DBIx::Class::Relationship/has_many> relationship with limit/group
303 applied to the left part of the join.
305 In its "pursuit of standards" Microsft SQL Server goes to great lengths to
306 forbid the use of ordered subselects. This breaks a very useful group of
307 searches like "Give me things number 4 to 6 (ordered by name), and prefetch
308 all their relations, no matter how many". While there is a hack which fools
309 the syntax checker, the optimizer may B<still elect to break the subselect>.
310 Testing has determined that while such breakage does occur (the test suite
311 contains an explicit test which demonstrates the problem), it is relative
312 rare. The benefits of ordered subselects are on the other hand too great to be
313 outright disabled for MSSQL.
315 Thus compromise between usability and perfection is the MSSQL-specific
316 L<resultset attribute|DBIx::Class::ResultSet/ATTRIBUTES> C<unsafe_subselect_ok>.
317 It is deliberately not possible to set this on the Storage level, as the user
318 should inspect (and preferably regression-test) the return of every such
319 ResultSet individually. The example above would work if written like:
322 unsafe_subselect_ok => 1,
323 prefetch => 'relation',
328 If it is possible to rewrite the search() in a way that will avoid the need
329 for this flag - you are urged to do so. If DBIC internals insist that an
330 ordered subselect is necessary for an operation, and you believe there is a
331 different/better way to get the same result - please file a bugreport.
335 See L<DBIx::Class/AUTHOR> and L<DBIx::Class/CONTRIBUTORS>.
339 You may distribute this code under the same terms as Perl itself.