Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
19 changes: 17 additions & 2 deletions lib/SQL/Abstract/Plugin/InsertMulti.pm
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,8 @@ use warnings;

our $VERSION = '0.05';

my $alias = 'new';

use Carp ();
use Sub::Exporter -setup => +{
into => 'SQL::Abstract',
Expand Down Expand Up @@ -141,6 +143,9 @@ sub _insert_multi_values {
);
}

if ($opts->{use_alias}) {
$sql .= " " . $self->_sqlcase('as') . ' ' . $alias;
}
$sql .=
$self->_sqlcase(' on duplicate key update ') . join( ', ', @set );
}
Expand Down Expand Up @@ -176,10 +181,10 @@ sub update_multi {
if ($opts->{update_ignore_fields}) {
@ignore{@{$opts->{update_ignore_fields}}} = map { 1 } @{$opts->{update_ignore_fields}};
}

$opts->{update} = +{
map {
my ( $k, $v ) = ( $_, $self->_sqlcase('values( ') . $_ . ' )' );
my ( $k, $v ) = ($opts->{use_alias}) ? ($_, "$alias.$_") : ( $_, $self->_sqlcase('values( ') . $_ . ' )' );
( $k, \$v );
}
grep { !exists $ignore{$_} }
Expand Down Expand Up @@ -252,6 +257,16 @@ given update_ignore_fields,
# $stmt = q|INSERT INTO foo( a, b, c ) VALUES ( ?, ?, ? ), ( ?, ?, ? ) ON DUPLICATE KEY UPDATE a = VALUES( a )|
# @bind = (1, 2, 3, 4, 5, 6);

=item use_alias

Use an alias for rows in 'ON DUPLICATE KEY UPDATE' instead of VALUES() function.
The use of VALUES() to refer to new rows and columns has been deprecated beginning with MySQL 8.0.20.
On the other hand, an alias can be used since MySQL 8.0.19.

my ($stmt, @bind) = $sql->update_multi('foo', [qw/a b c/], [ [ 1, 2, 3 ], [ 4, 5, 6 ] ], +{ use_alias => 1 });
# $stmt = q|INSERT INTO foo( a, b, c ) VALUES ( ?, ?, ? ), ( ?, ?, ? ) AS new ON DUPLICATE KEY UPDATE a = new.a, b = new.b, c = new.c|
# @bind = (1, 2, 3, 4, 5, 6);

=back

=head2 insert_multi($table, \@field, \@data, \%opts)
Expand Down
31 changes: 31 additions & 0 deletions t/02_insert_multi.t
Original file line number Diff line number Diff line change
Expand Up @@ -219,6 +219,37 @@ subtest "update_multi" => sub {
], 'update_multi bind test with update_ignore_fields option');
};

subtest "HASHREF list with use_alias option" => sub {
my $sql = SQL::Abstract->new;
my $now = time;

my ($stmt, @bind) = $sql->update_multi(
'app_data',
[
+{ app_id => 1, guid => 1, name => 'score', value => 100, created_on => \'NOW()', updated_on => \'NOW()', },
+{ app_id => 1, guid => 1, name => 'last_login', value => \'UNIX_TIMESTAMP()', created_on => \'NOW()', updated_on => \'NOW()', },
+{ app_id => 1, guid => 2, name => 'score', value => 200, created_on => \'NOW()', updated_on => \'NOW()', },
+{ app_id => 1, guid => 2, name => 'last_login', value => $now, created_on => \'NOW()', updated_on => \'NOW()', }
],
+{ use_alias => 1, }
);

is(
$stmt,
q|INSERT INTO app_data ( app_id, created_on, guid, name, updated_on, value ) |
. q|VALUES ( ?, NOW(), ?, ?, NOW(), ? ), ( ?, NOW(), ?, ?, NOW(), UNIX_TIMESTAMP() ), ( ?, NOW(), ?, ?, NOW(), ? ), ( ?, NOW(), ?, ?, NOW(), ? ) |
. q|AS new |
. q|ON DUPLICATE KEY UPDATE app_id = new.app_id, created_on = new.created_on, guid = new.guid, name = new.name, updated_on = new.updated_on, value = new.value|,
'update_multi statement test'
);
is_deeply(\@bind, [
1, 1, 'score', 100,
1, 1, 'last_login',
1, 2, 'score', 200,
1, 2, 'last_login', $now,
], 'update_multi bind test with use_alias option');
};

subtest "ARRAYREFREF will be thrown" => sub {
my $sql = SQL::Abstract->new;

Expand Down