1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 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(<DATABASE URL>)");
///
/// 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<&<DB as HasStatement<'q>>::Statement> {
None
}
fn take_arguments(&mut self) -> Option<<DB as HasArguments<'q>>::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<<E::Database as Database>::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<<E::Database as Database>::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<<E::Database as Database>::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<<E::Database as Database>::QueryResult, <E::Database as Database>::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<Vec<<E::Database as Database>::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<<E::Database as Database>::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<<E::Database as Database>::Row>
where
'q: 'e,
E: Executor<'e>,
{
executor.fetch_one(self).await
}
}