[Bps-public-commit] dbix-searchbuilder branch, cud-from-select, updated. 1.59-17-g8e4478b

Ruslan Zakirov ruz at bestpractical.com
Thu Sep 15 10:42:01 EDT 2011


The branch, cud-from-select has been updated
       via  8e4478b0ad6ca9b124dc92b246c7a404e762f45b (commit)
       via  7f7a5da483ea4051123b48437b35fdba7c7e46fe (commit)
       via  a7714243d5a88e455440f4435e26a3ecad33b0d5 (commit)
       via  f0e3196e095f31e7a2f68fc14e79413215b5ff83 (commit)
      from  b98a051dc4268f065e07e931fce1ad1863865276 (commit)

Summary of changes:
 lib/DBIx/SearchBuilder/Handle.pm        |    5 +++
 lib/DBIx/SearchBuilder/Handle/Oracle.pm |   26 +++++++++++++++++-
 t/03cud_from_select.t                   |   46 ++++++++++++++++++++++++++++---
 3 files changed, 72 insertions(+), 5 deletions(-)

- Log -----------------------------------------------------------------
commit f0e3196e095f31e7a2f68fc14e79413215b5ff83
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Sep 15 18:31:28 2011 +0400

    TMP tables can not be referenced twice in one query

diff --git a/t/03cud_from_select.t b/t/03cud_from_select.t
index 0096a6a..306b037 100644
--- a/t/03cud_from_select.t
+++ b/t/03cud_from_select.t
@@ -123,6 +123,8 @@ CREATE TABLE Groups (
 ]
 }
 
+# TEMPORARY tables can not be referenced more than once
+# in the same query, use real table for UsersToGroups
 sub schema_mysql {
 [
 q{
@@ -131,7 +133,7 @@ CREATE TEMPORARY TABLE Users (
     Login varchar(36)
 ) },
 q{
-CREATE TEMPORARY TABLE UsersToGroups (
+CREATE TABLE UsersToGroups (
     id integer primary key AUTO_INCREMENT,
     UserId  integer,
     GroupId integer
@@ -144,6 +146,10 @@ CREATE TEMPORARY TABLE Groups (
 ]
 }
 
+sub cleanup_schema_mysql { [
+    "DROP TABLE UsersToGroups", 
+] }
+
 sub schema_pg {
 [
 q{

commit a7714243d5a88e455440f4435e26a3ecad33b0d5
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Sep 15 18:33:29 2011 +0400

    generate id in InsertFromSelect for Oracle
    
    use ${table_name}_seq sequence, like we do in single
    record Insert

diff --git a/lib/DBIx/SearchBuilder/Handle/Oracle.pm b/lib/DBIx/SearchBuilder/Handle/Oracle.pm
index 3e5cc21..0860d98 100755
--- a/lib/DBIx/SearchBuilder/Handle/Oracle.pm
+++ b/lib/DBIx/SearchBuilder/Handle/Oracle.pm
@@ -127,6 +127,10 @@ unlike other DBs Oracle needs select query to be in parens.
 
 sub InsertFromSelect {
     my ($self, $table, $columns, $query, @binds) = @_;
+    if ( $columns && !grep lc($_) eq 'id', @$columns ) {
+        unshift @$columns, 'id';
+        $query = "SELECT ${table}_seq.nextval, insert_from.* FROM ($query) insert_from";
+    }
     return $self->SUPER::InsertFromSelect( $table, $columns, "($query)", @binds);
 }
 

commit 7f7a5da483ea4051123b48437b35fdba7c7e46fe
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Sep 15 18:40:00 2011 +0400

    document limitations of InsertFromSelect on Oracle

diff --git a/lib/DBIx/SearchBuilder/Handle.pm b/lib/DBIx/SearchBuilder/Handle.pm
index b5f1c99..c56e0ad 100755
--- a/lib/DBIx/SearchBuilder/Handle.pm
+++ b/lib/DBIx/SearchBuilder/Handle.pm
@@ -390,6 +390,11 @@ Takes table name, array reference with columns, select query
 and list of bind values. Inserts data select by the query
 into the table.
 
+To make sure call is portable every column in result of
+the query should have unique name or should be aliased.
+See L<DBIx::SearchBuilder::Handle::Oracle/InsertFromSelect> for
+details.
+
 =cut
 
 sub InsertFromSelect {
diff --git a/lib/DBIx/SearchBuilder/Handle/Oracle.pm b/lib/DBIx/SearchBuilder/Handle/Oracle.pm
index 0860d98..2eb7a17 100755
--- a/lib/DBIx/SearchBuilder/Handle/Oracle.pm
+++ b/lib/DBIx/SearchBuilder/Handle/Oracle.pm
@@ -121,7 +121,27 @@ sub Insert  {
 =head2 InsertFromSelect
 
 Customization of L<DBIx::SearchBuilder::Handle/InsertFromSelect>.
-unlike other DBs Oracle needs select query to be in parens.
+
+Unlike other DBs Oracle needs:
+
+=over 4
+
+=item * id generated from sequences for every new record.
+
+=item * query wrapping in parens.
+
+=back
+
+B<NOTE> that on Oracle there is a limitation on the query. Every
+column in the result should have unique name or alias, for example the
+following query would generate "ORA-00918: column ambiguously defined"
+error:
+
+    SELECT g.id, u.id FROM ...
+
+Solve with aliases:
+
+    SELECT g.id AS group_id, u.id AS user_id FROM ...
 
 =cut
 

commit 8e4478b0ad6ca9b124dc92b246c7a404e762f45b
Author: Ruslan Zakirov <ruz at bestpractical.com>
Date:   Thu Sep 15 18:41:24 2011 +0400

    update CUD tests with more InsertFromSelect cases

diff --git a/t/03cud_from_select.t b/t/03cud_from_select.t
index 306b037..3c40857 100644
--- a/t/03cud_from_select.t
+++ b/t/03cud_from_select.t
@@ -6,7 +6,7 @@ use Test::More;
 BEGIN { require "t/utils.pl" }
 our (@AvailableDrivers);
 
-use constant TESTS_PER_DRIVER => 11;
+use constant TESTS_PER_DRIVER => 14;
 
 my $total = scalar(@AvailableDrivers) * TESTS_PER_DRIVER;
 plan tests => $total;
@@ -46,11 +46,11 @@ diag "insert into table from other tables only" if $ENV{'TEST_VERBOSE'};
     is_deeply( [ sort map $_->Login, @{ $users->ItemsArrayRef } ], ['bob', 'john'] );
 }
 
-diag "insert into table we select from" if $ENV{'TEST_VERBOSE'};
+diag "insert into table from two tables" if $ENV{'TEST_VERBOSE'};
 {
     my $res = $handle->InsertFromSelect(
         'UsersToGroups' => ['UserId', 'GroupId'],
-        'SELECT u.id, g.id FROM Users u, Groups g WHERE u.Login LIKE ? AND g.Name = ?',
+        'SELECT u.id as col1, g.id as col2 FROM Users u, Groups g WHERE u.Login LIKE ? AND g.Name = ?',
         '%a%', 'Support'
     );
     is( $res, 2 );
@@ -94,6 +94,38 @@ diag "insert into table we select from" if $ENV{'TEST_VERBOSE'};
     is( $u2gs->Count, 1 );
 }
 
+diag "insert into table from the same table" if $ENV{'TEST_VERBOSE'};
+{
+    my $res = $handle->InsertFromSelect(
+        'UsersToGroups' => ['UserId', 'GroupId'],
+        'SELECT GroupId, UserId FROM UsersToGroups',
+    );
+    is( $res, 2 );
+}
+
+diag "insert into table from two tables" if $ENV{'TEST_VERBOSE'};
+{ TODO: {
+    local $TODO;
+    $TODO = "No idea how to make it work on Oracle" if $d eq 'Oracle';
+    my $res = do {
+        local $handle->dbh->{'PrintError'} = 0;
+        local $SIG{__WARN__} = sub {};
+        $handle->InsertFromSelect(
+            'UsersToGroups' => ['UserId', 'GroupId'],
+            'SELECT u.id, g.id FROM Users u, Groups g WHERE u.Login LIKE ? AND g.Name = ?',
+            '%a%', 'Support'
+        );
+    };
+    is( $res, 2 );
+    my $users = TestApp::Users->new( $handle );
+    my $u2g_alias = $users->Join( FIELD1 => 'id', TABLE2 => 'UsersToGroups', FIELD2 => 'UserId' );
+    my $g_alias = $users->Join(
+        ALIAS1 => $u2g_alias, FIELD1 => 'GroupId', TABLE2 => 'Groups', FIELD2 => 'id',
+    );
+    $users->Limit( ALIAS => $g_alias, FIELD => 'Name', VALUE => 'Support' );
+    is_deeply( [ sort map $_->Login, @{ $users->ItemsArrayRef } ], ['aurelia', 'ivan'] );
+} }
+
     cleanup_schema( 'TestApp', $handle );
 
 }} # SKIP, foreach blocks

-----------------------------------------------------------------------



More information about the Bps-public-commit mailing list