Skip to content

Commit b80a11b

Browse files
author
Adam Tal
committed
Explain query
1 parent 8dea354 commit b80a11b

File tree

4 files changed

+126
-5
lines changed

4 files changed

+126
-5
lines changed

Diff for: .gitignore

+2
Original file line numberDiff line numberDiff line change
@@ -1,2 +1,4 @@
11
.idea/*
22
venv/*
3+
example.txt
4+

Diff for: explain_query_locks.py

+123
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,123 @@
1+
import argparse
2+
3+
import psycopg2
4+
from prettytable import PrettyTable
5+
6+
LOCK_CHECK_QUERY = """
7+
SELECT l.relation,
8+
c.relname,
9+
l.mode
10+
FROM pg_locks l
11+
JOIN pg_class c ON c.oid=l.relation
12+
JOIN pg_stat_activity a on l.pid = a.pid
13+
AND a.query NOT ILIKE '%pg_stat_activity%'
14+
ORDER BY l.relation ASC;
15+
"""
16+
17+
RELATION_ID = 'Relation ID'
18+
RELATION_NAME = 'Relation Name'
19+
LOCK_TYPE = 'Lock Type'
20+
21+
22+
def main(
23+
user: str,
24+
password: str,
25+
host: str,
26+
port: str,
27+
database: str,
28+
query: str,
29+
):
30+
"""Execute and rollback a query to see what locks it will take"""
31+
32+
# Create a DB connection that will "stage" but not commit the DB change
33+
connection_for_schema_change = psycopg2.connect(
34+
user=user,
35+
password=password,
36+
host=host,
37+
port=port,
38+
database=database,
39+
)
40+
connection_for_schema_change.autocommit = False
41+
schema_change_cursor = connection_for_schema_change.cursor()
42+
43+
# Create a DB connection that will check what Locks are taken for "query"
44+
connection_for_lock_check = psycopg2.connect(
45+
user=user,
46+
password=password,
47+
host=host,
48+
port=port,
49+
database=database,
50+
)
51+
lock_check_cursor = connection_for_lock_check.cursor()
52+
53+
# Execute the query, but do not commit
54+
schema_change_cursor.execute(query)
55+
56+
lock_check_cursor.execute(LOCK_CHECK_QUERY)
57+
58+
results = lock_check_cursor.fetchall()
59+
60+
connection_for_schema_change.rollback()
61+
62+
results_table = PrettyTable()
63+
64+
results_table.field_names = [RELATION_ID, RELATION_NAME, LOCK_TYPE]
65+
results_table.align[RELATION_ID] = 'l'
66+
results_table.align[RELATION_NAME] = 'l'
67+
results_table.align[LOCK_TYPE] = 'l'
68+
69+
for relation_id, relation_name, lock_type in results:
70+
results_table.add_row([relation_id, relation_name, lock_type])
71+
72+
print(results_table)
73+
74+
75+
if __name__ == '__main__':
76+
parser = argparse.ArgumentParser()
77+
78+
parser.add_argument(
79+
'--query',
80+
required=True,
81+
help='A DDL statement to explain',
82+
)
83+
84+
parser.add_argument(
85+
'--user',
86+
required=True,
87+
help='User for database connection',
88+
)
89+
90+
parser.add_argument(
91+
'--password',
92+
required=True,
93+
help='Password for database connection',
94+
)
95+
96+
parser.add_argument(
97+
'--host',
98+
default='localhost',
99+
help='Host for database connection',
100+
)
101+
102+
parser.add_argument(
103+
'--port',
104+
default='5432',
105+
help='Port for database connection',
106+
)
107+
108+
parser.add_argument(
109+
'--database',
110+
required=True,
111+
help='Database for database connection',
112+
)
113+
114+
args = parser.parse_args()
115+
116+
main(
117+
args.user,
118+
args.password,
119+
args.host,
120+
args.port,
121+
args.database,
122+
args.query,
123+
)

Diff for: requirements.txt

+1
Original file line numberDiff line numberDiff line change
@@ -1 +1,2 @@
1+
prettytable==0.7.2
12
psycopg2==2.8.4

Diff for: schema_change_explainer.py

-5
This file was deleted.

0 commit comments

Comments
 (0)