Created
July 15, 2011 02:43
-
-
Save apinstein/1083936 to your computer and use it in GitHub Desktop.
postgres table-as-queue lock experiment
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
#!/bin/bash | |
# RESULTS, feel free to repro yourself | |
# | |
# noLock FAIL | |
# accessShare FAIL | |
# rowShare FAIL | |
# rowExclusive FAIL | |
# shareUpdateExclusive SUCCESS | |
# share FAIL+DEADLOCKS | |
# shareRowExclusive SUCCESS | |
# exclusive SUCCESS | |
# accessExclusive SUCCESS, but LOCKS against pg_dump | |
#config | |
strategy="exclusive" | |
db=postgres | |
dbuser=postgres | |
queuecount=100 | |
concurrency=30 | |
# code | |
psql84 -t -U $dbuser $db -c "create table tx_test_queue (job_id serial, status text);" | |
# empty queue | |
psql84 -t -U $dbuser $db -c "truncate tx_test_queue;"; | |
echo "Simulating 10 second pg_dump with ACCESS SHARE" | |
psql84 -t -U $dbuser $db -c "lock table tx_test_queue in ACCESS SHARE mode; select pg_sleep(10); select 'pg_dump finished...'" & | |
echo "Starting workers..." | |
# queue $queuecount items | |
seq $queuecount | xargs -n 1 -P $concurrency -I {} psql84 -q -U $dbuser $db -c "insert into tx_test_queue (status) values ('queued');" | |
#psql84 -t -U $dbuser $db -c "select * from tx_test_queue order by job_id;" | |
# process $queuecount w/concurrency of $concurrency | |
case $strategy in | |
"noLock") strategySql="update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"accessShare") strategySql="lock table tx_test_queue in ACCESS SHARE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"rowShare") strategySql="lock table tx_test_queue in ROW SHARE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"rowExclusive") strategySql="lock table tx_test_queue in ROW EXCLUSIVE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"shareUpdateExclusive") strategySql="lock table tx_test_queue in SHARE UPDATE EXCLUSIVE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"share") strategySql="lock table tx_test_queue in SHARE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"shareRowExclusive") strategySql="lock table tx_test_queue in SHARE ROW EXCLUSIVE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"exclusive") strategySql="lock table tx_test_queue in EXCLUSIVE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
"accessExclusive") strategySql="lock table tx_test_queue in ACCESS EXCLUSIVE mode; update tx_test_queue set status='running{}' where job_id in (select job_id from tx_test_queue where status='queued' order by job_id asc limit 1);";; | |
*) echo "Unknown strategy $strategy";; | |
esac | |
echo $strategySql | |
seq $queuecount | xargs -n 1 -P $concurrency -I {} psql84 -U $dbuser $db -c "$strategySql" | |
#psql84 -t -U $dbuser $db -c "select * from tx_test_queue order by job_id;" | |
psql84 -U $dbuser $db -c "select count(distinct(status)) as should_output_${concurrency} from tx_test_queue;" | |
psql84 -t -U $dbuser $db -c "drop table tx_test_queue;"; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
L49:
should_output_${concurrency} -> should_output_${queuecount}
... this has just made me a little seasick :)