From: Peter Rabbitson Date: Thu, 29 Aug 2013 06:14:05 +0000 (+0200) Subject: Centralize and sanify generation of synthetic group_by criteria X-Git-Tag: v0.08260~95 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=eb58c082cf9c35760d8fc199483d38c1d926b2e4;p=dbsrgits%2FDBIx-Class.git Centralize and sanify generation of synthetic group_by criteria This should solve multiple deficiencies when a limited prefetch is ordered by non-local columns (especially pre-multiplied ones). Also intelligently solves many problems combining distinct with various non-selecting external order criteria. Most current behaviors should remain unaffected except for cases of blatantly incorrect query generation (fingercross) --- diff --git a/Changes b/Changes index 381ad0f..0ab5d97 100644 --- a/Changes +++ b/Changes @@ -7,6 +7,8 @@ Revision history for DBIx::Class - More robust handling of circular relationship declarations by loading foreign classes less frequently (should resolve issues like http://lists.scsys.co.uk/pipermail/dbix-class/2013-June/011374.html) + - Fix multiple edge cases steming from interaction of a non-selecting + order_by specification and distinct and/or complex prefetch - Setting quote_names propagates to SQL::Translator when producing SQLite DDL (it is one of the few producers *NOT* quoting by default) - Fix incorrect binding of large integers on old versions of diff --git a/lib/DBIx/Class/ResultSet.pm b/lib/DBIx/Class/ResultSet.pm index 47f35e5..222e175 100644 --- a/lib/DBIx/Class/ResultSet.pm +++ b/lib/DBIx/Class/ResultSet.pm @@ -1358,7 +1358,7 @@ sub _construct_results { if ( $aliastypes->{multiplying}{$sel_alias} or - scalar grep { $aliastypes->{multiplying}{(values %$_)[0]} } @{ $aliastypes->{selecting}{$sel_alias}{-parents} } + $aliastypes->{premultiplied}{$sel_alias} ) { $multiplied_selectors->{$_} = 1 for values %{$aliastypes->{selecting}{$sel_alias}{-seen_columns}} } @@ -1970,6 +1970,8 @@ sub _rs_update_delete { if ( $existing_group_by or + # we do not need to check pre-multipliers, since if the premulti is there, its + # parent (who is multi) will be there too keys %{ $join_classifications->{multiplying} || {} } ) { # make sure if there is a supplied group_by it matches the columns compiled above @@ -3425,6 +3427,9 @@ sub _resolved_attrs { my $source = $self->result_source; my $alias = $attrs->{alias}; + $self->throw_exception("Specifying distinct => 1 in conjunction with collapse => 1 is unsupported") + if $attrs->{collapse} and $attrs->{distinct}; + # default selection list $attrs->{columns} = [ $source->columns ] unless List::Util::first { exists $attrs->{$_} } qw/columns cols select as/; @@ -3535,22 +3540,9 @@ sub _resolved_attrs { $attrs->{group_by} = [ $attrs->{group_by} ]; } - # generate the distinct induced group_by early, as prefetch will be carried via a - # subquery (since a group_by is present) - if (delete $attrs->{distinct}) { - if ($attrs->{group_by}) { - carp_unique ("Useless use of distinct on a grouped resultset ('distinct' is ignored when a 'group_by' is present)"); - } - else { - $attrs->{_grouped_by_distinct} = 1; - # distinct affects only the main selection part, not what prefetch may - # add below. - $attrs->{group_by} = $source->storage->_group_over_selection($attrs); - } - } # generate selections based on the prefetch helper - my $prefetch; + my ($prefetch, @prefetch_select, @prefetch_as); $prefetch = $self->_merge_joinpref_attr( {}, delete $attrs->{prefetch} ) if defined $attrs->{prefetch}; @@ -3559,6 +3551,9 @@ sub _resolved_attrs { $self->throw_exception("Unable to prefetch, resultset contains an unnamed selector $attrs->{_dark_selector}{string}") if $attrs->{_dark_selector}; + $self->throw_exception("Specifying prefetch in conjunction with an explicit collapse => 0 is unsupported") + if defined $attrs->{collapse} and ! $attrs->{collapse}; + $attrs->{collapse} = 1; # this is a separate structure (we don't look in {from} directly) @@ -3584,12 +3579,9 @@ sub _resolved_attrs { my @prefetch = $source->_resolve_prefetch( $prefetch, $alias, $join_map ); - push @{ $attrs->{select} }, (map { $_->[0] } @prefetch); - push @{ $attrs->{as} }, (map { $_->[1] } @prefetch); - } - - if ( List::Util::first { $_ =~ /\./ } @{$attrs->{as}} ) { - $attrs->{_related_results_construction} = 1; + # save these for after distinct resolution + @prefetch_select = map { $_->[0] } @prefetch; + @prefetch_as = map { $_->[1] } @prefetch; } # run through the resulting joinstructure (starting from our current slot) @@ -3641,6 +3633,34 @@ sub _resolved_attrs { } } + # generate the distinct induced group_by before injecting the prefetched select/as parts + if (delete $attrs->{distinct}) { + if ($attrs->{group_by}) { + carp_unique ("Useless use of distinct on a grouped resultset ('distinct' is ignored when a 'group_by' is present)"); + } + else { + $attrs->{_grouped_by_distinct} = 1; + # distinct affects only the main selection part, not what prefetch may add below + ($attrs->{group_by}, my $new_order) = $source->storage->_group_over_selection($attrs); + + # FIXME possibly ignore a rewritten order_by (may turn out to be an issue) + # The thinking is: if we are collapsing the subquerying prefetch engine will + # rip stuff apart for us anyway, and we do not want to have a potentially + # function-converted external order_by + # ( there is an explicit if ( collapse && _grouped_by_distinct ) check in DBIHacks ) + $attrs->{order_by} = $new_order unless $attrs->{collapse}; + } + } + + # inject prefetch-bound selection (if any) + push @{$attrs->{select}}, @prefetch_select; + push @{$attrs->{as}}, @prefetch_as; + + # whether we can get away with the dumbest (possibly DBI-internal) collapser + if ( List::Util::first { $_ =~ /\./ } @{$attrs->{as}} ) { + $attrs->{_related_results_construction} = 1; + } + # if both page and offset are specified, produce a combined offset # even though it doesn't make much sense, this is what pre 081xx has # been doing @@ -4433,8 +4453,17 @@ or with an in-place function in which case literal SQL is required: =back -Set to 1 to group by all columns. If the resultset already has a group_by -attribute, this setting is ignored and an appropriate warning is issued. +Set to 1 to automatically generate a L clause based on the selection +(including intelligent handling of L contents). Note that the group +criteria calculation takes place over the B selection. This includes +any L, L or L additions in subsequent +L calls, and standalone columns selected via +L (L). A notable exception are the +extra selections specified via L - such selections are explicitly +excluded from group criteria calculations. + +If the final ResultSet also explicitly defines a L attribute, this +setting is ignored and an appropriate warning is issued. =head2 where diff --git a/lib/DBIx/Class/Storage/DBI.pm b/lib/DBIx/Class/Storage/DBI.pm index ed3aa18..9678c28 100644 --- a/lib/DBIx/Class/Storage/DBI.pm +++ b/lib/DBIx/Class/Storage/DBI.pm @@ -2384,8 +2384,8 @@ sub _select_args { my ($prefetch_needs_subquery, @limit_args); if ( $attrs->{_grouped_by_distinct} and $attrs->{collapse} ) { - # we already know there is a valid group_by and we know it is intended - # to be based *only* on the main result columns + # we already know there is a valid group_by (we made it) and we know it is + # intended to be based *only* on non-multi stuff # short circuit the group_by parsing below $prefetch_needs_subquery = 1; } diff --git a/lib/DBIx/Class/Storage/DBIHacks.pm b/lib/DBIx/Class/Storage/DBIHacks.pm index 95b4092..8a3cb02 100644 --- a/lib/DBIx/Class/Storage/DBIHacks.pm +++ b/lib/DBIx/Class/Storage/DBIHacks.pm @@ -38,21 +38,28 @@ sub _prune_unused_joins { $self->_use_join_optimizer ); - my $aliastypes = $self->_resolve_aliastypes_from_select_args($attrs); + my $orig_aliastypes = $self->_resolve_aliastypes_from_select_args($attrs); - my $orig_joins = delete $aliastypes->{joining}; - my $orig_multiplying = $aliastypes->{multiplying}; + my $new_aliastypes = { %$orig_aliastypes }; + + # we will be recreating this entirely + my @reclassify = 'joining'; # a grouped set will not be affected by amount of rows. Thus any - # {multiplying} joins can go - delete $aliastypes->{multiplying} + # purely multiplicator classifications can go + # (will be reintroduced below if needed by something else) + push @reclassify, qw(multiplying premultiplied) if $attrs->{_force_prune_multiplying_joins} or $attrs->{group_by}; + # nuke what will be recalculated + delete @{$new_aliastypes}{@reclassify}; + my @newfrom = $attrs->{from}[0]; # FROM head is always present + # recalculate what we need once the multipliers are potentially gone + # ignore premultiplies, since they do not add any value to anything my %need_joins; - - for (values %$aliastypes) { + for ( @{$new_aliastypes}{grep { $_ ne 'premultiplied' } keys %$new_aliastypes }) { # add all requested aliases $need_joins{$_} = 1 for keys %$_; @@ -68,11 +75,16 @@ sub _prune_unused_joins { ); } - return ( \@newfrom, { - multiplying => { map { $need_joins{$_} ? ($_ => $orig_multiplying->{$_}) : () } keys %$orig_multiplying }, - %$aliastypes, - joining => { map { $_ => $orig_joins->{$_} } keys %need_joins }, - } ); + # we have a new set of joiners - for everything we nuked pull the classification + # off the original stack + for my $ctype (@reclassify) { + $new_aliastypes->{$ctype} = { map + { $need_joins{$_} ? ( $_ => $orig_aliastypes->{$ctype}{$_} ) : () } + keys %{$orig_aliastypes->{$ctype}} + } + } + + return ( \@newfrom, $new_aliastypes ); } # @@ -183,10 +195,10 @@ sub _adjust_select_args_for_complex_prefetch { # construct the inner {from} and lock it in a subquery # we need to prune first, because this will determine if we need a group_by below # throw away all non-selecting, non-restricting multijoins - # (since we def. do not care about multiplication those inside the subquery) + # (since we def. do not care about multiplication of the contents of the subquery) my $inner_subq = do { - # must use it here regardless of user requests + # must use it here regardless of user requests (vastly gentler on optimizer) local $self->{_use_join_optimizer} = 1; # throw away multijoins since we def. do not care about those inside the subquery @@ -194,116 +206,36 @@ sub _adjust_select_args_for_complex_prefetch { %$inner_attrs, _force_prune_multiplying_joins => 1 }); - # uh-oh a multiplier (which is not us) left in, this is a problem + # uh-oh a multiplier (which is not us) left in, this is a problem for limits + # we will need to add a group_by to collapse the resultset for proper counts if ( - $inner_aliastypes->{multiplying} + grep { $_ ne $root_alias } keys %{ $inner_aliastypes->{multiplying} || {} } and # if there are user-supplied groups - assume user knows wtf they are up to ( ! $inner_aliastypes->{grouping} or $inner_attrs->{_grouped_by_distinct} ) - and - my @multipliers = grep { $_ ne $root_alias } keys %{$inner_aliastypes->{multiplying}} ) { - # if none of the multipliers came from an order_by (guaranteed to have been combined - # with a limit) - easy - just slap a group_by to simulate a collapse and be on our way - if ( - ! $inner_aliastypes->{ordering} - or - ! first { $inner_aliastypes->{ordering}{$_} } @multipliers - ) { + my $cur_sel = { map { $_ => 1 } @{$inner_attrs->{select}} }; - my $unprocessed_order_chunks; - ($inner_attrs->{group_by}, $unprocessed_order_chunks) = $self->_group_over_selection ( - $inner_attrs, + # *possibly* supplement the main selection with pks if not already + # there, as they will have to be a part of the group_by to collapse + # things properly + my $inner_select_with_extras; + my @pks = map { "$root_alias.$_" } $root_node->{-rsrc}->primary_columns + or $self->throw_exception( sprintf + 'Unable to perform complex limited prefetch off %s without declared primary key', + $root_node->{-rsrc}->source_name, ); - - $self->throw_exception ( - 'A required group_by clause could not be constructed automatically due to a complex ' - . 'order_by criteria. Either order_by columns only (no functions) or construct a suitable ' - . 'group_by by hand' - ) if $unprocessed_order_chunks; + for my $col (@pks) { + push @{ $inner_select_with_extras ||= [ @{$inner_attrs->{select}} ] }, $col + unless $cur_sel->{$col}++; } - else { - # We need to order by external columns and group at the same time - # so we can calculate the proper limit - # This doesn't really make sense in SQL, however from DBICs point - # of view is rather valid (order the leftmost objects by whatever - # criteria and get the offset/rows many). There is a way around - # this however in SQL - we simply tae the direction of each piece - # of the foreign order and convert them to MIN(X) for ASC or MAX(X) - # for DESC, and group_by the root columns. The end result should be - # exactly what we expect - - # supplement the main selection with pks if not already there, - # as they will have to be a part of the group_by to collapse - # things properly - my $cur_sel = { map { $_ => 1 } @{$inner_attrs->{select}} }; - - my @pks = map { "$root_alias.$_" } $root_node->{-rsrc}->primary_columns - or $self->throw_exception( sprintf - 'Unable to perform complex limited prefetch off %s without declared primary key', - $root_node->{-rsrc}->source_name, - ); - for my $col (@pks) { - push @{$inner_attrs->{select}}, $col - unless $cur_sel->{$col}++; - } - - # wrap any part of the order_by that "responds" to an ordering alias - # into a MIN/MAX - # FIXME - this code is a joke, will need to be completely rewritten in - # the DQ branch. But I need to push a POC here, otherwise the - # pesky tests won't pass - my $sql_maker = $self->sql_maker; - my ($lquote, $rquote, $sep) = map { quotemeta $_ } ($sql_maker->_quote_chars, $sql_maker->name_sep); - my $own_re = qr/ $lquote \Q$root_alias\E $rquote $sep | \b \Q$root_alias\E $sep /x; - my @order_chunks = map { ref $_ eq 'ARRAY' ? $_ : [ $_ ] } $sql_maker->_order_by_chunks($attrs->{order_by}); - my @new_order = map { \$_ } @order_chunks; - my $inner_columns_info = $self->_resolve_column_info($inner_attrs->{from}); - - # loop through and replace stuff that is not "ours" with a min/max func - # everything is a literal at this point, since we are likely properly - # quoted and stuff - for my $i (0 .. $#new_order) { - my $chunk = $order_chunks[$i][0]; - - # skip ourselves - next if $chunk =~ $own_re; - - ($chunk, my $is_desc) = $sql_maker->_split_order_chunk($chunk); - - # maybe our own unqualified column - my $ord_bit = ( - $lquote and $sep and $chunk =~ /^ $lquote ([^$sep]+) $rquote $/x - ) ? $1 : $chunk; - - next if ( - $ord_bit - and - $inner_columns_info->{$ord_bit} - and - $inner_columns_info->{$ord_bit}{-source_alias} eq $root_alias - ); - - $new_order[$i] = \[ - sprintf( - '%s(%s)%s', - ($is_desc ? 'MAX' : 'MIN'), - $chunk, - ($is_desc ? ' DESC' : ''), - ), - @ {$order_chunks[$i]} [ 1 .. $#{$order_chunks[$i]} ] - ]; - } - $inner_attrs->{order_by} = \@new_order; - - # do not care about leftovers here - it will be all the functions - # we just created - ($inner_attrs->{group_by}) = $self->_group_over_selection ( - $inner_attrs, - ); - } + ($inner_attrs->{group_by}, $inner_attrs->{order_by}) = $self->_group_over_selection({ + %$inner_attrs, + $inner_select_with_extras ? ( select => $inner_select_with_extras ) : (), + _aliastypes => $inner_aliastypes, + }); } # we already optimized $inner_attrs->{from} above @@ -370,9 +302,7 @@ sub _adjust_select_args_for_complex_prefetch { } } qw/selecting restricting grouping ordering/; # see what's left - throw away if not selecting/restricting - # also throw in a group_by if a non-selecting multiplier, - # to guard against cross-join explosions - my $need_outer_group_by; + my $may_need_outer_group_by; while (my $j = shift @orig_from) { my $alias = $j->[0]{-alias}; @@ -383,23 +313,19 @@ sub _adjust_select_args_for_complex_prefetch { } elsif (first { $_->{$alias} } @outer_nonselecting_chains ) { push @outer_from, $j; - $need_outer_group_by ||= $outer_aliastypes->{multiplying}{$alias} ? 1 : 0; + $may_need_outer_group_by ||= $outer_aliastypes->{multiplying}{$alias} ? 1 : 0; } } - if ( $need_outer_group_by and $attrs->{_grouped_by_distinct} ) { - my $unprocessed_order_chunks; - ($outer_attrs->{group_by}, $unprocessed_order_chunks) = $self->_group_over_selection ({ + # also throw in a synthetic group_by if a non-selecting multiplier, + # to guard against cross-join explosions + # the logic is somewhat fragile, but relies on the idea that if a user supplied + # a group by on their own - they know what they were doing + if ( $may_need_outer_group_by and $attrs->{_grouped_by_distinct} ) { + ($outer_attrs->{group_by}, $outer_attrs->{order_by}) = $self->_group_over_selection ({ %$outer_attrs, from => \@outer_from, }); - - $self->throw_exception ( - 'A required group_by clause could not be constructed automatically due to a complex ' - . 'order_by criteria. Either order_by columns only (no functions) or construct a suitable ' - . 'group_by by hand' - ) if $unprocessed_order_chunks; - } # This is totally horrific - the {where} ends up in both the inner and outer query @@ -409,7 +335,6 @@ sub _adjust_select_args_for_complex_prefetch { # the outer select to exclude joins you didn't want in the first place # # OTOH it can be seen as a plus: (notes that this query would make a DBA cry ;) - return $outer_attrs; } @@ -434,6 +359,7 @@ sub _resolve_aliastypes_from_select_args { my $aliases_by_type; # see what aliases are there to work with + # and record who is a multiplier and who is premultiplied my $alias_list; for my $node (@{$attrs->{from}}) { @@ -443,13 +369,17 @@ sub _resolve_aliastypes_from_select_args { or next; $alias_list->{$al} = $j; - $aliases_by_type->{multiplying}{$al} ||= { -parents => $j->{-join_path}||[] } if ( + + $aliases_by_type->{multiplying}{$al} ||= { -parents => $j->{-join_path}||[] } # not array == {from} head == can't be multiplying - ( ref($node) eq 'ARRAY' and ! $j->{-is_single} ) - or - # a parent of ours is already a multiplier - ( grep { $aliases_by_type->{multiplying}{$_} } @{ $j->{-join_path}||[] } ) - ); + if ref($node) eq 'ARRAY' and ! $j->{-is_single}; + + $aliases_by_type->{premultiplied}{$al} ||= { -parents => $j->{-join_path}||[] } + # parts of the path that are not us but are multiplying + if grep { $aliases_by_type->{multiplying}{$_} } + grep { $_ ne $al } + map { values %$_ } + @{ $j->{-join_path}||[] } } # get a column to source/alias map (including unambiguous unqualified ones) @@ -575,7 +505,8 @@ sub _resolve_aliastypes_from_select_args { return $aliases_by_type; } -# This is the engine behind { distinct => 1 } +# This is the engine behind { distinct => 1 } and the general +# complex prefetch grouper sub _group_over_selection { my ($self, $attrs) = @_; @@ -597,36 +528,116 @@ sub _group_over_selection { } } - # add any order_by parts *from the main source* that are not already - # present in the group_by - # we need to be careful not to add any named functions/aggregates - # i.e. order_by => [ ... { count => 'foo' } ... ] - my @leftovers; - for ($self->_extract_order_criteria($attrs->{order_by})) { + my @order_by = $self->_extract_order_criteria($attrs->{order_by}) + or return (\@group_by, $attrs->{order_by}); + + # add any order_by parts that are not already present in the group_by + # to maintain SQL cross-compatibility and general sanity + # + # also in case the original selection is *not* unique, or in case part + # of the ORDER BY refers to a multiplier - we will need to replace the + # skipped order_by elements with their MIN/MAX equivalents as to maintain + # the proper overall order without polluting the group criteria (and + # possibly changing the outcome entirely) + + my ($leftovers, $sql_maker, @new_order_by, $order_chunks, $aliastypes); + + my $group_already_unique = $self->_columns_comprise_identifying_set($colinfos, \@group_by); + + for my $o_idx (0 .. $#order_by) { + + # if the chunk is already a min/max function - there is nothing left to touch + next if $order_by[$o_idx][0] =~ /^ (?: min | max ) \s* \( .+ \) $/ix; + # only consider real columns (for functions the user got to do an explicit group_by) - if (@$_ != 1) { - push @leftovers, $_; - next; + my $chunk_ci; + if ( + @{$order_by[$o_idx]} != 1 + or + # only declare an unknown *plain* identifier as "leftover" if we are called with + # aliastypes to examine. If there are none - we are still in _resolve_attrs, and + # can just assume the user knows what they want + ( ! ( $chunk_ci = $colinfos->{$order_by[$o_idx][0]} ) and $attrs->{_aliastypes} ) + ) { + push @$leftovers, $order_by[$o_idx][0]; } - my $chunk = $_->[0]; - if ( - !$colinfos->{$chunk} + next unless $chunk_ci; + + # no duplication of group criteria + next if $group_index{$chunk_ci->{-fq_colname}}; + + $aliastypes ||= ( + $attrs->{_aliastypes} or - $colinfos->{$chunk}{-source_alias} ne $attrs->{alias} + $self->_resolve_aliastypes_from_select_args({ + from => $attrs->{from}, + order_by => $attrs->{order_by}, + }) + ) if $group_already_unique; + + # check that we are not ordering by a multiplier (if a check is requested at all) + if ( + $group_already_unique + and + ! $aliastypes->{multiplying}{$chunk_ci->{-source_alias}} + and + ! $aliastypes->{premultiplied}{$chunk_ci->{-source_alias}} ) { - push @leftovers, $_; - next; + push @group_by, $chunk_ci->{-fq_colname}; + $group_index{$chunk_ci->{-fq_colname}}++ } + else { + # We need to order by external columns without adding them to the group + # (eiehter a non-unique selection, or a multi-external) + # + # This doesn't really make sense in SQL, however from DBICs point + # of view is rather valid (e.g. order the leftmost objects by whatever + # criteria and get the offset/rows many). There is a way around + # this however in SQL - we simply tae the direction of each piece + # of the external order and convert them to MIN(X) for ASC or MAX(X) + # for DESC, and group_by the root columns. The end result should be + # exactly what we expect + + # FIXME - this code is a joke, will need to be completely rewritten in + # the DQ branch. But I need to push a POC here, otherwise the + # pesky tests won't pass + # wrap any part of the order_by that "responds" to an ordering alias + # into a MIN/MAX + $sql_maker ||= $self->sql_maker; + $order_chunks ||= [ + map { ref $_ eq 'ARRAY' ? $_ : [ $_ ] } $sql_maker->_order_by_chunks($attrs->{order_by}) + ]; - $chunk = $colinfos->{$chunk}{-fq_colname}; - push @group_by, $chunk unless $group_index{$chunk}++; + my ($chunk, $is_desc) = $sql_maker->_split_order_chunk($order_chunks->[$o_idx][0]); + + $new_order_by[$o_idx] = \[ + sprintf( '%s( %s )%s', + ($is_desc ? 'MAX' : 'MIN'), + $chunk, + ($is_desc ? ' DESC' : ''), + ), + @ {$order_chunks->[$o_idx]} [ 1 .. $#{$order_chunks->[$o_idx]} ] + ]; + } } - return wantarray - ? (\@group_by, (@leftovers ? \@leftovers : undef) ) - : \@group_by - ; + $self->throw_exception ( sprintf + 'A required group_by clause could not be constructed automatically due to a complex ' + . 'order_by criteria (%s). Either order_by columns only (no functions) or construct a suitable ' + . 'group_by by hand', + join ', ', map { "'$_'" } @$leftovers, + ) if $leftovers; + + # recreate the untouched order parts + if (@new_order_by) { + $new_order_by[$_] ||= \ $order_chunks->[$_] for ( 0 .. $#$order_chunks ); + } + + return ( + \@group_by, + (@new_order_by ? \@new_order_by : $attrs->{order_by} ), # same ref as original == unchanged + ); } sub _resolve_ident_sources { @@ -838,15 +849,25 @@ sub _extract_order_criteria { sub _order_by_is_stable { my ($self, $ident, $order_by, $where) = @_; - my $colinfo = $self->_resolve_column_info($ident, [ + my @cols = ( (map { $_->[0] } $self->_extract_order_criteria($order_by)), $where ? @{$self->_extract_fixed_condition_columns($where)} :(), - ]); + ) or return undef; + + my $colinfo = $self->_resolve_column_info($ident, \@cols); + + return keys %$colinfo + ? $self->_columns_comprise_identifying_set( $colinfo, \@cols ) + : undef + ; +} - return undef unless keys %$colinfo; +sub _columns_comprise_identifying_set { + my ($self, $colinfo, $columns) = @_; my $cols_per_src; - $cols_per_src->{$_->{-source_alias}}{$_->{-colname}} = $_ for values %$colinfo; + $cols_per_src -> {$_->{-source_alias}} -> {$_->{-colname}} = $_ + for grep { defined $_ } @{$colinfo}{@$columns}; for (values %$cols_per_src) { my $src = (values %$_)[0]->{-result_source}; diff --git a/t/88result_set_column.t b/t/88result_set_column.t index c26f207..6eb9892 100644 --- a/t/88result_set_column.t +++ b/t/88result_set_column.t @@ -58,6 +58,51 @@ is_deeply ( 'distinct => 1 is passed through properly', ); +# test illogical distinct +my $dist_rs = $rs->search ({}, { + columns => ['year'], + distinct => 1, + order_by => { -desc => [qw( cdid year )] }, +}); + +is_same_sql_bind( + $dist_rs->as_query, + '( + SELECT me.year + FROM cd me + GROUP BY me.year + ORDER BY MAX(cdid) DESC, year DESC + )', + [], + 'Correct SQL on external-ordered distinct', +); + +is_same_sql_bind( + $dist_rs->count_rs->as_query, + '( + SELECT COUNT( * ) + FROM ( + SELECT me.year + FROM cd me + GROUP BY me.year + ) me + )', + [], + 'Correct SQL on count of external-orderdd distinct', +); + +is ( + $dist_rs->count_rs->next, + 4, + 'Correct rs-count', +); + +is ( + $dist_rs->count, + 4, + 'Correct direct count', +); + # test +select/+as for single column my $psrs = $schema->resultset('CD')->search({}, { diff --git a/t/prefetch/grouped.t b/t/prefetch/grouped.t index e967307..0eed0a7 100644 --- a/t/prefetch/grouped.t +++ b/t/prefetch/grouped.t @@ -399,7 +399,7 @@ for ($cd_rs->all) { ); } -# make sure distinct applies to the CD part only, not to the order_by part +# make sure distinct applies to the CD part only, not to the prefetched/collapsed order_by part { my $rs = $schema->resultset('CD')->search({}, { columns => [qw( cdid title )], diff --git a/t/prefetch/o2m_o2m_order_by_with_limit.t b/t/prefetch/o2m_o2m_order_by_with_limit.t index f9f78ca..75dda03 100644 --- a/t/prefetch/o2m_o2m_order_by_with_limit.t +++ b/t/prefetch/o2m_o2m_order_by_with_limit.t @@ -100,10 +100,10 @@ for ( LEFT JOIN "track" "tracks" ON "tracks"."cd" = "cds_unordered"."cdid" WHERE "me"."rank" = ? - GROUP BY "cds_unordered"."cdid", "cds_unordered"."artist", "cds_unordered"."title", "cds_unordered"."year", "cds_unordered"."genreid", "cds_unordered"."single_track" + GROUP BY "cds_unordered"."cdid", "cds_unordered"."artist", "cds_unordered"."title", "cds_unordered"."year", "cds_unordered"."genreid", "cds_unordered"."single_track", "me"."name" ORDER BY MAX("genre"."name") DESC, MAX( tracks.title ) DESC, - MIN("me"."name"), + "me"."name" ASC, "year" DESC, "cds_unordered"."title" DESC LIMIT ? diff --git a/t/prefetch/with_limit.t b/t/prefetch/with_limit.t index 71a8ceb..480dc40 100644 --- a/t/prefetch/with_limit.t +++ b/t/prefetch/with_limit.t @@ -153,7 +153,7 @@ throws_ok ( { order_by => \ 'some oddball literal sql', join => { cds => 'tracks' } } )->next }, qr/A required group_by clause could not be constructed automatically/, -); +) || exit; my $artist = $use_prefetch->search({'cds.title' => $artist_many_cds->cds->first->title })->next; is($artist->cds->count, 1, "count on search limiting prefetched has_many"); @@ -199,4 +199,91 @@ is_same_sql_bind ( 'No grouping of non-multiplying resultsets', ); +my $many_one_many_rs = $schema->resultset('CD')->search({}, { + prefetch => { tracks => { lyrics => 'lyric_versions' } }, + rows => 2, + order_by => ['lyrics.track_id'], +}); + +is_same_sql_bind( + $many_one_many_rs->as_query, + '( + SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, + tracks.trackid, tracks.cd, tracks.position, tracks.title, tracks.last_updated_on, tracks.last_updated_at, + lyrics.lyric_id, lyrics.track_id, lyric_versions.id, lyric_versions.lyric_id, lyric_versions.text + FROM ( + SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track + FROM cd me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + LEFT JOIN lyrics lyrics + ON lyrics.track_id = tracks.trackid + GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track + ORDER BY MIN(lyrics.track_id) + LIMIT ? + ) me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + LEFT JOIN lyrics lyrics + ON lyrics.track_id = tracks.trackid + LEFT JOIN lyric_versions lyric_versions + ON lyric_versions.lyric_id = lyrics.lyric_id + ORDER BY lyrics.track_id + )', + [ + [ { sqlt_datatype => 'integer' } => 2 ] + ], + 'Correct SQL on indirectly multiplied orderer', +); + +my $cond_on_multi_ord_by_single = $schema->resultset('CD')->search( + { + 'tracks.position' => { '!=', 1 }, + }, + { + prefetch => [qw( tracks artist )], + order_by => 'artist.name', + rows => 1, + }, +); + +is_same_sql_bind( + $cond_on_multi_ord_by_single->as_query, + '( + SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, + tracks.trackid, tracks.cd, tracks.position, tracks.title, tracks.last_updated_on, tracks.last_updated_at, + artist.artistid, artist.name, artist.rank, artist.charfield + FROM ( + SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track + FROM cd me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + JOIN artist artist + ON artist.artistid = me.artist + WHERE tracks.position != ? + GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, artist.name + ORDER BY artist.name + LIMIT ? + ) me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + JOIN artist artist + ON artist.artistid = me.artist + WHERE tracks.position != ? + ORDER BY artist.name + )', + [ + [ { dbic_colname => "tracks.position", sqlt_datatype => "int" } + => 1 + ], + [ { sqlt_datatype => "integer" } + => 1 + ], + [ { dbic_colname => "tracks.position", sqlt_datatype => "int" } + => 1 + ], + ], + 'Correct SQl on prefetch with limit of restricting multi ordered by a single' +); + done_testing; diff --git a/t/resultset/update_delete.t b/t/resultset/update_delete.t index 340bb41..3314b88 100644 --- a/t/resultset/update_delete.t +++ b/t/resultset/update_delete.t @@ -60,7 +60,7 @@ my $fks = $schema->resultset ('FourKeys')->search ( { sensors => { '!=', 'c' }, ( map { $_ => [1, 2] } qw/foo bar hello goodbye/ ), - }, { join => 'fourkeys_to_twokeys'} + }, { join => { fourkeys_to_twokeys => 'twokeys' }} ); is ($fks->count, 4, 'Joined FourKey count correct (2x2)'); @@ -87,11 +87,11 @@ is ($fb->discard_changes->read_count, 21, 'Update ran only once on discard-join is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier'); # make the multi-join stick -$fks = $fks->search({ 'fourkeys_to_twokeys.pilot_sequence' => { '!=' => 666 } }); +my $fks_multi = $fks->search({ 'fourkeys_to_twokeys.pilot_sequence' => { '!=' => 666 } }); $schema->storage->debugobj ($debugobj); $schema->storage->debug (1); -$fks->update ({ read_count => \ 'read_count + 1' }); +$fks_multi->update ({ read_count => \ 'read_count + 1' }); $schema->storage->debugobj ($orig_debugobj); $schema->storage->debug ($orig_debug); @@ -113,7 +113,7 @@ is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier'); $schema->storage->_use_multicolumn_in (1); $schema->storage->debugobj ($debugobj); $schema->storage->debug (1); -throws_ok { $fks->update ({ read_count => \ 'read_count + 1' }) } # this can't actually execute, we just need the "as_query" +throws_ok { $fks_multi->update ({ read_count => \ 'read_count + 1' }) } # this can't actually execute, we just need the "as_query" qr/\QDBI Exception:/ or do { $sql = ''; @bind = () }; $schema->storage->_use_multicolumn_in (undef); $schema->storage->debugobj ($orig_debugobj); @@ -145,6 +145,30 @@ is_same_sql_bind ( 'Correct update-SQL with multicolumn in support', ); +# make a *premultiplied* join stick +my $fks_premulti = $fks->search({ 'twokeys.artist' => { '!=' => 666 } }); + +$schema->storage->debugobj ($debugobj); +$schema->storage->debug (1); +$fks_premulti->update ({ read_count => \ 'read_count + 1' }); +$schema->storage->debugobj ($orig_debugobj); +$schema->storage->debug ($orig_debug); + +is_same_sql_bind ( + $sql, + \@bind, + 'UPDATE fourkeys + SET read_count = read_count + 1 + WHERE ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? ) OR ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? )', + [ map { "'$_'" } ( (1) x 4, (2) x 4 ) ], + 'Correct update-SQL with premultiplied restricting join without pruning', +); + +is ($fa->discard_changes->read_count, 13, 'Update ran only once on joined resultset'); +is ($fb->discard_changes->read_count, 23, 'Update ran only once on joined resultset'); +is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier'); + + # # Make sure multicolumn in or the equivalent functions correctly # diff --git a/t/search/distinct.t b/t/search/distinct.t index 1060541..7f6eb22 100644 --- a/t/search/distinct.t +++ b/t/search/distinct.t @@ -10,22 +10,106 @@ use DBICTest; my $schema = DBICTest->init_schema(); # make sure order + distinct do not double-inject group criteria -my $year_rs = $schema->resultset ('CD')->search ({}, { +my $rs = $schema->resultset ('CD')->search ({}, { distinct => 1, - columns => [qw/year/], - order_by => 'year', + columns => 'title', }); +# title + cdid == unique constraint +my $unique_rs = $rs->search ({}, { + '+columns' => 'cdid', +}); + +is_same_sql_bind ( + $rs->search({}, { order_by => 'title' })->as_query, + '( + SELECT me.title + FROM cd me + GROUP BY me.title + ORDER BY title + )', + [], + 'Correct GROUP BY on selection+order_by on same column', +); + +is_same_sql_bind ( + $rs->search({}, { order_by => 'year' })->as_query, + '( + SELECT me.title + FROM cd me + GROUP BY me.title + ORDER BY MIN(year) + )', + [], + 'Correct GROUP BY on non-unique selection and order by a different column', +); + is_same_sql_bind ( - $year_rs->as_query, + $unique_rs->search({}, { order_by => 'year' })->as_query, '( - SELECT me.year + SELECT me.title, me.cdid FROM cd me - GROUP BY me.year + GROUP BY me.title, me.cdid, me.year ORDER BY year )', [], - 'Correct GROUP BY', + 'Correct GROUP BY on unique selection and order by a different column', +); + +is_same_sql_bind ( + $rs->search({}, { order_by => 'artist.name', join => 'artist' })->as_query, + '( + SELECT me.title + FROM cd me + JOIN artist artist + ON artist.artistid = me.artist + GROUP BY me.title + ORDER BY MIN(artist.name) + )', + [], + 'Correct GROUP BY on non-unique selection and external single order_by', +); + +is_same_sql_bind ( + $unique_rs->search({}, { order_by => 'artist.name', join => 'artist' })->as_query, + '( + SELECT me.title, me.cdid + FROM cd me + JOIN artist artist + ON artist.artistid = me.artist + GROUP BY me.title, me.cdid, artist.name + ORDER BY artist.name + )', + [], + 'Correct GROUP BY on unique selection and external single order_by', +); + +is_same_sql_bind ( + $rs->search({}, { order_by => 'tracks.title', join => 'tracks' })->as_query, + '( + SELECT me.title + FROM cd me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + GROUP BY me.title + ORDER BY MIN(tracks.title) + )', + [], + 'Correct GROUP BY on non-unique selection and external multi order_by', +); + +is_same_sql_bind ( + $unique_rs->search({}, { order_by => 'tracks.title', join => 'tracks' })->as_query, + '( + SELECT me.title, me.cdid + FROM cd me + LEFT JOIN track tracks + ON tracks.cd = me.cdid + GROUP BY me.title, me.cdid + ORDER BY MIN(tracks.title) + )', + [], + 'Correct GROUP BY on unique selection and external multi order_by', ); done_testing;