1
+ import logging
1
2
from typing import Literal
3
+ from typing import LiteralString
2
4
from typing import Union
5
+ from typing import cast
3
6
4
7
from ..sql import SafeSqlDriver
5
8
from ..sql import SqlDriver
6
9
from ..sql .extension_utils import check_extension
7
10
from ..sql .extension_utils import get_postgres_version
8
11
12
+ logger = logging .getLogger (__name__ )
13
+
9
14
PG_STAT_STATEMENTS = "pg_stat_statements"
10
15
16
+ install_pg_stat_statements_message = (
17
+ "The pg_stat_statements extension is required to "
18
+ "report slow queries, but it is not currently "
19
+ "installed.\n \n "
20
+ "You can install it by running: "
21
+ "`CREATE EXTENSION pg_stat_statements;`\n \n "
22
+ "**What does it do?** It records statistics (like "
23
+ "execution time, number of calls, rows returned) for "
24
+ "every query executed against the database.\n \n "
25
+ "**Is it safe?** Installing 'pg_stat_statements' is "
26
+ "generally safe and a standard practice for performance "
27
+ "monitoring. It adds overhead by tracking statistics, "
28
+ "but this is usually negligible unless under extreme load."
29
+ )
30
+
11
31
12
32
class TopQueriesCalc :
13
33
"""Tool for retrieving the slowest SQL queries."""
14
34
15
35
def __init__ (self , sql_driver : Union [SqlDriver , SafeSqlDriver ]):
16
36
self .sql_driver = sql_driver
17
37
18
- async def get_top_queries (self , limit : int = 10 , sort_by : Literal ["total" , "mean" ] = "mean" ) -> str :
38
+ async def get_top_queries_by_time (self , limit : int = 10 , sort_by : Literal ["total" , "mean" ] = "mean" ) -> str :
19
39
"""Reports the slowest SQL queries based on execution time.
20
40
21
41
Args:
@@ -27,32 +47,21 @@ async def get_top_queries(self, limit: int = 10, sort_by: Literal["total", "mean
27
47
A string with the top queries or installation instructions
28
48
"""
29
49
try :
50
+ logger .debug (f"Getting top queries by time. limit={ limit } , sort_by={ sort_by } " )
30
51
extension_status = await check_extension (
31
52
self .sql_driver ,
32
53
PG_STAT_STATEMENTS ,
33
54
include_messages = False ,
34
55
)
35
56
36
- if not extension_status ["is_installed" ]:
57
+ if not extension_status .is_installed :
58
+ logger .warning (f"Extension { PG_STAT_STATEMENTS } is not installed" )
37
59
# Return installation instructions if the extension is not installed
38
- monitoring_message = (
39
- f"The '{ PG_STAT_STATEMENTS } ' extension is required to "
40
- f"report slow queries, but it is not currently "
41
- f"installed.\n \n "
42
- f"You can install it by running: "
43
- f"`CREATE EXTENSION { PG_STAT_STATEMENTS } ;`\n \n "
44
- f"**What does it do?** It records statistics (like "
45
- f"execution time, number of calls, rows returned) for "
46
- f"every query executed against the database.\n \n "
47
- f"**Is it safe?** Installing '{ PG_STAT_STATEMENTS } ' is "
48
- f"generally safe and a standard practice for performance "
49
- f"monitoring. It adds overhead by tracking statistics, "
50
- f"but this is usually negligible unless under extreme load."
51
- )
52
- return monitoring_message
60
+ return install_pg_stat_statements_message
53
61
54
62
# Check PostgreSQL version to determine column names
55
63
pg_version = await get_postgres_version (self .sql_driver )
64
+ logger .debug (f"PostgreSQL version: { pg_version } " )
56
65
57
66
# Column names changed in PostgreSQL 13
58
67
if pg_version >= 13 :
@@ -64,6 +73,8 @@ async def get_top_queries(self, limit: int = 10, sort_by: Literal["total", "mean
64
73
total_time_col = "total_time"
65
74
mean_time_col = "mean_time"
66
75
76
+ logger .debug (f"Using time columns: total={ total_time_col } , mean={ mean_time_col } " )
77
+
67
78
# Determine which column to sort by based on sort_by parameter and version
68
79
order_by_column = total_time_col if sort_by == "total" else mean_time_col
69
80
@@ -78,12 +89,14 @@ async def get_top_queries(self, limit: int = 10, sort_by: Literal["total", "mean
78
89
ORDER BY { order_by_column } DESC
79
90
LIMIT {{}};
80
91
"""
92
+ logger .debug (f"Executing query: { query } " )
81
93
slow_query_rows = await SafeSqlDriver .execute_param_query (
82
94
self .sql_driver ,
83
95
query ,
84
96
[limit ],
85
97
)
86
98
slow_queries = [row .cells for row in slow_query_rows ] if slow_query_rows else []
99
+ logger .info (f"Found { len (slow_queries )} slow queries" )
87
100
88
101
# Create result description based on sort criteria
89
102
if sort_by == "total" :
@@ -95,4 +108,104 @@ async def get_top_queries(self, limit: int = 10, sort_by: Literal["total", "mean
95
108
result += str (slow_queries )
96
109
return result
97
110
except Exception as e :
111
+ logger .error (f"Error getting slow queries: { e } " , exc_info = True )
98
112
return f"Error getting slow queries: { e } "
113
+
114
+ async def get_top_resource_queries (self , frac_threshold : float = 0.05 ) -> str :
115
+ """Reports the most time consuming queries based on a resource blend.
116
+
117
+ Args:
118
+ frac_threshold: Fraction threshold for filtering queries (default: 0.05)
119
+
120
+ Returns:
121
+ A string with the resource-heavy queries or error message
122
+ """
123
+
124
+ try :
125
+ logger .debug (f"Getting top resource queries with threshold { frac_threshold } " )
126
+ extension_status = await check_extension (
127
+ self .sql_driver ,
128
+ PG_STAT_STATEMENTS ,
129
+ include_messages = False ,
130
+ )
131
+
132
+ if not extension_status .is_installed :
133
+ logger .warning (f"Extension { PG_STAT_STATEMENTS } is not installed" )
134
+ # Return installation instructions if the extension is not installed
135
+ return install_pg_stat_statements_message
136
+
137
+ # Check PostgreSQL version to determine column names
138
+ pg_version = await get_postgres_version (self .sql_driver )
139
+ logger .debug (f"PostgreSQL version: { pg_version } " )
140
+
141
+ # Column names changed in PostgreSQL 13
142
+ if pg_version >= 13 :
143
+ # PostgreSQL 13 and newer
144
+ total_time_col = "total_exec_time"
145
+ mean_time_col = "mean_exec_time"
146
+ else :
147
+ # PostgreSQL 12 and older
148
+ total_time_col = "total_time"
149
+ mean_time_col = "mean_time"
150
+
151
+ query = cast (
152
+ LiteralString ,
153
+ f"""
154
+ WITH resource_fractions AS (
155
+ SELECT
156
+ query,
157
+ calls,
158
+ rows,
159
+ { total_time_col } total_exec_time,
160
+ { mean_time_col } mean_exec_time,
161
+ stddev_exec_time,
162
+ shared_blks_hit,
163
+ shared_blks_read,
164
+ shared_blks_dirtied,
165
+ wal_bytes,
166
+ total_exec_time / SUM(total_exec_time) OVER () AS total_exec_time_frac,
167
+ (shared_blks_hit + shared_blks_read) / SUM(shared_blks_hit + shared_blks_read) OVER () AS shared_blks_accessed_frac,
168
+ shared_blks_read / SUM(shared_blks_read) OVER () AS shared_blks_read_frac,
169
+ shared_blks_dirtied / SUM(shared_blks_dirtied) OVER () AS shared_blks_dirtied_frac,
170
+ wal_bytes / SUM(wal_bytes) OVER () AS total_wal_bytes_frac
171
+ FROM pg_stat_statements
172
+ )
173
+ SELECT
174
+ query,
175
+ calls,
176
+ rows,
177
+ total_exec_time,
178
+ mean_exec_time,
179
+ stddev_exec_time,
180
+ total_exec_time_frac,
181
+ shared_blks_accessed_frac,
182
+ shared_blks_read_frac,
183
+ shared_blks_dirtied_frac,
184
+ total_wal_bytes_frac,
185
+ shared_blks_hit,
186
+ shared_blks_read,
187
+ shared_blks_dirtied,
188
+ wal_bytes
189
+ FROM resource_fractions
190
+ WHERE
191
+ total_exec_time_frac > { frac_threshold }
192
+ OR shared_blks_accessed_frac > { frac_threshold }
193
+ OR shared_blks_read_frac > { frac_threshold }
194
+ OR shared_blks_dirtied_frac > { frac_threshold }
195
+ OR total_wal_bytes_frac > { frac_threshold }
196
+ ORDER BY total_exec_time DESC
197
+ """ ,
198
+ )
199
+
200
+ logger .debug (f"Executing query: { query } " )
201
+ slow_query_rows = await SafeSqlDriver .execute_param_query (
202
+ self .sql_driver ,
203
+ query ,
204
+ )
205
+ resource_queries = [row .cells for row in slow_query_rows ] if slow_query_rows else []
206
+ logger .info (f"Found { len (resource_queries )} resource-intensive queries" )
207
+
208
+ return str (resource_queries )
209
+ except Exception as e :
210
+ logger .error (f"Error getting resource-intensive queries: { e } " , exc_info = True )
211
+ return f"Error resource-intensive queries: { e } "
0 commit comments