|
3 | 3 | # simple script to log transaction locks to a table |
4 | 4 | # assumes that you're running it as the postgres user and don't need a password |
5 | 5 |
|
| 6 | +# set interval and number of executions |
| 7 | +# interval is set in seconds |
| 8 | +# defaults to 1000 minutes once per minute |
| 9 | +# not recommended to run this more than 4X per minute |
| 10 | +INTERVAL=${1:-60} |
| 11 | +XNUMBER=${2:-1000} |
| 12 | + |
6 | 13 | # change to path of psql |
7 | | -PSQL='/usr/pgsql-9.2/bin/psql' |
| 14 | +PSQL='psql' |
8 | 15 |
|
9 | 16 | # list all databases you're targeting, space separated |
10 | | -DBNAMES='postgres mydatabase' |
| 17 | +DBNAMES='postgres flo' |
11 | 18 |
|
12 | 19 | # modify if required |
| 20 | +# statement timeout is required to keep the lock query |
| 21 | +# from hanging |
13 | 22 | DBPORT='' |
14 | 23 | DBHOST='' |
| 24 | +STATTIMEOUT=2000 |
| 25 | +SUPER="josh" |
15 | 26 |
|
16 | | -for DBNAME in $DBNAMES; do |
17 | | - $PSQL -c "SELECT log_transaction_locks();" -U postgres $DBNAME $DBPORT $DBHOST |
18 | | - $PSQL -c "SELECT log_table_locks();" -U postgres $DBNAME $DBPORT $DBHOST |
19 | | -done |
| 27 | +# output files. you shouldn't need to modify these |
| 28 | +# unless you're doing something special |
| 29 | +TABLELOG='lock_table.log' |
| 30 | +XTNLOG='lock_transaction.log' |
| 31 | + |
| 32 | +# queries; you should not need to modify these |
| 33 | +TABLEQUERY="WITH table_locks AS ( |
| 34 | + select pid, |
| 35 | + relation::int as relation, |
| 36 | + (relation::regclass)::text as locked_relation, |
| 37 | + mode, |
| 38 | + page || ':' || tuple as locked_tuple, |
| 39 | + locktype, |
| 40 | + coalesce(transactionid::text, virtualxid) as lxid, |
| 41 | + granted |
| 42 | + from pg_locks |
| 43 | + join pg_database |
| 44 | + ON pg_locks.database = pg_database.oid |
| 45 | + where relation is not null |
| 46 | + and pg_database.datname = current_database() |
| 47 | + and locktype IN ( 'relation', 'extend', 'page', 'tuple' ) |
| 48 | + ), |
| 49 | + lock_granted AS ( |
| 50 | + select * from table_locks |
| 51 | + where granted |
| 52 | + ), |
| 53 | + lock_waiting AS ( |
| 54 | + select * from table_locks |
| 55 | + where not granted |
| 56 | + ) |
| 57 | + select now() as lock_ts, |
| 58 | + current_database() as dbname, |
| 59 | + lock_waiting.pid as waiting_pid, |
| 60 | + lock_waiting.lxid as wait_xid, |
| 61 | + lock_granted.pid as locked_pid, |
| 62 | + lock_granted.lxid as locked_xid, |
| 63 | + lock_granted.locked_relation, |
| 64 | + lock_waiting.locktype as waiting_type, |
| 65 | + lock_waiting.mode as waiting_mode, |
| 66 | + lock_waiting.locked_tuple as tuple_waiting, |
| 67 | + lock_granted.locktype as locked_type, |
| 68 | + lock_granted.mode as lock_mode, |
| 69 | + lock_granted.locked_tuple as tuple_locked, |
| 70 | + waiting_proc.application_name as waiting_app, |
| 71 | + waiting_proc.client_addr as waiting_addr, |
| 72 | + waiting_proc.xact_start as waiting_xact_start, |
| 73 | + waiting_proc.query_start as waiting_query_start, |
| 74 | + waiting_proc.state_change as waiting_start, |
| 75 | + waiting_proc.query as waiting_query, |
| 76 | + locked_proc.application_name as locked_app, |
| 77 | + locked_proc.client_addr as locked_addr, |
| 78 | + locked_proc.xact_start as locked_xact_start, |
| 79 | + locked_proc.query_start as locked_query_start, |
| 80 | + locked_proc.state as locked_state, |
| 81 | + locked_proc.state_change as locked_state_start, |
| 82 | + locked_proc.query as locked_last_query |
| 83 | + from lock_waiting |
| 84 | + JOIN pg_stat_activity as waiting_proc |
| 85 | + ON lock_waiting.pid = waiting_proc.pid |
| 86 | + LEFT OUTER JOIN lock_granted |
| 87 | + ON lock_waiting.relation = lock_granted.relation |
| 88 | + LEFT OUTER JOIN pg_stat_activity as locked_proc |
| 89 | + ON lock_granted.pid = locked_proc.pid |
| 90 | + order by locked_pid, locked_relation;" |
| 91 | + |
| 92 | +XTNQUERY="WITH mylocks AS ( |
| 93 | + SELECT * FROM pg_locks |
| 94 | + WHERE locktype IN ( 'transactionid', 'virtualxid' ) |
| 95 | + ), |
| 96 | + table_locks AS ( |
| 97 | + select pid, |
| 98 | + (relation::regclass)::TEXT as lockobj, |
| 99 | + case when page is not null and tuple is not null then |
| 100 | + mode || ' on ' || page::text || ':' || tuple::text |
| 101 | + else |
| 102 | + mode |
| 103 | + end as lock_mode, |
| 104 | + locktype |
| 105 | + from mylocks |
| 106 | + join pg_database |
| 107 | + ON mylocks.database = pg_database.oid |
| 108 | + where relation is not null |
| 109 | + and pg_database.datname = current_database() |
| 110 | + order by lockobj |
| 111 | + ), |
| 112 | + locked_list AS ( |
| 113 | + select pid, |
| 114 | + array_agg(lockobj) as lock_relations, |
| 115 | + array_agg(lock_mode) as lock_modes, |
| 116 | + array_agg(locktype) as lock_types |
| 117 | + from table_locks |
| 118 | + group by pid |
| 119 | + ), |
| 120 | + txn_locks AS ( |
| 121 | + select pid, transactionid::text as lxid, granted |
| 122 | + from mylocks |
| 123 | + where locktype = 'transactionid' |
| 124 | + union all |
| 125 | + select pid, virtualxid::text as lxid, granted |
| 126 | + from mylocks |
| 127 | + where locktype = 'virtualxid' |
| 128 | + ), |
| 129 | + txn_granted AS ( |
| 130 | + select pid, lxid from txn_locks |
| 131 | + where granted |
| 132 | + ), |
| 133 | + txn_waiting AS ( |
| 134 | + select pid, lxid from txn_locks |
| 135 | + where not granted |
| 136 | + ) |
| 137 | + select now() as lock_ts, |
| 138 | + current_database() AS dbname, |
| 139 | + txn_waiting.pid as waiting_pid, |
| 140 | + txn_waiting.lxid as wait_xid, |
| 141 | + txn_granted.pid as locked_pid, |
| 142 | + waiting_proc.application_name as waiting_app, |
| 143 | + waiting_proc.client_addr as waiting_addr, |
| 144 | + waiting_proc.xact_start as waiting_xact_start, |
| 145 | + waiting_proc.query_start as waiting_query_start, |
| 146 | + waiting_proc.state_change as waiting_start, |
| 147 | + waiting_proc.query as waiting_query, |
| 148 | + locked_proc.application_name as locked_app, |
| 149 | + locked_proc.client_addr as locked_addr, |
| 150 | + locked_proc.xact_start as locked_xact_start, |
| 151 | + locked_proc.query_start as locked_query_start, |
| 152 | + locked_proc.state as locked_state, |
| 153 | + locked_proc.state_change as locked_state_start, |
| 154 | + locked_proc.query as locked_last_query, |
| 155 | + waiting_locks.lock_relations as waiting_relations, |
| 156 | + waiting_locks.lock_modes as waiting_modes, |
| 157 | + waiting_locks.lock_types as waiting_lock_types, |
| 158 | + locked_locks.lock_relations as locked_relations, |
| 159 | + locked_locks.lock_modes as locked_modes, |
| 160 | + locked_locks.lock_types as locked_lock_types |
| 161 | + from txn_waiting |
| 162 | + JOIN pg_stat_activity as waiting_proc |
| 163 | + ON txn_waiting.pid = waiting_proc.pid |
| 164 | + LEFT OUTER JOIN txn_granted |
| 165 | + ON txn_waiting.lxid = txn_granted.lxid |
| 166 | + LEFT OUTER JOIN pg_stat_activity as locked_proc |
| 167 | + ON txn_granted.pid = locked_proc.pid |
| 168 | + LEFT OUTER JOIN locked_list AS waiting_locks |
| 169 | + ON txn_waiting.pid = waiting_locks.pid |
| 170 | + LEFT OUTER JOIN locked_list AS locked_locks |
| 171 | + ON txn_granted.pid = locked_locks.pid;" |
20 | 172 |
|
21 | | -# $PSQL -c "INSERT INTO activity_log SELECT * FROM pg_stat_activity;" -U postgres $DBNAME $DBPORT $DBHOST |
| 173 | +# write headers |
| 174 | +if [ ! -f $TABLELOG ]; then |
| 175 | + echo 'lock_ts|dbname|waiting_pid|wait_xid|locked_pid|locked_xid|locked_relation|waiting_type|waiting_mode|waiting_tuple|locked_type|locked_mode|locked_tuple|waiting_app|waiting_addr|waiting_xact_start|waiting_query_start|waiting_start|waiting_query|locked_app|locked_addr|locked_xact_start|locked_query_start|locked_state|locked_state_start|locked_last_query' > $TABLELOG |
| 176 | +fi |
| 177 | + |
| 178 | +if [ ! -f XTNLOG ]; then |
| 179 | + echo 'lock_ts|dbname|waiting_pid|waiting_xid|locked_pid|waiting_app|waiting_addr|waiting_xact_start|waiting_query_start|waiting_start|waiting_query|locked_app|locked_addr|locked_xact_start|locked_query_start|locked_state|locked_state_start|locked_last_query|waiting_relations|waiting_modes|waiting_lock_types|locked_relations|locked_modes|locked_lock_types' > $XTNLOG |
| 180 | +fi |
| 181 | + |
| 182 | +for ((i=0; i<$XNUMBER; i++)); do |
| 183 | + |
| 184 | + for DBNAME in $DBNAMES; do |
| 185 | + $PSQL -A -q -t -c "SET STATEMENT_TIMEOUT=${STATTIMEOUT}; ${TABLEQUERY}" -U $SUPER $DBNAME $DBPORT $DBHOST >> $TABLELOG |
| 186 | + $PSQL -A -q -t -c "SET STATEMENT_TIMEOUT=${STATTIMEOUT}; ${XTNQUERY}" -U $SUPER $DBNAME $DBPORT $DBHOST >> $XTNLOG |
| 187 | + done |
| 188 | + |
| 189 | + if (($i%10==0)); then |
| 190 | + echo "locks polled $i times" |
| 191 | + fi |
| 192 | + |
| 193 | + sleep $INTERVAL |
| 194 | + |
| 195 | +done |
22 | 196 |
|
23 | 197 | exit 0 |
0 commit comments