Skip to content

Commit 300da2a

Browse files
committed
feat: add raw_sql API
This is meant to be much easier to discover than the current approach of directly invoking `Executor` methods. In addition, I'm improving documentation for the `query*()` functions across the board.
1 parent a7862ae commit 300da2a

File tree

6 files changed

+596
-18
lines changed

6 files changed

+596
-18
lines changed

sqlx-core/src/lib.rs

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -74,6 +74,8 @@ pub mod net;
7474
pub mod query_as;
7575
pub mod query_builder;
7676
pub mod query_scalar;
77+
78+
pub mod raw_sql;
7779
pub mod row;
7880
pub mod rt;
7981
pub mod sync;

sqlx-core/src/query.rs

Lines changed: 172 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -12,7 +12,7 @@ use crate::executor::{Execute, Executor};
1212
use crate::statement::Statement;
1313
use crate::types::Type;
1414

15-
/// Raw SQL query with bind parameters. Returned by [`query`][crate::query::query].
15+
/// A single SQL query as a prepared statement. Returned by [`query()`].
1616
#[must_use = "query must be executed to affect database"]
1717
pub struct Query<'q, DB: Database, A> {
1818
pub(crate) statement: Either<&'q str, &'q <DB as HasStatement<'q>>::Statement>,
@@ -21,7 +21,9 @@ pub struct Query<'q, DB: Database, A> {
2121
pub(crate) persistent: bool,
2222
}
2323

24-
/// SQL query that will map its results to owned Rust types.
24+
/// A single SQL query that will map its results to an owned Rust type.
25+
///
26+
/// Executes as a prepared statement.
2527
///
2628
/// Returned by [`Query::try_map`], `query!()`, etc. Has most of the same methods as [`Query`] but
2729
/// the return types are changed to reflect the mapping. However, there is no equivalent of
@@ -96,6 +98,8 @@ where
9698
/// matching the one with the flag will use the cached statement until the
9799
/// cache is cleared.
98100
///
101+
/// If `false`, the prepared statement will be closed after execution.
102+
///
99103
/// Default: `true`.
100104
pub fn persistent(mut self, value: bool) -> Self {
101105
self.persistent = value;
@@ -155,6 +159,7 @@ where
155159

156160
/// Execute multiple queries and return the rows affected from each query, in a stream.
157161
#[inline]
162+
#[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."]
158163
pub async fn execute_many<'e, 'c: 'e, E>(
159164
self,
160165
executor: E,
@@ -178,9 +183,13 @@ where
178183
executor.fetch(self)
179184
}
180185

181-
/// Execute multiple queries and return the generated results as a stream
182-
/// from each query, in a stream.
186+
/// Execute multiple queries and return the generated results as a stream.
187+
///
188+
/// For each query in the stream, any generated rows are returned first,
189+
/// then the `QueryResult` with the number of rows affected.
183190
#[inline]
191+
#[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."]
192+
// TODO: we'll probably still want a way to get the `DB::QueryResult` at the end of a `fetch()` stream.
184193
pub fn fetch_many<'e, 'c: 'e, E>(
185194
self,
186195
executor: E,
@@ -193,7 +202,13 @@ where
193202
executor.fetch_many(self)
194203
}
195204

196-
/// Execute the query and return all the generated results, collected into a [`Vec`].
205+
/// Execute the query and return all the resulting rows collected into a [`Vec`].
206+
///
207+
/// ### Note: beware result set size.
208+
/// This will attempt to collect the full result set of the query into memory.
209+
///
210+
/// To avoid exhausting available memory, ensure the result set has a known upper bound,
211+
/// e.g. using `LIMIT`.
197212
#[inline]
198213
pub async fn fetch_all<'e, 'c: 'e, E>(self, executor: E) -> Result<Vec<DB::Row>, Error>
199214
where
@@ -204,7 +219,18 @@ where
204219
executor.fetch_all(self).await
205220
}
206221

207-
/// Execute the query and returns exactly one row.
222+
/// Execute the query, returning the first row or [`Error::RowNotFound`] otherwise.
223+
///
224+
/// ### Note: for best performance, ensure the query returns at most one row.
225+
/// Depending on the driver implementation, if your query can return more than one row,
226+
/// it may lead to wasted CPU time and bandwidth on the database server.
227+
///
228+
/// Even when the driver implementation takes this into account, ensuring the query returns at most one row
229+
/// can result in a more optimal query plan.
230+
///
231+
/// If your query has a `WHERE` clause filtering a unique column by a single value, you're good.
232+
///
233+
/// Otherwise, you might want to add `LIMIT 1` to your query.
208234
#[inline]
209235
pub async fn fetch_one<'e, 'c: 'e, E>(self, executor: E) -> Result<DB::Row, Error>
210236
where
@@ -215,7 +241,18 @@ where
215241
executor.fetch_one(self).await
216242
}
217243

218-
/// Execute the query and returns at most one row.
244+
/// Execute the query, returning the first row or `None` otherwise.
245+
///
246+
/// ### Note: for best performance, ensure the query returns at most one row.
247+
/// Depending on the driver implementation, if your query can return more than one row,
248+
/// it may lead to wasted CPU time and bandwidth on the database server.
249+
///
250+
/// Even when the driver implementation takes this into account, ensuring the query returns at most one row
251+
/// can result in a more optimal query plan.
252+
///
253+
/// If your query has a `WHERE` clause filtering a unique column by a single value, you're good.
254+
///
255+
/// Otherwise, you might want to add `LIMIT 1` to your query.
219256
#[inline]
220257
pub async fn fetch_optional<'e, 'c: 'e, E>(self, executor: E) -> Result<Option<DB::Row>, Error>
221258
where
@@ -394,7 +431,7 @@ where
394431
}
395432
}
396433

397-
// Make a SQL query from a statement.
434+
/// Execute a single SQL query as a prepared statement (explicitly created).
398435
pub fn query_statement<'q, DB>(
399436
statement: &'q <DB as HasStatement<'q>>::Statement,
400437
) -> Query<'q, DB, <DB as HasArguments<'_>>::Arguments>
@@ -409,7 +446,7 @@ where
409446
}
410447
}
411448

412-
// Make a SQL query from a statement, with the given arguments.
449+
/// Execute a single SQL query as a prepared statement (explicitly created), with the given arguments.
413450
pub fn query_statement_with<'q, DB, A>(
414451
statement: &'q <DB as HasStatement<'q>>::Statement,
415452
arguments: A,
@@ -426,7 +463,129 @@ where
426463
}
427464
}
428465

429-
/// Make a SQL query.
466+
/// Execute a single SQL query as a prepared statement (transparently cached).
467+
///
468+
/// The query string may only contain a single DML statement: `SELECT`, `INSERT`, `UPDATE`, `DELETE` and variants.
469+
/// The SQLite driver does not currently follow this restriction, but that behavior is deprecated.
470+
///
471+
/// The connection will transparently prepare and cache the statement, which means it only needs to be parsed once
472+
/// in the connection's lifetime, and any generated query plans can be retained.
473+
/// Thus, the overhead of executing the statement is amortized.
474+
///
475+
/// Some third-party databases that speak a supported protocol, e.g. CockroachDB or PGBouncer that speak Postgres,
476+
/// may have issues with the transparent caching of prepared statements. If you are having trouble,
477+
/// try setting [`.persistent(false)`][Query::persistent].
478+
///
479+
/// See the [`Query`] type for the methods you may call.
480+
///
481+
/// ### Dynamic Input: Use Query Parameters (Prevents SQL Injection)
482+
/// At some point, you'll likely want to include some form of dynamic input in your query, possibly from the user.
483+
///
484+
/// Your first instinct might be to do something like this:
485+
/// ```rust,no_run
486+
/// # async fn example() -> sqlx::Result<()> {
487+
/// # let mut conn: sqlx::PgConnection = unimplemented!();
488+
/// // Imagine this is input from the user, e.g. a search form on a website.
489+
/// let user_input = "possibly untrustworthy input!";
490+
///
491+
/// // DO NOT DO THIS unless you're ABSOLUTELY CERTAIN it's what you need!
492+
/// let query = format!("SELECT * FROM articles WHERE content LIKE '%{user_input}%'");
493+
/// // where `conn` is `PgConnection` or `MySqlConnection`
494+
/// // or some other type that implements `Executor`.
495+
/// let results = sqlx::query(&query).fetch_all(&mut conn).await?;
496+
/// # }
497+
/// ```
498+
///
499+
/// The example above showcases a **SQL injection vulnerability**, because it's trivial for a malicious user to craft
500+
/// an input that can "break out" of the string literal.
501+
///
502+
/// For example, if they send the input `foo'; DELETE FROM articles; --`
503+
/// then your application would send the following to the database server (line breaks added for clarity):
504+
///
505+
/// ```sql
506+
/// SELECT * FROM articles WHERE content LIKE '%foo';
507+
/// DELETE FROM articles;
508+
/// --%'
509+
/// ```
510+
///
511+
/// In this case, because this interface *always* uses prepared statements, you would likely be fine because prepared
512+
/// statements _generally_ (see above) are only allowed to contain a single query. This would simply return an error.
513+
///
514+
/// However, it would also break on legitimate user input.
515+
/// What if someone wanted to search for the string `Alice's Apples`? It would also return an error because
516+
/// the database would receive a query with a broken string literal (line breaks added for clarity):
517+
///
518+
/// ```sql
519+
/// SELECT * FROM articles WHERE content LIKE '%Alice'
520+
/// s Apples%'
521+
/// ```
522+
///
523+
/// Of course, it's possible to make this syntactically valid by escaping the apostrophe, but there's a better way.
524+
///
525+
/// ##### You should always prefer query parameters for dynamic input.
526+
///
527+
/// When using query parameters, you add placeholders to your query where a value
528+
/// should be substituted at execution time, then call [`.bind()`][Query::bind] with that value.
529+
///
530+
/// The syntax for placeholders is unfortunately not standardized and depends on the database:
531+
///
532+
/// * Postgres and SQLite: use `$1`, `$2`, `$3`, etc.
533+
/// * The number is the Nth bound value, starting from one.
534+
/// * The same placeholder can be used arbitrarily many times to refer to the same bound value.
535+
/// * SQLite technically supports MySQL's syntax as well as others, but we recommend using this syntax
536+
/// as SQLx's SQLite driver is written with it in mind.
537+
/// * MySQL and MariaDB: use `?`.
538+
/// * Placeholders are purely positional, similar to `println!("{}, {}", foo, bar)`.
539+
/// * The order of bindings must match the order of placeholders in the query.
540+
/// * To use a value in multiple places, you must bind it multiple times.
541+
///
542+
/// In both cases, the placeholder syntax acts as a variable expression representing the bound value:
543+
///
544+
/// ```rust,no_run
545+
/// # async fn example2() -> sqlx::Result<()> {
546+
/// # let mut conn: sqlx::PgConnection = unimplemented!();
547+
/// let user_input = "Alice's Apples";
548+
///
549+
/// // Postgres and SQLite
550+
/// let results = sqlx::query(
551+
/// // Notice how we only have to bind the argument once and we can use it multiple times:
552+
/// "SELECT * FROM articles
553+
/// WHERE title LIKE '%' || $1 || '%'
554+
/// OR content LIKE '%' || $1 || '%'"
555+
/// )
556+
/// .bind(user_input)
557+
/// .fetch_all(&mut conn)
558+
/// .await?;
559+
///
560+
/// // MySQL and MariaDB
561+
/// let results = sqlx::query(
562+
/// "SELECT * FROM articles
563+
/// WHERE title LIKE CONCAT('%', ?, '%')
564+
/// OR content LIKE CONCAT('%', ?, '%')"
565+
/// )
566+
/// // If we want to reference the same value multiple times, we have to bind it multiple times:
567+
/// .bind(user_input)
568+
/// .bind(user_input)
569+
/// .fetch_all(&mut conn)
570+
/// .await?;
571+
/// # Ok(())
572+
/// # }
573+
/// ```
574+
/// ##### The value bound to a query parameter is entirely separate from the query and does not affect its syntax.
575+
/// Thus, SQL injection is impossible (barring shenanigans like calling a SQL function that lets you execute a string
576+
/// as a statement) and *all* strings are valid.
577+
///
578+
/// This also means you cannot use query parameters to add conditional SQL fragments.
579+
///
580+
/// **SQLx does not substitute placeholders on the client side**. It is done by the database server itself.
581+
///
582+
/// ##### SQLx supports many different types for parameter binding, not just strings.
583+
/// Any type that implements [`Encode<DB>`][Encode] and [`Type<DB>`] can be bound as a parameter.
584+
///
585+
/// See [the `types` module][crate::types] (links to `sqlx_core::types` but you should use `sqlx::types`) for details.
586+
///
587+
/// As an additional benefit, query parameters are usually sent in a compact binary encoding instead of a human-readable
588+
/// text encoding, which saves bandwidth.
430589
pub fn query<DB>(sql: &str) -> Query<'_, DB, <DB as HasArguments<'_>>::Arguments>
431590
where
432591
DB: Database,
@@ -439,7 +598,9 @@ where
439598
}
440599
}
441600

442-
/// Make a SQL query, with the given arguments.
601+
/// Execute a SQL query as a prepared statement (transparently cached), with the given arguments.
602+
///
603+
/// See [`query()`][query] for details, such as supported syntax.
443604
pub fn query_with<'q, DB, A>(sql: &'q str, arguments: A) -> Query<'q, DB, A>
444605
where
445606
DB: Database,

0 commit comments

Comments
 (0)