1 package DBIx::Class::Storage::DBI::Oracle::Generic;
6 use Context::Preserve 'preserve_context';
8 use List::Util 'first';
11 __PACKAGE__->sql_limit_dialect ('RowNum');
12 __PACKAGE__->sql_quote_char ('"');
16 DBIx::Class::Storage::DBI::Oracle::Generic - Oracle Support for DBIx::Class
20 # In your result (table) classes
21 use base 'DBIx::Class::Core';
22 __PACKAGE__->add_columns({ id => { sequence => 'mysequence', auto_nextval => 1 } });
23 __PACKAGE__->set_primary_key('id');
25 # Somewhere in your Code
26 # add some data to a table with a hierarchical relationship
27 $schema->resultset('Person')->create ({
32 firstname => 'child1',
36 firstname => 'grandchild',
42 firstname => 'child2',
48 # select from the hierarchical relationship
49 my $rs = $schema->resultset('Person')->search({},
51 'start_with' => { 'firstname' => 'foo', 'lastname' => 'bar' },
52 'connect_by' => { 'parentid' => { '-prior' => { -ident => 'personid' } },
53 'order_siblings_by' => { -asc => 'name' },
57 # this will select the whole tree starting from person "foo bar", creating
60 # me.persionid me.firstname, me.lastname, me.parentid
64 # firstname = 'foo' and lastname = 'bar'
66 # parentid = prior personid
72 This class implements base Oracle support. The subclass
73 L<DBIx::Class::Storage::DBI::Oracle::WhereJoins> is for C<(+)> joins in Oracle
80 use base qw/DBIx::Class::Storage::DBI/;
83 __PACKAGE__->sql_maker_class('DBIx::Class::SQLMaker::Oracle');
84 __PACKAGE__->datetime_parser_type('DateTime::Format::Oracle');
86 sub __cache_queries_with_max_lob_parts { 2 }
88 sub _determine_supports_insert_returning {
91 # TODO find out which version supports the RETURNING syntax
92 # 8i has it and earlier docs are a 404 on oracle.com
95 if $self->_server_info->{normalized_dbms_version} >= 8.001;
100 __PACKAGE__->_use_insert_returning_bound (1);
102 sub deployment_statements {
104 my ($schema, $type, $version, $dir, $sqltargs, @rest) = @_;
107 my $quote_char = $self->schema->storage->sql_maker->quote_char;
108 $sqltargs->{quote_table_names} = $quote_char ? 1 : 0;
109 $sqltargs->{quote_field_names} = $quote_char ? 1 : 0;
112 ! exists $sqltargs->{producer_args}{oracle_version}
114 my $dver = $self->_server_info->{dbms_version}
116 $sqltargs->{producer_args}{oracle_version} = $dver;
119 $self->next::method($schema, $type, $version, $dir, $sqltargs, @rest);
122 sub _dbh_last_insert_id {
123 my ($self, $dbh, $source, @columns) = @_;
125 foreach my $col (@columns) {
126 my $seq = ($source->column_info($col)->{sequence} ||= $self->get_autoinc_seq($source,$col));
127 my $id = $self->_sequence_fetch( 'CURRVAL', $seq );
133 sub _dbh_get_autoinc_seq {
134 my ($self, $dbh, $source, $col) = @_;
136 my $sql_maker = $self->sql_maker;
137 my ($ql, $qr) = map { $_ ? (quotemeta $_) : '' } $sql_maker->_quote_chars;
140 if ( ref $source->name eq 'SCALAR' ) {
141 $source_name = ${$source->name};
143 # the ALL_TRIGGERS match further on is case sensitive - thus uppercase
144 # stuff unless it is already quoted
145 $source_name = uc ($source_name) if $source_name !~ /\"/;
148 $source_name = $source->name;
149 $source_name = uc($source_name) unless $ql;
152 # trigger_body is a LONG
153 local $dbh->{LongReadLen} = 64 * 1024 if ($dbh->{LongReadLen} < 64 * 1024);
155 # disable default bindtype
156 local $sql_maker->{bindtype} = 'normal';
158 # look up the correct sequence automatically
159 my ( $schema, $table ) = $source_name =~ /( (?:${ql})? \w+ (?:${qr})? ) \. ( (?:${ql})? \w+ (?:${qr})? )/x;
161 # if no explicit schema was requested - use the default schema (which in the case of Oracle is the db user)
162 $schema ||= uc( ($self->_dbi_connect_info||[])->[1] || '');
164 my ($sql, @bind) = $sql_maker->select (
166 [qw/TRIGGER_BODY TABLE_OWNER TRIGGER_NAME/],
168 $schema ? (OWNER => $schema) : (),
169 TABLE_NAME => $table || $source_name,
170 TRIGGERING_EVENT => { -like => '%INSERT%' }, # this will also catch insert_or_update
171 TRIGGER_TYPE => { -like => '%BEFORE%' }, # we care only about 'before' triggers
176 # to find all the triggers that mention the column in question a simple
177 # 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
188 $_->{sequences} = [ $_->{body} =~ / ( "? [\.\w\"\-]+ "? ) \. nextval /xig ];
193 # if only one trigger matched things are easy
194 if (@triggers == 1) {
196 if ( @{$triggers[0]{sequences}} == 1 ) {
197 $chosen_trigger = $triggers[0];
200 $self->throw_exception( sprintf (
201 "Unable to introspect trigger '%s' for column %s.%s (references multiple sequences). "
202 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
210 # got more than one matching trigger - see if we can narrow it down
211 elsif (@triggers > 1) {
213 my @candidates = grep
214 { $_->{body} =~ / into \s+ \:new\.$col /xi }
218 if (@candidates == 1 && @{$candidates[0]{sequences}} == 1) {
219 $chosen_trigger = $candidates[0];
222 $self->throw_exception( sprintf (
223 "Unable to reliably select a BEFORE INSERT trigger for column %s.%s (possibilities: %s). "
224 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
227 ( join ', ', map { "'$_->{name}'" } @triggers ),
233 if ($chosen_trigger) {
234 my $seq_name = $chosen_trigger->{sequences}[0];
236 $seq_name = "$chosen_trigger->{schema}.$seq_name"
237 unless $seq_name =~ /\./;
239 return \$seq_name if $seq_name =~ /\"/; # may already be quoted in-trigger
243 $self->throw_exception( sprintf (
244 "No suitable BEFORE INSERT triggers found for column %s.%s. "
245 . "You need to specify the correct 'sequence' explicitly in '%s's column_info.",
252 sub _sequence_fetch {
253 my ( $self, $type, $seq ) = @_;
255 # use the maker to leverage quoting settings
256 my $sql_maker = $self->sql_maker;
257 my ($id) = $self->_get_dbh->selectrow_array ($sql_maker->select('DUAL', [ ref $seq ? \"$$seq.$type" : "$seq.$type" ] ) );
264 my $dbh = $self->_dbh or return 0;
266 local $dbh->{RaiseError} = 1;
267 local $dbh->{PrintError} = 0;
270 $dbh->do('select 1 from dual');
278 my ($self, $dbh, $sql, @args) = @_;
281 my $want = wantarray;
282 my $next = $self->next::can;
286 # Turn off sth caching for multi-part LOBs. See _prep_for_execute above.
287 local $self->{disable_sth_caching} = 1
289 ($_->[0]{_ora_lob_autosplit_part}||0)
290 > (__cache_queries_with_max_lob_parts-1)
293 $self->$next($dbh, $sql, @args)
296 if (!defined $want) {
309 if (! $tried and $_ =~ /ORA-01003/) {
310 # ORA-01003: no statement parsed (someone changed the table somehow,
311 # invalidating your cursor.)
312 delete $dbh->{CachedKids}{$sql};
315 $self->throw_exception($_);
318 } while (! $tried++);
320 return wantarray ? @res : $res[0];
323 sub _dbh_execute_array {
324 #my ($self, $sth, $tuple_status, @extra) = @_;
326 # DBD::Oracle warns loudly on partial execute_array failures
327 local $_[1]->{PrintWarn} = 0;
329 shift->next::method(@_);
332 =head2 get_autoinc_seq
334 Returns the sequence name for an autoincrement column
338 sub get_autoinc_seq {
339 my ($self, $source, $col) = @_;
341 $self->dbh_do('_dbh_get_autoinc_seq', $source, $col);
344 =head2 datetime_parser_type
346 This sets the proper DateTime::Format module for use with
347 L<DBIx::Class::InflateColumn::DateTime>.
349 =head2 connect_call_datetime_setup
353 on_connect_call => 'datetime_setup'
355 In L<connect_info|DBIx::Class::Storage::DBI/connect_info> to set the session nls
356 date, and timestamp values for use with L<DBIx::Class::InflateColumn::DateTime>
357 and the necessary environment variables for L<DateTime::Format::Oracle>, which
360 Maximum allowable precision is used, unless the environment variables have
363 These are the defaults used:
365 $ENV{NLS_DATE_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS';
366 $ENV{NLS_TIMESTAMP_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS.FF';
367 $ENV{NLS_TIMESTAMP_TZ_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS.FF TZHTZM';
369 To get more than second precision with L<DBIx::Class::InflateColumn::DateTime>
370 for your timestamps, use something like this:
372 use Time::HiRes 'time';
373 my $ts = DateTime->from_epoch(epoch => time);
377 sub connect_call_datetime_setup {
380 my $date_format = $ENV{NLS_DATE_FORMAT} ||= 'YYYY-MM-DD HH24:MI:SS';
381 my $timestamp_format = $ENV{NLS_TIMESTAMP_FORMAT} ||=
382 'YYYY-MM-DD HH24:MI:SS.FF';
383 my $timestamp_tz_format = $ENV{NLS_TIMESTAMP_TZ_FORMAT} ||=
384 'YYYY-MM-DD HH24:MI:SS.FF TZHTZM';
387 "alter session set nls_date_format = '$date_format'"
390 "alter session set nls_timestamp_format = '$timestamp_format'"
393 "alter session set nls_timestamp_tz_format='$timestamp_tz_format'"
397 ### Note originally by Ron "Quinn" Straight <quinnfazigu@gmail.org>
398 ### http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/DBIx-Class.git;a=commitdiff;h=5db2758de644d53e07cd3e05f0e9037bf40116fc
400 # Handle LOB types in Oracle. Under a certain size (4k?), you can get away
401 # with the driver assuming your input is the deprecated LONG type if you
402 # encode it as a hex string. That ain't gonna fly at larger values, where
403 # you'll discover you have to do what this does.
405 # This method had to be overridden because we need to set ora_field to the
406 # actual column, and that isn't passed to the call (provided by Storage) to
407 # bind_attribute_by_data_type.
409 # According to L<DBD::Oracle>, the ora_field isn't always necessary, but
410 # adding it doesn't hurt, and will save your bacon if you're modifying a
411 # table with more than one LOB column.
413 sub _dbi_attrs_for_bind {
414 my ($self, $ident, $bind) = @_;
416 my $attrs = $self->next::method($ident, $bind);
418 for my $i (0 .. $#$attrs) {
419 if (keys %{$attrs->[$i]||{}} and my $col = $bind->[$i][0]{dbic_colname}) {
420 $attrs->[$i]{ora_field} = $col;
428 sub bind_attribute_by_data_type {
429 my ($self, $dt) = @_;
433 if ($DBD::Oracle::VERSION eq '1.23') {
434 $self->throw_exception(
435 "BLOB/CLOB support in DBD::Oracle == 1.23 is broken, use an earlier or later ".
436 "version.\n\nSee: https://rt.cpan.org/Public/Bug/Display.html?id=46016\n"
442 if ($self->_is_lob_type($dt)) {
444 ora_type => $self->_is_text_lob_type($dt)
445 ? DBD::Oracle::ORA_CLOB()
446 : DBD::Oracle::ORA_BLOB()
451 # Handle blob columns in WHERE.
453 # For equality comparisons:
455 # We split data intended for comparing to a LOB into 2000 character chunks and
456 # compare them using dbms_lob.substr on the LOB column.
458 # We turn off DBD::Oracle LOB binds for these partial LOB comparisons by passing
459 # dbd_attrs => undef, because these are regular varchar2 comparisons and
460 # otherwise the query will fail.
462 # Since the most common comparison size is likely to be under 4000 characters
463 # (TEXT comparisons previously deployed to other RDBMSes) we disable
464 # prepare_cached for queries with more than two part comparisons to a LOB
465 # column. This is done in _dbh_execute (above) which was previously overridden
466 # to gracefully recover from an Oracle error. This is to be careful to not
467 # exhaust your application's open cursor limit.
470 # http://itcareershift.com/blog1/2011/02/21/oracle-max-number-of-open-cursors-complete-reference-for-the-new-oracle-dba/
471 # on the open_cursor limit.
473 # For everything else:
475 # We assume that everything that is not a LOB comparison, will most likely be a
476 # LIKE query or some sort of function invocation. This may prove to be a naive
477 # assumption in the future, but for now it should cover the two most likely
478 # things users would want to do with a BLOB or CLOB, an equality test or a LIKE
481 # For these expressions, the bind must NOT have the attributes of a LOB bind for
482 # DBD::Oracle, otherwise the query will fail. This is done by passing
483 # dbd_attrs => undef.
485 sub _prep_for_execute {
489 my ($sql, $bind) = $self->next::method(@_);
491 return ($sql, $bind) if $op ne 'select';
493 my @sql_part = split /\?/, $sql;
494 my ($new_sql, @new_binds);
496 foreach my $bound (@$bind) {
497 my $data_type = $bound->[0]{sqlt_datatype}||'';
499 if ($self->_is_lob_type($data_type)) {
500 if (my ($col, $eq) = $sql_part[0] =~ /(?<=\s)([\w."]+)(\s*=\s*)$/) {
501 my $data = $bound->[1];
503 $data = "$data" if ref $data;
505 my @parts = unpack '(a2000)*', $data;
509 for my $idx (0..$#parts) {
511 "UTL_RAW.CAST_TO_VARCHAR2(RAWTOHEX(DBMS_LOB.SUBSTR($col, 2000, ".($idx*2000+1)."))) = ?";
514 my $sql_frag = '( ' . (join ' AND ', @sql_frag) . ' )';
516 $sql_part[0] =~ s/(?<=\s)([\w."]+)(\s*=\s*)$/$sql_frag/;
518 $new_sql .= shift @sql_part;
520 for my $idx (0..$#parts) {
524 _ora_lob_autosplit_part => $idx,
532 $new_sql .= shift(@sql_part) . '?';
544 $new_sql .= shift(@sql_part) . '?';
545 push @new_binds, $bound;
548 $new_sql .= join '', @sql_part;
550 return ($new_sql, \@new_binds);
555 sub _exec_svp_begin {
556 my ($self, $name) = @_;
557 $self->_dbh->do("SAVEPOINT $name");
560 # Oracle automatically releases a savepoint when you start another one with the
562 sub _exec_svp_release { 1 }
564 sub _exec_svp_rollback {
565 my ($self, $name) = @_;
566 $self->_dbh->do("ROLLBACK TO SAVEPOINT $name")
569 =head2 relname_to_table_alias
571 L<DBIx::Class> uses L<DBIx::Class::Relationship> names as table aliases in
574 Unfortunately, Oracle doesn't support identifiers over 30 chars in length, so
575 the L<DBIx::Class::Relationship> name is shortened and appended with half of an
578 See L<DBIx::Class::Storage/"relname_to_table_alias">.
582 sub relname_to_table_alias {
584 my ($relname, $join_count) = @_;
586 my $alias = $self->next::method(@_);
588 # we need to shorten here in addition to the shortening in SQLA itself,
589 # since the final relnames are a crucial for the join optimizer
590 return $self->sql_maker->_shorten_identifier($alias);
593 =head2 with_deferred_fk_checks
595 Runs a coderef between:
597 alter session set constraints = deferred
599 alter session set constraints = immediate
601 to defer foreign key checks.
603 Constraints must be declared C<DEFERRABLE> for this to work.
607 sub with_deferred_fk_checks {
608 my ($self, $sub) = @_;
610 my $txn_scope_guard = $self->txn_scope_guard;
612 $self->_do_query('alter session set constraints = deferred');
614 my $sg = Scope::Guard->new(sub {
615 $self->_do_query('alter session set constraints = immediate');
619 preserve_context { $sub->() } after => sub { $txn_scope_guard->commit };
624 Following additional attributes can be used in resultsets.
626 =head2 connect_by or connect_by_nocycle
630 =item Value: \%connect_by
634 A hashref of conditions used to specify the relationship between parent rows
635 and child rows of the hierarchy.
638 connect_by => { parentid => 'prior personid' }
640 # adds a connect by statement to the query:
642 # me.persionid me.firstname, me.lastname, me.parentid
646 # parentid = prior persionid
649 connect_by_nocycle => { parentid => 'prior personid' }
651 # adds a connect by statement to the query:
653 # me.persionid me.firstname, me.lastname, me.parentid
657 # parentid = prior persionid
664 =item Value: \%condition
668 A hashref of conditions which specify the root row(s) of the hierarchy.
670 It uses the same syntax as L<DBIx::Class::ResultSet/search>
672 start_with => { firstname => 'Foo', lastname => 'Bar' }
675 # me.persionid me.firstname, me.lastname, me.parentid
679 # firstname = 'foo' and lastname = 'bar'
681 # parentid = prior persionid
683 =head2 order_siblings_by
687 =item Value: ($order_siblings_by | \@order_siblings_by)
691 Which column(s) to order the siblings by.
693 It uses the same syntax as L<DBIx::Class::ResultSet/order_by>
695 'order_siblings_by' => 'firstname ASC'
698 # me.persionid me.firstname, me.lastname, me.parentid
702 # parentid = prior persionid
708 See L<DBIx::Class/AUTHOR> and L<DBIx::Class/CONTRIBUTORS>.
712 You may distribute this code under the same terms as Perl itself.