From b01d530dfcd2489dbfac8b1335c2ae0c5eb24584 Mon Sep 17 00:00:00 2001 From: Austin Bonander Date: Mon, 22 Jan 2024 19:53:02 -0800 Subject: [PATCH] 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. --- sqlx-core/src/lib.rs | 2 + sqlx-core/src/query.rs | 221 ++++++++++++++++++++++++++-- sqlx-core/src/query_as.rs | 193 ++++++++++++++++++++++-- sqlx-core/src/query_scalar.rs | 181 +++++++++++++++++++++-- sqlx-core/src/raw_sql.rs | 267 ++++++++++++++++++++++++++++++++++ src/lib.rs | 1 + tests/mysql/mysql.rs | 6 +- tests/postgres/postgres.rs | 3 +- tests/sqlite/sqlite.rs | 2 +- 9 files changed, 839 insertions(+), 37 deletions(-) create mode 100644 sqlx-core/src/raw_sql.rs diff --git a/sqlx-core/src/lib.rs b/sqlx-core/src/lib.rs index 468242e9e6..34c871729e 100644 --- a/sqlx-core/src/lib.rs +++ b/sqlx-core/src/lib.rs @@ -74,6 +74,8 @@ pub mod net; pub mod query_as; pub mod query_builder; pub mod query_scalar; + +pub mod raw_sql; pub mod row; pub mod rt; pub mod sync; diff --git a/sqlx-core/src/query.rs b/sqlx-core/src/query.rs index 2d7a1c9b15..4403fae006 100644 --- a/sqlx-core/src/query.rs +++ b/sqlx-core/src/query.rs @@ -12,7 +12,7 @@ use crate::executor::{Execute, Executor}; use crate::statement::Statement; use crate::types::Type; -/// Raw SQL query with bind parameters. Returned by [`query`][crate::query::query]. +/// A single SQL query as a prepared statement. Returned by [`query()`]. #[must_use = "query must be executed to affect database"] pub struct Query<'q, DB: Database, A> { pub(crate) statement: Either<&'q str, &'q >::Statement>, @@ -21,7 +21,9 @@ pub struct Query<'q, DB: Database, A> { pub(crate) persistent: bool, } -/// SQL query that will map its results to owned Rust types. +/// A single SQL query that will map its results to an owned Rust type. +/// +/// Executes as a prepared statement. /// /// Returned by [`Query::try_map`], `query!()`, etc. Has most of the same methods as [`Query`] but /// the return types are changed to reflect the mapping. However, there is no equivalent of @@ -96,6 +98,8 @@ where /// matching the one with the flag will use the cached statement until the /// cache is cleared. /// + /// If `false`, the prepared statement will be closed after execution. + /// /// Default: `true`. pub fn persistent(mut self, value: bool) -> Self { self.persistent = value; @@ -155,6 +159,7 @@ where /// Execute multiple queries and return the rows affected from each query, in a stream. #[inline] + #[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."] pub async fn execute_many<'e, 'c: 'e, E>( self, executor: E, @@ -178,9 +183,13 @@ where executor.fetch(self) } - /// Execute multiple queries and return the generated results as a stream - /// from each query, in a stream. + /// Execute multiple queries and return the generated results as a stream. + /// + /// For each query in the stream, any generated rows are returned first, + /// then the `QueryResult` with the number of rows affected. #[inline] + #[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."] + // TODO: we'll probably still want a way to get the `DB::QueryResult` at the end of a `fetch()` stream. pub fn fetch_many<'e, 'c: 'e, E>( self, executor: E, @@ -193,7 +202,13 @@ where executor.fetch_many(self) } - /// Execute the query and return all the generated results, collected into a [`Vec`]. + /// Execute the query and return all the resulting rows collected into a [`Vec`]. + /// + /// ### Note: beware result set size. + /// This will attempt to collect the full result set of the query into memory. + /// + /// To avoid exhausting available memory, ensure the result set has a known upper bound, + /// e.g. using `LIMIT`. #[inline] pub async fn fetch_all<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where @@ -204,7 +219,18 @@ where executor.fetch_all(self).await } - /// Execute the query and returns exactly one row. + /// Execute the query, returning the first row or [`Error::RowNotFound`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. #[inline] pub async fn fetch_one<'e, 'c: 'e, E>(self, executor: E) -> Result where @@ -215,7 +241,18 @@ where executor.fetch_one(self).await } - /// Execute the query and returns at most one row. + /// Execute the query, returning the first row or `None` otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. #[inline] pub async fn fetch_optional<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where @@ -307,6 +344,9 @@ where F: 'e, O: 'e, { + // FIXME: this should have used `executor.fetch()` but that's a breaking change + // because this technically allows multiple statements in one query string. + #[allow(deprecated)] self.fetch_many(executor) .try_filter_map(|step| async move { Ok(match step { @@ -319,6 +359,7 @@ where /// Execute multiple queries and return the generated results as a stream /// from each query, in a stream. + #[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."] pub fn fetch_many<'e, 'c: 'e, E>( mut self, executor: E, @@ -346,7 +387,13 @@ where }) } - /// Execute the query and return all the generated results, collected into a [`Vec`]. + /// Execute the query and return all the resulting rows collected into a [`Vec`]. + /// + /// ### Note: beware result set size. + /// This will attempt to collect the full result set of the query into memory. + /// + /// To avoid exhausting available memory, ensure the result set has a known upper bound, + /// e.g. using `LIMIT`. pub async fn fetch_all<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where 'q: 'e, @@ -358,7 +405,18 @@ where self.fetch(executor).try_collect().await } - /// Execute the query and returns exactly one row. + /// Execute the query, returning the first row or [`Error::RowNotFound`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. pub async fn fetch_one<'e, 'c: 'e, E>(self, executor: E) -> Result where 'q: 'e, @@ -375,7 +433,18 @@ where .await } - /// Execute the query and returns at most one row. + /// Execute the query, returning the first row or `None` otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. pub async fn fetch_optional<'e, 'c: 'e, E>(mut self, executor: E) -> Result, Error> where 'q: 'e, @@ -394,7 +463,7 @@ where } } -// Make a SQL query from a statement. +/// Execute a single SQL query as a prepared statement (explicitly created). pub fn query_statement<'q, DB>( statement: &'q >::Statement, ) -> Query<'q, DB, >::Arguments> @@ -409,7 +478,7 @@ where } } -// Make a SQL query from a statement, with the given arguments. +/// Execute a single SQL query as a prepared statement (explicitly created), with the given arguments. pub fn query_statement_with<'q, DB, A>( statement: &'q >::Statement, arguments: A, @@ -426,7 +495,129 @@ where } } -/// Make a SQL query. +/// Execute a single SQL query as a prepared statement (transparently cached). +/// +/// The query string may only contain a single DML statement: `SELECT`, `INSERT`, `UPDATE`, `DELETE` and variants. +/// The SQLite driver does not currently follow this restriction, but that behavior is deprecated. +/// +/// The connection will transparently prepare and cache the statement, which means it only needs to be parsed once +/// in the connection's lifetime, and any generated query plans can be retained. +/// Thus, the overhead of executing the statement is amortized. +/// +/// Some third-party databases that speak a supported protocol, e.g. CockroachDB or PGBouncer that speak Postgres, +/// may have issues with the transparent caching of prepared statements. If you are having trouble, +/// try setting [`.persistent(false)`][Query::persistent]. +/// +/// See the [`Query`] type for the methods you may call. +/// +/// ### Dynamic Input: Use Query Parameters (Prevents SQL Injection) +/// At some point, you'll likely want to include some form of dynamic input in your query, possibly from the user. +/// +/// Your first instinct might be to do something like this: +/// ```rust,no_run +/// # async fn example() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// // Imagine this is input from the user, e.g. a search form on a website. +/// let user_input = "possibly untrustworthy input!"; +/// +/// // DO NOT DO THIS unless you're ABSOLUTELY CERTAIN it's what you need! +/// let query = format!("SELECT * FROM articles WHERE content LIKE '%{user_input}%'"); +/// // where `conn` is `PgConnection` or `MySqlConnection` +/// // or some other type that implements `Executor`. +/// let results = sqlx::query(&query).fetch_all(&mut conn).await?; +/// # } +/// ``` +/// +/// The example above showcases a **SQL injection vulnerability**, because it's trivial for a malicious user to craft +/// an input that can "break out" of the string literal. +/// +/// For example, if they send the input `foo'; DELETE FROM articles; --` +/// then your application would send the following to the database server (line breaks added for clarity): +/// +/// ```sql +/// SELECT * FROM articles WHERE content LIKE '%foo'; +/// DELETE FROM articles; +/// --%' +/// ``` +/// +/// In this case, because this interface *always* uses prepared statements, you would likely be fine because prepared +/// statements _generally_ (see above) are only allowed to contain a single query. This would simply return an error. +/// +/// However, it would also break on legitimate user input. +/// What if someone wanted to search for the string `Alice's Apples`? It would also return an error because +/// the database would receive a query with a broken string literal (line breaks added for clarity): +/// +/// ```sql +/// SELECT * FROM articles WHERE content LIKE '%Alice' +/// s Apples%' +/// ``` +/// +/// Of course, it's possible to make this syntactically valid by escaping the apostrophe, but there's a better way. +/// +/// ##### You should always prefer query parameters for dynamic input. +/// +/// When using query parameters, you add placeholders to your query where a value +/// should be substituted at execution time, then call [`.bind()`][Query::bind] with that value. +/// +/// The syntax for placeholders is unfortunately not standardized and depends on the database: +/// +/// * Postgres and SQLite: use `$1`, `$2`, `$3`, etc. +/// * The number is the Nth bound value, starting from one. +/// * The same placeholder can be used arbitrarily many times to refer to the same bound value. +/// * SQLite technically supports MySQL's syntax as well as others, but we recommend using this syntax +/// as SQLx's SQLite driver is written with it in mind. +/// * MySQL and MariaDB: use `?`. +/// * Placeholders are purely positional, similar to `println!("{}, {}", foo, bar)`. +/// * The order of bindings must match the order of placeholders in the query. +/// * To use a value in multiple places, you must bind it multiple times. +/// +/// In both cases, the placeholder syntax acts as a variable expression representing the bound value: +/// +/// ```rust,no_run +/// # async fn example2() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// let user_input = "Alice's Apples"; +/// +/// // Postgres and SQLite +/// let results = sqlx::query( +/// // Notice how we only have to bind the argument once and we can use it multiple times: +/// "SELECT * FROM articles +/// WHERE title LIKE '%' || $1 || '%' +/// OR content LIKE '%' || $1 || '%'" +/// ) +/// .bind(user_input) +/// .fetch_all(&mut conn) +/// .await?; +/// +/// // MySQL and MariaDB +/// let results = sqlx::query( +/// "SELECT * FROM articles +/// WHERE title LIKE CONCAT('%', ?, '%') +/// OR content LIKE CONCAT('%', ?, '%')" +/// ) +/// // If we want to reference the same value multiple times, we have to bind it multiple times: +/// .bind(user_input) +/// .bind(user_input) +/// .fetch_all(&mut conn) +/// .await?; +/// # Ok(()) +/// # } +/// ``` +/// ##### The value bound to a query parameter is entirely separate from the query and does not affect its syntax. +/// Thus, SQL injection is impossible (barring shenanigans like calling a SQL function that lets you execute a string +/// as a statement) and *all* strings are valid. +/// +/// This also means you cannot use query parameters to add conditional SQL fragments. +/// +/// **SQLx does not substitute placeholders on the client side**. It is done by the database server itself. +/// +/// ##### SQLx supports many different types for parameter binding, not just strings. +/// Any type that implements [`Encode`][Encode] and [`Type`] can be bound as a parameter. +/// +/// See [the `types` module][crate::types] (links to `sqlx_core::types` but you should use `sqlx::types`) for details. +/// +/// As an additional benefit, query parameters are usually sent in a compact binary encoding instead of a human-readable +/// text encoding, which saves bandwidth. pub fn query(sql: &str) -> Query<'_, DB, >::Arguments> where DB: Database, @@ -439,7 +630,9 @@ where } } -/// Make a SQL query, with the given arguments. +/// Execute a SQL query as a prepared statement (transparently cached), with the given arguments. +/// +/// See [`query()`][query] for details, such as supported syntax. pub fn query_with<'q, DB, A>(sql: &'q str, arguments: A) -> Query<'q, DB, A> where DB: Database, diff --git a/sqlx-core/src/query_as.rs b/sqlx-core/src/query_as.rs index 43a611cf65..3877c4e401 100644 --- a/sqlx-core/src/query_as.rs +++ b/sqlx-core/src/query_as.rs @@ -13,8 +13,8 @@ use crate::from_row::FromRow; use crate::query::{query, query_statement, query_statement_with, query_with, Query}; use crate::types::Type; -/// Raw SQL query with bind parameters, mapped to a concrete type using [`FromRow`]. -/// Returned from [`query_as`][crate::query_as::query_as]. +/// A single SQL query as a prepared statement, mapping results using [`FromRow`]. +/// Returned by [`query_as()`]. #[must_use = "query must be executed to affect database"] pub struct QueryAs<'q, DB: Database, O, A> { pub(crate) inner: Query<'q, DB, A>, @@ -68,6 +68,8 @@ where /// matching the one with the flag will use the cached statement until the /// cache is cleared. /// + /// If `false`, the prepared statement will be closed after execution. + /// /// Default: `true`. pub fn persistent(mut self, value: bool) -> Self { self.inner = self.inner.persistent(value); @@ -92,6 +94,9 @@ where O: 'e, A: 'e, { + // FIXME: this should have used `executor.fetch()` but that's a breaking change + // because this technically allows multiple statements in one query string. + #[allow(deprecated)] self.fetch_many(executor) .try_filter_map(|step| async move { Ok(step.right()) }) .boxed() @@ -99,6 +104,7 @@ where /// Execute multiple queries and return the generated results as a stream /// from each query, in a stream. + #[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."] pub fn fetch_many<'e, 'c: 'e, E>( self, executor: E, @@ -120,7 +126,13 @@ where .boxed() } - /// Execute the query and return all the generated results, collected into a [`Vec`]. + /// Execute the query and return all the resulting rows collected into a [`Vec`]. + /// + /// ### Note: beware result set size. + /// This will attempt to collect the full result set of the query into memory. + /// + /// To avoid exhausting available memory, ensure the result set has a known upper bound, + /// e.g. using `LIMIT`. #[inline] pub async fn fetch_all<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where @@ -133,7 +145,18 @@ where self.fetch(executor).try_collect().await } - /// Execute the query and returns exactly one row. + /// Execute the query, returning the first row or [`Error::RowNotFound`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. pub async fn fetch_one<'e, 'c: 'e, E>(self, executor: E) -> Result where 'q: 'e, @@ -147,7 +170,18 @@ where .and_then(|row| row.ok_or(Error::RowNotFound)) } - /// Execute the query and returns at most one row. + /// Execute the query, returning the first row or `None` otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. pub async fn fetch_optional<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where 'q: 'e, @@ -165,8 +199,145 @@ where } } -/// Make a SQL query that is mapped to a concrete type -/// using [`FromRow`]. +/// Execute a single SQL query as a prepared statement (transparently cached). +/// Maps rows to Rust types using [`FromRow`]. +/// +/// For details about prepared statements and allowed SQL syntax, see [`query()`][crate::query::query]. +/// +/// ### Example: Map Rows using Tuples +/// [`FromRow`] is implemented for tuples of up to 16 elements1. +/// Using a tuple of N elements will extract the first N columns from each row using [`Decode`][crate::decode::Decode]. +/// Any extra columns are ignored. +/// +/// See [`sqlx::types`][crate::types] for the types that can be used. +/// +/// The `FromRow` implementation will check [`Type::compatible()`] for each column to ensure a compatible type mapping +/// is used. If an incompatible mapping is detected, an error is returned. +/// To statically assert compatible types at compile time, see the `query!()` family of macros. +/// +/// **NOTE**: `SELECT *` is not recommended with this approach because the ordering of returned columns may be different +/// than expected, especially when using joins. +/// +/// ```rust,no_run +/// # async fn example1() -> sqlx::Result<()> { +/// use sqlx::Connection; +/// use sqlx::PgConnection; +/// +/// // This example can be applied to any database as it only uses standard types and syntax. +/// let mut conn: PgConnection = PgConnection::connect("").await?; +/// +/// sqlx::raw_sql( +/// "CREATE TABLE users(id INTEGER PRIMARY KEY, username TEXT UNIQUE, created_at TIMESTAMP DEFAULT (now())" +/// ) +/// .execute(&mut conn) +/// .await?; +/// +/// sqlx::query("INSERT INTO users(id, username) VALUES (1, 'alice'), (2, 'bob');") +/// .execute(&mut conn) +/// .await?; +/// +/// // Get the first row of the result (note the `LIMIT 1` for efficiency) +/// // This assumes the `time` feature of SQLx is enabled. +/// let oldest_user: (i64, String, time::OffsetDateTime) = sqlx::query_as( +/// "SELECT id, username, created_at FROM users ORDER BY created_at LIMIT 1" +/// ) +/// .fetch_one(&mut conn) +/// .await?; +/// +/// assert_eq!(oldest_user.0, 1); +/// assert_eq!(oldest_user.1, "alice"); +/// +/// // Get at most one row +/// let maybe_charlie: Option<(i64, String, time::OffsetDateTime)> = sqlx::query_as( +/// "SELECT id, username, created_at FROM users WHERE username = 'charlie'" +/// ) +/// .fetch_optional(&mut conn) +/// .await?; +/// +/// assert_eq!(maybe_charlie, None); +/// +/// // Get all rows in result (Beware of the size of the result set! Consider using `LIMIT`) +/// let users: Vec<(i64, String, time::OffsetDateTime)> = sqlx::query_as( +/// "SELECT id, username, created_at FROM users ORDER BY id" +/// ) +/// .fetch_all(&mut conn) +/// .await?; +/// +/// println!("{users:?}"); +/// # Ok(()) +/// # } +/// ``` +/// +/// 1: It's impossible in Rust to implement a trait for tuples of arbitrary size. +/// For larger result sets, either use an explicit struct (see below) or use [`query()`][crate::query::query] +/// instead and extract columns dynamically. +/// +/// ### Example: Map Rows using `#[derive(FromRow)]` +/// Using `#[derive(FromRow)]`, we can create a Rust struct to represent our row type +/// so we can look up fields by name instead of tuple index. +/// +/// When querying this way, columns will be matched up to the corresponding fields by name, so `SELECT *` is safe to use. +/// However, you will still want to be aware of duplicate column names in your query when using joins. +/// +/// The derived `FromRow` implementation will check [`Type::compatible()`] for each column to ensure a compatible type +/// mapping is used. If an incompatible mapping is detected, an error is returned. +/// To statically assert compatible types at compile time, see the `query!()` family of macros. +/// +/// An error will also be returned if an expected column is missing from the result set. +/// +/// `#[derive(FromRow)]` supports several control attributes which can be used to change how column names and types +/// are mapped. See [`FromRow`] for details. +/// +/// Using our previous table definition, we can convert our queries like so: +/// ```rust,no_run +/// # async fn example2() -> sqlx::Result<()> { +/// use sqlx::Connection; +/// use sqlx::PgConnection; +/// +/// use time::OffsetDateTime; +/// +/// #[derive(sqlx::FromRow, Debug, PartialEq, Eq)] +/// struct User { +/// id: i64, +/// username: String, +/// // Note: the derive won't compile if the `time` feature of SQLx is not enabled. +/// created_at: OffsetDateTime, +/// } +/// +/// let mut conn: PgConnection = PgConnection::connect("").await?; +/// +/// // Get the first row of the result (note the `LIMIT 1` for efficiency) +/// let oldest_user: User = sqlx::query_as( +/// "SELECT id, username, created_at FROM users ORDER BY created_at LIMIT 1" +/// ) +/// .fetch_one(&mut conn) +/// .await?; +/// +/// assert_eq!(oldest_user.id, 1); +/// assert_eq!(oldest_user.username, "alice"); +/// +/// // Get at most one row +/// let maybe_charlie: Option = sqlx::query_as( +/// "SELECT id, username, created_at FROM users WHERE username = 'charlie'" +/// ) +/// .fetch_optional(&mut conn) +/// .await?; +/// +/// assert_eq!(maybe_charlie, None); +/// +/// // Get all rows in result (Beware of the size of the result set! Consider using `LIMIT`) +/// let users: Vec = sqlx::query_as( +/// "SELECT id, username, created_at FROM users ORDER BY id" +/// ) +/// .fetch_all(&mut conn) +/// .await?; +/// +/// assert_eq!(users[1].id, 2); +/// assert_eq!(users[1].username, "bob"); +/// # Ok(()) +/// # } +/// +/// ``` #[inline] pub fn query_as<'q, DB, O>(sql: &'q str) -> QueryAs<'q, DB, O, >::Arguments> where @@ -179,8 +350,12 @@ where } } -/// Make a SQL query, with the given arguments, that is mapped to a concrete type -/// using [`FromRow`]. +/// Execute a single SQL query, with the given arguments as a prepared statement (transparently cached). +/// Maps rows to Rust types using [`FromRow`]. +/// +/// For details about prepared statements and allowed SQL syntax, see [`query()`][crate::query::query]. +/// +/// For details about type mapping from [`FromRow`], see [`query_as()`]. #[inline] pub fn query_as_with<'q, DB, O, A>(sql: &'q str, arguments: A) -> QueryAs<'q, DB, O, A> where diff --git a/sqlx-core/src/query_scalar.rs b/sqlx-core/src/query_scalar.rs index 0ef8cbde30..395278a8d9 100644 --- a/sqlx-core/src/query_scalar.rs +++ b/sqlx-core/src/query_scalar.rs @@ -13,8 +13,8 @@ use crate::query_as::{ }; use crate::types::Type; -/// Raw SQL query with bind parameters, mapped to a concrete type using [`FromRow`] on `(O,)`. -/// Returned from [`query_scalar`]. +/// A single SQL query as a prepared statement which extracts only the first column of each row. +/// Returned by [`query_scalar()`]. #[must_use = "query must be executed to affect database"] pub struct QueryScalar<'q, DB: Database, O, A> { pub(crate) inner: QueryAs<'q, DB, (O,), A>, @@ -40,7 +40,7 @@ where #[inline] fn persistent(&self) -> bool { - self.inner.persistent() + Execute::persistent(&self.inner) } } @@ -65,6 +65,8 @@ where /// matching the one with the flag will use the cached statement until the /// cache is cleared. /// + /// If `false`, the prepared statement will be closed after execution. + /// /// Default: `true`. pub fn persistent(mut self, value: bool) -> Self { self.inner = self.inner.persistent(value); @@ -97,6 +99,7 @@ where /// Execute multiple queries and return the generated results as a stream /// from each query, in a stream. #[inline] + #[deprecated = "Only the SQLite driver supports multiple statements in one prepared statement and that behavior is deprecated. Use `sqlx::raw_sql()` instead."] pub fn fetch_many<'e, 'c: 'e, E>( self, executor: E, @@ -108,13 +111,20 @@ where A: 'e, O: 'e, { + #[allow(deprecated)] self.inner .fetch_many(executor) .map_ok(|v| v.map_right(|it| it.0)) .boxed() } - /// Execute the query and return all the generated results, collected into a [`Vec`]. + /// Execute the query and return all the resulting rows collected into a [`Vec`]. + /// + /// ### Note: beware result set size. + /// This will attempt to collect the full result set of the query into memory. + /// + /// To avoid exhausting available memory, ensure the result set has a known upper bound, + /// e.g. using `LIMIT`. #[inline] pub async fn fetch_all<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where @@ -131,7 +141,18 @@ where .await } - /// Execute the query and returns exactly one row. + /// Execute the query, returning the first row or [`Error::RowNotFound`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. #[inline] pub async fn fetch_one<'e, 'c: 'e, E>(self, executor: E) -> Result where @@ -144,7 +165,18 @@ where self.inner.fetch_one(executor).map_ok(|it| it.0).await } - /// Execute the query and returns at most one row. + /// Execute the query, returning the first row or `None` otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns at most one row + /// can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. #[inline] pub async fn fetch_optional<'e, 'c: 'e, E>(self, executor: E) -> Result, Error> where @@ -158,8 +190,133 @@ where } } -/// Make a SQL query that is mapped to a single concrete type -/// using [`FromRow`]. +/// Execute a single SQL query as a prepared statement (transparently cached) and extract the first +/// column of each row. +/// +/// Extracts the first column of each row. Additional columns are ignored. +/// Any type that implements `Type + Decode` may be used. +/// +/// For details about prepared statements and allowed SQL syntax, see [`query()`][crate::query::query]. +/// +/// ### Example: Simple Lookup +/// If you just want to look up a single value with little fanfare, this API is perfect for you: +/// +/// ```rust,no_run +/// # async fn example_lookup() -> Result<(), Box> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// use uuid::Uuid; +/// +/// // MySQL and MariaDB: use `?` +/// let user_id: Option = sqlx::query_scalar("SELECT user_id FROM users WHERE username = $1") +/// .bind("alice") +/// // Use `&mut` where `conn` is a connection or a transaction, or use `&` for a `Pool`. +/// .fetch_optional(&mut conn) +/// .await?; +/// +/// let user_id = user_id.ok_or("unknown user")?; +/// +/// # Ok(()) +/// # } +/// ``` +/// +/// Note how we're using `.fetch_optional()` because the lookup may return no results, +/// in which case we need to be able to handle an empty result set. +/// Any rows after the first are ignored. +/// +/// ### Example: `COUNT` +/// This API is the easiest way to invoke an aggregate query like `SELECT COUNT(*)`, because you +/// can conveniently extract the result: +/// +/// ```rust,no_run +/// # async fn example_count() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// // Note that `usize` is not used here because unsigned integers are generally not supported, +/// // and `usize` doesn't even make sense as a mapping because the database server may have +/// // a completely different architecture. +/// // +/// // `i64` is generally a safe choice for `COUNT`. +/// let count: i64 = sqlx::query_scalar("SELECT COUNT(*) FROM users WHERE accepted_tos IS TRUE") +/// // Use `&mut` where `conn` is a connection or a transaction, or use `&` for a `Pool`. +/// .fetch_one(&mut conn) +/// .await?; +/// +/// // The above is functionally equivalent to the following: +/// // Note the trailing comma, required for the compiler to recognize a 1-element tuple. +/// let (count,): (i64,) = sqlx::query_as("SELECT COUNT(*) FROM users WHERE accepted_tos IS TRUE") +/// .fetch_one(&mut conn) +/// .await?; +/// # Ok(()) +/// # } +/// ``` +/// +/// ### Example: `EXISTS` +/// To test if a row exists or not, use `SELECT EXISTS()`: +/// +/// ```rust,no_run +/// # async fn example_exists() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// // MySQL and MariaDB: use `?` +/// let username_taken: bool = sqlx::query_scalar( +/// "SELECT EXISTS(SELECT 1 FROM users WHERE username = $1)" +/// ) +/// .bind("alice") +/// // Use `&mut` where `conn` is a connection or a transaction, or use `&` for a `Pool`. +/// .fetch_one(&mut conn) +/// .await?; +/// # Ok(()) +/// # } +/// ``` +/// +/// ### Example: Other Aggregates +/// Be aware that most other aggregate functions return `NULL` if the query yields an empty set: +/// +/// ```rust,no_run +/// # async fn example_aggregate() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// let max_upvotes: Option = sqlx::query_scalar("SELECT MAX(upvotes) FROM posts") +/// // Use `&mut` where `conn` is a connection or a transaction, or use `&` for a `Pool`. +/// .fetch_one(&mut conn) +/// .await?; +/// # Ok(()) +/// # } +/// ``` +/// +/// Note how we're using `Option` with `.fetch_one()`, because we're always expecting one row +/// but the column value may be `NULL`. If no rows are returned, this will error. +/// +/// This is in contrast to using `.fetch_optional()` with `Option`, which implies that +/// we're expecting _either_ a row with a `i64` (`BIGINT`), _or_ no rows at all. +/// +/// Either way, any rows after the first are ignored. +/// +/// ### Example: `Vec` of Scalars +/// If you want to collect a single column from a query into a vector, +/// try `.fetch_all()`: +/// +/// ```rust,no_run +/// # async fn example_vec() -> sqlx::Result<()> { +/// # let mut conn: sqlx::PgConnection = unimplemented!(); +/// let top_users: Vec = sqlx::query_scalar( +/// // Note the `LIMIT` to ensure that this doesn't return *all* users: +/// "SELECT username +/// FROM ( +/// SELECT SUM(upvotes) total, user_id +/// FROM posts +/// GROUP BY user_id +/// ) top_users +/// INNER JOIN users USING (user_id) +/// ORDER BY total DESC +/// LIMIT 10" +/// ) +/// // Use `&mut` where `conn` is a connection or a transaction, or use `&` for a `Pool`. +/// .fetch_all(&mut conn) +/// .await?; +/// +/// // `top_users` could be empty, too. +/// assert!(top_users.len() <= 10); +/// # Ok(()) +/// # } +/// ``` #[inline] pub fn query_scalar<'q, DB, O>( sql: &'q str, @@ -173,8 +330,12 @@ where } } -/// Make a SQL query, with the given arguments, that is mapped to a single concrete type -/// using [`FromRow`]. +/// Execute a SQL query as a prepared statement (transparently cached), with the given arguments, +/// and extract the first column of each row. +/// +/// See [`query_scalar()`] for details. +/// +/// For details about prepared statements and allowed SQL syntax, see [`query()`][crate::query::query]. #[inline] pub fn query_scalar_with<'q, DB, O, A>(sql: &'q str, arguments: A) -> QueryScalar<'q, DB, O, A> where diff --git a/sqlx-core/src/raw_sql.rs b/sqlx-core/src/raw_sql.rs new file mode 100644 index 0000000000..48162f2c3b --- /dev/null +++ b/sqlx-core/src/raw_sql.rs @@ -0,0 +1,267 @@ +use crate::database::{Database, HasArguments, HasStatement}; +use crate::executor::{Execute, Executor}; +use crate::Error; +use either::Either; +use futures_core::stream::BoxStream; + +// AUTHOR'S NOTE: I was just going to call this API `sql()` and `Sql`, respectively, +// but realized that would be extremely annoying to deal with as a SQLite user +// because IDE smart completion would always recommend the `Sql` type first. +// +// It doesn't really need a super convenient name anyway as it's not meant to be used very often. + +/// One or more raw SQL statements, separated by semicolons (`;`). +/// +/// See [`raw_sql()`] for details. +pub struct RawSql<'q>(&'q str); + +/// Execute one or more statements as raw SQL, separated by semicolons (`;`). +/// +/// This interface can be used to execute both DML +/// (Data Manipulation Language: `SELECT`, `INSERT`, `UPDATE`, `DELETE` and variants) +/// as well as DDL (Data Definition Language: `CREATE TABLE`, `ALTER TABLE`, etc). +/// +/// This will not create or cache any prepared statements. +/// +/// ### Note: singular DML queries, prefer `query()` +/// This API does not use prepared statements, so usage of it is missing out on their benefits. +/// +/// Prefer [`query()`][crate::query::query] instead if executing a single query. +/// +/// It's also possible to combine multiple DML queries into one for use with `query()`: +/// +/// ##### Common Table Expressions (CTEs: i.e The `WITH` Clause) +/// Common Table Expressions effectively allow you to define aliases for queries +/// that can be referenced like temporary tables: +/// +/// ```sql +/// WITH inserted_foos AS ( +/// -- Note that only Postgres allows data-modifying statements in CTEs +/// INSERT INTO foo (bar_id) VALUES ($1) +/// RETURNING foo_id, bar_id +/// ) +/// SELECT foo_id, bar_id, bar +/// FROM inserted_foos +/// INNER JOIN bar USING (bar_id) +/// ``` +/// +/// It's important to note that data modifying statements (`INSERT`, `UPDATE`, `DELETE`) may +/// behave differently than expected. In Postgres, all data-modifying subqueries in a `WITH` +/// clause execute with the same view of the data; they *cannot* see each other's modifications. +/// +/// MySQL, MariaDB and SQLite appear to *only* allow `SELECT` statements in CTEs. +/// +/// See the appropriate entry in your database's manual for details: +/// * [MySQL](https://dev.mysql.com/doc/refman/8.0/en/with.html) +/// * [MariaDB](https://mariadb.com/kb/en/with/) +/// * [Postgres](https://www.postgresql.org/docs/current/queries-with.html) +/// * [SQLite](https://www.sqlite.org/lang_with.html) +/// +/// ##### `UNION`/`INTERSECT`/`EXCEPT` +/// You can also use various set-theory operations on queries, +/// including `UNION ALL` which simply concatenates their results. +/// +/// See the appropriate entry in your database's manual for details: +/// * [MySQL](https://dev.mysql.com/doc/refman/8.0/en/set-operations.html) +/// * [MariaDB](https://mariadb.com/kb/en/joins-subqueries/) +/// * [Postgres](https://www.postgresql.org/docs/current/queries-union.html) +/// * [SQLite](https://www.sqlite.org/lang_select.html#compound_select_statements) +/// +/// ### Note: query parameters are not supported. +/// Query parameters require the use of prepared statements which this API does support. +/// +/// If you require dynamic input data in your SQL, you can use `format!()` but **be very careful +/// doing this with user input**. SQLx does **not** provide escaping or sanitization for inserting +/// dynamic input into queries this way. +/// +/// See [`query()`][crate::query::query] for details. +/// +/// ### Note: multiple statements and autocommit. +/// By default, when you use this API to execute a SQL string containing multiple statements +/// separated by semicolons (`;`), the database server will treat those statements as all executing +/// within the same transaction block, i.e. wrapped in `BEGIN` and `COMMIT`: +/// +/// ```rust,no_run +/// # async fn example() -> sqlx::Result<()> { +/// let mut conn: sqlx::PgConnection = todo!("e.g. PgConnection::connect()"); +/// +/// sqlx::raw_sql( +/// // Imagine we're moving data from one table to another: +/// // Implicit `BEGIN;` +/// "UPDATE foo SET bar = foobar.bar FROM foobar WHERE foobar.foo_id = foo.id;\ +/// DELETE FROM foobar;" +/// // Implicit `COMMIT;` +/// ) +/// .execute(&mut conn) +/// .await?; +/// +/// # Ok(()) +/// # } +/// ``` +/// +/// If one statement triggers an error, the whole script aborts and rolls back. +/// You can include explicit `BEGIN` and `COMMIT` statements in the SQL string +/// to designate units that can be committed or rolled back piecemeal. +/// +/// This also allows for a rudimentary form of pipelining as the whole SQL string is sent in one go. +/// +/// ##### MySQL and MariaDB: DDL implicitly commits! +/// MySQL and MariaDB do not support DDL in transactions. Instead, any active transaction is +/// immediately and implicitly committed by the database server when executing a DDL statement. +/// Beware of this behavior. +/// +/// See [MySQL manual, section 13.3.3: Statements That Cause an Implicit Commit](https://dev.mysql.com/doc/refman/8.0/en/implicit-commit.html) for details. +/// See also: [MariaDB manual: SQL statements That Cause an Implicit Commit](https://mariadb.com/kb/en/sql-statements-that-cause-an-implicit-commit/). +pub fn raw_sql(sql: &str) -> RawSql<'_> { + RawSql(sql) +} + +impl<'q, DB: Database> Execute<'q, DB> for RawSql<'q> { + fn sql(&self) -> &'q str { + self.0 + } + + fn statement(&self) -> Option<&>::Statement> { + None + } + + fn take_arguments(&mut self) -> Option<>::Arguments> { + None + } + + fn persistent(&self) -> bool { + false + } +} + +impl<'q> RawSql<'q> { + /// Execute the SQL string and return the total number of rows affected. + #[inline] + pub async fn execute<'e, E>( + self, + executor: E, + ) -> crate::Result<::QueryResult> + where + 'q: 'e, + E: Executor<'e>, + { + executor.execute(self).await + } + + /// Execute the SQL string. Returns a stream which gives the number of rows affected for each statement in the string. + #[inline] + pub fn execute_many<'e, E>( + self, + executor: E, + ) -> BoxStream<'e, crate::Result<::QueryResult>> + where + 'q: 'e, + E: Executor<'e>, + { + executor.execute_many(self) + } + + /// Execute the SQL string and return the generated results as a stream. + /// + /// If the string contains multiple statements, their results will be concatenated together. + #[inline] + pub fn fetch<'e, E>( + self, + executor: E, + ) -> BoxStream<'e, Result<::Row, Error>> + where + 'q: 'e, + E: Executor<'e>, + { + executor.fetch(self) + } + + /// Execute the SQL string and return the generated results as a stream. + /// + /// For each query in the stream, any generated rows are returned first, + /// then the `QueryResult` with the number of rows affected. + #[inline] + pub fn fetch_many<'e, E>( + self, + executor: E, + ) -> BoxStream< + 'e, + Result< + Either<::QueryResult, ::Row>, + Error, + >, + > + where + 'q: 'e, + E: Executor<'e>, + { + executor.fetch_many(self) + } + + /// Execute the SQL string and return all the resulting rows collected into a [`Vec`]. + /// + /// ### Note: beware result set size. + /// This will attempt to collect the full result set of the query into memory. + /// + /// To avoid exhausting available memory, ensure the result set has a known upper bound, + /// e.g. using `LIMIT`. + #[inline] + pub async fn fetch_all<'e, E>( + self, + executor: E, + ) -> crate::Result::Row>> + where + 'q: 'e, + E: Executor<'e>, + { + executor.fetch_all(self).await + } + + /// Execute the SQL string, returning the first row or [`Error::RowNotFound`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns + /// at most one row can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. + #[inline] + pub async fn fetch_one<'e, E>( + self, + executor: E, + ) -> crate::Result<::Row> + where + 'q: 'e, + E: Executor<'e>, + { + executor.fetch_one(self).await + } + + /// Execute the SQL string, returning the first row or [`None`] otherwise. + /// + /// ### Note: for best performance, ensure the query returns at most one row. + /// Depending on the driver implementation, if your query can return more than one row, + /// it may lead to wasted CPU time and bandwidth on the database server. + /// + /// Even when the driver implementation takes this into account, ensuring the query returns + /// at most one row can result in a more optimal query plan. + /// + /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good. + /// + /// Otherwise, you might want to add `LIMIT 1` to your query. + #[inline] + pub async fn fetch_optional<'e, E>( + self, + executor: E, + ) -> crate::Result<::Row> + where + 'q: 'e, + E: Executor<'e>, + { + executor.fetch_one(self).await + } +} diff --git a/src/lib.rs b/src/lib.rs index c70dfcc66d..5ba95c241f 100644 --- a/src/lib.rs +++ b/src/lib.rs @@ -15,6 +15,7 @@ pub use sqlx_core::query::{query, query_with}; pub use sqlx_core::query_as::{query_as, query_as_with}; pub use sqlx_core::query_builder::{self, QueryBuilder}; pub use sqlx_core::query_scalar::{query_scalar, query_scalar_with}; +pub use sqlx_core::raw_sql::{raw_sql, RawSql}; pub use sqlx_core::row::Row; pub use sqlx_core::statement::Statement; pub use sqlx_core::transaction::{Transaction, TransactionManager}; diff --git a/tests/mysql/mysql.rs b/tests/mysql/mysql.rs index ba10824f89..19a3887c83 100644 --- a/tests/mysql/mysql.rs +++ b/tests/mysql/mysql.rs @@ -327,7 +327,7 @@ async fn it_can_bind_only_null_issue_540() -> anyhow::Result<()> { async fn it_can_bind_and_return_years() -> anyhow::Result<()> { let mut conn = new::().await?; - conn.execute( + sqlx::raw_sql( r#" CREATE TEMPORARY TABLE too_many_years ( id INT PRIMARY KEY AUTO_INCREMENT, @@ -335,6 +335,7 @@ CREATE TEMPORARY TABLE too_many_years ( ); "#, ) + .execute(&mut conn) .await?; sqlx::query( @@ -442,7 +443,8 @@ async fn test_issue_622() -> anyhow::Result<()> { #[sqlx_macros::test] async fn it_can_work_with_transactions() -> anyhow::Result<()> { let mut conn = new::().await?; - conn.execute("CREATE TEMPORARY TABLE users (id INTEGER PRIMARY KEY);") + sqlx::raw_sql("CREATE TEMPORARY TABLE users (id INTEGER PRIMARY KEY);") + .execute(&mut conn) .await?; // begin .. rollback diff --git a/tests/postgres/postgres.rs b/tests/postgres/postgres.rs index 352d3278ea..4f204e8005 100644 --- a/tests/postgres/postgres.rs +++ b/tests/postgres/postgres.rs @@ -49,7 +49,8 @@ async fn it_pings() -> anyhow::Result<()> { async fn it_pings_after_suspended_query() -> anyhow::Result<()> { let mut conn = new::().await?; - conn.execute("create temporary table processed_row(val int4 primary key)") + sqlx::raw_sql("create temporary table processed_row(val int4 primary key)") + .execute(&mut conn) .await?; // This query wants to return 50 rows but we only read the first one. diff --git a/tests/sqlite/sqlite.rs b/tests/sqlite/sqlite.rs index d4cb4b881f..2d0b3267ba 100644 --- a/tests/sqlite/sqlite.rs +++ b/tests/sqlite/sqlite.rs @@ -243,7 +243,7 @@ async fn it_opens_temp_on_disk() -> anyhow::Result<()> { #[sqlx_macros::test] async fn it_fails_to_parse() -> anyhow::Result<()> { let mut conn = new::().await?; - let res = conn.execute("SEELCT 1").await; + let res = sqlx::raw_sql("SEELCT 1").execute(&mut conn).await; assert!(res.is_err());