Skip to content

Commit 7b51990

Browse files
committed
new on_reset.sql
1 parent 600c6cf commit 7b51990

File tree

5 files changed

+113
-30
lines changed

5 files changed

+113
-30
lines changed

CHANGELOG.md

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,7 @@
22

33
## 0.32.0 (unreleased)
44

5-
- Rollback any open transactions when returning a connection to the pool.
5+
- Rollback any open transactions when an error occurs in a SQL file.
66
- Previously, if an error occurred in the middle of a transaction, the transaction would be left open, and the connection would be returned to the pool. The next request could get a connection with an open half-completed transaction, which could lead to hard to debug issues.
77
- This allows safely using features that require a transaction, like
88
- ```sql
@@ -21,6 +21,8 @@
2121
```
2222
- Fix `error returned from database: 1295 (HY000): This command is not supported in the prepared statement protocol yet` when trying to use transactions with MySQL. `START TRANSACTION` now works as expected in MySQL.
2323
- Fix a bug where a multi-select dropdown would unexpectedly open when the form was reset.
24+
- Add a new optional `sqlpage/on_reset.sql` file that can be used to execute some SQL code after the end of each page execution.
25+
- Useful to reset a connection to the database after each request.
2426

2527
## 0.31.0 (2024-11-24)
2628

configuration.md

Lines changed: 49 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -106,7 +106,9 @@ For instance, if you want to create a custom `my_component` component, that disp
106106

107107
[See the full custom component documentation](https://sql-page.com/custom_components.sql).
108108

109-
## Connection initialization scripts
109+
## Connection management
110+
111+
### Connection initialization scripts
110112

111113
SQLPage allows you to run a SQL script when a new database connection is opened,
112114
by simply creating a `sqlpage/on_connect.sql` file.
@@ -135,6 +137,52 @@ CREATE TEMPORARY TABLE my_temporary_table(
135137
);
136138
```
137139

140+
### Connection cleanup scripts: `on_reset.sql`
141+
142+
SQLPage allows you to run a SQL script after a request has been processed,
143+
by simply creating a `sqlpage/on_reset.sql` file.
144+
145+
This can be useful to clean up temporary tables,
146+
rollback transactions that were left open,
147+
or other resources that were created during the request.
148+
149+
You can also use this script to close database connections that are
150+
in an undesirable state, such as being in a transaction that was left open.
151+
To close a connection, write a select statement that returns a single row
152+
with a single boolean column named `is_healthy`, and set it to false.
153+
154+
#### Rollback transactions
155+
156+
You can automatically rollback any open transactions
157+
when a connection is returned to the pool,
158+
so that a new request is never executed in the context of an open transaction from a previous request.
159+
160+
For this to work, you need to create a `sqlpage/on_reset.sql` containing the following line:
161+
162+
```sql
163+
ROLLBACK;
164+
```
165+
166+
#### Cleaning up all connection state
167+
168+
Some databases allow you to clean up all the state associatPed with a connection.
169+
170+
##### PostgreSQL
171+
172+
By creating a `sqlpage/on_disconnect.sql` file containing a [`DISCARD ALL`](https://www.postgresql.org/docs/current/sql-discard.html) statement.
173+
174+
```sql
175+
DISCARD ALL;
176+
```
177+
178+
##### SQL Server
179+
180+
By creating a `sqlpage/on_disconnect.sql` file containing a call to the [`sp_reset_connection`](https://learn.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/system-stored-procedures-transact-sql?view=sql-server-ver16#api-system-stored-procedures) stored procedure.
181+
182+
```sql
183+
EXEC sp_reset_connection;
184+
```
185+
138186
## Migrations
139187

140188
SQLPage allows you to run SQL scripts when the database schema changes, by creating a `sqlpage/migrations` directory.

src/lib.rs

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -94,6 +94,7 @@ use webserver::Database;
9494
pub const TEMPLATES_DIR: &str = "sqlpage/templates/";
9595
pub const MIGRATIONS_DIR: &str = "migrations";
9696
pub const ON_CONNECT_FILE: &str = "on_connect.sql";
97+
pub const ON_RESET_FILE: &str = "on_reset.sql";
9798

9899
pub struct AppState {
99100
pub db: Database,

src/webserver/database/connect.rs

Lines changed: 34 additions & 21 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
use std::{mem::take, time::Duration};
22

33
use super::Database;
4-
use crate::{app_config::AppConfig, ON_CONNECT_FILE};
4+
use crate::{app_config::AppConfig, ON_CONNECT_FILE, ON_RESET_FILE};
55
use anyhow::Context;
66
use futures_util::future::BoxFuture;
77
use sqlx::{
@@ -93,37 +93,50 @@ impl Database {
9393
)
9494
.acquire_timeout(Duration::from_secs_f64(
9595
config.database_connection_acquire_timeout_seconds,
96-
))
97-
.after_release(on_return_to_pool);
96+
));
97+
pool_options = add_on_return_to_pool(config, pool_options);
9898
pool_options = add_on_connection_handler(config, pool_options);
9999
pool_options
100100
}
101101
}
102102

103+
fn add_on_return_to_pool(config: &AppConfig, pool_options: PoolOptions<Any>) -> PoolOptions<Any> {
104+
let on_disconnect_file = config.configuration_directory.join(ON_RESET_FILE);
105+
if !on_disconnect_file.exists() {
106+
log::debug!("Not creating a custom SQL connection cleanup handler because {on_disconnect_file:?} does not exist");
107+
return pool_options;
108+
}
109+
log::info!("Creating a custom SQL connection cleanup handler from {on_disconnect_file:?}");
110+
let sql = match std::fs::read_to_string(&on_disconnect_file) {
111+
Ok(sql) => std::sync::Arc::new(sql),
112+
Err(e) => {
113+
log::error!("Unable to read the file {on_disconnect_file:?}: {e}");
114+
return pool_options;
115+
}
116+
};
117+
log::trace!("The custom SQL connection cleanup handler is:\n{sql}");
118+
let sql = sql.clone();
119+
pool_options
120+
.after_release(move |conn, meta| on_return_to_pool(conn, meta, std::sync::Arc::clone(&sql)))
121+
}
122+
103123
fn on_return_to_pool(
104124
conn: &mut sqlx::AnyConnection,
105125
meta: sqlx::pool::PoolConnectionMetadata,
126+
sql: std::sync::Arc<String>,
106127
) -> BoxFuture<'_, Result<bool, sqlx::Error>> {
128+
use sqlx::Row;
107129
Box::pin(async move {
108-
match conn.execute("ROLLBACK").await {
109-
Ok(query_result) => {
110-
if query_result.rows_affected() > 0 {
111-
log::warn!(
112-
"Rolled back a transaction, because it was left open after a page was rendered, and it affected {} rows",
113-
query_result.rows_affected()
114-
);
115-
} else {
116-
log::trace!(
117-
"Rolled back a transaction before returning a connection to the pool"
118-
);
119-
}
120-
}
121-
Err(e) => log::trace!(
122-
"Failed to rollback before returning a connection to the pool. There was probably no transaction left open: {e:?}"
123-
),
130+
log::trace!("Running the custom SQL connection cleanup handler. {meta:?}");
131+
let query_result = conn.fetch_optional(sql.as_str()).await?;
132+
if let Some(query_result) = query_result {
133+
let is_healthy = query_result.try_get::<bool, _>(0);
134+
log::debug!("Is the connection healthy? {is_healthy:?}");
135+
is_healthy
136+
} else {
137+
log::debug!("No result from the custom SQL connection cleanup handler");
138+
Ok(true)
124139
}
125-
log::trace!("Releasing connection: {meta:#?}");
126-
Ok(true)
127140
})
128141
}
129142

src/webserver/database/execute_queries.rs

Lines changed: 26 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -21,7 +21,9 @@ use super::syntax_tree::{extract_req_param, StmtParam};
2121
use super::{error_highlighting::display_db_error, Database, DbItem};
2222
use sqlx::any::{AnyArguments, AnyQueryResult, AnyRow, AnyStatement, AnyTypeInfo};
2323
use sqlx::pool::PoolConnection;
24-
use sqlx::{Any, Arguments, Column, Either, Executor, Row as _, Statement, ValueRef};
24+
use sqlx::{
25+
Any, AnyConnection, Arguments, Column, Either, Executor, Row as _, Statement, ValueRef,
26+
};
2527

2628
pub type DbConn = Option<PoolConnection<sqlx::Any>>;
2729

@@ -58,18 +60,24 @@ pub fn stream_query_results_with_conn<'a>(
5860
let connection = take_connection(&request.app_state.db, db_connection).await?;
5961
log::trace!("Executing query {:?}", query.sql);
6062
let mut stream = connection.fetch_many(query);
63+
let mut error = None;
6164
while let Some(elem) = stream.next().await {
62-
let is_err = elem.is_err();
6365
let mut query_result = parse_single_sql_result(source_file, &stmt.query, elem);
66+
if let DbItem::Error(e) = query_result {
67+
error = Some(e);
68+
break;
69+
}
6470
apply_json_columns(&mut query_result, &stmt.json_columns);
6571
apply_delayed_functions(request, &stmt.delayed_functions, &mut query_result).await?;
66-
for i in parse_dynamic_rows(query_result) {
67-
yield i;
68-
}
69-
if is_err {
70-
break;
72+
for db_item in parse_dynamic_rows(query_result) {
73+
yield db_item;
7174
}
7275
}
76+
drop(stream);
77+
if let Some(error) = error {
78+
try_rollback_transaction(connection).await;
79+
yield DbItem::Error(error);
80+
}
7381
},
7482
ParsedStatement::SetVariable { variable, value} => {
7583
execute_set_variable_query(db_connection, request, variable, value, source_file).await
@@ -131,6 +139,16 @@ async fn exec_static_simple_select(
131139
Ok(serde_json::Value::Object(map))
132140
}
133141

142+
async fn try_rollback_transaction(db_connection: &mut AnyConnection) {
143+
log::debug!("Attempting to rollback transaction");
144+
match db_connection.execute("ROLLBACK").await {
145+
Ok(_) => log::debug!("Rolled back transaction"),
146+
Err(e) => {
147+
log::debug!("There was probably no transaction in progress when this happened: {e:?}");
148+
}
149+
}
150+
}
151+
134152
/// Extracts the value of a parameter from the request.
135153
/// Returns `Ok(None)` when NULL should be used as the parameter value.
136154
async fn extract_req_param_as_json(
@@ -177,6 +195,7 @@ async fn execute_set_variable_query<'a>(
177195
Ok(Some(row)) => row_to_string(&row),
178196
Ok(None) => None,
179197
Err(e) => {
198+
try_rollback_transaction(connection).await;
180199
let err = display_db_error(source_file, &statement.query, e);
181200
return Err(err);
182201
}

0 commit comments

Comments
 (0)