[Bps-public-commit] dbix-searchbuilder branch, quote-table-names, created. 1.67-11-gf77f2b0

Aaron Trevena ast at bestpractical.com
Fri Sep 4 15:19:09 EDT 2020


The branch, quote-table-names has been created
        at  f77f2b07393142284921ee929f758274f02a2dca (commit)

- Log -----------------------------------------------------------------
commit f79ae6cbd073fe268900d557c9cd17290eda5722
Author: Aaron Trevena <aaron at aarontrevena.co.uk>
Date:   Tue Aug 25 21:16:11 2020 +0100

    Add support for automatic quoting of table names
    
    MySQL 8 adds new reserved and keywords, that will cause queries with tables or
    columns of those names to fail with syntax errors.
    https://dev.mysql.com/doc/mysqld-version-reference/en/keywords-8-0.html
    
    The new QuoteTableNames option will automatically quote tables in SQL created
    by SearchBuilder, and will enabled if MySQL version 8 is detected. New helpers
    simplify quoting table or column names.

diff --git a/lib/DBIx/SearchBuilder.pm b/lib/DBIx/SearchBuilder.pm
index 195669e..fa271b0 100755
--- a/lib/DBIx/SearchBuilder.pm
+++ b/lib/DBIx/SearchBuilder.pm
@@ -1251,6 +1251,7 @@ sub NewAlias {
 
     my $alias = $self->_GetAlias($table);
 
+    $table = $self->_Handle->QuoteName($table) if ($self->_Handle->QuoteTableNames);
     unless ( $type ) {
         push @{ $self->{'aliases'} }, "$table $alias";
     } elsif ( lc $type eq 'left' ) {
diff --git a/lib/DBIx/SearchBuilder/Handle.pm b/lib/DBIx/SearchBuilder/Handle.pm
index d0f67fc..3ca27f6 100755
--- a/lib/DBIx/SearchBuilder/Handle.pm
+++ b/lib/DBIx/SearchBuilder/Handle.pm
@@ -27,7 +27,8 @@ DBIx::SearchBuilder::Handle - Perl extension which is a generic DBI handle
                     Database => 'dbname',
                     Host => 'hostname',
                     User => 'dbuser',
-                    Password => 'dbpassword');
+                    Password => 'dbpassword' );
+
   # now $handle isa DBIx::SearchBuilder::Handle::mysql                    
  
 =head1 DESCRIPTION
@@ -50,13 +51,17 @@ sub new  {
     my $self  = {};
     bless ($self, $class);
 
+    # Enable quotes table names
+    my %args = ( QuoteTableNames => 0, @_ );
+    $self->{'QuoteTableNames'} = $args{QuoteTableNames};
+
     @{$self->{'StatementLog'}} = ();
     return $self;
 }
 
 
 
-=head2 Connect PARAMHASH: Driver, Database, Host, User, Password
+=head2 Connect PARAMHASH: Driver, Database, Host, User, Password, QuoteTableNames
 
 Takes a paramhash and connects to your DBI datasource. 
 
@@ -71,6 +76,9 @@ If you created the handle with
 and there is a DBIx::SearchBuilder::Handle::(Driver) subclass for the driver you have chosen,
 the handle will be automatically "upgraded" into that subclass.
 
+QuoteTableNames option will force all table names to be quoted if the driver subclass has a method
+for quoting implemented. The mysql subclass will detect mysql version 8 and set the flag.
+
 =cut
 
 sub Connect  {
@@ -85,6 +93,7 @@ sub Connect  {
         Password => undef,
         RequireSSL => undef,
         DisconnectHandleOnDestroy => undef,
+        QuoteTableNames => undef,
         @_
     );
 
@@ -96,6 +105,9 @@ sub Connect  {
     # So we need to explicitly call it
     $self->{'DisconnectHandleOnDestroy'} = $args{'DisconnectHandleOnDestroy'};
 
+    # Enable optional quoted table names
+    $self->{'QuoteTableNames'} = delete $args{QuoteTableNames} if (defined $args{QuoteTableNames});
+
     my $old_dsn = $self->DSN || '';
     my $new_dsn = $self->BuildDSN( %args );
 
@@ -116,6 +128,9 @@ sub Connect  {
     # Cache version info
     $self->DatabaseVersion;
 
+    # force quoted tables for mysql 8
+    $self->{'QuoteTableNames'} = 1 if ($self->_RequireQuotedTables);
+
     return 1;
 }
 
@@ -390,6 +405,7 @@ sub InsertQueryString {
         push @bind, shift @pairs;
     }
 
+    $table = $self->QuoteName($table) if ($self->QuoteTableNames);
     my $QueryString = "INSERT INTO $table";
     $QueryString .= " (". join(", ", @cols) .")";
     $QueryString .= " VALUES (". join(", ", @vals). ")";
@@ -415,6 +431,7 @@ sub InsertFromSelect {
     $columns = join ', ', @$columns
         if $columns;
 
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     my $full_query = "INSERT INTO $table";
     $full_query .= " ($columns)" if $columns;
     $full_query .= ' '. $query;
@@ -446,6 +463,7 @@ sub UpdateRecordValue {
                  @_ );
 
     my @bind  = ();
+    $args{Table} = $self->QuoteName($args{Table}) if ($self->{'QuoteTableNames'});
     my $query = 'UPDATE ' . $args{'Table'} . ' ';
      $query .= 'SET '    . $args{'Column'} . '=';
 
@@ -518,6 +536,7 @@ sub SimpleUpdateFromSelect {
         push @binds, $values->{$k};
     }
 
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     my $full_query = "UPDATE $table SET ";
     $full_query .= join ', ', map "$_ = ?", @columns;
     $full_query .= ' WHERE id IN ('. $query .')';
@@ -541,6 +560,7 @@ select query, eg:
 
 sub DeleteFromSelect {
     my ($self, $table, $query, @binds) = @_;
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     my $sth = $self->SimpleQuery(
         "DELETE FROM $table WHERE id IN ($query)",
         @binds
@@ -753,6 +773,16 @@ sub CaseSensitive {
     return(1);
 }
 
+=head2 QuoteTableNames
+
+Returns 1 if table names will be quoted in queries, otherwise 0
+
+=cut
+
+sub QuoteTableNames  {
+    return shift->{'QuoteTableNames'}
+}
+
 
 
 
@@ -1016,6 +1046,7 @@ sub Join {
             if ( $old_alias =~ /^(.*?) (\Q$args{'ALIAS2'}\E)$/ ) {
                 $args{'TABLE2'} = $1;
                 $alias = $2;
+                $args{'TABLE2'} =~ s/`//g;
             }
             else {
                 push @new_aliases, $old_alias;
@@ -1039,7 +1070,7 @@ sub Join {
                 if ( $old_alias =~ /^(.*?) ($args{'ALIAS2'})$/ ) {
                     $args{'TABLE2'} = $1;
                     $alias = $2;
-
+                    $args{'TABLE2'} =~ s/`//g;
                 }
                 else {
                     push @new_aliases, $old_alias;
@@ -1055,6 +1086,7 @@ sub Join {
             # XXX: this situation is really bug in the caller!!!
             return ( $self->_NormalJoin(%args) );
         }
+        $args{TABLE2} = $self->QuoteName($args{TABLE2}) if ($self->QuoteTableNames);
         $args{'SearchBuilder'}->{'aliases'} = \@new_aliases;
     } elsif ( $args{'COLLECTION2'} ) {
         # We're joining to a pre-limited collection.  We need to take
@@ -1062,7 +1094,9 @@ sub Join {
         # alias, apply them locally, then proceed as usual.
         my $collection = delete $args{'COLLECTION2'};
         $alias = $args{ALIAS2} = $args{'SearchBuilder'}->_GetAlias( $collection->Table );
-        $args{TABLE2} = $collection->Table;
+        my $table2 = $collection->Table;
+        $table2 = $self->QuoteName($table2) if ($self->QuoteTableNames);
+        $args{TABLE2} = $table2;
 
         eval {$collection->_ProcessRestrictions}; # RT hate
 
@@ -1087,6 +1121,7 @@ sub Join {
         $args{SearchBuilder}{restrictions}{$_} = $restrictions->{$_} for keys %{$restrictions};
     } else {
         $alias = $args{'SearchBuilder'}->_GetAlias( $args{'TABLE2'} );
+        $args{TABLE2} = $self->QuoteName($args{TABLE2}) if ($self->QuoteTableNames);
     }
 
     my $meta = $args{'SearchBuilder'}->{'left_joins'}{"$alias"} ||= {};
@@ -1161,6 +1196,7 @@ sub _NormalJoin {
     if ( $args{'TYPE'} =~ /LEFT/i ) {
         my $alias = $sb->_GetAlias( $args{'TABLE2'} );
         my $meta = $sb->{'left_joins'}{"$alias"} ||= {};
+        $args{TABLE2} = $self->QuoteName($args{TABLE2}) if ($self->QuoteTableNames);
         $meta->{'alias_string'} = " LEFT JOIN $args{'TABLE2'} $alias ";
         $meta->{'depends_on'}   = $args{'ALIAS1'};
         $meta->{'type'}         = 'LEFT';
@@ -1192,8 +1228,9 @@ sub _BuildJoins {
     my $sb   = shift;
 
     $self->OptimizeJoins( SearchBuilder => $sb );
+    my $table = ($self->{'QuoteTableNames'}) ? $self->QuoteName($sb->Table) : $sb->Table;
 
-    my $join_clause = join " CROSS JOIN ", ($sb->Table ." main"), @{ $sb->{'aliases'} };
+    my $join_clause = join " CROSS JOIN ", ("$table main"), @{ $sb->{'aliases'} };
     my %processed = map { /^\S+\s+(\S+)$/; $1 => 1 } @{ $sb->{'aliases'} };
     $processed{'main'} = 1;
 
@@ -1449,12 +1486,16 @@ sub DistinctCount {
 
 sub Fields {
     my $self  = shift;
-    my $table = lc shift;
+    my $tablename = shift;
+    my $table = lc $tablename;
 
     unless ( $FIELDS_IN_TABLE{$table} ) {
         $FIELDS_IN_TABLE{ $table } = [];
-        my $sth = $self->dbh->column_info( undef, '', $table, '%' )
-            or return ();
+        my $sth = $self->dbh->column_info( undef, '', $tablename, '%' );
+        unless ($sth) {
+            warn "couldn't get column info for $tablename / $table " . $sth->errstr;
+            return ();
+        }
         my $info = $sth->fetchall_arrayref({});
         foreach my $e ( @$info ) {
             push @{ $FIELDS_IN_TABLE{ $table } }, $e->{'COLUMN_NAME'};
@@ -1738,6 +1779,27 @@ sub HasSupportForNullsOrder {
 }
 
 
+=head2 QuoteName
+
+Quote table or column name to avoid reserved word errors.
+
+Returns same value passed unless over-ridden in database-specific subclass.
+
+=cut
+
+# over-ride in subclass
+sub QuoteName {
+    my ($self, $name) = @_;
+    # use dbi built in quoting if we have a connection,
+    if ($self->dbh) {
+        return $self->dbh->quote_identifier($name);
+    }
+    warn "QuoteName called without a db handle";
+    return $name;
+}
+
+sub _RequireQuotedTables { return 0 };
+
 =head2 DESTROY
 
 When we get rid of the Searchbuilder::Handle, we need to disconnect from the database
diff --git a/lib/DBIx/SearchBuilder/Handle/mysql.pm b/lib/DBIx/SearchBuilder/Handle/mysql.pm
index a0302aa..e884d03 100755
--- a/lib/DBIx/SearchBuilder/Handle/mysql.pm
+++ b/lib/DBIx/SearchBuilder/Handle/mysql.pm
@@ -74,6 +74,7 @@ sub SimpleUpdateFromSelect {
         push @binds, $values->{$k};
     }
 
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     my $update_query = "UPDATE $table SET "
         . join( ', ', map "$_ = ?", @columns )
         .' WHERE ID IN ';
@@ -92,6 +93,7 @@ sub DeleteFromSelect {
         $table, $query, @query_binds
     ) unless $query =~ /\b\Q$table\E\b/i;
 
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     return $self->SimpleMassChangeFromSelect(
         "DELETE FROM $table WHERE id IN ", [],
         $query, @query_binds
@@ -206,6 +208,7 @@ sub Fields {
     my $table = shift;
 
     my $cache = \%DBIx::SearchBuilder::Handle::FIELDS_IN_TABLE;
+    $table = $self->QuoteName($table) if ($self->{'QuoteTableNames'});
     unless ( $cache->{ lc $table } ) {
         my $sth = $self->dbh->column_info( undef, undef, $table, '%' )
             or return ();
@@ -289,6 +292,33 @@ sub _DateTimeIntervalFunction {
     return "TIMESTAMPDIFF(SECOND, $args{'From'}, $args{'To'})";
 }
 
+
+=head2 QuoteName
+
+Quote table or column name to avoid reserved word errors.
+
+=cut
+
+# over-rides inherited method
+sub QuoteName {
+    my ($self, $name) = @_;
+    # use dbi built in quoting if we have a connection,
+    if ($self->dbh) {
+        return $self->dbh->quote_identifier($name);
+    }
+
+    return sprintf('`%s`', $name);
+}
+
+
+sub _RequireQuotedTables {
+    my $self = shift;
+    if ( substr($self->DatabaseVersion, 0, 1) == 8 ) {
+        return 1;
+    }
+    return 0;
+}
+
 1;
 
 __END__
diff --git a/lib/DBIx/SearchBuilder/Record.pm b/lib/DBIx/SearchBuilder/Record.pm
index c1428d0..5de18d0 100755
--- a/lib/DBIx/SearchBuilder/Record.pm
+++ b/lib/DBIx/SearchBuilder/Record.pm
@@ -709,7 +709,7 @@ sub __Value {
     my %pk = $self->PrimaryKeys;
     return undef if grep !defined, values %pk;
 
-    my $query = "SELECT $field FROM ". $self->Table
+    my $query = "SELECT $field FROM ". $self->QuotedTableName
         ." WHERE ". join " AND ", map "$_ = ?", sort keys %pk;
     my $sth = $self->_Handle->SimpleQuery( $query, sorted_values(%pk) ) or return undef;
     return $self->{'values'}{$field} = ($sth->fetchrow_array)[0];
@@ -1147,8 +1147,8 @@ sub LoadByCols  {
 
 	}
     }
-    
-    my $QueryString = "SELECT  * FROM ".$self->Table." WHERE ". 
+
+    my $QueryString = "SELECT  * FROM ".$self->QuotedTableName." WHERE ".
     join(' AND ', @phrases) ;
     return ($self->_LoadFromSQL($QueryString, @bind));
 }
@@ -1349,7 +1349,7 @@ sub __Delete {
     }
 
     $where =~ s/AND\s$//;
-    my $QueryString = "DELETE FROM ". $self->Table . ' ' . $where;
+    my $QueryString = "DELETE FROM ". $self->QuotedTableName . ' ' . $where;
    my $return = $self->_Handle->SimpleQuery($QueryString, @bind);
 
     if (UNIVERSAL::isa($return, 'Class::ReturnValue')) {
@@ -1369,8 +1369,6 @@ Returns or sets the name of the current Table
 
 =cut
 
-
-
 sub Table {
     my $self = shift;
     if (@_) {
@@ -1379,7 +1377,23 @@ sub Table {
     return ($self->{'table'});
 }
 
+=head2 QuotedTableName
+
+Returns the name of current Table, or the table provided as an argument, including any quoting
+ based on yje Handle's QuoteTableNames flag and driver method.
 
+=cut
+
+sub QuotedTableName {
+    my ($self, $name) = @_;
+    unless ($name) {
+        return $self->{'_quoted_table'} if (defined $self->{'_quoted_table'});
+        $self->{'_quoted_table'} = ( $self->_Handle->QuoteTableNames ) ?
+            $self->_Handle->QuoteName($self->Table) : $self->Table ;
+        return $self->{'_quoted_table'}
+    }
+    return ( $self->_Handle->QuoteTableNames ) ? $self->_Handle->QuoteName($name) : $name ;
+}
 
 =head2 _Handle
 

commit a5ea8fe7d11ac1be096c375e883fa3fbfc599ef9
Author: Aaron Trevena <ast at bestpractical.com>
Date:   Thu Aug 27 21:06:37 2020 +0100

    Update tests for mysql 8 and table quoting option
    
    Update tests to work with mysql 8 reserved words.
    Add host/port ENV var options for testing database

diff --git a/t/02searches_function.t b/t/02searches_function.t
index 2fd6e7e..51069ed 100644
--- a/t/02searches_function.t
+++ b/t/02searches_function.t
@@ -168,7 +168,7 @@ CREATE TEMPORARY TABLE UsersToGroups (
     GroupId integer
 ) },
 q{
-CREATE TEMPORARY TABLE Groups (
+CREATE TEMPORARY TABLE `Groups` (
     id integer primary key AUTO_INCREMENT,
     Name varchar(36)
 ) },
diff --git a/t/02searches_joins.t b/t/02searches_joins.t
index 1661f2b..1743ba8 100644
--- a/t/02searches_joins.t
+++ b/t/02searches_joins.t
@@ -19,7 +19,6 @@ SKIP: {
     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');
@@ -296,7 +295,6 @@ diag "mixing DISTINCT" if $ENV{'TEST_VERBOSE'};
     cleanup_schema( 'TestApp', $handle );
 
 }} # SKIP, foreach blocks
-
 1;
 
 
@@ -336,7 +334,7 @@ CREATE TEMPORARY TABLE UsersToGroups (
     GroupId integer
 ) },
 q{
-CREATE TEMPORARY TABLE Groups (
+CREATE TEMPORARY TABLE `Groups` (
     id integer primary key AUTO_INCREMENT,
     Name varchar(36)
 ) },
diff --git a/t/03cud_from_select.t b/t/03cud_from_select.t
index 7f5d21b..7c7974a 100644
--- a/t/03cud_from_select.t
+++ b/t/03cud_from_select.t
@@ -20,6 +20,7 @@ SKIP: {
         skip "ENV is not defined for driver '$d'", TESTS_PER_DRIVER;
     }
 
+    my $groups_table = ($d eq 'mysql') ? '`Groups`' : 'Groups';
     my $handle = get_handle( $d );
     connect_handle( $handle );
     isa_ok($handle->dbh, 'DBI::db');
@@ -50,7 +51,7 @@ diag "insert into table from two tables" if $ENV{'TEST_VERBOSE'};
 {
     my $res = $handle->InsertFromSelect(
         'UsersToGroups' => ['UserId', 'GroupId'],
-        'SELECT u.id as col1, g.id as col2 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_table g WHERE u.Login LIKE ? AND g.Name = ?",
         '%a%', 'Support'
     );
     is( $res, 2 );
@@ -113,7 +114,7 @@ diag "insert into table from two tables" if $ENV{'TEST_VERBOSE'};
         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 = ?',
+            "SELECT u.id, g.id FROM Users u, $groups_table g WHERE u.Login LIKE ? AND g.Name = ?",
             '%a%', 'Support'
         );
     };
@@ -172,7 +173,7 @@ CREATE TABLE UsersToGroups (
     GroupId integer
 ) },
 q{
-CREATE TEMPORARY TABLE Groups (
+CREATE TEMPORARY TABLE `Groups` (
     id integer primary key AUTO_INCREMENT,
     Name varchar(36)
 ) },
diff --git a/t/11schema_records.t b/t/11schema_records.t
index 4fc4dc4..06e650a 100644
--- a/t/11schema_records.t
+++ b/t/11schema_records.t
@@ -8,7 +8,7 @@ use Test::More;
 BEGIN { require "t/utils.pl" }
 our (@AvailableDrivers);
 
-use constant TESTS_PER_DRIVER => 63;
+use constant TESTS_PER_DRIVER => 66;
 
 my $total = scalar(@AvailableDrivers) * TESTS_PER_DRIVER;
 plan tests => $total;
@@ -180,7 +180,13 @@ SKIP: {
 	    is($phone_collection->Next, undef);
 	}
 	
-	
+	ok($phone3->Delete, "Deleted phone $p3_id");
+
+        my $group = TestApp::Group->new($handle);
+        my $g_id = $group->Create( Name => 'Employees' );
+        ok($g_id, "Got an id for the new group: $g_id");
+        $group->Load($g_id);
+        is($group->id, $g_id, "loaded group ok");
 
 	cleanup_schema( 'TestApp', $handle );
 }} # SKIP, foreach blocks
@@ -201,6 +207,10 @@ CREATE TABLE Phones (
 	id integer primary key,
 	Employee integer NOT NULL,
 	Phone varchar(18)
+) },
+q{CREATE TABLE Groups (
+	id integer primary key,
+	Name varchar(36)
 ) }
 ]
 }
@@ -217,7 +227,12 @@ CREATE TEMPORARY TABLE Phones (
 	Employee integer NOT NULL,
 	Phone varchar(18)
 )
-} ]
+},
+q{CREATE TEMPORARY TABLE `Groups` (
+	id integer AUTO_INCREMENT primary key,
+	Name varchar(36)
+) }
+]
 }
 
 sub schema_pg {
@@ -232,7 +247,12 @@ CREATE TEMPORARY TABLE Phones (
 	Employee integer references Employees(id),
 	Phone varchar
 )
-} ]
+},
+q{CREATE TEMPORARY TABLE Groups (
+	id serial primary key,
+	Name varchar
+) }
+]
 }
 
 package TestApp::Employee;
@@ -292,4 +312,35 @@ sub NewItem {
 }
 
 
+package TestApp::Group;
+
+use base $ENV{SB_TEST_CACHABLE}?
+    qw/DBIx::SearchBuilder::Record::Cachable/:
+    qw/DBIx::SearchBuilder::Record/;
+
+sub Table { 'Groups' }
+
+sub Schema {
+    return {
+        Name => { TYPE => 'varchar' },
+    }
+}
+
+package TestApp::GroupCollection;
+
+use base qw/DBIx::SearchBuilder/;
+
+sub Table {
+    my $self = shift;
+    my $tab = $self->NewItem->Table();
+    return $tab;
+}
+
+sub NewItem {
+    my $self = shift;
+    my $class = 'TestApp::Group';
+    return $class->new( $self->_Handle );
+
+}
+
 1;
diff --git a/t/utils.pl b/t/utils.pl
index b662034..7f99ba2 100644
--- a/t/utils.pl
+++ b/t/utils.pl
@@ -110,6 +110,8 @@ sub connect_mysql
 	return $handle->Connect(
 		Driver => 'mysql',
 		Database => $ENV{'SB_TEST_MYSQL'},
+                Host => $ENV{'SB_TEST_MYSQL_HOST'},
+                Port => $ENV{'SB_TEST_MYSQL_PORT'},
 		User => $ENV{'SB_TEST_MYSQL_USER'} || 'root',
 		Password => $ENV{'SB_TEST_MYSQL_PASS'} || '',
 	);

commit f77f2b07393142284921ee929f758274f02a2dca
Author: Aaron Trevena <ast at bestpractical.com>
Date:   Thu Aug 27 21:16:03 2020 +0100

    Update Changes with quoted table names update

diff --git a/Changes b/Changes
index bed91f1..a230dd9 100644
--- a/Changes
+++ b/Changes
@@ -1,5 +1,7 @@
 Revision history for Perl extension DBIx::SearchBuilder.
 
+ - New option to quote tablenames, initially for MySQL
+
 1.68 2020-07-06
  - Avoid segmentation faults on disconnect on MariaDB 10.2+
 

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


More information about the Bps-public-commit mailing list