[Bps-public-commit] dbix-searchbuilder branch master updated. 1.69-4-g2ec2d01

BPS Git Server git at git.bestpractical.com
Fri Sep 24 15:02:54 UTC 2021


This is an automated email from the git hooks/post-receive script. It was
generated because a ref change was pushed to the repository containing
the project "dbix-searchbuilder".

The branch, master has been updated
       via  2ec2d0123ff79e2ba88080c64965a4d487e6db0a (commit)
       via  229a2d5d23d3419cffbad61c742f3c8850cc2c4c (commit)
       via  4412b03e2ab636fd2a18a4ca788f45c871411962 (commit)
       via  22acd4602407d85a30e00a37a54c328763e3a0ae (commit)
      from  9390ab2468cc5ea3d2b52414e5d9e2aae07730d2 (commit)

Those revisions listed above that are new to this repository have
not appeared on any other notification email; so we list those
revisions in full, below.

- Log -----------------------------------------------------------------
commit 2ec2d0123ff79e2ba88080c64965a4d487e6db0a
Author: Jim Brandt <jbrandt at bestpractical.com>
Date:   Fri Sep 24 10:59:46 2021 -0400

    Prep version 1.70

diff --git a/Changes b/Changes
index 39b3120..0984c6d 100644
--- a/Changes
+++ b/Changes
@@ -1,5 +1,9 @@
 Revision history for Perl extension DBIx::SearchBuilder.
 
+1.70 2021-09-24
+ - Enable queries processed with BuildSelectQuery and BuildSelectCountQuery
+   to use bind variables
+
 1.69 2021-01-20
 
  - New option to quote tablenames in queries, enabled automatically for MySQL 8
diff --git a/MANIFEST b/MANIFEST
index 5d15017..cec146c 100644
--- a/MANIFEST
+++ b/MANIFEST
@@ -50,6 +50,7 @@ t/02records_dt_interval.t
 t/02records_integers.t
 t/02records_object.t
 t/02searches_function.t
+t/03searches_bind.t
 t/02searches_joins.t
 t/03compatibility.t
 t/03cud_from_select.t
diff --git a/META.yml b/META.yml
index 683f1c0..fd949b5 100644
--- a/META.yml
+++ b/META.yml
@@ -35,4 +35,4 @@ requires:
   capitalization: '0.03'
 resources:
   license: http://dev.perl.org/licenses/
-version: '1.69'
+version: '1.70'
diff --git a/lib/DBIx/SearchBuilder.pm b/lib/DBIx/SearchBuilder.pm
index d21ae4c..0c57fc2 100755
--- a/lib/DBIx/SearchBuilder.pm
+++ b/lib/DBIx/SearchBuilder.pm
@@ -4,7 +4,7 @@ package DBIx::SearchBuilder;
 use strict;
 use warnings;
 
-our $VERSION = "1.69";
+our $VERSION = "1.70";
 
 use Clone qw();
 use Encode qw();

commit 229a2d5d23d3419cffbad61c742f3c8850cc2c4c
Merge: 9390ab2 4412b03
Author: Jim Brandt <jbrandt at bestpractical.com>
Date:   Fri Sep 24 10:47:12 2021 -0400

    Merge branch 'search-support-bind'


commit 4412b03e2ab636fd2a18a4ca788f45c871411962
Author: sunnavy <sunnavy at bestpractical.com>
Date:   Thu Sep 2 03:18:22 2021 +0800

    Test bind values for searches

diff --git a/t/03searches_bind.t b/t/03searches_bind.t
new file mode 100644
index 0000000..c117e3a
--- /dev/null
+++ b/t/03searches_bind.t
@@ -0,0 +1,367 @@
+use strict;
+use Test::More;
+
+BEGIN { require "t/utils.pl" }
+our (@AvailableDrivers);
+
+use constant TESTS_PER_DRIVER => 39;
+
+my $total = scalar(@AvailableDrivers) * TESTS_PER_DRIVER;
+plan tests => $total;
+
+foreach my $d (@AvailableDrivers) {
+SKIP: {
+        unless ( has_schema( 'TestApp', $d ) ) {
+            skip "No schema for '$d' driver", TESTS_PER_DRIVER;
+        }
+        unless ( should_test($d) ) {
+            skip "ENV is not defined for driver '$d'", TESTS_PER_DRIVER;
+        }
+
+        my $handle = get_handle($d);
+        connect_handle($handle);
+        isa_ok( $handle->dbh, 'DBI::db' );
+
+        my $ret = init_schema( 'TestApp', $handle );
+        isa_ok( $ret, 'DBI::st', "Inserted the schema. got a statement handle back" );
+
+        my $count_users = init_data( 'TestApp::User', $handle );
+        ok( $count_users, "init users data" );
+        my $count_groups = init_data( 'TestApp::Group', $handle );
+        ok( $count_groups, "init groups data" );
+        my $count_us2gs = init_data( 'TestApp::UsersToGroup', $handle );
+        ok( $count_us2gs, "init users&groups relations data" );
+
+        my $clean_obj = TestApp::Users->new($handle);
+
+        local $DBIx::SearchBuilder::PREFER_BIND = 1;
+
+        my $users_obj = $clean_obj->Clone;
+        for my $login ( 'Gandalf', "Bilbo\\Baggins", "Baggins' Frodo" ) {
+            $users_obj->Limit( FIELD => 'Login', VALUE => $login );
+            is( $users_obj->Count,        1,      "only one value" );
+            is( $users_obj->First->Login, $login, "$login is the only match" );
+
+            # Using \W here because Login might be wrapped in LOWER().
+            ok( $users_obj->BuildSelectQuery =~ /Login\W*=\s*\?/i,
+                'found a placeholder in select query' );
+            ok( $users_obj->BuildSelectCountQuery =~ /Login\W*=\s*\?/i,
+                'found a placeholder in select count query'
+              );
+            $users_obj->CleanSlate;
+        }
+
+        $users_obj->Limit(
+            FIELD    => 'Login',
+            VALUE    => [ "Bilbo\\Baggins", "Baggins' Frodo" ],
+            OPERATOR => 'IN',
+        );
+        is( $users_obj->Count, 2, "2 values" );
+        is_deeply(
+            [ sort map { $_->Login } @{ $users_obj->ItemsArrayRef } ],
+            [ "Baggins' Frodo", "Bilbo\\Baggins" ],
+            '2 Baggins',
+        );
+        $users_obj->CleanSlate;
+
+        for my $name ( "Shire's Bag End", 'The Fellowship of the Ring' ) {
+            my $groups_obj = TestApp::Groups->new($handle);
+            $groups_obj->Limit( FIELD => 'Name', VALUE => $name, OPERATOR => 'LIKE' );
+            $groups_obj->Limit( FIELD => 'id',   VALUE => 0,     OPERATOR => '>' );
+            is( $groups_obj->Count,       1,     "only one value" );
+            is( $groups_obj->First->Name, $name, "$name is the only match" );
+
+            # Using \W here because Login might be wrapped in LOWER().
+            ok( $groups_obj->BuildSelectQuery =~ /Name\W*I?LIKE\s*\?/i,
+                'found a placeholder for Name in select query'
+              );
+            ok( $groups_obj->BuildSelectQuery =~ /id\s*>\s*\?/i,
+                'found a placeholder for id in select query'
+              );
+            ok( $groups_obj->BuildSelectCountQuery =~ /Name\W*I?LIKE\s*\?/i,
+                'found a placeholder for Name in select count query'
+              );
+            ok( $groups_obj->BuildSelectCountQuery =~ /id\s*>\s*\?/i,
+                'found a placeholder for id in select count query'
+              );
+        }
+
+        my $alias = $users_obj->Join(
+            FIELD1 => 'id',
+            TABLE2 => 'UsersToGroups',
+            FIELD2 => 'UserId'
+        );
+
+        my $group_alias = $users_obj->Join(
+            ALIAS1 => $alias,
+            FIELD1 => 'GroupID',
+            ALIAS2 => $users_obj->NewAlias('Groups'),
+            FIELD2 => 'id'
+        );
+        $users_obj->Limit(
+            LEFTJOIN => $group_alias,
+            FIELD    => 'Name',
+            VALUE    => "Shire's Bag End",
+        );
+
+        is( $users_obj->Count, 2, "2 values" );
+        is_deeply(
+            [ sort map { $_->Login } @{ $users_obj->ItemsArrayRef } ],
+            [ "Baggins' Frodo", "Bilbo\\Baggins" ],
+            '2 Baggins',
+        );
+
+        # ? in JOIN condition
+        ok( $users_obj->BuildSelectQuery( PreferBind => 0 ) !~ /\?/,
+            'found placeholder in select query' );
+        ok( $users_obj->BuildSelectCountQuery( PreferBind => 0 ) !~ /\?/,
+            'found placeholder in select count query' );
+
+        ok( $users_obj->BuildSelectQuery( PreferBind => 0 ) !~ /\?/,
+            'no placeholder in select query' );
+        ok( $users_obj->BuildSelectCountQuery( PreferBind => 0 ) !~ /\?/,
+            'no placeholder in select count query' );
+
+        $DBIx::SearchBuilder::PREFER_BIND = 0;
+        ok( $users_obj->BuildSelectQuery      !~ /\?/, 'no placeholder in select query' );
+        ok( $users_obj->BuildSelectCountQuery !~ /\?/, 'no placeholder in select count query' );
+
+        cleanup_schema( 'TestApp', $handle );
+
+    }
+}    # SKIP, foreach blocks
+
+1;
+
+package TestApp;
+
+sub schema_sqlite {
+    [   q{
+CREATE TABLE Users (
+    id integer primary key,
+    Login varchar(36)
+) },
+        q{
+CREATE TABLE UsersToGroups (
+    id integer primary key,
+    UserId  integer,
+    GroupId integer
+) },
+        q{
+CREATE TABLE Groups (
+    id integer primary key,
+    Name varchar(36)
+) },
+    ]
+}
+
+sub schema_mysql {
+    [   q{
+CREATE TEMPORARY TABLE Users (
+    id integer primary key AUTO_INCREMENT,
+    Login varchar(36)
+) },
+        q{
+CREATE TEMPORARY TABLE UsersToGroups (
+    id integer primary key AUTO_INCREMENT,
+    UserId  integer,
+    GroupId integer
+) },
+        q{
+CREATE TEMPORARY TABLE `Groups` (
+    id integer primary key AUTO_INCREMENT,
+    Name varchar(36)
+) },
+    ]
+}
+
+sub schema_pg {
+    [   q{
+CREATE TEMPORARY TABLE Users (
+    id serial primary key,
+    Login varchar(36)
+) },
+        q{
+CREATE TEMPORARY TABLE UsersToGroups (
+    id serial primary key,
+    UserId integer,
+    GroupId integer
+) },
+        q{
+CREATE TEMPORARY TABLE Groups (
+    id serial primary key,
+    Name varchar(36)
+) },
+    ]
+}
+
+sub schema_oracle {
+    [   "CREATE SEQUENCE Users_seq",
+        "CREATE TABLE Users (
+        id integer CONSTRAINT Users_Key PRIMARY KEY,
+        Login varchar(36)
+    )",
+        "CREATE SEQUENCE UsersToGroups_seq",
+        "CREATE TABLE UsersToGroups (
+        id integer CONSTRAINT UsersToGroups_Key PRIMARY KEY,
+        UserId integer,
+        GroupId integer
+    )",
+        "CREATE SEQUENCE Groups_seq",
+        "CREATE TABLE Groups (
+        id integer CONSTRAINT Groups_Key PRIMARY KEY,
+        Name varchar(36)
+    )",
+    ]
+}
+
+sub cleanup_schema_oracle {
+    [   "DROP SEQUENCE Users_seq",
+        "DROP TABLE Users",
+        "DROP SEQUENCE Groups_seq",
+        "DROP TABLE Groups",
+        "DROP SEQUENCE UsersToGroups_seq",
+        "DROP TABLE UsersToGroups",
+    ]
+}
+
+package TestApp::User;
+
+use base $ENV{SB_TEST_CACHABLE}
+    ? qw/DBIx::SearchBuilder::Record::Cachable/
+    : qw/DBIx::SearchBuilder::Record/;
+
+sub _Init {
+    my $self   = shift;
+    my $handle = shift;
+    $self->Table('Users');
+    $self->_Handle($handle);
+}
+
+sub _ClassAccessible {
+    {
+
+        id    => { read => 1, type  => 'int(11)' },
+        Login => { read => 1, write => 1, type => 'varchar(36)' },
+
+    }
+}
+
+sub init_data {
+    return (
+        ['Login'],
+
+        ['Gandalf'],
+        ["Bilbo\\Baggins"],
+        ["Baggins' Frodo"],
+    );
+}
+
+package TestApp::Users;
+
+use base qw/DBIx::SearchBuilder/;
+
+sub _Init {
+    my $self = shift;
+    $self->SUPER::_Init( Handle => shift );
+    $self->Table('Users');
+}
+
+sub NewItem {
+    my $self = shift;
+    return TestApp::User->new( $self->_Handle );
+}
+
+1;
+
+package TestApp::Group;
+
+use base $ENV{SB_TEST_CACHABLE}
+    ? qw/DBIx::SearchBuilder::Record::Cachable/
+    : qw/DBIx::SearchBuilder::Record/;
+
+sub _Init {
+    my $self   = shift;
+    my $handle = shift;
+    $self->Table('Groups');
+    $self->_Handle($handle);
+}
+
+sub _ClassAccessible {
+    {   id   => { read => 1, type  => 'int(11)' },
+        Name => { read => 1, write => 1, type => 'varchar(36)' },
+    }
+}
+
+sub init_data {
+    return (
+        ['Name'],
+
+        ["Shire's Bag End"],
+        ['The Fellowship of the Ring'],
+    );
+}
+
+package TestApp::Groups;
+
+use base qw/DBIx::SearchBuilder/;
+
+sub _Init {
+    my $self = shift;
+    $self->SUPER::_Init( Handle => shift );
+    $self->Table('Groups');
+}
+
+sub NewItem { return TestApp::Group->new( (shift)->_Handle ) }
+
+1;
+
+package TestApp::UsersToGroup;
+
+use base $ENV{SB_TEST_CACHABLE}
+    ? qw/DBIx::SearchBuilder::Record::Cachable/
+    : qw/DBIx::SearchBuilder::Record/;
+
+sub _Init {
+    my $self   = shift;
+    my $handle = shift;
+    $self->Table('UsersToGroups');
+    $self->_Handle($handle);
+}
+
+sub _ClassAccessible {
+    {
+
+        id      => { read => 1, type => 'int(11)' },
+        UserId  => { read => 1, type => 'int(11)' },
+        GroupId => { read => 1, type => 'int(11)' },
+    }
+}
+
+sub init_data {
+    return (
+        [ 'GroupId', 'UserId' ],
+
+        # Shire
+        [ 1, 2 ],
+        [ 1, 3 ],
+
+        # Fellowship of the Ring
+        [ 2, 1 ],
+        [ 2, 3 ],
+    );
+}
+
+package TestApp::UsersToGroups;
+
+use base qw/DBIx::SearchBuilder/;
+
+sub _Init {
+    my $self = shift;
+    $self->Table('UsersToGroups');
+    return $self->SUPER::_Init( Handle => shift );
+}
+
+sub NewItem { return TestApp::UsersToGroup->new( (shift)->_Handle ) }
+
+1;

commit 22acd4602407d85a30e00a37a54c328763e3a0ae
Author: sunnavy <sunnavy at bestpractical.com>
Date:   Mon Aug 30 04:19:13 2021 +0800

    Support bind values for searches
    
    This is mainly to reduce hard parses and help the DB
    re-use cached queries, especially Oracle. Improving
    use of cached query plans should improve performance.
    
    Provide a PREFER_BIND option to make it possible to
    disable this new feature since it has to dynamically
    evaluate and update queries and this may have
    issues on complicated queries not yet tested.

diff --git a/lib/DBIx/SearchBuilder.pm b/lib/DBIx/SearchBuilder.pm
index 2356f3b..d21ae4c 100755
--- a/lib/DBIx/SearchBuilder.pm
+++ b/lib/DBIx/SearchBuilder.pm
@@ -10,6 +10,7 @@ use Clone qw();
 use Encode qw();
 use Scalar::Util qw(blessed);
 use DBIx::SearchBuilder::Util qw/ sorted_values /;
+our $PREFER_BIND = $ENV{SB_PREFER_BIND};
 
 =head1 NAME
 
@@ -151,6 +152,8 @@ sub CleanSlate {
         group_by
         columns
         query_hint
+        _bind_values
+        _prefer_bind
     );
 
     #we have no limit statements. DoSearch won't work.
@@ -238,7 +241,7 @@ sub _DoSearch {
     delete $self->{'items'};
     $self->{'itemscount'} = 0;
 
-    my $records = $self->_Handle->SimpleQuery($QueryString);
+    my $records = $self->_Handle->SimpleQuery( $QueryString, @{ $self->{_bind_values} || [] } );
     return 0 unless $records;
 
     while ( my $row = $records->fetchrow_hashref() ) {
@@ -294,7 +297,7 @@ sub _DoCount {
     my $all  = shift || 0;
 
     my $QueryString = $self->BuildSelectCountQuery();
-    my $records     = $self->_Handle->SimpleQuery($QueryString);
+    my $records     = $self->_Handle->SimpleQuery( $QueryString, @{ $self->{_bind_values} || [] } );
     return 0 unless $records;
 
     my @row = $records->fetchrow_array();
@@ -419,10 +422,20 @@ sub _isLimited {
 
 
 
-=head2 BuildSelectQuery
+=head2 BuildSelectQuery PreferBind => 1|0
 
 Builds a query string for a "SELECT rows from Tables" statement for this SearchBuilder object
 
+If C<PreferBind> is true, the generated query will use bind variables where
+possible. If C<PreferBind> is not passed, it defaults to package variable
+C<$DBIx::SearchBuilder::PREFER_BIND>, which defaults to
+C<$ENV{SB_PREFER_BIND}>.
+
+To override global C<$DBIx::SearchBuilder::PREFER_BIND> for current object
+only, you can also set C<_prefer_bind> accordingly, e.g.
+
+    $sb->{_prefer_bind} = 1;
+
 =cut
 
 sub BuildSelectQuery {
@@ -434,6 +447,8 @@ sub BuildSelectQuery {
     $QueryString .= $self->_WhereClause . " "
       if ( $self->_isLimited > 0 );
 
+    $self->_OptimizeQuery(\$QueryString, @_);
+
     my $QueryHint = $self->QueryHintFormatted;
 
     # DISTINCT query only required for multi-table selects
@@ -461,7 +476,7 @@ sub BuildSelectQuery {
 
 
 
-=head2 BuildSelectCountQuery
+=head2 BuildSelectCountQuery PreferBind => 1|0
 
 Builds a SELECT statement to find the number of rows this SearchBuilder object would find.
 
@@ -477,7 +492,7 @@ sub BuildSelectCountQuery {
     $QueryString .= $self->_WhereClause . " "
       if ( $self->_isLimited > 0 );
 
-
+    $self->_OptimizeQuery(\$QueryString, @_);
 
     # DISTINCT query only required for multi-table selects
     if ($self->_isJoined) {
@@ -877,7 +892,7 @@ sub Limit {
                     warn "Collection in '$args{OPERATOR}' with more than one column selected, using first";
                     splice @{ $args{'VALUE'}{'columns'} }, 1;
                 }
-                $args{'VALUE'} = '('. $args{'VALUE'}->BuildSelectQuery .')';
+                $args{'VALUE'} = '('. $args{'VALUE'}->BuildSelectQuery(PreferBind => 0) .')';
                 $args{'QUOTEVALUE'} = 0;
             }
             elsif ( ref $args{'VALUE'} ) {
@@ -1870,6 +1885,22 @@ sub QueryHintFormatted {
     return $QueryHint ? " /* $QueryHint */ " : " ";
 }
 
+
+sub _OptimizeQuery {
+    my $self  = shift;
+    my $query = shift;
+
+    my %args = ( PreferBind => $self->{_prefer_bind} // $PREFER_BIND, @_ );
+
+    undef $self->{_bind_values};
+    if ( $args{PreferBind} ) {
+        ( $$query, my @bind_values ) = $self->_Handle->_ExtractBindValues($$query);
+        if (@bind_values) {
+            $self->{_bind_values} = \@bind_values;
+        }
+    }
+}
+
 =head1 DEPRECATED METHODS
 
 =head2 GroupBy
diff --git a/lib/DBIx/SearchBuilder/Handle.pm b/lib/DBIx/SearchBuilder/Handle.pm
index ed49ff7..d08faa5 100755
--- a/lib/DBIx/SearchBuilder/Handle.pm
+++ b/lib/DBIx/SearchBuilder/Handle.pm
@@ -1813,6 +1813,77 @@ sub DequoteName {
     return $name;
 }
 
+sub _ExtractBindValues {
+    my $self                = shift;
+    my $string              = shift;
+    my $default_escape_char = shift || q{'};
+    return $string unless defined $string;
+
+    my $placeholder = '';
+
+    my @chars       = split //, $string;
+    my $value       = '';
+    my $escape_char = $default_escape_char;
+
+    my @values;
+    my $in = 0;    # keep state in the loop: is it in a quote?
+    while ( defined( my $c = shift @chars ) ) {
+        my $escaped;
+        if ( $c eq $escape_char && $in ) {
+            if ( $escape_char eq q{'} ) {
+                if ( ( $chars[0] || '' ) eq q{'} ) {
+                    $c       = shift @chars;
+                    $escaped = 1;
+                }
+            }
+            else {
+                $c       = shift @chars;
+                $escaped = 1;
+            }
+        }
+
+        if ($in) {
+            if ( $c eq q{'} ) {
+                if ( !$escaped ) {
+                    push @values, $value;
+                    $in          = 0;
+                    $value       = '';
+                    $escape_char = $default_escape_char;
+                    $placeholder .= '?';
+                    next;
+                }
+            }
+            $value .= $c;
+        }
+        else {
+            if ( $c eq q{'} ) {
+                $in = 1;
+            }
+
+            # Handle quoted string like e'foo\\bar'
+            elsif ( lc $c eq 'e' && ( $chars[0] // '' ) eq q{'} ) {
+                $escape_char = '\\';
+            }
+
+            # Handle numbers
+            elsif ( $c =~ /[\d.]/ && $placeholder !~ /\w$/ ) {    # Do not catch Groups_1.Name
+                $value .= $c;
+                while ( ( $chars[0] // '' ) =~ /[\d.]/ ) {
+                    $value .= shift @chars;
+                }
+
+                push @values, $value;
+                $placeholder .= '?';
+                $value = '';
+            }
+            else {
+                $placeholder .= $c;
+            }
+        }
+    }
+    return ( $placeholder, @values );
+}
+
 sub _RequireQuotedTables { return 0 };
 
 =head2 DESTROY
diff --git a/lib/DBIx/SearchBuilder/Handle/mysql.pm b/lib/DBIx/SearchBuilder/Handle/mysql.pm
index 0e24364..7e2ae77 100755
--- a/lib/DBIx/SearchBuilder/Handle/mysql.pm
+++ b/lib/DBIx/SearchBuilder/Handle/mysql.pm
@@ -323,6 +323,12 @@ sub DequoteName {
     return $name;
 }
 
+sub _ExtractBindValues {
+    my $self  = shift;
+    my $value = shift;
+    return $self->SUPER::_ExtractBindValues( $value, '\\' );
+}
+
 sub _IsMariaDB {
     my $self = shift;
 

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

Summary of changes:
 Changes                                |   4 +
 MANIFEST                               |   1 +
 META.yml                               |   2 +-
 lib/DBIx/SearchBuilder.pm              |  45 +++-
 lib/DBIx/SearchBuilder/Handle.pm       |  71 +++++++
 lib/DBIx/SearchBuilder/Handle/mysql.pm |   6 +
 t/03searches_bind.t                    | 367 +++++++++++++++++++++++++++++++++
 7 files changed, 488 insertions(+), 8 deletions(-)
 create mode 100644 t/03searches_bind.t


hooks/post-receive
-- 
dbix-searchbuilder


More information about the Bps-public-commit mailing list