From: Brian Phillips Date: Wed, 11 May 2011 13:28:56 +0000 (-0500) Subject: take more care in mangling SELECT when applying subquery limits X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=f74d22e2933e0ffed5955df8f35b47a4b096d6ef;p=dbsrgits%2FDBIx-Class-Historic.git take more care in mangling SELECT when applying subquery limits Previously, if there was a SELECT sub-query in the WHERE clause, the regular expression was being a bit too greedy and stripping too much out. --- diff --git a/Changes b/Changes index 0111ffa..cfaacab 100644 --- a/Changes +++ b/Changes @@ -1,5 +1,9 @@ Revision history for DBIx::Class + - Fix issue where the query was becoming overly mangled when trying + to use pagination with a query that has a sub-select in the WHERE + clause. + 0.08192 2011-05-10 04:20 (UTC) * Fixes - Fix serious regression on SQLite, corrupting data when an alphanum diff --git a/lib/DBIx/Class/SQLMaker.pm b/lib/DBIx/Class/SQLMaker.pm index 66b6c73..c4bd627 100644 --- a/lib/DBIx/Class/SQLMaker.pm +++ b/lib/DBIx/Class/SQLMaker.pm @@ -205,7 +205,12 @@ sub select { } ; - $sql = $self->$limiter ($sql, $rs_attrs, $limit, $offset); + $sql = $self->$limiter ( + $sql, + { %{$rs_attrs||{}}, _selector_sql => $fields }, + $limit, + $offset + ); } else { ($sql, @bind) = $self->next::method ($table, $fields, $where, $rs_attrs); diff --git a/lib/DBIx/Class/SQLMaker/LimitDialects.pm b/lib/DBIx/Class/SQLMaker/LimitDialects.pm index e3da121..f3b815b 100644 --- a/lib/DBIx/Class/SQLMaker/LimitDialects.pm +++ b/lib/DBIx/Class/SQLMaker/LimitDialects.pm @@ -623,9 +623,14 @@ sub _subqueried_limit_attrs { 'Limit dialect implementation usable only in the context of DBIC (missing $rs_attrs)' ) unless ref ($rs_attrs) eq 'HASH'; - # mangle the input sql as we will be replacing the selector - $proto_sql =~ s/^ \s* SELECT \s+ .+ \s+ (?= \b FROM \b )//ix - or $self->throw_exception("Unrecognizable SELECT: $proto_sql"); + # mangle the input sql as we will be replacing the selector entirely + unless ( + $rs_attrs->{_selector_sql} + and + $proto_sql =~ s/^ \s* SELECT \s* \Q$rs_attrs->{_selector_sql}//ix + ) { + $self->throw_exception("Unrecognizable SELECT: $proto_sql"); + } my ($re_sep, $re_alias) = map { quotemeta $_ } ( $self->{name_sep}, $rs_attrs->{alias} ); diff --git a/t/sqlmaker/limit_dialects/rno.t b/t/sqlmaker/limit_dialects/rno.t index 00a6523..457cf7d 100644 --- a/t/sqlmaker/limit_dialects/rno.t +++ b/t/sqlmaker/limit_dialects/rno.t @@ -180,5 +180,35 @@ is_same_sql_bind( ); } +{ +my $subq = $schema->resultset('Owners')->search({ + 'books.owner' => { -ident => 'owner.id' }, +}, { alias => 'owner', select => ['id'] } )->count_rs; + +my $rs_selectas_rel = $schema->resultset('BooksInLibrary')->search( { -exists => $subq->as_query }, { select => ['id','owner'], rows => 1 } ); + +is_same_sql_bind( + $rs_selectas_rel->as_query, + '( + SELECT [id], [owner] FROM ( + SELECT [id], [owner], ROW_NUMBER() OVER( ) AS [rno__row__index] FROM ( + SELECT [me].[id], [me].[owner] + FROM [books] [me] + WHERE ( ( (EXISTS ( + SELECT COUNT( * ) FROM [owners] [owner] WHERE ( [books].[owner] = [owner].[id] ) + )) AND [source] = ? ) ) + ) [me] + ) [me] WHERE [rno__row__index] >= ? AND [rno__row__index] <= ? + )', + [ + [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ], + [ $OFFSET => 1 ], + [ $TOTAL => 1 ], + ], + 'Pagination with sub-query in WHERE works' +); + +} + done_testing; diff --git a/t/sqlmaker/limit_dialects/rownum.t b/t/sqlmaker/limit_dialects/rownum.t index f263166..d9bc1a4 100644 --- a/t/sqlmaker/limit_dialects/rownum.t +++ b/t/sqlmaker/limit_dialects/rownum.t @@ -125,5 +125,29 @@ is_same_sql_bind( ); } +{ +my $subq = $s->resultset('Owners')->search({ + 'books.owner' => { -ident => 'owner.id' }, +}, { alias => 'owner', select => ['id'] } )->count_rs; + +my $rs_selectas_rel = $s->resultset('BooksInLibrary')->search( { -exists => $subq->as_query }, { select => ['id','owner'], rows => 1 } ); + +is_same_sql_bind( + $rs_selectas_rel->as_query, + '( SELECT id, owner FROM ( + SELECT me.id, me.owner + FROM books me + WHERE ( ( (EXISTS (SELECT COUNT( * ) FROM owners owner WHERE ( books.owner = owner.id ))) AND source = ? ) ) + ) me WHERE ROWNUM <= ? + )', + [ + [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ], + [ $TOTAL => 1 ], + ], + 'Pagination with sub-query in WHERE works' +); + +} + done_testing; diff --git a/t/sqlmaker/limit_dialects/toplimit.t b/t/sqlmaker/limit_dialects/toplimit.t index fc1c7fb..bb9ef9a 100644 --- a/t/sqlmaker/limit_dialects/toplimit.t +++ b/t/sqlmaker/limit_dialects/toplimit.t @@ -253,4 +253,22 @@ is_same_sql_bind( $rs_selectas_top->search({})->as_query, ); } +{ +my $subq = $schema->resultset('Owners')->search({ + 'books.owner' => { -ident => 'owner.id' }, +}, { alias => 'owner', select => ['id'] } )->count_rs; + +my $rs_selectas_rel = $schema->resultset('BooksInLibrary')->search( { -exists => $subq->as_query }, { select => ['id','owner'], rows => 1 } ); + +is_same_sql_bind( + $rs_selectas_rel->as_query, + '(SELECT TOP 1 me.id, me.owner FROM books me WHERE ( ( (EXISTS (SELECT COUNT( * ) FROM owners owner WHERE ( books.owner = owner.id ))) AND source = ? ) ) ORDER BY me.id)', + [ + [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ], + ], + 'Pagination with sub-query in WHERE works' +); + +} + done_testing;