1use super::{Aggregation, EncodeColumn, Entity, IntoSqlValue, Schema, Window};
100use regex::{Captures, Regex};
101use std::{borrow::Cow, fmt::Display, marker::PhantomData};
102use zino_core::{
103 JsonValue, LazyLock, Map, SharedString,
104 extension::{JsonObjectExt, JsonValueExt},
105 model::{Query, QueryOrder},
106};
107
108#[derive(Debug, Clone)]
129pub struct QueryBuilder<E: Entity> {
130 fields: Vec<String>,
132 group_by_fields: Vec<String>,
134 having_conditions: Vec<Map>,
136 filters: Map,
138 logical_and: Vec<Map>,
140 logical_or: Vec<Map>,
142 sort_order: Vec<QueryOrder>,
144 offset: usize,
146 limit: usize,
148 extra: Map,
150 phantom: PhantomData<E>,
152}
153
154impl<E: Entity> QueryBuilder<E> {
155 #[inline]
157 pub fn new() -> Self {
158 Self {
159 fields: Vec::new(),
160 group_by_fields: Vec::new(),
161 having_conditions: Vec::new(),
162 filters: Map::new(),
163 logical_and: Vec::new(),
164 logical_or: Vec::new(),
165 sort_order: Vec::new(),
166 offset: 0,
167 limit: 0,
168 extra: Map::new(),
169 phantom: PhantomData,
170 }
171 }
172
173 #[inline]
175 pub fn table_name(mut self, table_name: String) -> Self {
176 self.extra.upsert("table_name", table_name);
177 self
178 }
179
180 #[inline]
182 pub fn field(mut self, col: E::Column) -> Self {
183 self.fields.push(E::format_column(&col));
184 self
185 }
186
187 #[inline]
189 pub fn fields<V: Into<Vec<E::Column>>>(mut self, cols: V) -> Self {
190 let mut fields = cols.into().iter().map(E::format_column).collect();
191 self.fields.append(&mut fields);
192 self
193 }
194
195 pub fn alias(mut self, col: E::Column, alias: &str) -> Self {
197 let col_name = E::format_column(&col);
198 let field = Query::format_field(&col_name);
199 let field_alias = [alias, ":", &field].concat();
200 self.fields.push(field_alias);
201 self
202 }
203
204 pub fn json_extract(mut self, col: E::Column, path: &str, alias: &str) -> Self {
206 let col_name = E::format_column(&col);
207 let field = Query::format_field(&col_name);
208 let json_field = if cfg!(feature = "orm-postgres") {
209 let path = path.strip_prefix("$.").unwrap_or(path).replace('.', ", ");
210 format!(r#"({field} #>> '{{{path}}}')"#)
211 } else {
212 format!(r#"json_unquote(json_extract({field}, '{path}'))"#)
213 };
214 let field_alias = [alias, ":", &json_field].concat();
215 self.fields.push(field_alias);
216 self
217 }
218
219 pub fn aggregate(mut self, aggregation: Aggregation<E>, alias: Option<&str>) -> Self {
221 let expr = aggregation.expr();
222 let field_alias = if let Some(alias) = alias {
223 [alias, ":", &expr].concat()
224 } else {
225 let mut field_alias = aggregation.default_alias();
226 field_alias.push(':');
227 field_alias.push_str(&expr);
228 field_alias
229 };
230 self.fields.push(field_alias);
231 self
232 }
233
234 pub fn window(mut self, window: Window<E>, alias: Option<&str>) -> Self {
236 let expr = window.expr();
237 let field_alias = if let Some(alias) = alias {
238 [alias, ":", &expr].concat()
239 } else {
240 let mut field_alias = window.default_alias();
241 field_alias.push(':');
242 field_alias.push_str(&expr);
243 field_alias
244 };
245 self.fields.push(field_alias);
246 self
247 }
248
249 pub fn group_by(mut self, col: E::Column) -> Self {
251 let field = E::format_column(&col);
252 if !self.fields.contains(&field) {
253 self.fields.push(field.clone());
254 }
255 self.group_by_fields.push(field);
256 self
257 }
258
259 #[inline]
261 pub fn having_filter(mut self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
262 let condition = Map::from_entry(aggregation.expr(), value.into_sql_value());
263 self.having_conditions.push(condition);
264 self
265 }
266
267 #[inline]
269 pub fn having_eq(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
270 self.push_having_condition(aggregation, "$eq", value.into_sql_value())
271 }
272
273 #[inline]
275 pub fn having_ne(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
276 self.push_having_condition(aggregation, "$ne", value.into_sql_value())
277 }
278
279 #[inline]
281 pub fn having_lt(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
282 self.push_having_condition(aggregation, "$lt", value.into_sql_value())
283 }
284
285 #[inline]
287 pub fn having_le(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
288 self.push_having_condition(aggregation, "$le", value.into_sql_value())
289 }
290
291 #[inline]
293 pub fn having_gt(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
294 self.push_having_condition(aggregation, "$gt", value.into_sql_value())
295 }
296
297 #[inline]
299 pub fn having_ge(self, aggregation: Aggregation<E>, value: impl IntoSqlValue) -> Self {
300 self.push_having_condition(aggregation, "$ge", value.into_sql_value())
301 }
302
303 #[inline]
305 pub fn primary_key(mut self, value: impl IntoSqlValue) -> Self {
306 let field = E::format_column(&E::PRIMARY_KEY);
307 self.filters.upsert(field, value.into_sql_value());
308 self
309 }
310
311 #[inline]
313 pub fn rand(mut self, value: impl IntoSqlValue) -> Self {
314 self.filters.upsert("$rand", value.into_sql_value());
315 self
316 }
317
318 pub fn and<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
320 let mut logical_and = other.logical_and;
321 let logical_or = other.logical_or;
322 if !logical_or.is_empty() {
323 logical_and.push(Map::from_entry("$or", logical_or));
324 }
325 if !logical_and.is_empty() {
326 self.logical_and.push(Map::from_entry("$and", logical_and));
327 }
328 self.fields.append(&mut other.fields);
329 self.group_by_fields.append(&mut other.group_by_fields);
330 self
331 }
332
333 pub fn and_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
335 let mut logical_and = other.logical_and;
336 let logical_or = other.logical_or;
337 if !logical_or.is_empty() {
338 logical_and.push(Map::from_entry("$or", logical_or));
339 }
340 if !logical_and.is_empty() {
341 self.logical_and.push(Map::from_entry("$not", logical_and));
342 }
343 self.fields.append(&mut other.fields);
344 self.group_by_fields.append(&mut other.group_by_fields);
345 self
346 }
347
348 #[inline]
350 pub fn and_filter(mut self, col: E::Column, value: impl IntoSqlValue) -> Self {
351 let condition = Map::from_entry(E::format_column(&col), value.into_sql_value());
352 self.logical_and.push(condition);
353 self
354 }
355
356 #[inline]
358 pub fn and_eq(self, col: E::Column, value: impl IntoSqlValue) -> Self {
359 self.push_logical_and(col, "$eq", value.into_sql_value())
360 }
361
362 #[inline]
364 pub fn and_eq_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
365 let value = value.into_sql_value();
366 if !value.is_null() {
367 self.push_logical_and(col, "$eq", value)
368 } else {
369 self
370 }
371 }
372
373 #[inline]
375 pub fn and_eq_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
376 if let Some(value) = value {
377 self.push_logical_and(col, "$eq", value.into_sql_value())
378 } else {
379 self
380 }
381 }
382
383 #[inline]
385 pub fn and_ne(self, col: E::Column, value: impl IntoSqlValue) -> Self {
386 self.push_logical_and(col, "$ne", value.into_sql_value())
387 }
388
389 #[inline]
391 pub fn and_ne_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
392 let value = value.into_sql_value();
393 if !value.is_null() {
394 self.push_logical_and(col, "$ne", value)
395 } else {
396 self
397 }
398 }
399
400 #[inline]
402 pub fn and_ne_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
403 if let Some(value) = value {
404 self.push_logical_and(col, "$ne", value.into_sql_value())
405 } else {
406 self
407 }
408 }
409
410 #[inline]
412 pub fn and_lt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
413 self.push_logical_and(col, "$lt", value.into_sql_value())
414 }
415
416 #[inline]
418 pub fn and_le(self, col: E::Column, value: impl IntoSqlValue) -> Self {
419 self.push_logical_and(col, "$le", value.into_sql_value())
420 }
421
422 #[inline]
424 pub fn and_gt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
425 self.push_logical_and(col, "$gt", value.into_sql_value())
426 }
427
428 #[inline]
430 pub fn and_ge(self, col: E::Column, value: impl IntoSqlValue) -> Self {
431 self.push_logical_and(col, "$ge", value.into_sql_value())
432 }
433
434 #[inline]
436 pub fn and_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, "$in", values.into().into_sql_value())
442 }
443
444 #[inline]
446 pub fn and_not_in<T, V>(self, col: E::Column, values: V) -> Self
447 where
448 T: IntoSqlValue,
449 V: Into<Vec<T>>,
450 {
451 self.push_logical_and(col, "$nin", values.into().into_sql_value())
452 }
453
454 pub fn and_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
456 where
457 C: Into<Vec<E::Column>>,
458 M: Entity + Schema,
459 {
460 let cols = cols
461 .into()
462 .into_iter()
463 .map(|col| {
464 let col_name = E::format_column(&col);
465 Query::format_field(&col_name).into_owned()
466 })
467 .collect::<Vec<_>>()
468 .join(", ");
469 let field = format!("({cols})");
470 let condition = Map::from_entry("$in", subquery.into_sql_value());
471 self.logical_and.push(Map::from_entry(field, condition));
472 self
473 }
474
475 pub fn and_not_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
477 where
478 C: Into<Vec<E::Column>>,
479 M: Entity + Schema,
480 {
481 let cols = cols
482 .into()
483 .into_iter()
484 .map(|col| {
485 let col_name = E::format_column(&col);
486 Query::format_field(&col_name).into_owned()
487 })
488 .collect::<Vec<_>>()
489 .join(", ");
490 let field = format!("({cols})");
491 let condition = Map::from_entry("$nin", subquery.into_sql_value());
492 self.logical_and.push(Map::from_entry(field, condition));
493 self
494 }
495
496 pub fn and_in_range<T: IntoSqlValue>(mut self, col: E::Column, min: T, max: T) -> Self {
498 let field = E::format_column(&col);
499 let mut condition = Map::new();
500 condition.upsert("$ge", min.into_sql_value());
501 condition.upsert("$lt", max.into_sql_value());
502 self.logical_and.push(Map::from_entry(field, condition));
503 self
504 }
505
506 #[inline]
508 pub fn and_between<T: IntoSqlValue>(self, col: E::Column, min: T, max: T) -> Self {
509 self.push_logical_and(col, "$betw", [min, max].into_sql_value())
510 }
511
512 #[inline]
514 pub fn and_like(self, col: E::Column, value: String) -> Self {
515 self.push_logical_and(col, "$like", value.into_sql_value())
516 }
517
518 #[inline]
520 pub fn and_ilike(self, col: E::Column, value: String) -> Self {
521 self.push_logical_and(col, "$ilike", value.into_sql_value())
522 }
523
524 #[inline]
526 pub fn and_rlike(self, col: E::Column, value: String) -> Self {
527 self.push_logical_and(col, "$rlike", value.into_sql_value())
528 }
529
530 #[inline]
532 pub fn and_contains(self, col: E::Column, value: &str) -> Self {
533 let value = ["%", value, "%"].concat();
534 self.push_logical_and(col, "$like", value.into_sql_value())
535 }
536
537 #[inline]
539 pub fn and_starts_with(self, col: E::Column, value: &str) -> Self {
540 let value = [value, "%"].concat();
541 self.push_logical_and(col, "$like", value.into_sql_value())
542 }
543
544 #[inline]
546 pub fn and_ends_with(self, col: E::Column, value: &str) -> Self {
547 let value = ["%", value].concat();
548 self.push_logical_and(col, "$like", value.into_sql_value())
549 }
550
551 #[inline]
553 pub fn and_null(self, col: E::Column) -> Self {
554 self.and_filter(col, JsonValue::Null)
555 }
556
557 #[inline]
559 pub fn and_not_null(self, col: E::Column) -> Self {
560 self.and_filter(col, "not_null")
561 }
562
563 #[inline]
565 pub fn and_empty(self, col: E::Column) -> Self {
566 self.and_filter(col, "empty")
567 }
568
569 #[inline]
571 pub fn and_nonempty(self, col: E::Column) -> Self {
572 self.and_filter(col, "nonempty")
573 }
574
575 pub fn and_overlaps<T: IntoSqlValue>(
577 mut self,
578 cols: (E::Column, E::Column),
579 values: (T, T),
580 ) -> Self {
581 let mut condition = Map::new();
582 condition.upsert(
583 E::format_column(&cols.0),
584 Map::from_entry("$le", values.1.into_sql_value()),
585 );
586 condition.upsert(
587 E::format_column(&cols.1),
588 Map::from_entry("$ge", values.0.into_sql_value()),
589 );
590 self.logical_and.push(condition);
591 self
592 }
593
594 pub fn or<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
596 let mut logical_and = other.logical_and;
597 let logical_or = other.logical_or;
598 if !logical_or.is_empty() {
599 logical_and.push(Map::from_entry("$or", logical_or));
600 }
601 if !logical_and.is_empty() {
602 self.logical_or.push(Map::from_entry("$and", logical_and));
603 }
604 self.fields.append(&mut other.fields);
605 self.group_by_fields.append(&mut other.group_by_fields);
606 self
607 }
608
609 pub fn or_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
611 let mut logical_and = other.logical_and;
612 let logical_or = other.logical_or;
613 if !logical_or.is_empty() {
614 logical_and.push(Map::from_entry("$or", logical_or));
615 }
616 if !logical_and.is_empty() {
617 self.logical_or.push(Map::from_entry("$not", logical_and));
618 }
619 self.fields.append(&mut other.fields);
620 self.group_by_fields.append(&mut other.group_by_fields);
621 self
622 }
623
624 #[inline]
626 pub fn or_filter(mut self, col: E::Column, value: impl IntoSqlValue) -> Self {
627 let condition = Map::from_entry(E::format_column(&col), value.into_sql_value());
628 self.logical_or.push(condition);
629 self
630 }
631
632 #[inline]
634 pub fn or_eq(self, col: E::Column, value: impl IntoSqlValue) -> Self {
635 self.push_logical_or(col, "$eq", value.into_sql_value())
636 }
637
638 #[inline]
640 pub fn or_eq_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
641 let value = value.into_sql_value();
642 if !value.is_null() {
643 self.push_logical_or(col, "$eq", value)
644 } else {
645 self
646 }
647 }
648
649 #[inline]
651 pub fn or_eq_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
652 if let Some(value) = value {
653 self.push_logical_or(col, "$eq", value.into_sql_value())
654 } else {
655 self
656 }
657 }
658
659 #[inline]
661 pub fn or_ne(self, col: E::Column, value: impl IntoSqlValue) -> Self {
662 self.push_logical_or(col, "$ne", value.into_sql_value())
663 }
664
665 #[inline]
667 pub fn or_ne_if_not_null(self, col: E::Column, value: impl IntoSqlValue) -> Self {
668 let value = value.into_sql_value();
669 if !value.is_null() {
670 self.push_logical_or(col, "$ne", value)
671 } else {
672 self
673 }
674 }
675
676 #[inline]
678 pub fn or_ne_if_some<T: IntoSqlValue>(self, col: E::Column, value: Option<T>) -> Self {
679 if let Some(value) = value {
680 self.push_logical_or(col, "$ne", value.into_sql_value())
681 } else {
682 self
683 }
684 }
685
686 #[inline]
688 pub fn or_lt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
689 self.push_logical_or(col, "$lt", value.into_sql_value())
690 }
691
692 #[inline]
694 pub fn or_le(self, col: E::Column, value: impl IntoSqlValue) -> Self {
695 self.push_logical_or(col, "$le", value.into_sql_value())
696 }
697
698 #[inline]
700 pub fn or_gt(self, col: E::Column, value: impl IntoSqlValue) -> Self {
701 self.push_logical_or(col, "$gt", value.into_sql_value())
702 }
703
704 #[inline]
706 pub fn or_ge(self, col: E::Column, value: impl IntoSqlValue) -> Self {
707 self.push_logical_or(col, "$ge", value.into_sql_value())
708 }
709
710 #[inline]
712 pub fn or_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, "$in", values.into().into_sql_value())
718 }
719
720 #[inline]
722 pub fn or_not_in<T, V>(self, col: E::Column, values: V) -> Self
723 where
724 T: IntoSqlValue,
725 V: Into<Vec<T>>,
726 {
727 self.push_logical_or(col, "$nin", values.into().into_sql_value())
728 }
729
730 pub fn or_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
732 where
733 C: Into<Vec<E::Column>>,
734 M: Entity + Schema,
735 {
736 let cols = cols
737 .into()
738 .into_iter()
739 .map(|col| {
740 let col_name = E::format_column(&col);
741 Query::format_field(&col_name).into_owned()
742 })
743 .collect::<Vec<_>>()
744 .join(", ");
745 let field = format!("({cols})");
746 let condition = Map::from_entry("$in", subquery.into_sql_value());
747 self.logical_or.push(Map::from_entry(field, condition));
748 self
749 }
750
751 pub fn or_not_in_subquery<C, M>(mut self, cols: C, subquery: QueryBuilder<M>) -> Self
753 where
754 C: Into<Vec<E::Column>>,
755 M: Entity + Schema,
756 {
757 let cols = cols
758 .into()
759 .into_iter()
760 .map(|col| {
761 let col_name = E::format_column(&col);
762 Query::format_field(&col_name).into_owned()
763 })
764 .collect::<Vec<_>>()
765 .join(", ");
766 let field = format!("({cols})");
767 let condition = Map::from_entry("$nin", subquery.into_sql_value());
768 self.logical_or.push(Map::from_entry(field, condition));
769 self
770 }
771
772 pub fn or_in_range<T: IntoSqlValue>(mut self, col: E::Column, min: T, max: T) -> Self {
774 let field = E::format_column(&col);
775 let mut condition = Map::new();
776 condition.upsert("$ge", min.into_sql_value());
777 condition.upsert("$lt", max.into_sql_value());
778 self.logical_or.push(Map::from_entry(field, condition));
779 self
780 }
781
782 #[inline]
784 pub fn or_between<T: IntoSqlValue>(self, col: E::Column, min: T, max: T) -> Self {
785 self.push_logical_or(col, "$betw", [min, max].into_sql_value())
786 }
787
788 #[inline]
790 pub fn or_like(self, col: E::Column, value: String) -> Self {
791 self.push_logical_or(col, "$like", value.into_sql_value())
792 }
793
794 #[inline]
796 pub fn or_ilike(self, col: E::Column, value: String) -> Self {
797 self.push_logical_or(col, "$ilike", value.into_sql_value())
798 }
799
800 #[inline]
802 pub fn or_rlike(self, col: E::Column, value: String) -> Self {
803 self.push_logical_or(col, "$rlike", value.into_sql_value())
804 }
805
806 #[inline]
808 pub fn or_contains(self, col: E::Column, value: &str) -> Self {
809 let value = ["%", value, "%"].concat();
810 self.push_logical_or(col, "$like", value.into_sql_value())
811 }
812
813 #[inline]
815 pub fn or_starts_with(self, col: E::Column, value: &str) -> Self {
816 let value = [value, "%"].concat();
817 self.push_logical_or(col, "$like", value.into_sql_value())
818 }
819
820 #[inline]
822 pub fn or_ends_with(self, col: E::Column, value: &str) -> Self {
823 let value = ["%", value].concat();
824 self.push_logical_or(col, "$like", value.into_sql_value())
825 }
826
827 #[inline]
829 pub fn or_null(self, col: E::Column) -> Self {
830 self.or_filter(col, JsonValue::Null)
831 }
832
833 #[inline]
835 pub fn or_not_null(self, col: E::Column) -> Self {
836 self.or_filter(col, "not_null")
837 }
838
839 #[inline]
841 pub fn or_empty(self, col: E::Column) -> Self {
842 self.or_filter(col, "empty")
843 }
844
845 #[inline]
847 pub fn or_nonempty(self, col: E::Column) -> Self {
848 self.or_filter(col, "nonempty")
849 }
850
851 pub fn or_overlaps<T: IntoSqlValue>(
853 mut self,
854 cols: (E::Column, E::Column),
855 values: (T, T),
856 ) -> Self {
857 let mut condition = Map::new();
858 condition.upsert(
859 E::format_column(&cols.0),
860 Map::from_entry("$le", values.1.into_sql_value()),
861 );
862 condition.upsert(
863 E::format_column(&cols.1),
864 Map::from_entry("$ge", values.0.into_sql_value()),
865 );
866 self.logical_or.push(condition);
867 self
868 }
869
870 #[inline]
872 pub fn order_by(mut self, col: impl ToString, descending: bool) -> Self {
873 self.sort_order
874 .push(QueryOrder::new(col.to_string(), descending));
875 self
876 }
877
878 #[inline]
880 pub fn order_by_with_nulls(
881 mut self,
882 col: impl ToString,
883 descending: bool,
884 nulls_first: bool,
885 ) -> Self {
886 let mut order = QueryOrder::new(col.to_string(), descending);
887 if nulls_first {
888 order.set_nulls_first();
889 } else {
890 order.set_nulls_last();
891 }
892 self.sort_order.push(order);
893 self
894 }
895
896 #[inline]
898 pub fn order_asc(mut self, col: impl ToString) -> Self {
899 self.sort_order
900 .push(QueryOrder::new(col.to_string(), false));
901 self
902 }
903
904 #[inline]
906 pub fn order_desc(mut self, col: impl ToString) -> Self {
907 self.sort_order.push(QueryOrder::new(col.to_string(), true));
908 self
909 }
910
911 #[inline]
913 pub fn offset(mut self, offset: usize) -> Self {
914 self.offset = offset;
915 self
916 }
917
918 #[inline]
920 pub fn limit(mut self, limit: usize) -> Self {
921 self.limit = limit;
922 self
923 }
924
925 pub fn build(mut self) -> Query {
927 let mut filters = self.filters;
928 let group_by_fields = self.group_by_fields;
929 let having_conditions = self.having_conditions;
930 let logical_and = self.logical_and;
931 let logical_or = self.logical_or;
932 if !group_by_fields.is_empty() {
933 filters.upsert("$group", group_by_fields);
934 }
935 if !having_conditions.is_empty() {
936 filters.upsert("$having", having_conditions);
937 }
938 if !logical_and.is_empty() {
939 filters.upsert("$and", logical_and);
940 }
941 if !logical_or.is_empty() {
942 filters.upsert("$or", logical_or);
943 }
944
945 let mut query = Query::new(filters);
946 query.set_fields(self.fields);
947 query.set_order(self.sort_order);
948 query.set_offset(self.offset);
949 query.set_limit(self.limit);
950 query.append_extra_flags(&mut self.extra);
951 query
952 }
953
954 fn push_having_condition(
956 mut self,
957 aggregation: Aggregation<E>,
958 operator: &str,
959 value: JsonValue,
960 ) -> Self {
961 let condition = Map::from_entry(operator, value);
962 self.having_conditions
963 .push(Map::from_entry(aggregation.expr(), condition));
964 self
965 }
966
967 fn push_logical_and(mut self, col: E::Column, operator: &str, value: JsonValue) -> Self {
969 let condition = Map::from_entry(operator, value);
970 self.logical_and
971 .push(Map::from_entry(E::format_column(&col), condition));
972 self
973 }
974
975 fn push_logical_or(mut self, col: E::Column, operator: &str, value: JsonValue) -> Self {
977 let condition = Map::from_entry(operator, value);
978 self.logical_or
979 .push(Map::from_entry(E::format_column(&col), condition));
980 self
981 }
982}
983
984impl<E: Entity + Schema> QueryBuilder<E> {
985 #[inline]
987 pub fn build_subquery(self) -> String {
988 let query = self.build();
989 let table_name = query.format_table_name::<E>();
990 let projection = query.format_table_fields::<E>();
991 let filters = query.format_filters::<E>();
992 let sort = query.format_sort();
993 let pagination = query.format_pagination();
994 format!("(SELECT {projection} FROM {table_name} {filters} {sort} {pagination})")
995 }
996}
997
998impl<E: Entity> Default for QueryBuilder<E> {
999 #[inline]
1000 fn default() -> Self {
1001 Self::new()
1002 }
1003}
1004
1005pub(super) trait QueryExt<DB> {
1007 type QueryResult;
1009
1010 fn parse_query_result(query_result: Self::QueryResult) -> (Option<i64>, u64);
1012
1013 fn query_fields(&self) -> &[String];
1015
1016 fn query_filters(&self) -> ⤅
1018
1019 fn query_order(&self) -> &[QueryOrder];
1021
1022 fn query_offset(&self) -> usize;
1024
1025 fn query_limit(&self) -> usize;
1027
1028 fn placeholder(n: usize) -> SharedString;
1030
1031 fn prepare_query<'a>(
1033 query: &'a str,
1034 params: Option<&'a Map>,
1035 ) -> (Cow<'a, str>, Vec<&'a JsonValue>);
1036
1037 fn format_field(field: &str) -> Cow<'_, str>;
1039
1040 fn format_table_fields<M: Schema>(&self) -> Cow<'_, str>;
1042
1043 fn format_table_name<M: Schema>(&self) -> String;
1045
1046 fn escape_table_name(table_name: &str) -> String;
1048
1049 fn parse_text_search(filter: &Map) -> Option<String>;
1051
1052 #[inline]
1054 fn escape_string(value: impl Display) -> String {
1055 format!("'{}'", value.to_string().replace('\'', "''"))
1056 }
1057
1058 fn format_projection(&self) -> Cow<'_, str> {
1060 let fields = self.query_fields();
1061 if fields.is_empty() {
1062 "*".into()
1063 } else {
1064 fields
1065 .iter()
1066 .map(|field| {
1067 if let Some((alias, expr)) = field.split_once(':') {
1068 let alias = Self::format_field(alias.trim());
1069 format!(r#"{expr} AS {alias}"#).into()
1070 } else {
1071 Self::format_field(field)
1072 }
1073 })
1074 .collect::<Vec<_>>()
1075 .join(", ")
1076 .into()
1077 }
1078 }
1079
1080 fn format_filters<M: Schema>(&self) -> String {
1082 let filters = self.query_filters();
1083 if filters.is_empty() {
1084 return String::new();
1085 }
1086
1087 let mut expression = String::new();
1088 let mut logical_and_conditions = Vec::with_capacity(filters.len());
1089 for (key, value) in filters {
1090 match key.as_str() {
1091 "$and" => {
1092 if let Some(filters) = value.as_array() {
1093 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1094 logical_and_conditions.push(condition);
1095 }
1096 }
1097 "$not" => {
1098 if let Some(filters) = value.as_array() {
1099 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1100 logical_and_conditions.push(format!("(NOT {condition})"));
1101 }
1102 }
1103 "$or" => {
1104 if let Some(filters) = value.as_array() {
1105 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1106 logical_and_conditions.push(condition);
1107 }
1108 }
1109 "$rand" => {
1110 if let Some(Ok(value)) = value.parse_f64() {
1111 let condition = if cfg!(any(
1112 feature = "orm-mariadb",
1113 feature = "orm-mysql",
1114 feature = "orm-tidb"
1115 )) {
1116 format!("rand() < {value}")
1117 } else if cfg!(feature = "orm-postgres") {
1118 format!("random() < {value}")
1119 } else {
1120 let value = (value * i64::MAX as f64) as i64;
1121 format!("abs(random()) < {value}")
1122 };
1123 logical_and_conditions.push(condition);
1124 }
1125 }
1126 "$text" => {
1127 if let Some(condition) = value.as_object().and_then(Self::parse_text_search) {
1128 logical_and_conditions.push(condition);
1129 }
1130 }
1131 _ => {
1132 if let Some(col) = M::get_column(key) {
1133 let condition = if let Some(subquery) =
1134 value.as_object().and_then(|m| m.get_str("$subquery"))
1135 {
1136 let key = Self::format_field(key);
1137 format!(r#"{key} = {subquery}"#)
1138 } else {
1139 col.format_filter(key, value)
1140 };
1141 if !condition.is_empty() {
1142 logical_and_conditions.push(condition);
1143 }
1144 } else if key.contains('.') {
1145 let condition = Self::format_query_filter::<M>(key, value);
1146 if !condition.is_empty() {
1147 logical_and_conditions.push(condition);
1148 }
1149 }
1150 }
1151 }
1152 }
1153 if !logical_and_conditions.is_empty() {
1154 expression += &format!("WHERE {}", logical_and_conditions.join(" AND "));
1155 };
1156 if let Some(groups) = filters.parse_str_array("$group") {
1157 let groups = groups
1158 .into_iter()
1159 .map(Self::format_field)
1160 .collect::<Vec<_>>()
1161 .join(", ");
1162 expression += &format!(" GROUP BY {groups}");
1163 if let Some(filters) = filters.get_array("$having") {
1164 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1165 expression += &format!(" HAVING {condition}");
1166 }
1167 }
1168 expression
1169 }
1170
1171 fn format_logical_filters<M: Schema>(filters: &[JsonValue], operator: &str) -> String {
1173 let mut conditions = Vec::with_capacity(filters.len());
1174 for filter in filters {
1175 if let JsonValue::Object(filter) = filter {
1176 let mut logical_and_conditions = Vec::with_capacity(filter.len());
1177 for (key, value) in filter {
1178 match key.as_str() {
1179 "$and" => {
1180 if let Some(filters) = value.as_array() {
1181 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1182 logical_and_conditions.push(condition);
1183 }
1184 }
1185 "$not" => {
1186 if let Some(filters) = value.as_array() {
1187 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1188 logical_and_conditions.push(format!("(NOT {condition})"));
1189 }
1190 }
1191 "$nor" => {
1192 if let Some(filters) = value.as_array() {
1193 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1194 logical_and_conditions.push(format!("(NOT {condition})"));
1195 }
1196 }
1197 "$or" => {
1198 if let Some(filters) = value.as_array() {
1199 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1200 logical_and_conditions.push(condition);
1201 }
1202 }
1203 _ => {
1204 if let Some(col) = M::get_column(key) {
1205 let condition = if let Some(subquery) =
1206 value.as_object().and_then(|m| m.get_str("$subquery"))
1207 {
1208 let key = Self::format_field(key);
1209 format!(r#"{key} = {subquery}"#)
1210 } else {
1211 col.format_filter(key, value)
1212 };
1213 if !condition.is_empty() {
1214 logical_and_conditions.push(condition);
1215 }
1216 } else if key.contains('.') {
1217 let condition = Self::format_query_filter::<M>(key, value);
1218 if !condition.is_empty() {
1219 logical_and_conditions.push(condition);
1220 }
1221 }
1222 }
1223 }
1224 }
1225 if !logical_and_conditions.is_empty() {
1226 let condition = Self::join_conditions(logical_and_conditions, " AND ");
1227 conditions.push(condition);
1228 }
1229 }
1230 }
1231 Self::join_conditions(conditions, operator)
1232 }
1233
1234 fn format_query_filter<M: Schema>(key: &str, value: &JsonValue) -> String {
1236 let json_field = key.split_once('.').and_then(|(key, path)| {
1237 M::get_column(key)
1238 .filter(|col| col.type_name() == "Map")
1239 .map(|col| {
1240 let key = [M::model_name(), ".", col.name()].concat();
1241 let field = Self::format_field(&key);
1242 if cfg!(feature = "orm-postgres") {
1243 let path = path.replace('.', ", ");
1244 format!(r#"({field} #> '{{{path}}}')"#)
1245 } else {
1246 format!(r#"json_extract({field}, '$.{path}')"#)
1247 }
1248 })
1249 });
1250 let requires_json_value = json_field.is_some();
1251 let field = json_field
1252 .map(|s| s.into())
1253 .unwrap_or_else(|| Self::format_field(key));
1254 if let Some(filter) = value.as_object() {
1255 let mut conditions = Vec::with_capacity(filter.len());
1256 for (name, value) in filter {
1257 let operator = match name.as_str() {
1258 "$eq" => "=",
1259 "$ne" => "<>",
1260 "$lt" => "<",
1261 "$le" => "<=",
1262 "$gt" => ">",
1263 "$ge" => ">=",
1264 "$in" => "IN",
1265 "$nin" => "NOT IN",
1266 _ => "=",
1267 };
1268 let condition = if let Some(subquery) =
1269 value.as_object().and_then(|m| m.get_str("$subquery"))
1270 {
1271 format!(r#"{field} {operator} {subquery}"#)
1272 } else if requires_json_value {
1273 Self::format_json_filter(&field, operator, value)
1274 } else if let Some(s) = value.as_str() {
1275 if name == "$subquery" {
1276 format!(r#"{field} {operator} {s}"#)
1277 } else {
1278 let value = Self::escape_string(s);
1279 format!(r#"{field} {operator} {value}"#)
1280 }
1281 } else {
1282 format!(r#"{field} {operator} {value}"#)
1283 };
1284 conditions.push(condition);
1285 }
1286 Self::join_conditions(conditions, " AND ")
1287 } else if requires_json_value {
1288 Self::format_json_filter(&field, "=", value)
1289 } else if let Some(s) = value.as_str() {
1290 let value = Self::escape_string(s);
1291 format!(r#"{field} = {value}"#)
1292 } else {
1293 format!(r#"{field} = {value}"#)
1294 }
1295 }
1296
1297 fn format_json_filter(field: &str, operator: &str, value: &JsonValue) -> String {
1299 match value {
1300 JsonValue::Null => format!(r#"{field} IS NULL"#),
1301 JsonValue::Bool(b) => {
1302 let value = if *b { "true" } else { "false" };
1303 if cfg!(feature = "orm-postgres") {
1304 format!(r#"({field})::boolean IS {value}"#)
1305 } else {
1306 format!(r#"{field} = {value}"#)
1307 }
1308 }
1309 JsonValue::Number(n) => {
1310 if cfg!(feature = "orm-postgres") {
1311 format!(r#"{field} {operator} '{n}'"#)
1312 } else {
1313 format!(r#"{field} {operator} {n}"#)
1314 }
1315 }
1316 JsonValue::String(s) => {
1317 if s == "null" {
1318 format!(r#"{field} IS NULL"#)
1319 } else if s == "not_null" {
1320 format!(r#"{field} IS NOT NULL"#)
1321 } else if s == "true" || s == "false" {
1322 if cfg!(feature = "orm-postgres") {
1323 format!(r#"({field})::boolean IS {s}"#)
1324 } else {
1325 format!(r#"{field} = {s}"#)
1326 }
1327 } else if let Ok(n) = s.parse::<serde_json::Number>() {
1328 if cfg!(feature = "orm-postgres") {
1329 format!(r#"{field} {operator} '{n}'"#)
1330 } else {
1331 format!(r#"{field} {operator} {n}"#)
1332 }
1333 } else {
1334 let value = if cfg!(feature = "orm-postgres") {
1335 Self::escape_string(value)
1336 } else {
1337 Self::escape_string(s)
1338 };
1339 format!(r#"{field} {operator} {value}"#)
1340 }
1341 }
1342 _ => {
1343 let value = Self::escape_string(value);
1344 format!(r#"{field} {operator} {value}"#)
1345 }
1346 }
1347 }
1348
1349 fn format_sort(&self) -> String {
1351 let sort_order = self.query_order();
1352 if sort_order.is_empty() {
1353 String::new()
1354 } else {
1355 let sort_order = sort_order
1356 .iter()
1357 .map(|order| {
1358 let sort_field = Self::format_field(order.field());
1359 let mut expr = if order.is_descending() {
1360 format!("{sort_field} DESC")
1361 } else {
1362 format!("{sort_field} ASC")
1363 };
1364 if order.nulls_first() {
1365 expr.push_str(" NULLS FIRST");
1366 } else if order.nulls_last() {
1367 expr.push_str(" NULLS LAST");
1368 }
1369 expr
1370 })
1371 .collect::<Vec<_>>();
1372 format!("ORDER BY {}", sort_order.join(", "))
1373 }
1374 }
1375
1376 fn format_pagination(&self) -> String {
1378 let limit = self.query_limit();
1379 if limit == 0 || limit == usize::MAX {
1380 return String::new();
1381 }
1382
1383 let offset = self.query_offset();
1384 format!("LIMIT {limit} OFFSET {offset}")
1385 }
1386
1387 fn join_conditions(mut conditions: Vec<String>, operator: &str) -> String {
1389 match conditions.len() {
1390 0 => String::new(),
1391 1 => conditions.remove(0),
1392 _ => format!("({})", conditions.join(operator)),
1393 }
1394 }
1395}
1396
1397pub(crate) fn format_query<'a>(query: &'a str, params: Option<&'a Map>) -> Cow<'a, str> {
1402 if let Some(params) = params.filter(|_| query.contains('$')) {
1403 INTERPOLATION_PATTERN.replace_all(query, |captures: &Captures| {
1404 let key = &captures[1];
1405 params
1406 .get(key)
1407 .map(|value| match value {
1408 JsonValue::String(s) => s.to_owned(),
1409 _ => value.to_string(),
1410 })
1411 .unwrap_or_else(|| ["${", key, "}"].concat())
1412 })
1413 } else {
1414 Cow::Borrowed(query)
1415 }
1416}
1417
1418pub(crate) fn prepare_sql_query<'a>(
1424 query: &'a str,
1425 params: Option<&'a Map>,
1426 placeholder: char,
1427) -> (Cow<'a, str>, Vec<&'a JsonValue>) {
1428 let sql = format_query(query, params);
1429 if let Some(params) = params.filter(|_| sql.contains('#')) {
1430 let mut values = Vec::new();
1431 let sql = STATEMENT_PATTERN.replace_all(&sql, |captures: &Captures| {
1432 let key = &captures[1];
1433 let value = params.get(key).unwrap_or(&JsonValue::Null);
1434 values.push(value);
1435 if placeholder == '$' {
1436 Cow::Owned(format!("${}", values.len()))
1437 } else {
1438 Cow::Borrowed("?")
1439 }
1440 });
1441 (sql.into_owned().into(), values)
1442 } else {
1443 (sql, Vec::new())
1444 }
1445}
1446
1447static INTERPOLATION_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1449 Regex::new(r"\$\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1450 .expect("fail to create a regex for the interpolation parameter")
1451});
1452
1453static STATEMENT_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1455 Regex::new(r"\#\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1456 .expect("fail to create a regex for the prepared statement")
1457});
1458
1459#[cfg(test)]
1460mod tests {
1461 use zino_core::{Map, extension::JsonObjectExt};
1462
1463 #[test]
1464 fn it_formats_query_params() {
1465 let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1466 let mut params = Map::new();
1467 params.upsert("fields", "id, name, age");
1468 params.upsert("age", 18);
1469
1470 let sql = super::format_query(query, Some(¶ms));
1471 assert_eq!(
1472 sql,
1473 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= #{age};"
1474 );
1475 }
1476
1477 #[test]
1478 fn it_formats_sql_query_params() {
1479 let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1480 let mut params = Map::new();
1481 params.upsert("fields", "id, name, age");
1482 params.upsert("age", 18);
1483
1484 let (sql, values) = super::prepare_sql_query(query, Some(¶ms), '?');
1485 assert_eq!(
1486 sql,
1487 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= ?;"
1488 );
1489 assert_eq!(values[0], 18);
1490
1491 let (sql, values) = super::prepare_sql_query(query, Some(¶ms), '$');
1492 assert_eq!(
1493 sql,
1494 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= $1;"
1495 );
1496 assert_eq!(values[0], 18);
1497 }
1498}