sqlx_build_trust_core/raw_sql.rs
1use crate::database::{Database, HasArguments, HasStatement};
2use crate::executor::{Execute, Executor};
3use crate::Error;
4use either::Either;
5use futures_core::stream::BoxStream;
6
7// AUTHOR'S NOTE: I was just going to call this API `sql()` and `Sql`, respectively,
8// but realized that would be extremely annoying to deal with as a SQLite user
9// because IDE smart completion would always recommend the `Sql` type first.
10//
11// It doesn't really need a super convenient name anyway as it's not meant to be used very often.
12
13/// One or more raw SQL statements, separated by semicolons (`;`).
14///
15/// See [`raw_sql()`] for details.
16pub struct RawSql<'q>(&'q str);
17
18/// Execute one or more statements as raw SQL, separated by semicolons (`;`).
19///
20/// This interface can be used to execute both DML
21/// (Data Manipulation Language: `SELECT`, `INSERT`, `UPDATE`, `DELETE` and variants)
22/// as well as DDL (Data Definition Language: `CREATE TABLE`, `ALTER TABLE`, etc).
23///
24/// This will not create or cache any prepared statements.
25///
26/// ### Note: singular DML queries, prefer `query()`
27/// This API does not use prepared statements, so usage of it is missing out on their benefits.
28///
29/// Prefer [`query()`][crate::query::query] instead if executing a single query.
30///
31/// It's also possible to combine multiple DML queries into one for use with `query()`:
32///
33/// ##### Common Table Expressions (CTEs: i.e The `WITH` Clause)
34/// Common Table Expressions effectively allow you to define aliases for queries
35/// that can be referenced like temporary tables:
36///
37/// ```sql
38/// WITH inserted_foos AS (
39/// -- Note that only Postgres allows data-modifying statements in CTEs
40/// INSERT INTO foo (bar_id) VALUES ($1)
41/// RETURNING foo_id, bar_id
42/// )
43/// SELECT foo_id, bar_id, bar
44/// FROM inserted_foos
45/// INNER JOIN bar USING (bar_id)
46/// ```
47///
48/// It's important to note that data modifying statements (`INSERT`, `UPDATE`, `DELETE`) may
49/// behave differently than expected. In Postgres, all data-modifying subqueries in a `WITH`
50/// clause execute with the same view of the data; they *cannot* see each other's modifications.
51///
52/// MySQL, MariaDB and SQLite appear to *only* allow `SELECT` statements in CTEs.
53///
54/// See the appropriate entry in your database's manual for details:
55/// * [MySQL](https://dev.mysql.com/doc/refman/8.0/en/with.html)
56/// * [MariaDB](https://mariadb.com/kb/en/with/)
57/// * [Postgres](https://www.postgresql.org/docs/current/queries-with.html)
58/// * [SQLite](https://www.sqlite.org/lang_with.html)
59///
60/// ##### `UNION`/`INTERSECT`/`EXCEPT`
61/// You can also use various set-theory operations on queries,
62/// including `UNION ALL` which simply concatenates their results.
63///
64/// See the appropriate entry in your database's manual for details:
65/// * [MySQL](https://dev.mysql.com/doc/refman/8.0/en/set-operations.html)
66/// * [MariaDB](https://mariadb.com/kb/en/joins-subqueries/)
67/// * [Postgres](https://www.postgresql.org/docs/current/queries-union.html)
68/// * [SQLite](https://www.sqlite.org/lang_select.html#compound_select_statements)
69///
70/// ### Note: query parameters are not supported.
71/// Query parameters require the use of prepared statements which this API does support.
72///
73/// If you require dynamic input data in your SQL, you can use `format!()` but **be very careful
74/// doing this with user input**. SQLx does **not** provide escaping or sanitization for inserting
75/// dynamic input into queries this way.
76///
77/// See [`query()`][crate::query::query] for details.
78///
79/// ### Note: multiple statements and autocommit.
80/// By default, when you use this API to execute a SQL string containing multiple statements
81/// separated by semicolons (`;`), the database server will treat those statements as all executing
82/// within the same transaction block, i.e. wrapped in `BEGIN` and `COMMIT`:
83///
84/// ```rust,no_run
85/// # async fn example() -> sqlx::Result<()> {
86/// let mut conn: sqlx::PgConnection = todo!("e.g. PgConnection::connect(<DATABASE URL>)");
87///
88/// sqlx::raw_sql(
89/// // Imagine we're moving data from one table to another:
90/// // Implicit `BEGIN;`
91/// "UPDATE foo SET bar = foobar.bar FROM foobar WHERE foobar.foo_id = foo.id;\
92/// DELETE FROM foobar;"
93/// // Implicit `COMMIT;`
94/// )
95/// .execute(&mut conn)
96/// .await?;
97///
98/// # Ok(())
99/// # }
100/// ```
101///
102/// If one statement triggers an error, the whole script aborts and rolls back.
103/// You can include explicit `BEGIN` and `COMMIT` statements in the SQL string
104/// to designate units that can be committed or rolled back piecemeal.
105///
106/// This also allows for a rudimentary form of pipelining as the whole SQL string is sent in one go.
107///
108/// ##### MySQL and MariaDB: DDL implicitly commits!
109/// MySQL and MariaDB do not support DDL in transactions. Instead, any active transaction is
110/// immediately and implicitly committed by the database server when executing a DDL statement.
111/// Beware of this behavior.
112///
113/// 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.
114/// See also: [MariaDB manual: SQL statements That Cause an Implicit Commit](https://mariadb.com/kb/en/sql-statements-that-cause-an-implicit-commit/).
115pub fn raw_sql(sql: &str) -> RawSql<'_> {
116 RawSql(sql)
117}
118
119impl<'q, DB: Database> Execute<'q, DB> for RawSql<'q> {
120 fn sql(&self) -> &'q str {
121 self.0
122 }
123
124 fn statement(&self) -> Option<&<DB as HasStatement<'q>>::Statement> {
125 None
126 }
127
128 fn take_arguments(&mut self) -> Option<<DB as HasArguments<'q>>::Arguments> {
129 None
130 }
131
132 fn persistent(&self) -> bool {
133 false
134 }
135}
136
137impl<'q> RawSql<'q> {
138 /// Execute the SQL string and return the total number of rows affected.
139 #[inline]
140 pub async fn execute<'e, E>(
141 self,
142 executor: E,
143 ) -> crate::Result<<E::Database as Database>::QueryResult>
144 where
145 'q: 'e,
146 E: Executor<'e>,
147 {
148 executor.execute(self).await
149 }
150
151 /// Execute the SQL string. Returns a stream which gives the number of rows affected for each statement in the string.
152 #[inline]
153 pub fn execute_many<'e, E>(
154 self,
155 executor: E,
156 ) -> BoxStream<'e, crate::Result<<E::Database as Database>::QueryResult>>
157 where
158 'q: 'e,
159 E: Executor<'e>,
160 {
161 executor.execute_many(self)
162 }
163
164 /// Execute the SQL string and return the generated results as a stream.
165 ///
166 /// If the string contains multiple statements, their results will be concatenated together.
167 #[inline]
168 pub fn fetch<'e, E>(
169 self,
170 executor: E,
171 ) -> BoxStream<'e, Result<<E::Database as Database>::Row, Error>>
172 where
173 'q: 'e,
174 E: Executor<'e>,
175 {
176 executor.fetch(self)
177 }
178
179 /// Execute the SQL string and return the generated results as a stream.
180 ///
181 /// For each query in the stream, any generated rows are returned first,
182 /// then the `QueryResult` with the number of rows affected.
183 #[inline]
184 pub fn fetch_many<'e, E>(
185 self,
186 executor: E,
187 ) -> BoxStream<
188 'e,
189 Result<
190 Either<<E::Database as Database>::QueryResult, <E::Database as Database>::Row>,
191 Error,
192 >,
193 >
194 where
195 'q: 'e,
196 E: Executor<'e>,
197 {
198 executor.fetch_many(self)
199 }
200
201 /// Execute the SQL string and return all the resulting rows collected into a [`Vec`].
202 ///
203 /// ### Note: beware result set size.
204 /// This will attempt to collect the full result set of the query into memory.
205 ///
206 /// To avoid exhausting available memory, ensure the result set has a known upper bound,
207 /// e.g. using `LIMIT`.
208 #[inline]
209 pub async fn fetch_all<'e, E>(
210 self,
211 executor: E,
212 ) -> crate::Result<Vec<<E::Database as Database>::Row>>
213 where
214 'q: 'e,
215 E: Executor<'e>,
216 {
217 executor.fetch_all(self).await
218 }
219
220 /// Execute the SQL string, returning the first row or [`Error::RowNotFound`] otherwise.
221 ///
222 /// ### Note: for best performance, ensure the query returns at most one row.
223 /// Depending on the driver implementation, if your query can return more than one row,
224 /// it may lead to wasted CPU time and bandwidth on the database server.
225 ///
226 /// Even when the driver implementation takes this into account, ensuring the query returns
227 /// at most one row can result in a more optimal query plan.
228 ///
229 /// If your query has a `WHERE` clause filtering a unique column by a single value, you're good.
230 ///
231 /// Otherwise, you might want to add `LIMIT 1` to your query.
232 #[inline]
233 pub async fn fetch_one<'e, E>(
234 self,
235 executor: E,
236 ) -> crate::Result<<E::Database as Database>::Row>
237 where
238 'q: 'e,
239 E: Executor<'e>,
240 {
241 executor.fetch_one(self).await
242 }
243
244 /// Execute the SQL string, 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
251 /// at most one row 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.
256 #[inline]
257 pub async fn fetch_optional<'e, E>(
258 self,
259 executor: E,
260 ) -> crate::Result<<E::Database as Database>::Row>
261 where
262 'q: 'e,
263 E: Executor<'e>,
264 {
265 executor.fetch_one(self).await
266 }
267}