zino_orm/
query.rs

1//! Query builder for SQL.
2//!
3//! # Design references
4//!
5//! The design of our ORM is inspired by [`Mongoose`], [`Prisma`], [`TypeORM`] and [`PostgREST`].
6//!
7//! ```rust,ignore
8//! use zino_core::{model::{Mutation, Query}, json, Map, Record};
9//! use zino_orm::{JoinOn, Schema};
10//!
11//! // Constructs a model `Query` with JSON expressions.
12//! let query = Query::new(json!({
13//!     "$or": [
14//!         {
15//!             "roles": "worker",
16//!             "visibility": "Public",
17//!         },
18//!         {
19//!             "roles": { "$in": ["admin", "auditor"] },
20//!             "visibility": { "$ne": "Public" },
21//!         },
22//!     ],
23//!     "status": { "$nin": ["Deleted", "Locked"] },
24//! }));
25//!
26//! // Constructs a model `Mutation` with JSON expressions.
27//! let mut mutation = Mutation::new(json!({
28//!     "status": "Active",
29//!     "refreshed_at": DateTime::now(),
30//!     "$inc": { "refresh_count": 1 },
31//! }));
32//!
33//! // Updates the models using `update_many` provided by the `Schema` trait.
34//! let ctx = User::update_many(&query, &mut mutation).await?;
35//! ctx.emit_metrics("user_refresh");
36//!
37//! // Constructs a model `Query` with projection fields.
38//! let mut query = Query::new(json!({
39//!     "project.start_date": { "$le": "2023-10-07" },
40//!     "project.end_date": { "$ge": "2023-10-01" },
41//!     "task.status": "Completed",
42//! }));
43//! query.allow_fields(&[
44//!     "task.id",
45//!     "task.name",
46//!     "task.status",
47//!     "task.project_id",
48//!     "project.start_date",
49//!     "project.end_date",
50//! ]);
51//! query.order_desc("task.updated_at");
52//!
53//! // Performs a LEFT OUTER JOIN using `lookup` provided by the `Schema` trait.
54//! let join_on = JoinOn::left_join().with("project_id", "id");
55//! let entries = Task::lookup::<Project, Map>(&query, &join_on).await?;
56//!
57//! // Executes the raw SQL with interpolations `${param}` and argument bindings `#{param}`.
58//! let sql =
59//!     "SELECT u.id, u.name, u.tags, t.id, t.name \
60//!         FROM ${user_table} u INNER JOIN ${tag_table} t \
61//!             ON t.id = ANY(u.tags) AND t.category = #{category};";
62//! let params = json!({
63//!     "user_table": User::table_name(),
64//!     "tag_table": Tag::table_name(),
65//!     "category": "Rustacean",
66//! });
67//! let records = User::query::<Record>(sql, params.as_object()).await?;
68//! ```
69//!
70//! # Query operators
71//!
72//! | Name       | MySQL               | PostgreSQL       | SQLite                |
73//! |------------|---------------------|------------------|-----------------------|
74//! | `$and`     | `AND`               | `AND`            | `AND`                 |
75//! | `$or`      | `OR`                | `OR`             | `OR`                  |
76//! | `$not`     | `NOT`               | `NOT`            | `NOT`                 |
77//! | `$rand`    | `rand()`            | `random()`       | `abs(random())`       |
78//! | `$text`    | `match() against()` | `to_tsvector()`  | `MATCH`               |
79//! | `$eq`      | `=`                 | `=`              | `=`                   |
80//! | `$ne`      | `<>`                | `<>`             | `<>`                  |
81//! | `$lt`      | `<`                 | `<`              | `<`                   |
82//! | `$le`      | `<=`                | `<=`             | `<=`                  |
83//! | `$gt`      | `>`                 | `>`              | `>`                   |
84//! | `$ge`      | `>=`                | `>=`             | `>=`                  |
85//! | `$in`      | `IN`                | `IN`             | `IN`                  |
86//! | `$nin`     | `NOT IN`            | `NOT IN`         | `NOT IN`              |
87//! | `$betw`    | `BETWEEN AND`       | `BETWEEN AND`    | `BETWEEN AND`         |
88//! | `$like`    | `LIKE`              | `LIKE`           | `LIKE`                |
89//! | `$ilike`   | `ILIKE`             | `ILIKE`          | `LOWER() LIKE`        |
90//! | `$rlike`   | `RLIKE`             | `~*`             | `REGEXP`              |
91//! | `$is`      | `IS`                | `IS`             | `IS`                  |
92//! | `$size`    | `json_length()`     | `array_length()` | `json_array_length()` |
93//!
94//! [`Mongoose`]: https://mongoosejs.com/
95//! [`Prisma`]: https://www.prisma.io/
96//! [`TypeORM`]: https://typeorm.io/
97//! [`PostgREST`]: https://postgrest.org/
98
99use super::{Aggregation, EncodeColumn, Entity, IntoSqlValue, Schema, Window};
100use regex::{Captures, Regex};
101use std::{borrow::Cow, fmt::Display, marker::PhantomData};
102use zino_core::{
103    extension::{JsonObjectExt, JsonValueExt},
104    model::{Query, QueryOrder},
105    JsonValue, LazyLock, Map, SharedString,
106};
107
108/// A query builder for the model entity.
109///
110/// # Examples
111/// ```rust,ignore
112/// use crate::model::{User, UserColumn};
113/// use zino_core::orm::{QueryBuilder, Schema};
114///
115/// let query = QueryBuilder::<User>::new()
116///     .and_not_in(UserColumn::Status, ["Deleted", "Locked"])
117///     .or(QueryBuilder::<User>::new()
118///         .and_eq(UserColumn::Roles, "worker")
119///         .and_eq(UserColumn::Visibility, "Public"))
120///     .or(QueryBuilder::<User>::new()
121///         .and_in(UserColumn::Roles, ["admin", "auditor"])
122///         .and_ne(UserColumn::Visibility, "Public"))
123///     .order_desc(UserColumn::UpdatedAt)
124///     .limit(10)
125///     .build();
126/// let users: Vec<User> = User::find(&query).await?;
127/// ```
128#[derive(Debug, Clone)]
129pub struct QueryBuilder<E: Entity> {
130    /// The projection fields.
131    fields: Vec<String>,
132    /// The `GROUP BY` fields.
133    group_by_fields: Vec<String>,
134    /// The `HAVING` conditions.
135    having_conditions: Vec<Map>,
136    /// The filters.
137    filters: Map,
138    /// The logical `AND` conditions.
139    logical_and: Vec<Map>,
140    /// The logical `OR` conditions.
141    logical_or: Vec<Map>,
142    /// Sort order.
143    sort_order: Vec<QueryOrder>,
144    /// Offset.
145    offset: usize,
146    /// Limit.
147    limit: usize,
148    /// The phantom data.
149    phantom: PhantomData<E>,
150}
151
152impl<E: Entity> QueryBuilder<E> {
153    /// Creates a new instance.
154    #[inline]
155    pub fn new() -> Self {
156        Self {
157            fields: Vec::new(),
158            group_by_fields: Vec::new(),
159            having_conditions: Vec::new(),
160            filters: Map::new(),
161            logical_and: Vec::new(),
162            logical_or: Vec::new(),
163            sort_order: Vec::new(),
164            offset: 0,
165            limit: 0,
166            phantom: PhantomData,
167        }
168    }
169
170    /// Adds a field corresponding to the column.
171    #[inline]
172    pub fn field(mut self, col: E::Column) -> Self {
173        self.fields.push(E::format_column(&col));
174        self
175    }
176
177    /// Adds the fields corresponding to the columns.
178    #[inline]
179    pub fn fields<V: Into<Vec<E::Column>>>(mut self, cols: V) -> Self {
180        let mut fields = cols.into().iter().map(E::format_column).collect();
181        self.fields.append(&mut fields);
182        self
183    }
184
185    /// Adds a field with an alias for the column.
186    pub fn alias(mut self, col: E::Column, alias: &str) -> Self {
187        let col_name = E::format_column(&col);
188        let field = Query::format_field(&col_name);
189        let field_alias = [alias, ":", &field].concat();
190        self.fields.push(field_alias);
191        self
192    }
193
194    /// Adds a field with an alias extracted from a JSON column.
195    pub fn json_extract(mut self, col: E::Column, path: &str, alias: &str) -> Self {
196        let col_name = E::format_column(&col);
197        let field = Query::format_field(&col_name);
198        let json_field = if cfg!(feature = "orm-postgres") {
199            let path = path.strip_prefix("$.").unwrap_or(path).replace('.', ", ");
200            format!(r#"({field} #>> '{{{path}}}')"#)
201        } else {
202            format!(r#"json_unquote(json_extract({field}, '{path}'))"#)
203        };
204        let field_alias = [alias, ":", &json_field].concat();
205        self.fields.push(field_alias);
206        self
207    }
208
209    /// Adds a field with an optional alias for the aggregate function.
210    pub fn aggregate(mut self, aggregation: Aggregation<E>, alias: Option<&str>) -> Self {
211        let expr = aggregation.expr();
212        let field_alias = if let Some(alias) = alias {
213            [alias, ":", &expr].concat()
214        } else {
215            let mut field_alias = aggregation.default_alias();
216            field_alias.push(':');
217            field_alias.push_str(&expr);
218            field_alias
219        };
220        self.fields.push(field_alias);
221        self
222    }
223
224    /// Adds a field with an optional alias for the window function.
225    pub fn window(mut self, window: Window<E>, alias: Option<&str>) -> Self {
226        let expr = window.expr();
227        let field_alias = if let Some(alias) = alias {
228            [alias, ":", &expr].concat()
229        } else {
230            let mut field_alias = window.default_alias();
231            field_alias.push(':');
232            field_alias.push_str(&expr);
233            field_alias
234        };
235        self.fields.push(field_alias);
236        self
237    }
238
239    /// Adds a `GROUP BY` column.
240    pub fn group_by(mut self, col: E::Column) -> Self {
241        let field = E::format_column(&col);
242        if !self.fields.contains(&field) {
243            self.fields.push(field.clone());
244        }
245        self.group_by_fields.push(field);
246        self
247    }
248
249    /// Adds a `HAVING` condition using the value as a filter for the column.
250    #[inline]
251    pub fn having_filter(mut self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
252        let condition = Map::from_entry(aggregation.expr(), value.into_sql_value());
253        self.having_conditions.push(condition);
254        self
255    }
256
257    /// Adds a `HAVING` condition for equal parts.
258    #[inline]
259    pub fn having_eq(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
260        self.push_having_condition(aggregation, "$eq", value.into_sql_value())
261    }
262
263    /// Adds a `HAVING` condition for non-equal parts.
264    #[inline]
265    pub fn having_ne(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
266        self.push_having_condition(aggregation, "$ne", value.into_sql_value())
267    }
268
269    /// Adds a `HAVING` condition for the column less than a value.
270    #[inline]
271    pub fn having_lt(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
272        self.push_having_condition(aggregation, "$lt", value.into_sql_value())
273    }
274
275    /// Adds a `HAVING` condition for the column not greater than a value.
276    #[inline]
277    pub fn having_le(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
278        self.push_having_condition(aggregation, "$le", value.into_sql_value())
279    }
280
281    /// Adds a `HAVING` condition for the column greater than a value.
282    #[inline]
283    pub fn having_gt(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
284        self.push_having_condition(aggregation, "$gt", value.into_sql_value())
285    }
286
287    /// Adds a `HAVING` condition for the column not less than a value.
288    #[inline]
289    pub fn having_ge(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
290        self.push_having_condition(aggregation, "$ge", value.into_sql_value())
291    }
292
293    /// Adds a logical `AND` condition for the primary key.
294    #[inline]
295    pub fn primary_key(mut self, value: impl IntoSqlValue) -> Self {
296        let field = E::format_column(&E::PRIMARY_KEY);
297        self.filters.upsert(field, value.into_sql_value());
298        self
299    }
300
301    /// Adds a logical `AND` condition which selects random items by `rand() < value`.
302    #[inline]
303    pub fn rand(mut self, value: impl IntoSqlValue) -> Self {
304        self.filters.upsert("$rand", value.into_sql_value());
305        self
306    }
307
308    /// Adds a logical `AND` condition by merging the other query builder.
309    pub fn and<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
310        let mut logical_and = other.logical_and;
311        let logical_or = other.logical_or;
312        if !logical_or.is_empty() {
313            logical_and.push(Map::from_entry("$or", logical_or));
314        }
315        if !logical_and.is_empty() {
316            self.logical_and.push(Map::from_entry("$and", logical_and));
317        }
318        self.fields.append(&mut other.fields);
319        self.group_by_fields.append(&mut other.group_by_fields);
320        self
321    }
322
323    /// Adds a logical `AND NOT` condition by merging the other query builder.
324    pub fn and_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
325        let mut logical_and = other.logical_and;
326        let logical_or = other.logical_or;
327        if !logical_or.is_empty() {
328            logical_and.push(Map::from_entry("$or", logical_or));
329        }
330        if !logical_and.is_empty() {
331            self.logical_and.push(Map::from_entry("$not", logical_and));
332        }
333        self.fields.append(&mut other.fields);
334        self.group_by_fields.append(&mut other.group_by_fields);
335        self
336    }
337
338    /// Adds a logical `AND` condition using the value as a filter for the column.
339    #[inline]
340    pub fn and_filter(mut self, col: E::Column, value: impl IntoSqlValue) -> Self {
341        let condition = Map::from_entry(E::format_column(&col), value.into_sql_value());
342        self.logical_and.push(condition);
343        self
344    }
345
346    /// Adds a logical `AND` condition for equal parts.
347    #[inline]
348    pub fn and_eq(self, col: E::Column, value: impl IntoSqlValue) -> Self {
349        self.push_logical_and(col, "$eq", value.into_sql_value())
350    }
351
352    /// Adds a logical `AND` condition for equal parts if the value is not null.
353    #[inline]
354    pub fn and_eq_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
355        let value = value.into_sql_value();
356        if !value.is_null() {
357            self.push_logical_and(col, "$eq", value)
358        } else {
359            self
360        }
361    }
362
363    /// Adds a logical `AND` condition for equal parts if the value is not none.
364    #[inline]
365    pub fn and_eq_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
366        if let Some(value) = value {
367            self.push_logical_and(col, "$eq", value.into_sql_value())
368        } else {
369            self
370        }
371    }
372
373    /// Adds a logical `AND` condition for non-equal parts.
374    #[inline]
375    pub fn and_ne(self, col: E::Column, value: impl IntoSqlValue) -> Self {
376        self.push_logical_and(col, "$ne", value.into_sql_value())
377    }
378
379    /// Adds a logical `AND` condition for non-equal parts if the value is not null.
380    #[inline]
381    pub fn and_ne_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
382        let value = value.into_sql_value();
383        if !value.is_null() {
384            self.push_logical_and(col, "$ne", value)
385        } else {
386            self
387        }
388    }
389
390    /// Adds a logical `AND` condition for non-equal parts if the value is not none.
391    #[inline]
392    pub fn and_ne_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
393        if let Some(value) = value {
394            self.push_logical_and(col, "$ne", value.into_sql_value())
395        } else {
396            self
397        }
398    }
399
400    /// Adds a logical `AND` condition for the column less than a value.
401    #[inline]
402    pub fn and_lt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
403        self.push_logical_and(col, "$lt", value.into_sql_value())
404    }
405
406    /// Adds a logical `AND` condition for the column not greater than a value.
407    #[inline]
408    pub fn and_le(self, col: E::Column, value: impl IntoSqlValue) -> Self {
409        self.push_logical_and(col, "$le", value.into_sql_value())
410    }
411
412    /// Adds a logical `AND` condition for the column greater than a value.
413    #[inline]
414    pub fn and_gt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
415        self.push_logical_and(col, "$gt", value.into_sql_value())
416    }
417
418    /// Adds a logical `AND` condition for the column not less than a value.
419    #[inline]
420    pub fn and_ge(self, col: E::Column, value: impl IntoSqlValue) -> Self {
421        self.push_logical_and(col, "$ge", value.into_sql_value())
422    }
423
424    /// Adds a logical `AND` condition for the column `IN` a list of values.
425    #[inline]
426    pub fn and_in<T, V>(self, col: E::Column, values: V) -> Self
427    where
428        T: IntoSqlValue,
429        V: Into<Vec<T>>,
430    {
431        self.push_logical_and(col, "$in", values.into().into_sql_value())
432    }
433
434    /// Adds a logical `AND` condition for the column `NOT IN` a list of values.
435    #[inline]
436    pub fn and_not_in<T, V>(self, col: E::Column, values: V) -> Self
437    where
438        T: IntoSqlValue,
439        V: Into<Vec<T>>,
440    {
441        self.push_logical_and(col, "$nin", values.into().into_sql_value())
442    }
443
444    /// Adds a logical `AND` condition for the columns `IN` a subquery.
445    pub fn and_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
446    where
447        C: Into<Vec<E::Column>>,
448        M: Entity + Schema,
449    {
450        let cols = cols
451            .into()
452            .into_iter()
453            .map(|col| {
454                let col_name = E::format_column(&col);
455                Query::format_field(&col_name).into_owned()
456            })
457            .collect::<Vec<_>>()
458            .join(", ");
459        let field = format!("({cols})");
460        let condition = Map::from_entry("$in", subquery.into_sql_value());
461        self.logical_and.push(Map::from_entry(field, condition));
462        self
463    }
464
465    /// Adds a logical `AND` condition for the columns `NOT IN` a subquery.
466    pub fn and_not_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
467    where
468        C: Into<Vec<E::Column>>,
469        M: Entity + Schema,
470    {
471        let cols = cols
472            .into()
473            .into_iter()
474            .map(|col| {
475                let col_name = E::format_column(&col);
476                Query::format_field(&col_name).into_owned()
477            })
478            .collect::<Vec<_>>()
479            .join(", ");
480        let field = format!("({cols})");
481        let condition = Map::from_entry("$nin", subquery.into_sql_value());
482        self.logical_and.push(Map::from_entry(field, condition));
483        self
484    }
485
486    /// Adds a logical `AND` condition for the column in a range `[min, max)`.
487    pub fn and_in_range<T: IntoSqlValue>(mut self, col: E::Column, min: T, max: T) -> Self {
488        let field = E::format_column(&col);
489        let mut condition = Map::new();
490        condition.upsert("$ge", min.into_sql_value());
491        condition.upsert("$lt", max.into_sql_value());
492        self.logical_and.push(Map::from_entry(field, condition));
493        self
494    }
495
496    /// Adds a logical `AND` condition for the column `BETWEEN` two values.
497    #[inline]
498    pub fn and_between<T: IntoSqlValue>(self, col: E::Column, min: T, max: T) -> Self {
499        self.push_logical_and(col, "$betw", [min, max].into_sql_value())
500    }
501
502    /// Adds a logical `AND` condition for the column `LIKE` a string value.
503    #[inline]
504    pub fn and_like(self, col: E::Column, value: String) -> Self {
505        self.push_logical_and(col, "$like", value.into_sql_value())
506    }
507
508    /// Adds a logical `AND` condition for the column `ILIKE` a string value.
509    #[inline]
510    pub fn and_ilike(self, col: E::Column, value: String) -> Self {
511        self.push_logical_and(col, "$ilike", value.into_sql_value())
512    }
513
514    /// Adds a logical `AND` condition for the column `RLIKE` a string value.
515    #[inline]
516    pub fn and_rlike(self, col: E::Column, value: String) -> Self {
517        self.push_logical_and(col, "$rlike", value.into_sql_value())
518    }
519
520    /// Adds a logical `AND` condition for the column which contains a string value.
521    #[inline]
522    pub fn and_contains(self, col: E::Column, value: &str) -> Self {
523        let value = ["%", value, "%"].concat();
524        self.push_logical_and(col, "$like", value.into_sql_value())
525    }
526
527    /// Adds a logical `AND` condition for the column which starts with a string value.
528    #[inline]
529    pub fn and_starts_with(self, col: E::Column, value: &str) -> Self {
530        let value = [value, "%"].concat();
531        self.push_logical_and(col, "$like", value.into_sql_value())
532    }
533
534    /// Adds a logical `AND` condition for the column which ends with a string value.
535    #[inline]
536    pub fn and_ends_with(self, col: E::Column, value: &str) -> Self {
537        let value = ["%", value].concat();
538        self.push_logical_and(col, "$like", value.into_sql_value())
539    }
540
541    /// Adds a logical `AND` condition for the column which is null.
542    #[inline]
543    pub fn and_null(self, col: E::Column) -> Self {
544        self.and_filter(col, JsonValue::Null)
545    }
546
547    /// Adds a logical `AND` condition for the column which is not null.
548    #[inline]
549    pub fn and_not_null(self, col: E::Column) -> Self {
550        self.and_filter(col, "not_null")
551    }
552
553    /// Adds a logical `AND` condition for the column which is an empty string or a null.
554    #[inline]
555    pub fn and_empty(self, col: E::Column) -> Self {
556        self.and_filter(col, "empty")
557    }
558
559    /// Adds a logical `AND` condition for the column which is not an empty string or a null.
560    #[inline]
561    pub fn and_nonempty(self, col: E::Column) -> Self {
562        self.and_filter(col, "nonempty")
563    }
564
565    /// Adds a logical `AND` condition for the two ranges which overlaps with each other.
566    pub fn and_overlaps<T: IntoSqlValue>(
567        mut self,
568        cols: (E::Column, E::Column),
569        values: (T, T),
570    ) -> Self {
571        let mut condition = Map::new();
572        condition.upsert(
573            E::format_column(&cols.0),
574            Map::from_entry("$le", values.1.into_sql_value()),
575        );
576        condition.upsert(
577            E::format_column(&cols.1),
578            Map::from_entry("$ge", values.0.into_sql_value()),
579        );
580        self.logical_and.push(condition);
581        self
582    }
583
584    /// Adds a logical `OR` condition by merging the other query builder.
585    pub fn or<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
586        let mut logical_and = other.logical_and;
587        let logical_or = other.logical_or;
588        if !logical_or.is_empty() {
589            logical_and.push(Map::from_entry("$or", logical_or));
590        }
591        if !logical_and.is_empty() {
592            self.logical_or.push(Map::from_entry("$and", logical_and));
593        }
594        self.fields.append(&mut other.fields);
595        self.group_by_fields.append(&mut other.group_by_fields);
596        self
597    }
598
599    /// Adds a logical `OR NOT` condition by merging the other query builder.
600    pub fn or_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
601        let mut logical_and = other.logical_and;
602        let logical_or = other.logical_or;
603        if !logical_or.is_empty() {
604            logical_and.push(Map::from_entry("$or", logical_or));
605        }
606        if !logical_and.is_empty() {
607            self.logical_or.push(Map::from_entry("$not", logical_and));
608        }
609        self.fields.append(&mut other.fields);
610        self.group_by_fields.append(&mut other.group_by_fields);
611        self
612    }
613
614    /// Adds a logical `OR` condition using the value as a filter for the column.
615    #[inline]
616    pub fn or_filter(mut self, col: E::Column, value: impl IntoSqlValue) -> Self {
617        let condition = Map::from_entry(E::format_column(&col), value.into_sql_value());
618        self.logical_or.push(condition);
619        self
620    }
621
622    /// Adds a logical `OR` condition for equal parts.
623    #[inline]
624    pub fn or_eq(self, col: E::Column, value: impl IntoSqlValue) -> Self {
625        self.push_logical_or(col, "$eq", value.into_sql_value())
626    }
627
628    /// Adds a logical `OR` condition for equal parts if the value is not null.
629    #[inline]
630    pub fn or_eq_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
631        let value = value.into_sql_value();
632        if !value.is_null() {
633            self.push_logical_or(col, "$eq", value)
634        } else {
635            self
636        }
637    }
638
639    /// Adds a logical `OR` condition for equal parts if the value is not none.
640    #[inline]
641    pub fn or_eq_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
642        if let Some(value) = value {
643            self.push_logical_or(col, "$eq", value.into_sql_value())
644        } else {
645            self
646        }
647    }
648
649    /// Adds a logical `OR` condition for non-equal parts.
650    #[inline]
651    pub fn or_ne(self, col: E::Column, value: impl IntoSqlValue) -> Self {
652        self.push_logical_or(col, "$ne", value.into_sql_value())
653    }
654
655    /// Adds a logical `OR` condition for non-equal parts if the value is not none.
656    #[inline]
657    pub fn or_ne_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
658        let value = value.into_sql_value();
659        if !value.is_null() {
660            self.push_logical_or(col, "$ne", value)
661        } else {
662            self
663        }
664    }
665
666    /// Adds a logical `OR` condition for non-equal parts if the value is not none.
667    #[inline]
668    pub fn or_ne_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
669        if let Some(value) = value {
670            self.push_logical_or(col, "$ne", value.into_sql_value())
671        } else {
672            self
673        }
674    }
675
676    /// Adds a logical `OR` condition for the column less than a value.
677    #[inline]
678    pub fn or_lt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
679        self.push_logical_or(col, "$lt", value.into_sql_value())
680    }
681
682    /// Adds a logical `OR` condition for the column not greater than a value.
683    #[inline]
684    pub fn or_le(self, col: E::Column, value: impl IntoSqlValue) -> Self {
685        self.push_logical_or(col, "$le", value.into_sql_value())
686    }
687
688    /// Adds a logical `OR` condition for the column greater than a value.
689    #[inline]
690    pub fn or_gt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
691        self.push_logical_or(col, "$gt", value.into_sql_value())
692    }
693
694    /// Adds a logical `OR` condition for the column not less than a value.
695    #[inline]
696    pub fn or_ge(self, col: E::Column, value: impl IntoSqlValue) -> Self {
697        self.push_logical_or(col, "$ge", value.into_sql_value())
698    }
699
700    /// Adds a logical `OR` condition for the column `IN` a list of values.
701    #[inline]
702    pub fn or_in<T, V>(self, col: E::Column, values: V) -> Self
703    where
704        T: IntoSqlValue,
705        V: Into<Vec<T>>,
706    {
707        self.push_logical_or(col, "$in", values.into().into_sql_value())
708    }
709
710    /// Adds a logical `OR` condition for the column `NOT IN` a list of values.
711    #[inline]
712    pub fn or_not_in<T, V>(self, col: E::Column, values: V) -> Self
713    where
714        T: IntoSqlValue,
715        V: Into<Vec<T>>,
716    {
717        self.push_logical_or(col, "$nin", values.into().into_sql_value())
718    }
719
720    /// Adds a logical `OR` condition for the columns `IN` a subquery.
721    pub fn or_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
722    where
723        C: Into<Vec<E::Column>>,
724        M: Entity + Schema,
725    {
726        let cols = cols
727            .into()
728            .into_iter()
729            .map(|col| {
730                let col_name = E::format_column(&col);
731                Query::format_field(&col_name).into_owned()
732            })
733            .collect::<Vec<_>>()
734            .join(", ");
735        let field = format!("({cols})");
736        let condition = Map::from_entry("$in", subquery.into_sql_value());
737        self.logical_or.push(Map::from_entry(field, condition));
738        self
739    }
740
741    /// Adds a logical `OR` condition for the columns `NOT IN` a subquery.
742    pub fn or_not_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
743    where
744        C: Into<Vec<E::Column>>,
745        M: Entity + Schema,
746    {
747        let cols = cols
748            .into()
749            .into_iter()
750            .map(|col| {
751                let col_name = E::format_column(&col);
752                Query::format_field(&col_name).into_owned()
753            })
754            .collect::<Vec<_>>()
755            .join(", ");
756        let field = format!("({cols})");
757        let condition = Map::from_entry("$nin", subquery.into_sql_value());
758        self.logical_or.push(Map::from_entry(field, condition));
759        self
760    }
761
762    /// Adds a logical `OR` condition for the column is in a range `[min, max)`.
763    pub fn or_in_range<T: IntoSqlValue>(mut self, col: E::Column, min: T, max: T) -> Self {
764        let field = E::format_column(&col);
765        let mut condition = Map::new();
766        condition.upsert("$ge", min.into_sql_value());
767        condition.upsert("$lt", max.into_sql_value());
768        self.logical_or.push(Map::from_entry(field, condition));
769        self
770    }
771
772    /// Adds a logical `OR` condition for the column `BETWEEN` two values.
773    #[inline]
774    pub fn or_between<T: IntoSqlValue>(self, col: E::Column, min: T, max: T) -> Self {
775        self.push_logical_or(col, "$betw", [min, max].into_sql_value())
776    }
777
778    /// Adds a logical `OR` condition for the column `LIKE` a string value.
779    #[inline]
780    pub fn or_like(self, col: E::Column, value: String) -> Self {
781        self.push_logical_or(col, "$like", value.into_sql_value())
782    }
783
784    /// Adds a logical `OR` condition for the column `ILIKE` a string value.
785    #[inline]
786    pub fn or_ilike(self, col: E::Column, value: String) -> Self {
787        self.push_logical_or(col, "$ilike", value.into_sql_value())
788    }
789
790    /// Adds a logical `OR` condition for the column `RLIKE` a string value.
791    #[inline]
792    pub fn or_rlike(self, col: E::Column, value: String) -> Self {
793        self.push_logical_or(col, "$rlike", value.into_sql_value())
794    }
795
796    /// Adds a logical `OR` condition for the column which contains a string value.
797    #[inline]
798    pub fn or_contains(self, col: E::Column, value: &str) -> Self {
799        let value = ["%", value, "%"].concat();
800        self.push_logical_or(col, "$like", value.into_sql_value())
801    }
802
803    /// Adds a logical `OR` condition for the column which starts with a string value.
804    #[inline]
805    pub fn or_starts_with(self, col: E::Column, value: &str) -> Self {
806        let value = [value, "%"].concat();
807        self.push_logical_or(col, "$like", value.into_sql_value())
808    }
809
810    /// Adds a logical `OR` condition for the column which ends with a string value.
811    #[inline]
812    pub fn or_ends_with(self, col: E::Column, value: &str) -> Self {
813        let value = ["%", value].concat();
814        self.push_logical_or(col, "$like", value.into_sql_value())
815    }
816
817    /// Adds a logical `OR` condition for the column which is null.
818    #[inline]
819    pub fn or_null(self, col: E::Column) -> Self {
820        self.or_filter(col, JsonValue::Null)
821    }
822
823    /// Adds a logical `OR` condition for the column which is not null.
824    #[inline]
825    pub fn or_not_null(self, col: E::Column) -> Self {
826        self.or_filter(col, "not_null")
827    }
828
829    /// Adds a logical `OR` condition for the column which is an empty string or a null.
830    #[inline]
831    pub fn or_empty(self, col: E::Column) -> Self {
832        self.or_filter(col, "empty")
833    }
834
835    /// Adds a logical `OR` condition for the column which is not an empty string or a null.
836    #[inline]
837    pub fn or_nonempty(self, col: E::Column) -> Self {
838        self.or_filter(col, "nonempty")
839    }
840
841    /// Adds a logical `OR` condition for the two ranges which overlaps with each other.
842    pub fn or_overlaps<T: IntoSqlValue>(
843        mut self,
844        cols: (E::Column, E::Column),
845        values: (T, T),
846    ) -> Self {
847        let mut condition = Map::new();
848        condition.upsert(
849            E::format_column(&cols.0),
850            Map::from_entry("$le", values.1.into_sql_value()),
851        );
852        condition.upsert(
853            E::format_column(&cols.1),
854            Map::from_entry("$ge", values.0.into_sql_value()),
855        );
856        self.logical_or.push(condition);
857        self
858    }
859
860    /// Adds a query order.
861    #[inline]
862    pub fn order_by(mut self, col: impl ToString, descending: bool) -> Self {
863        self.sort_order
864            .push(QueryOrder::new(col.to_string(), descending));
865        self
866    }
867
868    /// Adds a query order with an extra flag to indicate whether the nulls appear first or last.
869    #[inline]
870    pub fn order_by_with_nulls(
871        mut self,
872        col: impl ToString,
873        descending: bool,
874        nulls_first: bool,
875    ) -> Self {
876        let mut order = QueryOrder::new(col.to_string(), descending);
877        if nulls_first {
878            order.set_nulls_first();
879        } else {
880            order.set_nulls_last();
881        }
882        self.sort_order.push(order);
883        self
884    }
885
886    /// Adds a query order with an ascending order.
887    #[inline]
888    pub fn order_asc(mut self, col: impl ToString) -> Self {
889        self.sort_order
890            .push(QueryOrder::new(col.to_string(), false));
891        self
892    }
893
894    /// Adds a query order with an descending order.
895    #[inline]
896    pub fn order_desc(mut self, col: impl ToString) -> Self {
897        self.sort_order.push(QueryOrder::new(col.to_string(), true));
898        self
899    }
900
901    /// Sets the offset.
902    #[inline]
903    pub fn offset(mut self, offset: usize) -> Self {
904        self.offset = offset;
905        self
906    }
907
908    /// Sets the limit.
909    #[inline]
910    pub fn limit(mut self, limit: usize) -> Self {
911        self.limit = limit;
912        self
913    }
914
915    /// Builds the model query.
916    pub fn build(self) -> Query {
917        let mut filters = self.filters;
918        let group_by_fields = self.group_by_fields;
919        let having_conditions = self.having_conditions;
920        let logical_and = self.logical_and;
921        let logical_or = self.logical_or;
922        if !group_by_fields.is_empty() {
923            filters.upsert("$group", group_by_fields);
924        }
925        if !having_conditions.is_empty() {
926            filters.upsert("$having", having_conditions);
927        }
928        if !logical_and.is_empty() {
929            filters.upsert("$and", logical_and);
930        }
931        if !logical_or.is_empty() {
932            filters.upsert("$or", logical_or);
933        }
934
935        let mut query = Query::new(filters);
936        query.set_fields(self.fields);
937        query.set_order(self.sort_order);
938        query.set_offset(self.offset);
939        query.set_limit(self.limit);
940        query
941    }
942
943    /// Adds a `HAVING` condition for non-equal parts.
944    fn push_having_condition(
945        mut self,
946        aggregation: Aggregation<E>,
947        operator: &str,
948        value: JsonValue,
949    ) -> Self {
950        let condition = Map::from_entry(operator, value);
951        self.having_conditions
952            .push(Map::from_entry(aggregation.expr(), condition));
953        self
954    }
955
956    /// Pushes a logical `AND` condition for the column and expressions.
957    fn push_logical_and(mut self, col: E::Column, operator: &str, value: JsonValue) -> Self {
958        let condition = Map::from_entry(operator, value);
959        self.logical_and
960            .push(Map::from_entry(E::format_column(&col), condition));
961        self
962    }
963
964    /// Pushes a logical `OR` condition for the column and expressions.
965    fn push_logical_or(mut self, col: E::Column, operator: &str, value: JsonValue) -> Self {
966        let condition = Map::from_entry(operator, value);
967        self.logical_or
968            .push(Map::from_entry(E::format_column(&col), condition));
969        self
970    }
971}
972
973impl<E: Entity + Schema> QueryBuilder<E> {
974    /// Builds a subquery SQL expression.
975    #[inline]
976    pub fn build_subquery(self) -> String {
977        let query = self.build();
978        let table_name = query.format_table_name::<E>();
979        let projection = query.format_table_fields::<E>();
980        let filters = query.format_filters::<E>();
981        let sort = query.format_sort();
982        let pagination = query.format_pagination();
983        format!("(SELECT {projection} FROM {table_name} {filters} {sort} {pagination})")
984    }
985}
986
987impl<E: Entity> Default for QueryBuilder<E> {
988    #[inline]
989    fn default() -> Self {
990        Self::new()
991    }
992}
993
994/// Extension trait for [`Query`](crate::model::Query).
995pub(super) trait QueryExt<DB> {
996    /// Query result type.
997    type QueryResult;
998
999    /// Parses the query result to get `last_insert_id` and `rows_affected`.
1000    fn parse_query_result(query_result: Self::QueryResult) -> (Option<i64>, u64);
1001
1002    /// Returns a reference to the projection fields.
1003    fn query_fields(&self) -> &[String];
1004
1005    /// Returns a reference to the filters.
1006    fn query_filters(&self) -> &Map;
1007
1008    /// Returns the sort order.
1009    fn query_order(&self) -> &[QueryOrder];
1010
1011    /// Returns the query offset.
1012    fn query_offset(&self) -> usize;
1013
1014    /// Returns the query limit.
1015    fn query_limit(&self) -> usize;
1016
1017    /// Returns a placeholder for the n-th parameter.
1018    fn placeholder(n: usize) -> SharedString;
1019
1020    /// Prepares the SQL query for binding parameters.
1021    fn prepare_query<'a>(
1022        query: &'a str,
1023        params: Option<&'a Map>,
1024    ) -> (Cow<'a, str>, Vec<&'a JsonValue>);
1025
1026    /// Formats a field for the query.
1027    fn format_field(field: &str) -> Cow<'_, str>;
1028
1029    /// Formats table fields.
1030    fn format_table_fields<M: Schema>(&self) -> Cow<'_, str>;
1031
1032    /// Formats the table name.
1033    fn format_table_name<M: Schema>(&self) -> String;
1034
1035    /// Returns the escaped table name.
1036    fn table_name_escaped<M: Schema>() -> String;
1037
1038    /// Parses text search filter.
1039    fn parse_text_search(filter: &Map) -> Option<String>;
1040
1041    /// Escapes a string.
1042    #[inline]
1043    fn escape_string(value: impl Display) -> String {
1044        format!("'{}'", value.to_string().replace('\'', "''"))
1045    }
1046
1047    /// Formats projection fields.
1048    fn format_projection(&self) -> Cow<'_, str> {
1049        let fields = self.query_fields();
1050        if fields.is_empty() {
1051            "*".into()
1052        } else {
1053            fields
1054                .iter()
1055                .map(|field| {
1056                    if let Some((alias, expr)) = field.split_once(':') {
1057                        let alias = Self::format_field(alias.trim());
1058                        format!(r#"{expr} AS {alias}"#).into()
1059                    } else {
1060                        Self::format_field(field)
1061                    }
1062                })
1063                .collect::<Vec<_>>()
1064                .join(", ")
1065                .into()
1066        }
1067    }
1068
1069    /// Formats the query filters to generate SQL `WHERE` expression.
1070    fn format_filters<M: Schema>(&self) -> String {
1071        let filters = self.query_filters();
1072        if filters.is_empty() {
1073            return String::new();
1074        }
1075
1076        let mut expression = String::new();
1077        let mut logical_and_conditions = Vec::with_capacity(filters.len());
1078        for (key, value) in filters {
1079            match key.as_str() {
1080                "$and" => {
1081                    if let Some(filters) = value.as_array() {
1082                        let condition = Self::format_logical_filters::<M>(filters, " AND ");
1083                        logical_and_conditions.push(condition);
1084                    }
1085                }
1086                "$not" => {
1087                    if let Some(filters) = value.as_array() {
1088                        let condition = Self::format_logical_filters::<M>(filters, " AND ");
1089                        logical_and_conditions.push(format!("(NOT {condition})"));
1090                    }
1091                }
1092                "$or" => {
1093                    if let Some(filters) = value.as_array() {
1094                        let condition = Self::format_logical_filters::<M>(filters, " OR ");
1095                        logical_and_conditions.push(condition);
1096                    }
1097                }
1098                "$rand" => {
1099                    if let Some(Ok(value)) = value.parse_f64() {
1100                        let condition = if cfg!(any(
1101                            feature = "orm-mariadb",
1102                            feature = "orm-mysql",
1103                            feature = "orm-tidb"
1104                        )) {
1105                            format!("rand() < {value}")
1106                        } else if cfg!(feature = "orm-postgres") {
1107                            format!("random() < {value}")
1108                        } else {
1109                            let value = (value * i64::MAX as f64) as i64;
1110                            format!("abs(random()) < {value}")
1111                        };
1112                        logical_and_conditions.push(condition);
1113                    }
1114                }
1115                "$text" => {
1116                    if let Some(condition) = value.as_object().and_then(Self::parse_text_search) {
1117                        logical_and_conditions.push(condition);
1118                    }
1119                }
1120                _ => {
1121                    if let Some(col) = M::get_column(key) {
1122                        let condition = if let Some(subquery) =
1123                            value.as_object().and_then(|m| m.get_str("$subquery"))
1124                        {
1125                            let key = Self::format_field(key);
1126                            format!(r#"{key} = {subquery}"#)
1127                        } else {
1128                            col.format_filter(key, value)
1129                        };
1130                        if !condition.is_empty() {
1131                            logical_and_conditions.push(condition);
1132                        }
1133                    } else if key.contains('.') {
1134                        let condition = Self::format_query_filter::<M>(key, value);
1135                        if !condition.is_empty() {
1136                            logical_and_conditions.push(condition);
1137                        }
1138                    }
1139                }
1140            }
1141        }
1142        if !logical_and_conditions.is_empty() {
1143            expression += &format!("WHERE {}", logical_and_conditions.join(" AND "));
1144        };
1145        if let Some(groups) = filters.parse_str_array("$group") {
1146            let groups = groups
1147                .into_iter()
1148                .map(Self::format_field)
1149                .collect::<Vec<_>>()
1150                .join(", ");
1151            expression += &format!(" GROUP BY {groups}");
1152            if let Some(filters) = filters.get_array("$having") {
1153                let condition = Self::format_logical_filters::<M>(filters, " AND ");
1154                expression += &format!(" HAVING {condition}");
1155            }
1156        }
1157        expression
1158    }
1159
1160    // Formats the filters with a logic operator.
1161    fn format_logical_filters<M: Schema>(filters: &[JsonValue], operator: &str) -> String {
1162        let mut conditions = Vec::with_capacity(filters.len());
1163        for filter in filters {
1164            if let JsonValue::Object(filter) = filter {
1165                let mut logical_and_conditions = Vec::with_capacity(filter.len());
1166                for (key, value) in filter {
1167                    match key.as_str() {
1168                        "$and" => {
1169                            if let Some(filters) = value.as_array() {
1170                                let condition = Self::format_logical_filters::<M>(filters, " AND ");
1171                                logical_and_conditions.push(condition);
1172                            }
1173                        }
1174                        "$not" => {
1175                            if let Some(filters) = value.as_array() {
1176                                let condition = Self::format_logical_filters::<M>(filters, " AND ");
1177                                logical_and_conditions.push(format!("(NOT {condition})"));
1178                            }
1179                        }
1180                        "$nor" => {
1181                            if let Some(filters) = value.as_array() {
1182                                let condition = Self::format_logical_filters::<M>(filters, " OR ");
1183                                logical_and_conditions.push(format!("(NOT {condition})"));
1184                            }
1185                        }
1186                        "$or" => {
1187                            if let Some(filters) = value.as_array() {
1188                                let condition = Self::format_logical_filters::<M>(filters, " OR ");
1189                                logical_and_conditions.push(condition);
1190                            }
1191                        }
1192                        _ => {
1193                            if let Some(col) = M::get_column(key) {
1194                                let condition = if let Some(subquery) =
1195                                    value.as_object().and_then(|m| m.get_str("$subquery"))
1196                                {
1197                                    let key = Self::format_field(key);
1198                                    format!(r#"{key} = {subquery}"#)
1199                                } else {
1200                                    col.format_filter(key, value)
1201                                };
1202                                if !condition.is_empty() {
1203                                    logical_and_conditions.push(condition);
1204                                }
1205                            } else if key.contains('.') {
1206                                let condition = Self::format_query_filter::<M>(key, value);
1207                                if !condition.is_empty() {
1208                                    logical_and_conditions.push(condition);
1209                                }
1210                            }
1211                        }
1212                    }
1213                }
1214                if !logical_and_conditions.is_empty() {
1215                    let condition = Self::join_conditions(logical_and_conditions, " AND ");
1216                    conditions.push(condition);
1217                }
1218            }
1219        }
1220        Self::join_conditions(conditions, operator)
1221    }
1222
1223    /// Formats a query filter.
1224    fn format_query_filter<M: Schema>(key: &str, value: &JsonValue) -> String {
1225        let json_field = key.split_once('.').and_then(|(key, path)| {
1226            M::get_column(key)
1227                .filter(|col| col.type_name() == "Map")
1228                .map(|col| {
1229                    let key = [M::model_name(), ".", col.name()].concat();
1230                    let field = Self::format_field(&key);
1231                    if cfg!(feature = "orm-postgres") {
1232                        let path = path.replace('.', ", ");
1233                        format!(r#"({field} #> '{{{path}}}')"#)
1234                    } else {
1235                        format!(r#"json_extract({field}, '$.{path}')"#)
1236                    }
1237                })
1238        });
1239        let requires_json_value = json_field.is_some();
1240        let field = json_field
1241            .map(|s| s.into())
1242            .unwrap_or_else(|| Self::format_field(key));
1243        if let Some(filter) = value.as_object() {
1244            let mut conditions = Vec::with_capacity(filter.len());
1245            for (name, value) in filter {
1246                let operator = match name.as_str() {
1247                    "$eq" => "=",
1248                    "$ne" => "<>",
1249                    "$lt" => "<",
1250                    "$le" => "<=",
1251                    "$gt" => ">",
1252                    "$ge" => ">=",
1253                    "$in" => "IN",
1254                    "$nin" => "NOT IN",
1255                    _ => "=",
1256                };
1257                let condition = if let Some(subquery) =
1258                    value.as_object().and_then(|m| m.get_str("$subquery"))
1259                {
1260                    format!(r#"{field} {operator} {subquery}"#)
1261                } else if requires_json_value {
1262                    Self::format_json_filter(&field, operator, value)
1263                } else if let Some(s) = value.as_str() {
1264                    if name == "$subquery" {
1265                        format!(r#"{field} {operator} {s}"#)
1266                    } else {
1267                        let value = Self::escape_string(s);
1268                        format!(r#"{field} {operator} {value}"#)
1269                    }
1270                } else {
1271                    format!(r#"{field} {operator} {value}"#)
1272                };
1273                conditions.push(condition);
1274            }
1275            Self::join_conditions(conditions, " AND ")
1276        } else if requires_json_value {
1277            Self::format_json_filter(&field, "=", value)
1278        } else if let Some(s) = value.as_str() {
1279            let value = Self::escape_string(s);
1280            format!(r#"{field} = {value}"#)
1281        } else {
1282            format!(r#"{field} = {value}"#)
1283        }
1284    }
1285
1286    /// Formats the filter for a JSON field.
1287    fn format_json_filter(field: &str, operator: &str, value: &JsonValue) -> String {
1288        match value {
1289            JsonValue::Null => format!(r#"{field} IS NULL"#),
1290            JsonValue::Bool(b) => {
1291                let value = if *b { "true" } else { "false" };
1292                if cfg!(feature = "orm-postgres") {
1293                    format!(r#"({field})::boolean IS {value}"#)
1294                } else {
1295                    format!(r#"{field} = {value}"#)
1296                }
1297            }
1298            JsonValue::Number(n) => {
1299                if cfg!(feature = "orm-postgres") {
1300                    format!(r#"{field} {operator} '{n}'"#)
1301                } else {
1302                    format!(r#"{field} {operator} {n}"#)
1303                }
1304            }
1305            JsonValue::String(s) => {
1306                if s == "null" {
1307                    format!(r#"{field} IS NULL"#)
1308                } else if s == "not_null" {
1309                    format!(r#"{field} IS NOT NULL"#)
1310                } else if s == "true" || s == "false" {
1311                    if cfg!(feature = "orm-postgres") {
1312                        format!(r#"({field})::boolean IS {s}"#)
1313                    } else {
1314                        format!(r#"{field} = {s}"#)
1315                    }
1316                } else if let Ok(n) = s.parse::<serde_json::Number>() {
1317                    if cfg!(feature = "orm-postgres") {
1318                        format!(r#"{field} {operator} '{n}'"#)
1319                    } else {
1320                        format!(r#"{field} {operator} {n}"#)
1321                    }
1322                } else {
1323                    let value = if cfg!(feature = "orm-postgres") {
1324                        Self::escape_string(value)
1325                    } else {
1326                        Self::escape_string(s)
1327                    };
1328                    format!(r#"{field} {operator} {value}"#)
1329                }
1330            }
1331            _ => {
1332                let value = Self::escape_string(value);
1333                format!(r#"{field} {operator} {value}"#)
1334            }
1335        }
1336    }
1337
1338    /// Formats the query sort to generate SQL `ORDER BY` expression.
1339    fn format_sort(&self) -> String {
1340        let sort_order = self.query_order();
1341        if sort_order.is_empty() {
1342            String::new()
1343        } else {
1344            let sort_order = sort_order
1345                .iter()
1346                .map(|order| {
1347                    let sort_field = Self::format_field(order.field());
1348                    let mut expr = if order.is_descending() {
1349                        format!("{sort_field} DESC")
1350                    } else {
1351                        format!("{sort_field} ASC")
1352                    };
1353                    if order.nulls_first() {
1354                        expr.push_str(" NULLS FIRST");
1355                    } else if order.nulls_last() {
1356                        expr.push_str(" NULLS LAST");
1357                    }
1358                    expr
1359                })
1360                .collect::<Vec<_>>();
1361            format!("ORDER BY {}", sort_order.join(", "))
1362        }
1363    }
1364
1365    /// Formats the query pagination to generate SQL `LIMIT` expression.
1366    fn format_pagination(&self) -> String {
1367        let limit = self.query_limit();
1368        if limit == 0 || limit == usize::MAX {
1369            return String::new();
1370        }
1371
1372        let offset = self.query_offset();
1373        format!("LIMIT {limit} OFFSET {offset}")
1374    }
1375
1376    /// Joins the conditions.
1377    fn join_conditions(mut conditions: Vec<String>, operator: &str) -> String {
1378        match conditions.len() {
1379            0 => String::new(),
1380            1 => conditions.remove(0),
1381            _ => format!("({})", conditions.join(operator)),
1382        }
1383    }
1384}
1385
1386/// Formats the query using interpolation of the parameters.
1387///
1388/// The interpolation parameter is represented as `${param}`,
1389/// in which `param` can only contain restricted chracters `[a-zA-Z]+[\w\.]*`.
1390pub(crate) fn format_query<'a>(query: &'a str, params: Option<&'a Map>) -> Cow<'a, str> {
1391    if let Some(params) = params.filter(|_| query.contains('$')) {
1392        INTERPOLATION_PATTERN.replace_all(query, |captures: &Captures| {
1393            let key = &captures[1];
1394            params
1395                .get(key)
1396                .map(|value| match value {
1397                    JsonValue::String(s) => s.to_owned(),
1398                    _ => value.to_string(),
1399                })
1400                .unwrap_or_else(|| ["${", key, "}"].concat())
1401        })
1402    } else {
1403        Cow::Borrowed(query)
1404    }
1405}
1406
1407/// Prepares the SQL query for binding parameters
1408/// (`?` for most SQL flavors and `$N` for PostgreSQL).
1409///
1410/// The parameter is represented as `${param}` or `#{param}`,
1411/// in which `param` can only contain restricted chracters `[a-zA-Z]+[\w\.]*`.
1412pub(crate) fn prepare_sql_query<'a>(
1413    query: &'a str,
1414    params: Option<&'a Map>,
1415    placeholder: char,
1416) -> (Cow<'a, str>, Vec<&'a JsonValue>) {
1417    let sql = format_query(query, params);
1418    if let Some(params) = params.filter(|_| sql.contains('#')) {
1419        let mut values = Vec::new();
1420        let sql = STATEMENT_PATTERN.replace_all(&sql, |captures: &Captures| {
1421            let key = &captures[1];
1422            let value = params.get(key).unwrap_or(&JsonValue::Null);
1423            values.push(value);
1424            if placeholder == '$' {
1425                Cow::Owned(format!("${}", values.len()))
1426            } else {
1427                Cow::Borrowed("?")
1428            }
1429        });
1430        (sql.into_owned().into(), values)
1431    } else {
1432        (sql, Vec::new())
1433    }
1434}
1435
1436/// Regex for the interpolation parameter.
1437static INTERPOLATION_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1438    Regex::new(r"\$\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1439        .expect("fail to create a regex for the interpolation parameter")
1440});
1441
1442/// Regex for the prepared statement.
1443static STATEMENT_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1444    Regex::new(r"\#\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1445        .expect("fail to create a regex for the prepared statement")
1446});
1447
1448#[cfg(test)]
1449mod tests {
1450    use zino_core::{extension::JsonObjectExt, Map};
1451
1452    #[test]
1453    fn it_formats_query_params() {
1454        let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1455        let mut params = Map::new();
1456        params.upsert("fields", "id, name, age");
1457        params.upsert("age", 18);
1458
1459        let sql = super::format_query(query, Some(&params));
1460        assert_eq!(
1461            sql,
1462            "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= #{age};"
1463        );
1464    }
1465
1466    #[test]
1467    fn it_formats_sql_query_params() {
1468        let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1469        let mut params = Map::new();
1470        params.upsert("fields", "id, name, age");
1471        params.upsert("age", 18);
1472
1473        let (sql, values) = super::prepare_sql_query(query, Some(&params), '?');
1474        assert_eq!(
1475            sql,
1476            "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= ?;"
1477        );
1478        assert_eq!(values[0], 18);
1479
1480        let (sql, values) = super::prepare_sql_query(query, Some(&params), '$');
1481        assert_eq!(
1482            sql,
1483            "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= $1;"
1484        );
1485        assert_eq!(values[0], 18);
1486    }
1487}