Skip to content

Commit 76a860e

Browse files
committed
Handle simultaneous inserts of addresses by concurrent sessions.
Use a retry strategy with a plpgsql exception handler for PK violations, or the INSERT... ON CONFLICT.. construct with postgres 9.5 and newer.
1 parent 7af8017 commit 76a860e

File tree

1 file changed

+65
-9
lines changed

1 file changed

+65
-9
lines changed

script/manitou-mdx

+65-9
Original file line numberDiff line numberDiff line change
@@ -358,9 +358,35 @@ sub min {
358358

359359
sub db_reconnect {
360360
db_connect();
361+
create_db_temp_functions();
361362
notice_log("Successful database reconnect");
362363
}
363364

365+
sub create_db_temp_functions {
366+
# Insert a new email address, handling a potential concurrent session that
367+
# has inserted the same address and not yet committed.
368+
# Called only with PG 9.4 and older, otherwise INSERT...ON CONFLICT is used.
369+
my $r = $dbh->do(q{
370+
CREATE FUNCTION pg_temp.insert_address(in_email text, in_name text) returns integer as $$
371+
DECLARE
372+
v_addr_id int;
373+
BEGIN
374+
BEGIN
375+
INSERT INTO addresses(addr_id,email_addr,name,last_recv_from,nb_recv_from)
376+
VALUES(nextval('seq_addr_id'), in_email, in_name, now(), 1)
377+
RETURNING addr_id
378+
INTO v_addr_id;
379+
380+
EXCEPTION WHEN unique_violation THEN
381+
SELECT addr_id FROM addresses WHERE email_addr=in_email
382+
INTO v_addr_id;
383+
END;
384+
385+
RETURN v_addr_id;
386+
END $$ language plpgsql;
387+
});
388+
389+
}
364390

365391
# Extract one message from a mailbox and copy it into a temporary file
366392
# The first line may be ^From_ but it may also be the next line
@@ -505,6 +531,7 @@ sub main_multi {
505531
}
506532
}
507533

534+
create_db_temp_functions();
508535

509536
if (defined($mailbox_file)) {
510537
my $mail_cnt=0;
@@ -1452,9 +1479,28 @@ sub insert_addresses {
14521479
# scenario.
14531480
my $do_update_addr_last = getconf_bool("update_addresses_last", $mbox_name);
14541481

1455-
my $sth = $dbh->prepare("SELECT addr_id,recv_pri FROM addresses WHERE email_addr=?") or die $dbh->errstr;
1482+
my $sth = $dbh->prepare("SELECT addr_id,recv_pri FROM addresses WHERE email_addr=?")
1483+
or die $dbh->errstr;
14561484

1457-
my $sth_insert_ad = $dbh->prepare("INSERT INTO addresses(addr_id,email_addr,name) VALUES(nextval('seq_addr_id'),?,?) RETURNING addr_id") or die $dbh->errstr;
1485+
my $ins_query;
1486+
1487+
if ($dbh->{pg_server_version} < 90500) {
1488+
# use plpgsql function for potentially concurrent inserts
1489+
$ins_query = "select pg_temp.insert_address(?,?)";
1490+
}
1491+
else {
1492+
# use the ON CONFLICT mechanism of PG 9.5+ to handle the case of an address
1493+
# inserted but not yet committed by another transaction
1494+
$ins_query = qq{
1495+
INSERT INTO addresses(addr_id,email_addr,name)
1496+
VALUES(nextval('seq_addr_id'), ?, ?)
1497+
ON CONFLICT (email_addr)
1498+
DO NOTHING
1499+
RETURNING addr_id
1500+
};
1501+
}
1502+
1503+
my $sth_insert_ad = $dbh->prepare($ins_query);
14581504

14591505
# Collect all addresses, for all address types (from,to,cc...)
14601506
for my $addrtype (keys %AddrTypes) {
@@ -1483,13 +1529,23 @@ sub insert_addresses {
14831529
# Insert the addresses following the alphabetical order of email to suppress the risk
14841530
# of deadlocks with other parallel inserts
14851531
for my $addr (sort { $a->{email} cmp $b->{email} } @haddr) {
1486-
$sth->execute($addr->{email});
1487-
my ($id,$addr_pri) = $sth->fetchrow_array;
1488-
if (!$id) {
1489-
$sth_insert_ad->execute(substr($addr->{email},0,300),
1490-
substr($addr->{name},0,300));
1491-
($id) = $sth_insert_ad->fetchrow_array;
1492-
}
1532+
my ($id,$addr_pri);
1533+
do { # retry inserts
1534+
$sth->execute($addr->{email});
1535+
($id, $addr_pri) = $sth->fetchrow_array;
1536+
if (!$id) {
1537+
$sth_insert_ad->execute($addr->{email}, $addr->{name});
1538+
($id) = $sth_insert_ad->fetchrow_array;
1539+
}
1540+
# if $id is not set, the row was not inserrted
1541+
# Either the other session blocking us from inserting
1542+
# has committed or rolled back. In both cases, we need
1543+
# to retry the select and insert.
1544+
# In the worst case, we loop until no other session blocks us,
1545+
# and we can either read the addr_id assigned to this address by
1546+
# another session, or having our own session insert it.
1547+
} while (!$id);
1548+
14931549
$addr->{addr_id} = $id;
14941550
$addr->{prio} = $addr_pri;
14951551
# update addresses.last_recv_from

0 commit comments

Comments
 (0)