├── .gitignore ├── LICENSE ├── README.md ├── pg_explain_locks.py ├── requirements.txt └── setup.py /.gitignore: -------------------------------------------------------------------------------- 1 | .idea/* 2 | venv/* 3 | example.txt 4 | .settings 5 | build/* 6 | dist/* 7 | pg_explain_locks.egg-info/* 8 | 9 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2019 pg_explain_locks 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL Query Lock Explainer 2 | 3 | Utility to show what locks will be acquired by a given query. 4 | 5 | Query is executed but not committed. 6 | 7 | > **Warning** 8 | > 9 | > Don't run this on a production DB. 10 | > 11 | > The suggested strategy is to run this using a test DB to figure out the locks 12 | > And then use that information later if you need it. 13 | 14 | ## Installation instructions 15 | 16 | ```.env 17 | pip install pg_explain_locks 18 | ``` 19 | 20 | ## How this thing works 21 | 22 | This tool runs a given query like this: 23 | 24 | 1. `BEGIN` 25 | 2. `-- Run given query` 26 | 3. `-- Check which locks are taken` 27 | 4. `ROLLBACK` 28 | 29 | ## Example Usage 30 | 31 | Examples shown against [dvdrental sample database](http://www.postgresqltutorial.com/postgresql-sample-database/) 32 | 33 | ```.env 34 | pg_explain_locks \ 35 | --user DB_USER \ 36 | --password DB_PASSWORD \ 37 | --database DATABASE \ 38 | --host HOST \ 39 | --query "DROP table actor CASCADE" 40 | 41 | +-------------+----------------------------+---------------------+ 42 | | Relation ID | Relation Name | Lock Type | 43 | +-------------+----------------------------+---------------------+ 44 | | 16422 | actor | AccessExclusiveLock | 45 | | 16448 | film_actor | AccessExclusiveLock | 46 | | 16456 | actor_info | AccessExclusiveLock | 47 | | 16487 | film_list | AccessExclusiveLock | 48 | | 16506 | nicer_but_slower_film_list | AccessExclusiveLock | 49 | | 16557 | actor_pkey | AccessExclusiveLock | 50 | | 16588 | idx_actor_last_name | AccessExclusiveLock | 51 | +-------------+----------------------------+---------------------+ 52 | 53 | ``` 54 | 55 | ```.env 56 | pg_explain_locks \ 57 | --user DB_USER \ 58 | --password DB_PASSWORD \ 59 | --database DATABASE \ 60 | --host HOST \ 61 | --query "SELECT * FROM film_actor fa JOIN actor a on a.actor_id=fa.actor_id FOR UPDATE" 62 | 63 | +-------------+---------------------+-----------------+ 64 | | Relation ID | Relation Name | Lock Type | 65 | +-------------+---------------------+-----------------+ 66 | | 16422 | actor | RowShareLock | 67 | | 16448 | film_actor | RowShareLock | 68 | | 16557 | actor_pkey | AccessShareLock | 69 | | 16569 | film_actor_pkey | AccessShareLock | 70 | | 16588 | idx_actor_last_name | AccessShareLock | 71 | | 16593 | idx_fk_film_id | AccessShareLock | 72 | +-------------+---------------------+-----------------+ 73 | 74 | ``` 75 | 76 | ```.env 77 | 78 | pg_explain_locks \ 79 | --user DB_USER \ 80 | --password DB_PASSWORD \ 81 | --database DATABASE \ 82 | --host HOST \ 83 | --query "ALTER TABLE customer ADD COLUMN deleted BOOLEAN" 84 | 85 | +-------------+---------------+---------------------+ 86 | | Relation ID | Relation Name | Lock Type | 87 | +-------------+---------------+---------------------+ 88 | | 16411 | customer | AccessExclusiveLock | 89 | +-------------+---------------+---------------------+ 90 | ``` 91 | 92 | ## Example usage with settings file 93 | 94 | Create a settings file at `~/.pg_explain_locks_settings` in order to use the same DB settings every time. 95 | 96 | Settings file contents : 97 | ```.env 98 | USER=your_user 99 | PASSWORD=your_password 100 | DATABASE=your_database 101 | HOST=your_host 102 | PORT=your_post 103 | ``` 104 | 105 | Usage: 106 | 107 | ```.env 108 | pg_explain_locks "ALTER TABLE customer ADD COLUMN deleted BOOLEAN" 109 | 110 | +-------------+---------------+---------------------+ 111 | | Relation ID | Relation Name | Lock Type | 112 | +-------------+---------------+---------------------+ 113 | | 16411 | customer | AccessExclusiveLock | 114 | +-------------+---------------+---------------------+ 115 | ``` 116 | 117 | 118 | -------------------------------------------------------------------------------- /pg_explain_locks.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python 2 | 3 | import argparse 4 | import os 5 | import sys 6 | 7 | import psycopg2 8 | from prettytable import PrettyTable 9 | 10 | LOCK_CHECK_QUERY = """ 11 | SELECT l.relation, 12 | c.relname, 13 | l.mode 14 | FROM pg_locks l 15 | JOIN pg_class c ON c.oid=l.relation 16 | JOIN pg_stat_activity a on l.pid = a.pid 17 | AND a.query NOT ILIKE '%pg_stat_activity%' 18 | ORDER BY l.relation ASC; 19 | """ 20 | 21 | RELATION_ID = 'Relation ID' 22 | RELATION_NAME = 'Relation Name' 23 | LOCK_TYPE = 'Lock Type' 24 | 25 | SETTINGS_FILE = f"{os.path.expanduser('~')}/.pg_explain_locks_settings" 26 | 27 | 28 | def explain_locks_for_query( 29 | user: str, 30 | password: str, 31 | host: str, 32 | port: str, 33 | database: str, 34 | query: str, 35 | ): 36 | """Execute and rollback a query to see what locks it will take""" 37 | 38 | # Create a DB connection that will "stage" but not commit the DB change 39 | connection_for_schema_change = psycopg2.connect( 40 | user=user, 41 | password=password, 42 | host=host, 43 | port=port, 44 | database=database, 45 | ) 46 | connection_for_schema_change.autocommit = False 47 | schema_change_cursor = connection_for_schema_change.cursor() 48 | 49 | # Create a DB connection that will check what Locks are taken for "query" 50 | connection_for_lock_check = psycopg2.connect( 51 | user=user, 52 | password=password, 53 | host=host, 54 | port=port, 55 | database=database, 56 | ) 57 | lock_check_cursor = connection_for_lock_check.cursor() 58 | 59 | # Execute the query, but do not commit 60 | schema_change_cursor.execute(query) 61 | 62 | lock_check_cursor.execute(LOCK_CHECK_QUERY) 63 | 64 | results = lock_check_cursor.fetchall() 65 | 66 | connection_for_schema_change.rollback() 67 | 68 | results_table = PrettyTable() 69 | 70 | results_table.field_names = [RELATION_ID, RELATION_NAME, LOCK_TYPE] 71 | results_table.align[RELATION_ID] = 'l' 72 | results_table.align[RELATION_NAME] = 'l' 73 | results_table.align[LOCK_TYPE] = 'l' 74 | 75 | for relation_id, relation_name, lock_type in results: 76 | results_table.add_row([relation_id, relation_name, lock_type]) 77 | 78 | print(results_table) 79 | 80 | 81 | def parse_args_from_command_line(): 82 | parser = argparse.ArgumentParser() 83 | 84 | parser.add_argument( 85 | '--query', 86 | required=True, 87 | help='A DDL statement to explain', 88 | ) 89 | 90 | parser.add_argument( 91 | '--user', 92 | required=True, 93 | help='User for database connection', 94 | ) 95 | 96 | parser.add_argument( 97 | '--password', 98 | required=True, 99 | help='Password for database connection', 100 | ) 101 | 102 | parser.add_argument( 103 | '--host', 104 | default='localhost', 105 | help='Host for database connection', 106 | ) 107 | 108 | parser.add_argument( 109 | '--port', 110 | default='5432', 111 | help='Port for database connection', 112 | ) 113 | 114 | parser.add_argument( 115 | '--database', 116 | required=True, 117 | help='Database for database connection', 118 | ) 119 | 120 | return vars(parser.parse_args()) 121 | 122 | 123 | def parse_args_from_settings_file(): 124 | if len(sys.argv) != 2: 125 | print('Error : need to provide query as only arugment') 126 | print('Example: pg_explain_locks "SELECT * FROM actors"') 127 | exit() 128 | 129 | args = {} 130 | with open(SETTINGS_FILE, 'r') as settings_file: 131 | content = settings_file.read() 132 | lines = content.strip().split('\n') 133 | for line in lines: 134 | setting, value = line.split('=') 135 | args[setting.lower()] = value 136 | 137 | args['query'] = sys.argv[1] 138 | 139 | return args 140 | 141 | 142 | def main(): 143 | if os.path.exists(SETTINGS_FILE): 144 | args = parse_args_from_settings_file() 145 | else: 146 | args = parse_args_from_command_line() 147 | 148 | if 'commit' in args['query'].lower(): 149 | print( 150 | 'Just to be super safe, this tool will not work for queries that ' 151 | 'include the word commit :)' 152 | ) 153 | exit() 154 | 155 | explain_locks_for_query(**args) 156 | -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | prettytable==0.7.2 2 | psycopg2==2.8.4 3 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | import setuptools 2 | 3 | with open("README.md", "r") as fh: 4 | long_description = fh.read() 5 | 6 | requirements = [ 7 | 'prettytable', 8 | 'psycopg2', 9 | ] 10 | 11 | setuptools.setup( 12 | name="pg_explain_locks", # Replace with your own username 13 | version="0.0.3", 14 | author="Adam Tal", 15 | author_email="admtal@gmail.com", 16 | description="Postgres utility to show what locks will be acquired by a given query.", 17 | long_description=long_description, 18 | long_description_content_type="text/markdown", 19 | url="https://github.com/AdmTal/PostgreSQL-Query-Lock-Explainer", 20 | py_modules=['pg_explain_locks'], 21 | packages=setuptools.find_packages(), 22 | setup_requires=requirements, 23 | install_requires=requirements, 24 | classifiers=[ 25 | "Programming Language :: Python :: 3", 26 | "License :: OSI Approved :: MIT License", 27 | "Operating System :: OS Independent", 28 | ], 29 | entry_points={ 30 | 'console_scripts': [ 31 | 'pg_explain_locks = pg_explain_locks:main', 32 | ], 33 | }, 34 | python_requires='>=3.6', 35 | ) 36 | --------------------------------------------------------------------------------