Skip to content

Commit

Permalink
impl insert_multi
Browse files Browse the repository at this point in the history
  • Loading branch information
xaicron committed May 14, 2012
1 parent 360488b commit 40a3c2a
Show file tree
Hide file tree
Showing 4 changed files with 359 additions and 0 deletions.
170 changes: 170 additions & 0 deletions lib/SQL/Format.pm
Expand Up @@ -790,6 +790,74 @@ sub delete {
sqlf($format, @args);
}

sub insert_multi {
my ($self, $table, $cols, $values, $opts) = @_;
croak 'Usage: $sqlf->insert_multi($table, \@cols, [ \@values1, \@values2, ... ] [, \%opts])'
unless ref $cols eq 'ARRAY' && ref $values eq 'ARRAY';

local $SELF = $self;
local $DELIMITER = $self->{delimiter};
local $NAME_SEP = $self->{name_sep};
local $QUOTE_CHAR = $self->{quote_char};
local $LIMIT_DIALECT = $self->{limit_dialect};

my $prefix = $opts->{prefix} || 'INSERT INTO';
my $quoted_table = _quote($table);

my $columns_num = @$cols;
my @bind_params;
my @values_stmt;
for my $value (@$values) {
my @bind_cols;
for (my $i = 0; $i < $columns_num; $i++) {
my $val = $value->[$i];
if (ref $val eq 'SCALAR') {
# \'NOW()'
push @bind_cols, $$val;
}
elsif (ref $val eq 'REF' && ref $$val eq 'ARRAY') {
# \['UNIX_TIMESTAMP(?)', '2011-11-11 11:11:11']
my ($expr, @sub_bind) = @{$$val};
push @bind_cols, $expr;
push @bind_params, @sub_bind;
}
else {
# 'baz'
push @bind_cols, '?';
push @bind_params, $val;
}
}
push @values_stmt, '('.join($self->{delimiter}, @bind_cols).')';
}

my $stmt = "$prefix $quoted_table "
. '('.join($self->{delimiter}, map { _quote($_) } @$cols).') '
. 'VALUES '.join($self->{delimiter}, @values_stmt);

if ($opts->{update}) {
my ($update_stmt, @bind) = sqlf '%s', $opts->{update};
$stmt .= " ON DUPLICATE KEY UPDATE $update_stmt";
push @bind_params, @bind;
}

return $stmt, @bind_params;
}

sub insert_multi_from_hash {
my ($self, $table, $values, $opts) = @_;
croak 'Usage: $sqlf->insert_multi_from_hash($table, [ { colA => $valA, colB => $valB }, { ... } ] [, \%opts])'
unless ref $values eq 'ARRAY' && ref $values->[0] eq 'HASH';

my $cols = [ keys %{$values->[0]} ];
my $new_values = [];
for my $value (@$values) {
push @$new_values, [ @$value{@$cols} ];
}

$self->insert_multi($table, $cols, $new_values, $opts);
}


1;
__END__
Expand Down Expand Up @@ -1332,6 +1400,108 @@ See also C<< %o >> format.
=back
=head2 insert_multi($table, \@cols, \@values [, \%opts])
This method returns SQL string and bind parameters for bulk insert.
my ($stmt, @bind) = $self->insert_multi(
foo => [qw/bar baz/],
[
[qw/hoge fuga/],
[qw/fizz buzz/],
],
);
# $stmt: INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)
# @bind: (qw/hoge fuga fizz buzz/)
Argument details are:
=over
=item $table
This is a table name for target of INSERT.
=item \@cols
This is a columns for target of INSERT.
=item \@values
This is a values parameters. Must be ARRAY within ARRAY.
my ($stmt, @bind) = $sqlf->insert_multi(
foo => [qw/bar baz/], [
[qw/foo bar/],
[\'NOW()', \['UNIX_TIMESTAMP(?)', '2012-12-12 12:12:12'] ],
],
);
# $stmt: INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (NOW(), UNIX_TIMESTAMP(?))
# @bind: (qw/foo bar/, '2012-12-12 12:12:12')
=item \%opts
=over
=item $opts->{prefix}
This is a prefix for INSERT statement.
my ($stmt, @bind) = $sqlf->insert_multi(..., { prefix => 'INSERT IGNORE INTO' });
# $stmt: INSERT IGNORE INTO ...
Default value is C<< INSERT INTO >>.
=item $opts->{update}
Some as C<< %s >> format.
If this value specified then add C<< ON DUPLICATE KEY UPDATE >> statement.
my ($stmt, @bind) = $sqlf->insert_multi(
foo => [qw/bar baz/],
[
[qw/hoge fuga/],
[qw/fizz buzz/],
],
{ update => { bar => 'piyo' } },
);
# $stmt: INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?) ON DUPLICATE KEY UPDATE `bar` = ?
# @bind: (qw/hoge fuga fizz buzz piyo/)
=back
=back
=head2 insert_multi_from_hash($table, \@values [, \%opts])
This method is a wrapper for C<< insert_multi() >>.
Argument dialects are:
=over
=item $table
Same as C<< insert_multi() >>
=item \@values
This is a values parameters. Must be HASH within ARRAY.
my ($stmt, @bind) = $sqlf->insert_multi_from_hash(foo => [
{ bar => 'hoge', baz => 'fuga' },
{ bar => 'fizz', baz => 'buzz' },
]);
# $stmt: INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)
# @bind: (qw/hoge fuga fizz buzz/)
=item \%opts
Same as C<< insert_multi() >>
=back
=head1 AUTHOR
xaicron E<lt>xaicron {at} cpan.orgE<gt>
Expand Down
70 changes: 70 additions & 0 deletions t/70_insert_multi.t
@@ -0,0 +1,70 @@
use strict;
use warnings;
use t::Util;
use Test::More;

my $test = mk_test 'insert_multi';

$test->(
desc => 'basic',
input => [
foo => [qw/bar baz/],
[ [qw/hoge fuga/], [qw/fizz buzz/] ],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/],
},
);

$test->(
desc => 'mismatch params',
input => [
foo => [qw/bar baz/],
[ [qw/hoge fuga/], [qw/fizz buzz fizzbuzz/], [qw//] ],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/, undef, undef],
},
);

$test->(
desc => 'complex',
input => [
foo => [qw/bar baz/],
[ ['hoge', \'NOW()'], ['fuga', \['UNIX_TIMESTAMP(?)', '2012-12-12'] ] ],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, NOW()), (?, UNIX_TIMESTAMP(?))',
bind => [qw/hoge fuga 2012-12-12/],
},
);

$test->(
desc => 'insert ignore',
input => [
foo => [qw/bar baz/],
[ [qw/hoge fuga/], [qw/fizz buzz/] ],
{ prefix => 'INSERT IGNORE INTO' },
],
expects => {
stmt => 'INSERT IGNORE INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/],
},
);

$test->(
desc => 'on duplicate key update',
input => [
foo => [qw/bar baz/],
[ [qw/hoge fuga/], [qw/fizz buzz/] ],
{ update => { bar => 'piyo' } },
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?) ON DUPLICATE KEY UPDATE `bar` = ?',
bind => [qw/hoge fuga fizz buzz piyo/],
},
);

done_testing;
81 changes: 81 additions & 0 deletions t/71_insert_multi_from_hash.t
@@ -0,0 +1,81 @@
use strict;
use warnings;
use t::Util;
use Test::More;

my $test = mk_test 'insert_multi_from_hash';

$test->(
desc => 'basic',
input => [
foo => [
{ bar => 'hoge', baz => 'fuga' },
{ bar => 'fizz', baz => 'buzz' },
],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/],
},
);

$test->(
desc => 'mismatch params',
input => [
foo => [
{ bar => 'hoge', baz => 'fuga' },
{ bar => 'fizz', baz => 'buzz', xxx => 'yyy' },
{ },
],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/, undef, undef],
},
);

$test->(
desc => 'complex',
input => [
foo => [
{ bar => 'hoge', baz => \'NOW()' },
{ bar => 'fuga', baz => \['UNIX_TIMESTAMP(?)', '2012-12-12'] },
],
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, NOW()), (?, UNIX_TIMESTAMP(?))',
bind => [qw/hoge fuga 2012-12-12/],
},
);

$test->(
desc => 'insert ignore',
input => [
foo => [
{ bar => 'hoge', baz => 'fuga' },
{ bar => 'fizz', baz => 'buzz' },
],
{ prefix => 'INSERT IGNORE INTO' },
],
expects => {
stmt => 'INSERT IGNORE INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?)',
bind => [qw/hoge fuga fizz buzz/],
},
);

$test->(
desc => 'on duplicate key update',
input => [
foo => [
{ bar => 'hoge', baz => 'fuga' },
{ bar => 'fizz', baz => 'buzz' },
],
{ update => { bar => 'piyo' } },
],
expects => {
stmt => 'INSERT INTO `foo` (`bar`, `baz`) VALUES (?, ?), (?, ?) ON DUPLICATE KEY UPDATE `bar` = ?',
bind => [qw/hoge fuga fizz buzz piyo/],
},
);

done_testing;
38 changes: 38 additions & 0 deletions t/79_insert_multi_exception.t
@@ -0,0 +1,38 @@
use strict;
use warnings;
use Test::More;

use SQL::Format;

my $f = SQL::Format->new;
subtest 'insert_multi no args' => sub {
eval { $f->insert_multi };
like $@, qr/Usage: \$sqlf->insert_multi\(/;
};

subtest 'insert_multi cols is not array' => sub {
eval { $f->insert_multi(foo => {}) };
like $@, qr/Usage: \$sqlf->insert_multi\(/;
};

subtest 'insert_multi values is not array' => sub {
eval { $f->insert_multi(foo => [qw/bar baz/], {}) };
like $@, qr/Usage: \$sqlf->insert_multi\(/;
};

subtest 'insert_multi_from_hash no args' => sub {
eval { $f->insert_multi_from_hash };
like $@, qr/Usage: \$sqlf->insert_multi_from_hash\(/;
};

subtest 'insert_multi_from_hash values is not array' => sub {
eval { $f->insert_multi_from_hash(foo => {}) };
like $@, qr/Usage: \$sqlf->insert_multi_from_hash\(/;
};

subtest 'insert_multi_from_hash values is not array in hash' => sub {
eval { $f->insert_multi_from_hash(foo => [[]]) };
like $@, qr/Usage: \$sqlf->insert_multi_from_hash\(/;
};

done_testing;

0 comments on commit 40a3c2a

Please sign in to comment.