Skip to content

Commit 91b096f

Browse files
committed
implement parameter deduplication
1 parent 4d8ebd8 commit 91b096f

File tree

2 files changed

+28
-19
lines changed

2 files changed

+28
-19
lines changed

CHANGELOG.md

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -6,6 +6,11 @@
66
- Fix a bug with date sorting in the table component.
77
- Center table descriptions.
88
- Fix a rare crash on startup in some restricted linux environments.
9+
- Fix a rare but serious issue when on SQLite and MySQL, some variable values were assigned incorrectly
10+
- `CASE WHEN $a THEN $x WHEN $b THEN $y` would be executed as `CASE WHEN $a THEN $b WHEN $x THEN $y` on these databases.
11+
- the issue only occured when using in case expressions where variables were used both in conditions and results.
12+
- Implement parameter deduplication.
13+
Now, when you write `select $x where $x is not null`, the value of `$x` is sent to the database only once. It used to be sent as many times as `$x` appeared in the statement.
914

1015
## 0.33.0 (2025-02-15)
1116

src/webserver/database/sql.rs

Lines changed: 23 additions & 19 deletions
Original file line numberDiff line numberDiff line change
@@ -473,10 +473,10 @@ struct ParameterExtractor {
473473
parameters: Vec<StmtParam>,
474474
}
475475

476-
const PLACEHOLDER_PREFIXES: [(AnyKind, &str); 3] =[
476+
const PLACEHOLDER_PREFIXES: [(AnyKind, &str); 3] = [
477477
(AnyKind::Sqlite, "?"),
478478
(AnyKind::Postgres, "$"),
479-
(AnyKind::Mssql, "@p")
479+
(AnyKind::Mssql, "@p"),
480480
];
481481
const DEFAULT_PLACEHOLDER: &str = "?";
482482

@@ -494,23 +494,23 @@ impl ParameterExtractor {
494494
}
495495

496496
fn replace_with_placeholder(&mut self, value: &mut Expr, param: StmtParam) {
497-
let placeholder = self.make_placeholder();
498-
log::trace!("Replacing {value:?} with {placeholder:?}, which references parameter {param:?}");
499-
self.parameters.push(param);
497+
let placeholder =
498+
if let Some(existing_idx) = self.parameters.iter().position(|p| *p == param) {
499+
// Parameter already exists, use its index
500+
self.make_placeholder_for_index(existing_idx + 1)
501+
} else {
502+
// New parameter, add it to the list
503+
let placeholder = self.make_placeholder();
504+
log::trace!("Replacing {param} with {placeholder}");
505+
self.parameters.push(param);
506+
placeholder
507+
};
500508
*value = placeholder;
501509
}
502510

503-
fn make_placeholder(&self) -> Expr {
504-
// This now uses the current length before sorting, which will be corrected after sorting
505-
let current_index = self.parameters.len();
506-
let name = make_placeholder(self.db_kind, current_index + 1);
507-
// We cast our placeholders to TEXT even though we always bind TEXT data to them anyway
508-
// because that helps the database engine to prepare the query.
509-
// For instance in PostgreSQL, the query planner will not be able to use an index on a
510-
// column if the column is compared to a placeholder of type VARCHAR, but it will be able
511-
// to use the index if the column is compared to a placeholder of type TEXT.
511+
fn make_placeholder_for_index(&self, index: usize) -> Expr {
512+
let name = make_placeholder(self.db_kind, index);
512513
let data_type = match self.db_kind {
513-
// MySQL requires CAST(? AS CHAR) and does not understand CAST(? AS TEXT)
514514
AnyKind::MySql => DataType::Char(None),
515515
AnyKind::Mssql => DataType::Varchar(Some(CharacterLength::Max)),
516516
_ => DataType::Text,
@@ -524,6 +524,10 @@ impl ParameterExtractor {
524524
}
525525
}
526526

527+
fn make_placeholder(&self) -> Expr {
528+
self.make_placeholder_for_index(self.parameters.len() + 1)
529+
}
530+
527531
fn is_own_placeholder(&self, param: &str) -> bool {
528532
if let Some((_, prefix)) = PLACEHOLDER_PREFIXES
529533
.iter()
@@ -746,7 +750,6 @@ fn extract_ident_param(Ident { value, .. }: &mut Ident) -> Option<StmtParam> {
746750
impl VisitorMut for ParameterExtractor {
747751
type Break = ();
748752
fn pre_visit_expr(&mut self, value: &mut Expr) -> ControlFlow<Self::Break> {
749-
log::trace!("Visiting {value} with span {span:?}", span = value.span());
750753
match value {
751754
Expr::Identifier(ident) => {
752755
if let Some(param) = extract_ident_param(ident) {
@@ -979,15 +982,16 @@ mod test {
979982
let mut ast =
980983
parse_postgres_stmt("select $a from t where $x > $a OR $x = sqlpage.cookie('cookoo')");
981984
let parameters = ParameterExtractor::extract_parameters(&mut ast, AnyKind::Postgres);
985+
// $a -> $1
986+
// $x -> $2
987+
// sqlpage.cookie(...) -> $3
982988
assert_eq!(
983989
ast.to_string(),
984-
"SELECT CAST($1 AS TEXT) FROM t WHERE CAST($2 AS TEXT) > CAST($3 AS TEXT) OR CAST($4 AS TEXT) = CAST($5 AS TEXT)"
990+
"SELECT CAST($1 AS TEXT) FROM t WHERE CAST($2 AS TEXT) > CAST($1 AS TEXT) OR CAST($2 AS TEXT) = CAST($3 AS TEXT)"
985991
);
986992
assert_eq!(
987993
parameters,
988994
[
989-
StmtParam::PostOrGet("a".to_string()),
990-
StmtParam::PostOrGet("x".to_string()),
991995
StmtParam::PostOrGet("a".to_string()),
992996
StmtParam::PostOrGet("x".to_string()),
993997
StmtParam::FunctionCall(SqlPageFunctionCall {

0 commit comments

Comments
 (0)