1 package DBIx::Class::Storage::DBI::Oracle::Generic;
5 use base qw/DBIx::Class::Storage::DBI/;
9 use Context::Preserve 'preserve_context';
11 use List::Util 'first';
14 __PACKAGE__->sql_limit_dialect ('RowNum');
15 __PACKAGE__->sql_quote_char ('"');
16 __PACKAGE__->sql_maker_class('DBIx::Class::SQLMaker::Oracle');
17 __PACKAGE__->datetime_parser_type('DateTime::Format::Oracle');
19 sub __cache_queries_with_max_lob_parts { 2 }
23 DBIx::Class::Storage::DBI::Oracle::Generic - Oracle Support for DBIx::Class
27 # In your result (table) classes
28 use base 'DBIx::Class::Core';
29 __PACKAGE__->add_columns({ id => { sequence => 'mysequence', auto_nextval => 1 } });
30 __PACKAGE__->set_primary_key('id');
32 # Somewhere in your Code
33 # add some data to a table with a hierarchical relationship
34 $schema->resultset('Person')->create ({
39 firstname => 'child1',
43 firstname => 'grandchild',
49 firstname => 'child2',
55 # select from the hierarchical relationship
56 my $rs = $schema->resultset('Person')->search({},
58 'start_with' => { 'firstname' => 'foo', 'lastname' => 'bar' },
59 'connect_by' => { 'parentid' => { '-prior' => { -ident => 'personid' } },
60 'order_siblings_by' => { -asc => 'name' },
64 # this will select the whole tree starting from person "foo bar", creating
67 # me.persionid me.firstname, me.lastname, me.parentid
71 # firstname = 'foo' and lastname = 'bar'
73 # parentid = prior personid
79 This class implements base Oracle support. The subclass
80 L<DBIx::Class::Storage::DBI::Oracle::WhereJoins> is for C<(+)> joins in Oracle
87 sub _determine_supports_insert_returning {
90 # TODO find out which version supports the RETURNING syntax
91 # 8i has it and earlier docs are a 404 on oracle.com
94 if $self->_server_info->{normalized_dbms_version} >= 8.001;
99 __PACKAGE__->_use_insert_returning_bound (1);
101 sub deployment_statements {
103 my ($schema, $type, $version, $dir, $sqltargs, @rest) = @_;
106 my $quote_char = $self->schema->storage->sql_maker->quote_char;
107 $sqltargs->{quote_table_names} = $quote_char ? 1 : 0;
108 $sqltargs->{quote_field_names} = $quote_char ? 1 : 0;
111 ! exists $sqltargs->{producer_args}{oracle_version}
113 my $dver = $self->_server_info->{dbms_version}
115 $sqltargs->{producer_args}{oracle_version} = $dver;
118 $self->next::method($schema, $type, $version, $dir, $sqltargs, @rest);
121 sub _dbh_last_insert_id {
122 my ($self, $dbh, $source, @columns) = @_;
124 foreach my $col (@columns) {
125 my $seq = ($source->column_info($col)->{sequence} ||= $self->get_autoinc_seq($source,$col));
126 my $id = $self->_sequence_fetch( 'CURRVAL', $seq );
132 sub _dbh_get_autoinc_seq {
133 my ($self, $dbh, $source, $col) = @_;
135 my $sql_maker = $self->sql_maker;
136 my ($ql, $qr) = map { $_ ? (quotemeta $_) : '' } $sql_maker->_quote_chars;
139 if ( ref $source->name eq 'SCALAR' ) {
140 $source_name = ${$source->name};
142 # the ALL_TRIGGERS match further on is case sensitive - thus uppercase
143 # stuff unless it is already quoted
144 $source_name = uc ($source_name) if $source_name !~ /\"/;
147 $source_name = $source->name;
148 $source_name = uc($source_name) unless $ql;
151 # trigger_body is a LONG
152 local $dbh->{LongReadLen} = 64 * 1024 if ($dbh->{LongReadLen} < 64 * 1024);
154 # disable default bindtype
155 local $sql_maker->{bindtype} = 'normal';
157 # look up the correct sequence automatically
158 my ( $schema, $table ) = $source_name =~ /( (?:${ql})? \w+ (?:${qr})? ) \. ( (?:${ql})? \w+ (?:${qr})? )/x;
160 # if no explicit schema was requested - use the default schema (which in the case of Oracle is the db user)
161 $schema ||= \'= USER';
163 my ($sql, @bind) = $sql_maker->select (
165 [qw/TRIGGER_BODY TABLE_OWNER TRIGGER_NAME/],
168 TABLE_NAME => $table || $source_name,
169 TRIGGERING_EVENT => { -like => '%INSERT%' }, # this will also catch insert_or_update
170 TRIGGER_TYPE => { -like => '%BEFORE%' }, # we care only about 'before' triggers
175 # to find all the triggers that mention the column in question a simple
176 # regex grep since the trigger_body above is a LONG and hence not searchable
179 { my %inf; @inf{qw/body schema name/} = @$_; \%inf }
181 { $_->[0] =~ /\:new\.${ql}${col}${qr} | \:new\.$col/xi }
182 @{ $dbh->selectall_arrayref( $sql, {}, @bind ) }
186 # extract all sequence names mentioned in each trigger, throw away
187 # triggers without apparent sequences
189 my @seqs = $_->{body} =~ / ( [\.\w\"\-]+ ) \. nextval /xig;
191 ? { %$_, sequences => \@seqs }
198 # if only one trigger matched things are easy
199 if (@triggers == 1) {
201 if ( @{$triggers[0]{sequences}} == 1 ) {
202 $chosen_trigger = $triggers[0];
205 $self->throw_exception( sprintf (
206 "Unable to introspect trigger '%s' for column '%s.%s' (references multiple sequences). "
207 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
215 # got more than one matching trigger - see if we can narrow it down
216 elsif (@triggers > 1) {
218 my @candidates = grep
219 { $_->{body} =~ / into \s+ \:new\.$col /xi }
223 if (@candidates == 1 && @{$candidates[0]{sequences}} == 1) {
224 $chosen_trigger = $candidates[0];
227 $self->throw_exception( sprintf (
228 "Unable to reliably select a BEFORE INSERT trigger for column '%s.%s' (possibilities: %s). "
229 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
232 ( join ', ', map { "'$_->{name}'" } @triggers ),
238 if ($chosen_trigger) {
239 my $seq_name = $chosen_trigger->{sequences}[0];
241 $seq_name = "$chosen_trigger->{schema}.$seq_name"
242 unless $seq_name =~ /\./;
244 return \$seq_name if $seq_name =~ /\"/; # may already be quoted in-trigger
248 $self->throw_exception( sprintf (
249 "No suitable BEFORE INSERT triggers found for column '%s.%s'. "
250 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
257 sub _sequence_fetch {
258 my ( $self, $type, $seq ) = @_;
260 # use the maker to leverage quoting settings
261 my $sth = $self->_dbh->prepare_cached(
262 $self->sql_maker->select('DUAL', [ ref $seq ? \"$$seq.$type" : "$seq.$type" ] )
265 my ($id) = $sth->fetchrow_array;
273 my $dbh = $self->_dbh or return 0;
275 local $dbh->{RaiseError} = 1;
276 local $dbh->{PrintError} = 0;
279 $dbh->do('select 1 from dual');
287 #my ($self, $dbh, $sql, $bind, $bind_attrs) = @_;
288 my ($self, $bind) = @_[0,3];
290 # Turn off sth caching for multi-part LOBs. See _prep_for_execute below
291 local $self->{disable_sth_caching} = 1 if first {
292 ($_->[0]{_ora_lob_autosplit_part}||0)
294 (__cache_queries_with_max_lob_parts - 1)
297 my $next = $self->next::can;
299 # if we are already in a txn we can't retry anything
300 return shift->$next(@_)
301 if $self->transaction_depth;
303 # cheat the blockrunner - we do want to rerun things regardless of outer state
304 local $self->{_in_do_block};
306 return DBIx::Class::Storage::BlockRunner->new(
311 retry_handler => sub {
312 # ORA-01003: no statement parsed (someone changed the table somehow,
313 # invalidating your cursor.)
314 return 0 if ($_[0]->retried_count or $_[0]->last_exception !~ /ORA-01003/);
316 # re-prepare towards new table data
317 if (my $dbh = $_[0]->storage->_dbh) {
318 delete $dbh->{CachedKids}{$_[0]->run_args->[2]};
325 sub _dbh_execute_for_fetch {
326 #my ($self, $sth, $tuple_status, @extra) = @_;
328 # DBD::Oracle warns loudly on partial execute_for_fetch failures
329 local $_[1]->{PrintWarn} = 0;
331 shift->next::method(@_);
334 =head2 get_autoinc_seq
336 Returns the sequence name for an autoincrement column
340 sub get_autoinc_seq {
341 my ($self, $source, $col) = @_;
343 $self->dbh_do('_dbh_get_autoinc_seq', $source, $col);
346 =head2 datetime_parser_type
348 This sets the proper DateTime::Format module for use with
349 L<DBIx::Class::InflateColumn::DateTime>.
351 =head2 connect_call_datetime_setup
355 on_connect_call => 'datetime_setup'
357 In L<connect_info|DBIx::Class::Storage::DBI/connect_info> to set the session nls
358 date, and timestamp values for use with L<DBIx::Class::InflateColumn::DateTime>
359 and the necessary environment variables for L<DateTime::Format::Oracle>, which
362 Maximum allowable precision is used, unless the environment variables have
365 These are the defaults used:
367 $ENV{NLS_DATE_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS';
368 $ENV{NLS_TIMESTAMP_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS.FF';
369 $ENV{NLS_TIMESTAMP_TZ_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS.FF TZHTZM';
371 To get more than second precision with L<DBIx::Class::InflateColumn::DateTime>
372 for your timestamps, use something like this:
374 use Time::HiRes 'time';
375 my $ts = DateTime->from_epoch(epoch => time);
379 sub connect_call_datetime_setup {
382 my $date_format = $ENV{NLS_DATE_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS';
383 my $timestamp_format = $ENV{NLS_TIMESTAMP_FORMAT} ||=
384 'YYYY-MM-DD HH24:MI:SS.FF';
385 my $timestamp_tz_format = $ENV{NLS_TIMESTAMP_TZ_FORMAT} ||=
386 'YYYY-MM-DD HH24:MI:SS.FF TZHTZM';
389 "alter session set nls_date_format = '$date_format'"
392 "alter session set nls_timestamp_format = '$timestamp_format'"
395 "alter session set nls_timestamp_tz_format='$timestamp_tz_format'"
399 ### Note originally by Ron "Quinn" Straight <quinnfazigu@gmail.org>
400 ### http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/DBIx-Class.git;a=commitdiff;h=5db2758de644d53e07cd3e05f0e9037bf40116fc
402 # Handle LOB types in Oracle. Under a certain size (4k?), you can get away
403 # with the driver assuming your input is the deprecated LONG type if you
404 # encode it as a hex string. That ain't gonna fly at larger values, where
405 # you'll discover you have to do what this does.
407 # This method had to be overridden because we need to set ora_field to the
408 # actual column, and that isn't passed to the call (provided by Storage) to
409 # bind_attribute_by_data_type.
411 # According to L<DBD::Oracle>, the ora_field isn't always necessary, but
412 # adding it doesn't hurt, and will save your bacon if you're modifying a
413 # table with more than one LOB column.
415 sub _dbi_attrs_for_bind {
416 my ($self, $ident, $bind) = @_;
418 my $attrs = $self->next::method($ident, $bind);
420 for my $i (0 .. $#$attrs) {
421 if (keys %{$attrs->[$i]||{}} and my $col = $bind->[$i][0]{dbic_colname}) {
422 $attrs->[$i]{ora_field} = $col;
429 sub bind_attribute_by_data_type {
430 my ($self, $dt) = @_;
432 if ($self->_is_lob_type($dt)) {
434 # this is a hot-ish codepath, store an escape-flag in the DBD namespace, so that
435 # things like Class::Unload work (unlikely but possible)
436 unless ($DBD::Oracle::__DBIC_DBD_VERSION_CHECK_OK__) {
438 # no earlier - no later
439 if ($DBD::Oracle::VERSION eq '1.23') {
440 $self->throw_exception(
441 "BLOB/CLOB support in DBD::Oracle == 1.23 is broken, use an earlier or later ".
442 "version (https://rt.cpan.org/Public/Bug/Display.html?id=46016)"
446 $DBD::Oracle::__DBIC_DBD_VERSION_CHECK_OK__ = 1;
450 ora_type => $self->_is_text_lob_type($dt)
451 ? DBD::Oracle::ORA_CLOB()
452 : DBD::Oracle::ORA_BLOB()
460 # Handle blob columns in WHERE.
462 # For equality comparisons:
464 # We split data intended for comparing to a LOB into 2000 character chunks and
465 # compare them using dbms_lob.substr on the LOB column.
467 # We turn off DBD::Oracle LOB binds for these partial LOB comparisons by passing
468 # dbd_attrs => undef, because these are regular varchar2 comparisons and
469 # otherwise the query will fail.
471 # Since the most common comparison size is likely to be under 4000 characters
472 # (TEXT comparisons previously deployed to other RDBMSes) we disable
473 # prepare_cached for queries with more than two part comparisons to a LOB
474 # column. This is done in _dbh_execute (above) which was previously overridden
475 # to gracefully recover from an Oracle error. This is to be careful to not
476 # exhaust your application's open cursor limit.
479 # http://itcareershift.com/blog1/2011/02/21/oracle-max-number-of-open-cursors-complete-reference-for-the-new-oracle-dba/
480 # on the open_cursor limit.
482 # For everything else:
484 # We assume that everything that is not a LOB comparison, will most likely be a
485 # LIKE query or some sort of function invocation. This may prove to be a naive
486 # assumption in the future, but for now it should cover the two most likely
487 # things users would want to do with a BLOB or CLOB, an equality test or a LIKE
490 # For these expressions, the bind must NOT have the attributes of a LOB bind for
491 # DBD::Oracle, otherwise the query will fail. This is done by passing
492 # dbd_attrs => undef.
494 sub _prep_for_execute {
498 return $self->next::method(@_)
501 my ($sql, $bind) = $self->next::method(@_);
503 my $lob_bind_indices = { map {
505 $bind->[$_][0]{sqlt_datatype}
507 $self->_is_lob_type($bind->[$_][0]{sqlt_datatype})
509 } ( 0 .. $#$bind ) };
511 return ($sql, $bind) unless %$lob_bind_indices;
513 my ($final_sql, @final_binds);
514 if ($op eq 'update') {
515 $self->throw_exception('Update with complex WHERE clauses involving BLOB columns currently not supported')
516 if $sql =~ /\bWHERE\b .+ \bWHERE\b/xs;
519 ($final_sql, $where_sql) = $sql =~ /^ (.+?) ( \bWHERE\b .+) /xs;
521 if (my $set_bind_count = $final_sql =~ y/?//) {
523 delete $lob_bind_indices->{$_} for (0 .. ($set_bind_count - 1));
525 # bail if only the update part contains blobs
526 return ($sql, $bind) unless %$lob_bind_indices;
528 @final_binds = splice @$bind, 0, $set_bind_count;
529 $lob_bind_indices = { map
530 { $_ - $set_bind_count => $lob_bind_indices->{$_} }
531 keys %$lob_bind_indices
535 # if we got that far - assume the where SQL is all we got
536 # (the first part is already shoved into $final_sql)
539 elsif ($op ne 'select' and $op ne 'delete') {
540 $self->throw_exception("Unsupported \$op: $op");
543 my @sql_parts = split /\?/, $sql;
545 my $col_equality_re = qr/ (?<=\s) ([\w."]+) (\s*=\s*) $/x;
547 for my $b_idx (0 .. $#$bind) {
548 my $bound = $bind->[$b_idx];
551 $lob_bind_indices->{$b_idx}
553 my ($col, $eq) = $sql_parts[0] =~ $col_equality_re
555 my $data = $bound->[1];
557 $data = "$data" if ref $data;
559 my @parts = unpack '(a2000)*', $data;
563 for my $idx (0..$#parts) {
564 push @sql_frag, sprintf (
565 'UTL_RAW.CAST_TO_VARCHAR2(RAWTOHEX(DBMS_LOB.SUBSTR(%s, 2000, %d))) = ?',
566 $col, ($idx*2000 + 1),
570 my $sql_frag = '( ' . (join ' AND ', @sql_frag) . ' )';
572 $sql_parts[0] =~ s/$col_equality_re/$sql_frag/;
574 $final_sql .= shift @sql_parts;
576 for my $idx (0..$#parts) {
580 _ora_lob_autosplit_part => $idx,
588 $final_sql .= shift(@sql_parts) . '?';
589 push @final_binds, $lob_bind_indices->{$b_idx}
601 if (@sql_parts > 1) {
602 carp "There are more placeholders than binds, this should not happen!";
603 @sql_parts = join ('?', @sql_parts);
606 $final_sql .= $sql_parts[0];
608 return ($final_sql, \@final_binds);
613 sub _exec_svp_begin {
614 my ($self, $name) = @_;
615 $self->_dbh->do("SAVEPOINT $name");
618 # Oracle automatically releases a savepoint when you start another one with the
620 sub _exec_svp_release { 1 }
622 sub _exec_svp_rollback {
623 my ($self, $name) = @_;
624 $self->_dbh->do("ROLLBACK TO SAVEPOINT $name")
627 =head2 relname_to_table_alias
629 L<DBIx::Class> uses L<DBIx::Class::Relationship> names as table aliases in
632 Unfortunately, Oracle doesn't support identifiers over 30 chars in length, so
633 the L<DBIx::Class::Relationship> name is shortened and appended with half of an
636 See L<DBIx::Class::Storage/"relname_to_table_alias">.
640 sub relname_to_table_alias {
642 my ($relname, $join_count) = @_;
644 my $alias = $self->next::method(@_);
646 # we need to shorten here in addition to the shortening in SQLA itself,
647 # since the final relnames are a crucial for the join optimizer
648 return $self->sql_maker->_shorten_identifier($alias);
651 =head2 with_deferred_fk_checks
653 Runs a coderef between:
655 alter session set constraints = deferred
657 alter session set constraints = immediate
659 to defer foreign key checks.
661 Constraints must be declared C<DEFERRABLE> for this to work.
665 sub with_deferred_fk_checks {
666 my ($self, $sub) = @_;
668 my $txn_scope_guard = $self->txn_scope_guard;
670 $self->_do_query('alter session set constraints = deferred');
672 my $sg = Scope::Guard->new(sub {
673 $self->_do_query('alter session set constraints = immediate');
677 preserve_context { $sub->() } after => sub { $txn_scope_guard->commit };
682 Following additional attributes can be used in resultsets.
684 =head2 connect_by or connect_by_nocycle
688 =item Value: \%connect_by
692 A hashref of conditions used to specify the relationship between parent rows
693 and child rows of the hierarchy.
696 connect_by => { parentid => 'prior personid' }
698 # adds a connect by statement to the query:
700 # me.persionid me.firstname, me.lastname, me.parentid
704 # parentid = prior persionid
707 connect_by_nocycle => { parentid => 'prior personid' }
709 # adds a connect by statement to the query:
711 # me.persionid me.firstname, me.lastname, me.parentid
715 # parentid = prior persionid
722 =item Value: \%condition
726 A hashref of conditions which specify the root row(s) of the hierarchy.
728 It uses the same syntax as L<DBIx::Class::ResultSet/search>
730 start_with => { firstname => 'Foo', lastname => 'Bar' }
733 # me.persionid me.firstname, me.lastname, me.parentid
737 # firstname = 'foo' and lastname = 'bar'
739 # parentid = prior persionid
741 =head2 order_siblings_by
745 =item Value: ($order_siblings_by | \@order_siblings_by)
749 Which column(s) to order the siblings by.
751 It uses the same syntax as L<DBIx::Class::ResultSet/order_by>
753 'order_siblings_by' => 'firstname ASC'
756 # me.persionid me.firstname, me.lastname, me.parentid
760 # parentid = prior persionid
766 See L<DBIx::Class/AUTHOR> and L<DBIx::Class/CONTRIBUTORS>.
770 You may distribute this code under the same terms as Perl itself.