From: Peter Rabbitson Date: Sun, 7 Jun 2009 21:07:55 +0000 (+0000) Subject: Fix for mysql subquery problem X-Git-Tag: v0.08106~30 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=b5963465440da3fac2f38651f6470355b07a3a9d;p=dbsrgits%2FDBIx-Class.git Fix for mysql subquery problem --- diff --git a/Changes b/Changes index 1869f7f..ab51a54 100644 --- a/Changes +++ b/Changes @@ -8,6 +8,9 @@ Revision history for DBIx::Class an exception - fixed corner case when populate() erroneously falls back to create() + - work around braindead mysql when doing subquery counts on + resultsets containing identically named columns from several + tables 0.08103 2009-05-26 19:50:00 (UTC) - Multiple $resultset -> count/update/delete fixes. Now any diff --git a/lib/DBIx/Class/ResultSet.pm b/lib/DBIx/Class/ResultSet.pm index 079edc6..e105e79 100644 --- a/lib/DBIx/Class/ResultSet.pm +++ b/lib/DBIx/Class/ResultSet.pm @@ -1329,7 +1329,7 @@ sub _rs_update_delete { my $subrs = (ref $self)->new($rsrc, $attrs); - return $self->result_source->storage->subq_update_delete($subrs, $op, $values); + return $self->result_source->storage->_subq_update_delete($subrs, $op, $values); } else { return $rsrc->storage->$op( diff --git a/lib/DBIx/Class/Storage/DBI.pm b/lib/DBIx/Class/Storage/DBI.pm index 89b9096..e96dece 100644 --- a/lib/DBIx/Class/Storage/DBI.pm +++ b/lib/DBIx/Class/Storage/DBI.pm @@ -1104,7 +1104,7 @@ sub delete { # Genarating a single PK column subquery is trivial and supported # by all RDBMS. However if we have a multicolumn PK, things get ugly. # Look at _multipk_update_delete() -sub subq_update_delete { +sub _subq_update_delete { my $self = shift; my ($rs, $op, $values) = @_; @@ -1269,7 +1269,7 @@ sub count_grouped { } $sub_attrs->{group_by} ||= [ map { "$attrs->{alias}.$_" } ($source->primary_columns) ]; - $sub_attrs->{select} = $self->_grouped_count_select ($sub_attrs); + $sub_attrs->{select} = $self->_grouped_count_select ($source, $sub_attrs); $attrs->{from} = [{ count_subq => $source->resultset_class->new ($source, $sub_attrs )->as_query @@ -1288,8 +1288,8 @@ sub count_grouped { # choke in various ways. # sub _grouped_count_select { - my ($self, $attrs) = @_; - return $attrs->{group_by}; + my ($self, $source, $rs_args) = @_; + return $rs_args->{group_by}; } sub source_bind_attributes { diff --git a/lib/DBIx/Class/Storage/DBI/mysql.pm b/lib/DBIx/Class/Storage/DBI/mysql.pm index dcdeafe..77aadff 100644 --- a/lib/DBIx/Class/Storage/DBI/mysql.pm +++ b/lib/DBIx/Class/Storage/DBI/mysql.pm @@ -53,10 +53,23 @@ sub lag_behind_master { # MySql can not do subquery update/deletes, only way is slow per-row operations. # This assumes you have set proper transaction isolation and use innodb. -sub subq_update_delete { +sub _subq_update_delete { return shift->_per_row_update_delete (@_); } +# MySql chokes on things like: +# COUNT(*) FROM (SELECT tab1.col, tab2.col FROM tab1 JOIN tab2 ... ) +# claiming that col is a duplicate column (it loses the table specifiers by +# the time it gets to the *). Thus for any subquery count we select only the +# primary keys of the main table in the inner query. This hopefully still +# hits the indexes and keeps mysql happy. +# (mysql does not care if the SELECT and the GROUP BY match) +sub _grouped_count_select { + my ($self, $source, $rs_args) = @_; + my @pcols = map { join '.', $rs_args->{alias}, $_ } ($source->primary_columns); + return @pcols ? \@pcols : $rs_args->{group_by}; +} + 1; =head1 NAME diff --git a/t/71mysql.t b/t/71mysql.t index cf02a61..d8254db 100644 --- a/t/71mysql.t +++ b/t/71mysql.t @@ -14,7 +14,7 @@ my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_MYSQL_${_}" } qw/DSN USER PASS/}; plan skip_all => 'Set $ENV{DBICTEST_MYSQL_DSN}, _USER and _PASS to run this test' unless ($dsn && $user); -plan tests => 23; +plan tests => 19; my $schema = DBICTest::Schema->connect($dsn, $user, $pass); @@ -122,41 +122,19 @@ SKIP: { ); my $owners2 = $schema->resultset ('Owners')->search ({ id => { -in => $owners->get_column ('me.id')->as_query }}); for ($owners, $owners2) { - lives_ok { is ($_->all, 2, 'Prefetched grouped search returns correct number of rows') } - || skip ('No test due to exception', 1); - lives_ok { is ($_->count, 2, 'Prefetched grouped search returns correct count') } - || skip ('No test due to exception', 1); + is ($_->all, 2, 'Prefetched grouped search returns correct number of rows'); + is ($_->count, 2, 'Prefetched grouped search returns correct count'); } - TODO: { - # try a ->prefetch direction (no select collapse) - my $books = $schema->resultset ('BooksInLibrary')->search ( - { 'owner.name' => 'wiggle' }, - { prefetch => 'owner', distinct => 1 } - ); - - local $TODO = 'MySQL is crazy - there seems to be no way to make this work'; - # error thrown is: - # Duplicate column name 'id' [for Statement " - # SELECT COUNT( * ) - # FROM ( - # SELECT me.id, me.source, me.owner, me.title, me.price, owner.id, owner.name - # FROM books me - # JOIN owners owner ON owner.id = me.owner - # WHERE ( ( owner.name = ? AND source = ? ) ) - # GROUP BY me.id, me.source, me.owner, me.title, me.price, owner.id, owner.name - # ) count_subq - # " with ParamValues: 0='wiggle', 1='Library'] - # - # go fucking figure - - my $books2 = $schema->resultset ('BooksInLibrary')->search ({ id => { -in => $books->get_column ('me.id')->as_query }}); - for ($books, $books2) { - lives_ok { is ($_->all, 1, 'Prefetched grouped search returns correct number of rows') } - || skip ('No test due to exception', 1); - lives_ok { is ($_->count, 1, 'Prefetched grouped search returns correct count') } - || skip ('No test due to exception', 1); - } + # try a ->prefetch direction (no select collapse) + my $books = $schema->resultset ('BooksInLibrary')->search ( + { 'owner.name' => 'wiggle' }, + { prefetch => 'owner', distinct => 1 } + ); + my $books2 = $schema->resultset ('BooksInLibrary')->search ({ id => { -in => $books->get_column ('me.id')->as_query }}); + for ($books, $books2) { + is ($_->all, 1, 'Prefetched grouped search returns correct number of rows'); + is ($_->count, 1, 'Prefetched grouped search returns correct count'); } }