|
| 1 | +//! Runtime query-builder API. |
| 2 | +
|
1 | 3 | use std::fmt::Display;
|
2 | 4 | use std::fmt::Write;
|
| 5 | +use std::marker::PhantomData; |
3 | 6 |
|
4 | 7 | use crate::arguments::Arguments;
|
5 | 8 | use crate::database::{Database, HasArguments};
|
6 | 9 | use crate::encode::Encode;
|
7 | 10 | use crate::query::Query;
|
8 | 11 | use crate::types::Type;
|
9 |
| -use either::Either; |
10 |
| -use std::marker::PhantomData; |
11 |
| - |
12 |
| -pub struct QueryBuilder<'a, DB> |
| 12 | +use crate::Either; |
| 13 | + |
| 14 | +/// A builder type for constructing queries at runtime. |
| 15 | +/// |
| 16 | +/// See [`.push_values()`][Self::push_values] for an example of building a bulk `INSERT` statement. |
| 17 | +/// Note, however, that with Postgres you can get much better performance by using arrays |
| 18 | +/// and `UNNEST()`. [See our FAQ] for details. |
| 19 | +/// |
| 20 | +/// [See our FAQ]: https://github.com/launchbadge/sqlx/blob/master/FAQ.md#how-can-i-bind-an-array-to-a-values-clause-how-can-i-do-bulk-inserts |
| 21 | +pub struct QueryBuilder<'args, DB> |
13 | 22 | where
|
14 | 23 | DB: Database,
|
15 | 24 | {
|
16 | 25 | query: String,
|
17 |
| - arguments: Option<<DB as HasArguments<'a>>::Arguments>, |
| 26 | + init_len: usize, |
| 27 | + arguments: Option<<DB as HasArguments<'args>>::Arguments>, |
18 | 28 | }
|
19 | 29 |
|
20 |
| -impl<'a, DB: Database> QueryBuilder<'a, DB> |
| 30 | +impl<'args, DB: Database> QueryBuilder<'args, DB> |
21 | 31 | where
|
22 | 32 | DB: Database,
|
23 | 33 | {
|
| 34 | + // `init` is provided because a query will almost always start with a constant fragment |
| 35 | + // such as `INSERT INTO ...` or `SELECT ...`, etc. |
| 36 | + /// Start building a query with an initial SQL fragment, which may be an empty string. |
24 | 37 | pub fn new(init: impl Into<String>) -> Self
|
25 | 38 | where
|
26 |
| - <DB as HasArguments<'a>>::Arguments: Default, |
| 39 | + <DB as HasArguments<'args>>::Arguments: Default, |
27 | 40 | {
|
| 41 | + let init = init.into(); |
| 42 | + |
28 | 43 | QueryBuilder {
|
29 |
| - query: init.into(), |
| 44 | + init_len: init.len(), |
| 45 | + query: init, |
30 | 46 | arguments: Some(Default::default()),
|
31 | 47 | }
|
32 | 48 | }
|
33 | 49 |
|
| 50 | + #[inline] |
| 51 | + fn sanity_check(&self) { |
| 52 | + assert!( |
| 53 | + self.arguments.is_some(), |
| 54 | + "QueryBuilder must be reset before reuse after `.build()`" |
| 55 | + ); |
| 56 | + } |
| 57 | + |
| 58 | + /// Append a SQL fragment to the query. |
| 59 | + /// |
| 60 | + /// May be a string or anything that implements `Display`. |
| 61 | + /// You can also use `format_args!()` here to push a formatted string without an intermediate |
| 62 | + /// allocation. |
| 63 | + /// |
| 64 | + /// ### Warning: Beware SQL Injection Vulnerabilities and Untrusted Input! |
| 65 | + /// You should *not* use this to insert input directly into the query from an untrusted user as |
| 66 | + /// this can be used by an attacker to extract sensitive data or take over your database. |
| 67 | + /// |
| 68 | + /// Security breaches due to SQL injection can cost your organization a lot of money from |
| 69 | + /// damage control and lost clients, damage the trust of your users in your system, and are just |
| 70 | + /// plain embarrassing. If you are unfamiliar with the threat that SQL injection imposes, you |
| 71 | + /// should take some time to learn more about it before proceeding: |
| 72 | + /// |
| 73 | + /// * [SQL Injection on OWASP.org](https://owasp.org/www-community/attacks/SQL_Injection) |
| 74 | + /// * [SQL Injection on Wikipedia](https://en.wikipedia.org/wiki/SQL_injection) |
| 75 | + /// * See "Examples" for notable instances of security breaches due to SQL injection. |
| 76 | + /// |
| 77 | + /// This method does *not* perform sanitization. Instead, you should use |
| 78 | + /// [`.push_bind()`][Self::push_bind] which inserts a placeholder into the query and then |
| 79 | + /// sends the possibly untrustworthy value separately (called a "bind argument") so that it |
| 80 | + /// cannot be misinterpreted by the database server. |
34 | 81 | pub fn push(&mut self, sql: impl Display) -> &mut Self {
|
35 |
| - if self.arguments.is_none() { |
36 |
| - panic!("QueryBuilder must be reset before reuse") |
37 |
| - } |
| 82 | + self.sanity_check(); |
38 | 83 |
|
39 | 84 | write!(self.query, "{}", sql).expect("error formatting `sql`");
|
40 | 85 |
|
41 | 86 | self
|
42 | 87 | }
|
43 | 88 |
|
44 |
| - pub fn push_bind<A>(&mut self, value: A) -> &mut Self |
| 89 | + /// Push a bind argument placeholder (`?` or `$N` for Postgres) and bind a value to it. |
| 90 | + /// |
| 91 | + /// ### Note: Database-specific Limits |
| 92 | + /// Note that every database has a practical limit on the number of bind parameters |
| 93 | + /// you can add to a single query. This varies by database. |
| 94 | + /// |
| 95 | + /// While you should consult the manual of your specific database version and/or current |
| 96 | + /// configuration for the exact value as it may be different than listed here, |
| 97 | + /// the defaults for supported databases as of writing are as follows: |
| 98 | + /// |
| 99 | + /// * Postgres and MySQL: 65535 |
| 100 | + /// * You may find sources that state that Postgres has a limit of 32767, |
| 101 | + /// but that is a misinterpretation of the specification by the JDBC driver implementation |
| 102 | + /// as discussed in [this Github issue][postgres-limit-issue]. Postgres itself |
| 103 | + /// asserts that the number of parameters is in the range `[0, 65535)`. |
| 104 | + /// * SQLite: 32766 (configurable by [`SQLITE_LIMIT_VARIABLE_NUMBER`]) |
| 105 | + /// * SQLite prior to 3.32.0: 999 |
| 106 | + /// * MSSQL: 2100 |
| 107 | + /// |
| 108 | + /// Exceeding these limits may panic (as a sanity check) or trigger a database error at runtime |
| 109 | + /// depending on the implementation. |
| 110 | + /// |
| 111 | + /// [`SQLITE_LIMIT_VARIABLE_NUMBER`]: https://www.sqlite.org/limits.html#max_variable_number |
| 112 | + /// [postgres-limit-issue]: https://github.com/launchbadge/sqlx/issues/671#issuecomment-687043510 |
| 113 | + pub fn push_bind<T>(&mut self, value: T) -> &mut Self |
45 | 114 | where
|
46 |
| - A: 'a + Encode<'a, DB> + Send + Type<DB>, |
| 115 | + T: 'args + Encode<'args, DB> + Send + Type<DB>, |
47 | 116 | {
|
48 |
| - match self.arguments { |
49 |
| - Some(ref mut arguments) => { |
50 |
| - arguments.add(value); |
51 |
| - |
52 |
| - arguments |
53 |
| - .format_placeholder(&mut self.query) |
54 |
| - .expect("error in format_placeholder"); |
55 |
| - } |
56 |
| - None => panic!("Arguments taken already"), |
57 |
| - } |
| 117 | + self.sanity_check(); |
| 118 | + |
| 119 | + let arguments = self |
| 120 | + .arguments |
| 121 | + .as_mut() |
| 122 | + .expect("BUG: Arguments taken already"); |
| 123 | + arguments.add(value); |
| 124 | + |
| 125 | + arguments |
| 126 | + .format_placeholder(&mut self.query) |
| 127 | + .expect("error in format_placeholder"); |
58 | 128 |
|
59 | 129 | self
|
60 | 130 | }
|
61 | 131 |
|
62 |
| - pub fn build(&mut self) -> Query<'_, DB, <DB as HasArguments<'a>>::Arguments> { |
| 132 | + /// Start a list separated by `separator`. |
| 133 | + /// |
| 134 | + /// The returned type exposes identical [`.push()`][Separated::push] and |
| 135 | + /// [`.push_bind()`][Separated::push_bind] methods which push `separator` to the query |
| 136 | + /// before their normal behavior. [`.push_unseparated()`][Separated::push_unseparated] is also |
| 137 | + /// provided to push a SQL fragment without the separator. |
| 138 | + pub fn separated<'qb, Sep>(&'qb mut self, separator: Sep) -> Separated<'qb, 'args, DB, Sep> |
| 139 | + where |
| 140 | + 'args: 'qb, |
| 141 | + Sep: Display, |
| 142 | + { |
| 143 | + self.sanity_check(); |
| 144 | + |
| 145 | + Separated { |
| 146 | + query_builder: self, |
| 147 | + separator, |
| 148 | + push_separator: false, |
| 149 | + } |
| 150 | + } |
| 151 | + |
| 152 | + /// Push a `VALUES` clause where each item in `tuples` represents a tuple/row in the clause. |
| 153 | + /// |
| 154 | + /// This can be used to construct a bulk `INSERT` statement, although keep in mind that all |
| 155 | + /// databases have some practical limit on the number of bind arguments in a single query. |
| 156 | + /// See [`.push_bind()`][Self::push_bind] for details. |
| 157 | + /// |
| 158 | + /// To be safe, you can do `tuples.into_iter().take(N)` where `N` is the limit for your database |
| 159 | + /// divided by the number of fields in each tuple; since integer division always rounds down, |
| 160 | + /// this will ensure that you don't exceed the limit. |
| 161 | + /// |
| 162 | + /// ### Notes |
| 163 | + /// |
| 164 | + /// If `tuples` is empty, this will likely produce a syntactically invalid query as `VALUES` |
| 165 | + /// generally expects to be followed by at least 1 tuple. |
| 166 | + /// |
| 167 | + /// If `tuples` can have many different lengths, you may want to call |
| 168 | + /// [`.persistent(false)`][Query::persistent] after [`.build()`][Self::build] to avoid |
| 169 | + /// filling up the connection's prepared statement cache. |
| 170 | + /// |
| 171 | + /// ### Example (MySQL) |
| 172 | + /// |
| 173 | + /// ```rust |
| 174 | + /// # #[cfg(feature = "mysql")] |
| 175 | + /// # { |
| 176 | + /// use sqlx::{Execute, MySql, QueryBuilder}; |
| 177 | + /// |
| 178 | + /// struct User { |
| 179 | + /// id: i32, |
| 180 | + /// username: String, |
| 181 | + /// email: String, |
| 182 | + /// password: String, |
| 183 | + /// } |
| 184 | + /// |
| 185 | + /// // The number of parameters in MySQL must fit in a `u16`. |
| 186 | + /// const BIND_LIMIT: usize = 65535; |
| 187 | + /// |
| 188 | + /// // This would normally produce values forever! |
| 189 | + /// let users = (0..).map(|i| User { |
| 190 | + /// id: i, |
| 191 | + /// username: format!("test_user_{}", i), |
| 192 | + /// email: format!("test-user-{}@example.com", i), |
| 193 | + /// password: format!("Test!User@Password#{}", i), |
| 194 | + /// }); |
| 195 | + /// |
| 196 | + /// let mut query_builder: QueryBuilder<MySql> = QueryBuilder::new( |
| 197 | + /// // Note the trailing space: |
| 198 | + /// "INSERT INTO users(id, username, email, password) " |
| 199 | + /// ); |
| 200 | + /// |
| 201 | + /// // Note that `.into_iter()` wasn't needed here since `users` is already an iterator. |
| 202 | + /// query_builder.push_values(users.take(BIND_LIMIT / 4), |mut b, user| { |
| 203 | + /// b.push_bind(user.id) |
| 204 | + /// .push_bind(user.username) |
| 205 | + /// .push_bind(user.email) |
| 206 | + /// .push_bind(user.password); |
| 207 | + /// }); |
| 208 | + /// |
| 209 | + /// let mut query = query_builder.build(); |
| 210 | + /// |
| 211 | + /// // You can then call `query.execute()`, `.fetch_one()`, `.fetch_all()`, etc. |
| 212 | + /// // For the sake of demonstration though, we're just going to assert the contents |
| 213 | + /// // of the query. |
| 214 | + /// |
| 215 | + /// // These are methods of the `Execute` trait, not normally meant to be called in user code. |
| 216 | + /// let sql = query.sql(); |
| 217 | + /// let arguments = query.take_arguments().unwrap(); |
| 218 | + /// |
| 219 | + /// assert!(sql.starts_with( |
| 220 | + /// "INSERT INTO users(id, username, email, password) VALUES (?, ?, ?, ?), (?, ?, ?, ?)" |
| 221 | + /// )); |
| 222 | + /// |
| 223 | + /// // Not a normally exposed function, only used for this doctest. |
| 224 | + /// // 65535 / 4 = 16383 (rounded down) |
| 225 | + /// // 16383 * 4 = 65532 |
| 226 | + /// assert_eq!(arguments.len(), 65532); |
| 227 | + /// # } |
| 228 | + pub fn push_values<I, F>(&mut self, tuples: I, mut push_tuple: F) -> &mut Self |
| 229 | + where |
| 230 | + I: IntoIterator, |
| 231 | + F: FnMut(Separated<'_, 'args, DB, &'static str>, I::Item), |
| 232 | + { |
| 233 | + self.sanity_check(); |
| 234 | + |
| 235 | + self.push("VALUES "); |
| 236 | + |
| 237 | + let mut separated = self.separated(", "); |
| 238 | + |
| 239 | + for tuple in tuples { |
| 240 | + separated.push("("); |
| 241 | + |
| 242 | + // use a `Separated` with a separate (hah) internal state |
| 243 | + push_tuple(separated.query_builder.separated(", "), tuple); |
| 244 | + |
| 245 | + separated.push_unseparated(")"); |
| 246 | + } |
| 247 | + |
| 248 | + separated.query_builder |
| 249 | + } |
| 250 | + |
| 251 | + /// Produce an executable query from this builder. |
| 252 | + /// |
| 253 | + /// ### Note: Query is not Checked |
| 254 | + /// It is your responsibility to ensure that you produce a syntactically correct query here, |
| 255 | + /// this API has no way to check it for you. |
| 256 | + /// |
| 257 | + /// ### Note: Reuse |
| 258 | + /// You can reuse this builder afterwards to amortize the allocation overhead of the query |
| 259 | + /// string, however you must call [`.reset()`][Self::reset] first, which returns `Self` |
| 260 | + /// to the state it was in immediately after [`new()`][Self::new]. |
| 261 | + /// |
| 262 | + /// Calling any other method but `.reset()` after `.build()` will panic for sanity reasons. |
| 263 | + pub fn build(&mut self) -> Query<'_, DB, <DB as HasArguments<'args>>::Arguments> { |
| 264 | + self.sanity_check(); |
| 265 | + |
63 | 266 | Query {
|
64 | 267 | statement: Either::Left(&self.query),
|
65 |
| - arguments: match self.arguments.take() { |
66 |
| - Some(arguments) => Some(arguments), |
67 |
| - None => None, |
68 |
| - }, |
| 268 | + arguments: self.arguments.take(), |
69 | 269 | database: PhantomData,
|
70 | 270 | persistent: true,
|
71 | 271 | }
|
72 | 272 | }
|
73 | 273 |
|
| 274 | + /// Reset this `QueryBuilder` back to its initial state. |
| 275 | + /// |
| 276 | + /// The query is truncated to the initial fragment provided to [`new()`][Self::new] and |
| 277 | + /// the bind arguments are reset. |
74 | 278 | pub fn reset(&mut self) -> &mut Self {
|
75 |
| - self.query.clear(); |
| 279 | + self.query.truncate(self.init_len); |
76 | 280 | self.arguments = Some(Default::default());
|
77 | 281 |
|
78 | 282 | self
|
79 | 283 | }
|
80 | 284 | }
|
81 | 285 |
|
| 286 | +/// A wrapper around `QueryBuilder` for creating comma(or other token)-separated lists. |
| 287 | +/// |
| 288 | +/// See [`QueryBuilder::separated()`] for details. |
| 289 | +pub struct Separated<'qb, 'args: 'qb, DB, Sep> |
| 290 | +where |
| 291 | + DB: Database, |
| 292 | +{ |
| 293 | + query_builder: &'qb mut QueryBuilder<'args, DB>, |
| 294 | + separator: Sep, |
| 295 | + push_separator: bool, |
| 296 | +} |
| 297 | + |
| 298 | +impl<'qb, 'args: 'qb, DB, Sep> Separated<'qb, 'args, DB, Sep> |
| 299 | +where |
| 300 | + DB: Database, |
| 301 | + Sep: Display, |
| 302 | +{ |
| 303 | + /// Push the separator if applicable, and then the given SQL fragment. |
| 304 | + /// |
| 305 | + /// See [`QueryBuilder::push()`] for details. |
| 306 | + pub fn push(&mut self, sql: impl Display) -> &mut Self { |
| 307 | + if self.push_separator { |
| 308 | + self.query_builder |
| 309 | + .push(format_args!("{}{}", self.separator, sql)); |
| 310 | + } else { |
| 311 | + self.query_builder.push(sql); |
| 312 | + self.push_separator = true; |
| 313 | + } |
| 314 | + |
| 315 | + self |
| 316 | + } |
| 317 | + |
| 318 | + /// Push a SQL fragment without a separator. |
| 319 | + /// |
| 320 | + /// Simply calls [`QueryBuilder::push()`] directly. |
| 321 | + pub fn push_unseparated(&mut self, sql: impl Display) -> &mut Self { |
| 322 | + self.query_builder.push(sql); |
| 323 | + self |
| 324 | + } |
| 325 | + |
| 326 | + /// Push the separator if applicable, then append a bind argument. |
| 327 | + /// |
| 328 | + /// See [`QueryBuilder::push_bind()`] for details. |
| 329 | + pub fn push_bind<T>(&mut self, value: T) -> &mut Self |
| 330 | + where |
| 331 | + T: 'args + Encode<'args, DB> + Send + Type<DB>, |
| 332 | + { |
| 333 | + if self.push_separator { |
| 334 | + self.query_builder.push(&self.separator); |
| 335 | + } |
| 336 | + |
| 337 | + self.query_builder.push_bind(value); |
| 338 | + self.push_separator = true; |
| 339 | + |
| 340 | + self |
| 341 | + } |
| 342 | +} |
| 343 | + |
82 | 344 | #[cfg(test)]
|
83 | 345 | mod test {
|
84 |
| - use super::*; |
85 | 346 | use crate::postgres::Postgres;
|
86 | 347 |
|
| 348 | + use super::*; |
| 349 | + |
87 | 350 | #[test]
|
88 | 351 | fn test_new() {
|
89 | 352 | let qb: QueryBuilder<'_, Postgres> = QueryBuilder::new("SELECT * FROM users");
|
|
0 commit comments