1use super::{Aggregation, EncodeColumn, Entity, IntoSqlValue, ModelColumn, 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<C: ModelColumn<E>>(mut self, col: C) -> Self {
183 self.fields.push(col.into_column_expr());
184 self
185 }
186
187 #[inline]
189 pub fn fields<C, V>(mut self, cols: V) -> Self
190 where
191 C: ModelColumn<E>,
192 V: Into<Vec<C>>,
193 {
194 let mut fields = cols
195 .into()
196 .into_iter()
197 .map(|col| col.into_column_expr())
198 .collect();
199 self.fields.append(&mut fields);
200 self
201 }
202
203 pub fn alias<C: ModelColumn<E>>(mut self, col: C, alias: &str) -> Self {
205 let col_name = col.into_column_expr();
206 let field = Query::format_field(&col_name);
207 let field_alias = [alias, ":", &field].concat();
208 self.fields.push(field_alias);
209 self
210 }
211
212 pub fn aggregate(mut self, aggregation: Aggregation<E>, alias: Option<&str>) -> Self {
214 let expr = aggregation.expr();
215 let field_alias = if let Some(alias) = alias {
216 [alias, ":", &expr].concat()
217 } else {
218 let mut field_alias = aggregation.default_alias();
219 field_alias.push(':');
220 field_alias.push_str(&expr);
221 field_alias
222 };
223 self.fields.push(field_alias);
224 self
225 }
226
227 pub fn window(mut self, window: Window<E>, alias: Option<&str>) -> Self {
229 let expr = window.expr();
230 let field_alias = if let Some(alias) = alias {
231 [alias, ":", &expr].concat()
232 } else {
233 let mut field_alias = window.default_alias();
234 field_alias.push(':');
235 field_alias.push_str(&expr);
236 field_alias
237 };
238 self.fields.push(field_alias);
239 self
240 }
241
242 pub fn group_by<C: ModelColumn<E>>(mut self, col: C, alias: Option<&str>) -> Self {
244 let expr = col.into_column_expr();
245 let field = if let Some(alias) = alias {
246 [alias, ":", &expr].concat()
247 } else {
248 expr.clone()
249 };
250 if !self.fields.contains(&field) {
251 self.fields.push(field);
252 }
253 self.group_by_fields.push(expr);
254 self
255 }
256
257 #[inline]
259 pub fn having_filter<V: IntoSqlValue>(mut self, aggregation: Aggregation<E>, value: V) -> Self {
260 let condition = Map::from_entry(aggregation.expr(), value.into_sql_value());
261 self.having_conditions.push(condition);
262 self
263 }
264
265 #[inline]
267 pub fn having_eq<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
268 self.push_having_condition(aggregation, "$eq", value.into_sql_value())
269 }
270
271 #[inline]
273 pub fn having_ne<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
274 self.push_having_condition(aggregation, "$ne", value.into_sql_value())
275 }
276
277 #[inline]
279 pub fn having_lt<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
280 self.push_having_condition(aggregation, "$lt", value.into_sql_value())
281 }
282
283 #[inline]
285 pub fn having_le<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
286 self.push_having_condition(aggregation, "$le", value.into_sql_value())
287 }
288
289 #[inline]
291 pub fn having_gt<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
292 self.push_having_condition(aggregation, "$gt", value.into_sql_value())
293 }
294
295 #[inline]
297 pub fn having_ge<V: IntoSqlValue>(self, aggregation: Aggregation<E>, value: V) -> Self {
298 self.push_having_condition(aggregation, "$ge", value.into_sql_value())
299 }
300
301 #[inline]
303 pub fn primary_key<V: IntoSqlValue>(mut self, value: V) -> Self {
304 let field = E::format_column(&E::PRIMARY_KEY);
305 self.filters.upsert(field, value.into_sql_value());
306 self
307 }
308
309 #[inline]
311 pub fn rand<V: IntoSqlValue>(mut self, value: V) -> Self {
312 self.filters.upsert("$rand", value.into_sql_value());
313 self
314 }
315
316 pub fn and<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
318 let mut logical_and = other.logical_and;
319 let logical_or = other.logical_or;
320 if !logical_or.is_empty() {
321 logical_and.push(Map::from_entry("$or", logical_or));
322 }
323 if !logical_and.is_empty() {
324 self.logical_and.push(Map::from_entry("$and", logical_and));
325 }
326 self.fields.append(&mut other.fields);
327 self.group_by_fields.append(&mut other.group_by_fields);
328 self
329 }
330
331 pub fn and_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
333 let mut logical_and = other.logical_and;
334 let logical_or = other.logical_or;
335 if !logical_or.is_empty() {
336 logical_and.push(Map::from_entry("$or", logical_or));
337 }
338 if !logical_and.is_empty() {
339 self.logical_and.push(Map::from_entry("$not", logical_and));
340 }
341 self.fields.append(&mut other.fields);
342 self.group_by_fields.append(&mut other.group_by_fields);
343 self
344 }
345
346 #[inline]
348 pub fn and_filter<C, V>(mut self, col: C, value: V) -> Self
349 where
350 C: ModelColumn<E>,
351 V: IntoSqlValue,
352 {
353 let condition = Map::from_entry(col.into_column_expr(), value.into_sql_value());
354 self.logical_and.push(condition);
355 self
356 }
357
358 #[inline]
360 pub fn and_eq<C, V>(self, col: C, value: V) -> Self
361 where
362 C: ModelColumn<E>,
363 V: IntoSqlValue,
364 {
365 self.push_logical_and(col, "$eq", value.into_sql_value())
366 }
367
368 #[inline]
370 pub fn and_eq_if_not_null<C, V>(self, col: C, value: V) -> Self
371 where
372 C: ModelColumn<E>,
373 V: IntoSqlValue,
374 {
375 let value = value.into_sql_value();
376 if !value.is_null() {
377 self.push_logical_and(col, "$eq", value)
378 } else {
379 self
380 }
381 }
382
383 #[inline]
385 pub fn and_eq_if_some<C, V>(self, col: C, value: Option<V>) -> Self
386 where
387 C: ModelColumn<E>,
388 V: IntoSqlValue,
389 {
390 if let Some(value) = value {
391 self.push_logical_and(col, "$eq", value.into_sql_value())
392 } else {
393 self
394 }
395 }
396
397 #[inline]
399 pub fn and_ne<C, V>(self, col: C, value: V) -> Self
400 where
401 C: ModelColumn<E>,
402 V: IntoSqlValue,
403 {
404 self.push_logical_and(col, "$ne", value.into_sql_value())
405 }
406
407 #[inline]
409 pub fn and_ne_if_not_null<C, V>(self, col: C, value: V) -> Self
410 where
411 C: ModelColumn<E>,
412 V: IntoSqlValue,
413 {
414 let value = value.into_sql_value();
415 if !value.is_null() {
416 self.push_logical_and(col, "$ne", value)
417 } else {
418 self
419 }
420 }
421
422 #[inline]
424 pub fn and_ne_if_some<C, V>(self, col: C, value: Option<V>) -> Self
425 where
426 C: ModelColumn<E>,
427 V: IntoSqlValue,
428 {
429 if let Some(value) = value {
430 self.push_logical_and(col, "$ne", value.into_sql_value())
431 } else {
432 self
433 }
434 }
435
436 #[inline]
438 pub fn and_lt<C, V>(self, col: C, value: V) -> Self
439 where
440 C: ModelColumn<E>,
441 V: IntoSqlValue,
442 {
443 self.push_logical_and(col, "$lt", value.into_sql_value())
444 }
445
446 #[inline]
448 pub fn and_le<C, V>(self, col: C, value: V) -> Self
449 where
450 C: ModelColumn<E>,
451 V: IntoSqlValue,
452 {
453 self.push_logical_and(col, "$le", value.into_sql_value())
454 }
455
456 #[inline]
458 pub fn and_gt<C, V>(self, col: C, value: V) -> Self
459 where
460 C: ModelColumn<E>,
461 V: IntoSqlValue,
462 {
463 self.push_logical_and(col, "$gt", value.into_sql_value())
464 }
465
466 #[inline]
468 pub fn and_ge<C, V>(self, col: C, value: V) -> Self
469 where
470 C: ModelColumn<E>,
471 V: IntoSqlValue,
472 {
473 self.push_logical_and(col, "$ge", value.into_sql_value())
474 }
475
476 #[inline]
478 pub fn and_in<C, T, V>(self, col: C, values: V) -> Self
479 where
480 C: ModelColumn<E>,
481 T: IntoSqlValue,
482 V: Into<Vec<T>>,
483 {
484 self.push_logical_and(col, "$in", values.into().into_sql_value())
485 }
486
487 #[inline]
489 pub fn and_not_in<C, T, V>(self, col: C, values: V) -> Self
490 where
491 C: ModelColumn<E>,
492 T: IntoSqlValue,
493 V: Into<Vec<T>>,
494 {
495 self.push_logical_and(col, "$nin", values.into().into_sql_value())
496 }
497
498 #[inline]
501 pub fn and_in_if_nonempty<C, T, V>(self, col: C, values: V) -> Self
502 where
503 C: ModelColumn<E>,
504 T: IntoSqlValue,
505 V: Into<Vec<T>>,
506 {
507 let values = values.into();
508 if values.is_empty() {
509 self
510 } else {
511 self.push_logical_and(col, "$in", values.into_sql_value())
512 }
513 }
514
515 #[inline]
518 pub fn and_not_in_if_nonempty<C, T, V>(self, col: C, values: V) -> Self
519 where
520 C: ModelColumn<E>,
521 T: IntoSqlValue,
522 V: Into<Vec<T>>,
523 {
524 let values = values.into();
525 if values.is_empty() {
526 self
527 } else {
528 self.push_logical_and(col, "$nin", values.into_sql_value())
529 }
530 }
531
532 pub fn and_in_subquery<C, V, M>(mut self, cols: V, subquery: QueryBuilder<M>) -> Self
534 where
535 C: ModelColumn<E>,
536 V: Into<Vec<C>>,
537 M: Entity + Schema,
538 {
539 let cols = cols
540 .into()
541 .into_iter()
542 .map(|col| {
543 let col_name = col.into_column_expr();
544 Query::format_field(&col_name).into_owned()
545 })
546 .collect::<Vec<_>>()
547 .join(", ");
548 let field = format!("({cols})");
549 let condition = Map::from_entry("$in", subquery.into_sql_value());
550 self.logical_and.push(Map::from_entry(field, condition));
551 self
552 }
553
554 pub fn and_not_in_subquery<C, V, M>(mut self, cols: V, subquery: QueryBuilder<M>) -> Self
556 where
557 C: ModelColumn<E>,
558 V: Into<Vec<C>>,
559 M: Entity + Schema,
560 {
561 let cols = cols
562 .into()
563 .into_iter()
564 .map(|col| {
565 let col_name = col.into_column_expr();
566 Query::format_field(&col_name).into_owned()
567 })
568 .collect::<Vec<_>>()
569 .join(", ");
570 let field = format!("({cols})");
571 let condition = Map::from_entry("$nin", subquery.into_sql_value());
572 self.logical_and.push(Map::from_entry(field, condition));
573 self
574 }
575
576 pub fn and_in_range<C, V>(mut self, col: C, min: V, max: V) -> Self
578 where
579 C: ModelColumn<E>,
580 V: IntoSqlValue,
581 {
582 let field = col.into_column_expr();
583 let mut condition = Map::new();
584 condition.upsert("$ge", min.into_sql_value());
585 condition.upsert("$lt", max.into_sql_value());
586 self.logical_and.push(Map::from_entry(field, condition));
587 self
588 }
589
590 #[inline]
592 pub fn and_between<C, V>(self, col: C, min: V, max: V) -> Self
593 where
594 C: ModelColumn<E>,
595 V: IntoSqlValue,
596 {
597 self.push_logical_and(col, "$betw", [min, max].into_sql_value())
598 }
599
600 #[inline]
602 pub fn and_like<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
603 self.push_logical_and(col, "$like", value.into_sql_value())
604 }
605
606 #[inline]
608 pub fn and_ilike<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
609 self.push_logical_and(col, "$ilike", value.into_sql_value())
610 }
611
612 #[inline]
614 pub fn and_rlike<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
615 self.push_logical_and(col, "$rlike", value.into_sql_value())
616 }
617
618 #[inline]
620 pub fn and_contains<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
621 let value = ["%", value, "%"].concat();
622 self.push_logical_and(col, "$like", value.into_sql_value())
623 }
624
625 #[inline]
627 pub fn and_starts_with<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
628 let value = [value, "%"].concat();
629 self.push_logical_and(col, "$like", value.into_sql_value())
630 }
631
632 #[inline]
634 pub fn and_ends_with<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
635 let value = ["%", value].concat();
636 self.push_logical_and(col, "$like", value.into_sql_value())
637 }
638
639 #[inline]
641 pub fn and_null<C: ModelColumn<E>>(self, col: C) -> Self {
642 self.and_filter(col, JsonValue::Null)
643 }
644
645 #[inline]
647 pub fn and_not_null<C: ModelColumn<E>>(self, col: C) -> Self {
648 self.and_filter(col, "not_null")
649 }
650
651 #[inline]
653 pub fn and_empty<C: ModelColumn<E>>(self, col: C) -> Self {
654 self.and_filter(col, "empty")
655 }
656
657 #[inline]
659 pub fn and_nonempty<C: ModelColumn<E>>(self, col: C) -> Self {
660 self.and_filter(col, "nonempty")
661 }
662
663 pub fn and_overlaps<L, R, V>(mut self, cols: (L, R), values: (V, V)) -> Self
665 where
666 L: ModelColumn<E>,
667 R: ModelColumn<E>,
668 V: IntoSqlValue,
669 {
670 let mut condition = Map::new();
671 condition.upsert(
672 cols.0.into_column_expr(),
673 Map::from_entry("$le", values.1.into_sql_value()),
674 );
675 condition.upsert(
676 cols.1.into_column_expr(),
677 Map::from_entry("$ge", values.0.into_sql_value()),
678 );
679 self.logical_and.push(condition);
680 self
681 }
682
683 pub fn or<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
685 let mut logical_and = other.logical_and;
686 let logical_or = other.logical_or;
687 if !logical_or.is_empty() {
688 logical_and.push(Map::from_entry("$or", logical_or));
689 }
690 if !logical_and.is_empty() {
691 self.logical_or.push(Map::from_entry("$and", logical_and));
692 }
693 self.fields.append(&mut other.fields);
694 self.group_by_fields.append(&mut other.group_by_fields);
695 self
696 }
697
698 pub fn or_not<M: Entity>(mut self, mut other: QueryBuilder<M>) -> Self {
700 let mut logical_and = other.logical_and;
701 let logical_or = other.logical_or;
702 if !logical_or.is_empty() {
703 logical_and.push(Map::from_entry("$or", logical_or));
704 }
705 if !logical_and.is_empty() {
706 self.logical_or.push(Map::from_entry("$not", logical_and));
707 }
708 self.fields.append(&mut other.fields);
709 self.group_by_fields.append(&mut other.group_by_fields);
710 self
711 }
712
713 #[inline]
715 pub fn or_filter<C, V>(mut self, col: C, value: V) -> Self
716 where
717 C: ModelColumn<E>,
718 V: IntoSqlValue,
719 {
720 let condition = Map::from_entry(col.into_column_expr(), value.into_sql_value());
721 self.logical_or.push(condition);
722 self
723 }
724
725 #[inline]
727 pub fn or_eq<C, V>(self, col: C, value: V) -> Self
728 where
729 C: ModelColumn<E>,
730 V: IntoSqlValue,
731 {
732 self.push_logical_or(col, "$eq", value.into_sql_value())
733 }
734
735 #[inline]
737 pub fn or_eq_if_not_null<C, V>(self, col: C, value: V) -> Self
738 where
739 C: ModelColumn<E>,
740 V: IntoSqlValue,
741 {
742 let value = value.into_sql_value();
743 if !value.is_null() {
744 self.push_logical_or(col, "$eq", value)
745 } else {
746 self
747 }
748 }
749
750 #[inline]
752 pub fn or_eq_if_some<C, V>(self, col: C, value: Option<V>) -> Self
753 where
754 C: ModelColumn<E>,
755 V: IntoSqlValue,
756 {
757 if let Some(value) = value {
758 self.push_logical_or(col, "$eq", value.into_sql_value())
759 } else {
760 self
761 }
762 }
763
764 #[inline]
766 pub fn or_ne<C, V>(self, col: C, value: V) -> Self
767 where
768 C: ModelColumn<E>,
769 V: IntoSqlValue,
770 {
771 self.push_logical_or(col, "$ne", value.into_sql_value())
772 }
773
774 #[inline]
776 pub fn or_ne_if_not_null<C, V>(self, col: C, value: V) -> Self
777 where
778 C: ModelColumn<E>,
779 V: IntoSqlValue,
780 {
781 let value = value.into_sql_value();
782 if !value.is_null() {
783 self.push_logical_or(col, "$ne", value)
784 } else {
785 self
786 }
787 }
788
789 #[inline]
791 pub fn or_ne_if_some<C, V>(self, col: C, value: Option<V>) -> Self
792 where
793 C: ModelColumn<E>,
794 V: IntoSqlValue,
795 {
796 if let Some(value) = value {
797 self.push_logical_or(col, "$ne", value.into_sql_value())
798 } else {
799 self
800 }
801 }
802
803 #[inline]
805 pub fn or_lt<C, V>(self, col: C, value: V) -> Self
806 where
807 C: ModelColumn<E>,
808 V: IntoSqlValue,
809 {
810 self.push_logical_or(col, "$lt", value.into_sql_value())
811 }
812
813 #[inline]
815 pub fn or_le<C, V>(self, col: C, value: V) -> Self
816 where
817 C: ModelColumn<E>,
818 V: IntoSqlValue,
819 {
820 self.push_logical_or(col, "$le", value.into_sql_value())
821 }
822
823 #[inline]
825 pub fn or_gt<C, V>(self, col: C, value: V) -> Self
826 where
827 C: ModelColumn<E>,
828 V: IntoSqlValue,
829 {
830 self.push_logical_or(col, "$gt", value.into_sql_value())
831 }
832
833 #[inline]
835 pub fn or_ge<C, V>(self, col: C, value: V) -> Self
836 where
837 C: ModelColumn<E>,
838 V: IntoSqlValue,
839 {
840 self.push_logical_or(col, "$ge", value.into_sql_value())
841 }
842
843 #[inline]
845 pub fn or_in<C, T, V>(self, col: C, values: V) -> Self
846 where
847 C: ModelColumn<E>,
848 T: IntoSqlValue,
849 V: Into<Vec<T>>,
850 {
851 self.push_logical_or(col, "$in", values.into().into_sql_value())
852 }
853
854 #[inline]
856 pub fn or_not_in<C, T, V>(self, col: C, values: V) -> Self
857 where
858 C: ModelColumn<E>,
859 T: IntoSqlValue,
860 V: Into<Vec<T>>,
861 {
862 self.push_logical_or(col, "$nin", values.into().into_sql_value())
863 }
864
865 #[inline]
868 pub fn or_in_if_nonempty<C, T, V>(self, col: C, values: V) -> Self
869 where
870 C: ModelColumn<E>,
871 T: IntoSqlValue,
872 V: Into<Vec<T>>,
873 {
874 let values = values.into();
875 if values.is_empty() {
876 self
877 } else {
878 self.push_logical_or(col, "$in", values.into_sql_value())
879 }
880 }
881
882 #[inline]
885 pub fn or_not_in_if_nonempty<C, T, V>(self, col: C, values: V) -> Self
886 where
887 C: ModelColumn<E>,
888 T: IntoSqlValue,
889 V: Into<Vec<T>>,
890 {
891 let values = values.into();
892 if values.is_empty() {
893 self
894 } else {
895 self.push_logical_or(col, "$nin", values.into_sql_value())
896 }
897 }
898
899 pub fn or_in_subquery<C, V, M>(mut self, cols: V, subquery: QueryBuilder<M>) -> Self
901 where
902 C: ModelColumn<E>,
903 V: Into<Vec<C>>,
904 M: Entity + Schema,
905 {
906 let cols = cols
907 .into()
908 .into_iter()
909 .map(|col| {
910 let col_name = col.into_column_expr();
911 Query::format_field(&col_name).into_owned()
912 })
913 .collect::<Vec<_>>()
914 .join(", ");
915 let field = format!("({cols})");
916 let condition = Map::from_entry("$in", subquery.into_sql_value());
917 self.logical_or.push(Map::from_entry(field, condition));
918 self
919 }
920
921 pub fn or_not_in_subquery<C, V, M>(mut self, cols: V, subquery: QueryBuilder<M>) -> Self
923 where
924 C: ModelColumn<E>,
925 V: Into<Vec<C>>,
926 M: Entity + Schema,
927 {
928 let cols = cols
929 .into()
930 .into_iter()
931 .map(|col| {
932 let col_name = col.into_column_expr();
933 Query::format_field(&col_name).into_owned()
934 })
935 .collect::<Vec<_>>()
936 .join(", ");
937 let field = format!("({cols})");
938 let condition = Map::from_entry("$nin", subquery.into_sql_value());
939 self.logical_or.push(Map::from_entry(field, condition));
940 self
941 }
942
943 pub fn or_in_range<C, V>(mut self, col: C, min: V, max: V) -> Self
945 where
946 C: ModelColumn<E>,
947 V: IntoSqlValue,
948 {
949 let field = col.into_column_expr();
950 let mut condition = Map::new();
951 condition.upsert("$ge", min.into_sql_value());
952 condition.upsert("$lt", max.into_sql_value());
953 self.logical_or.push(Map::from_entry(field, condition));
954 self
955 }
956
957 #[inline]
959 pub fn or_between<C, V>(self, col: C, min: V, max: V) -> Self
960 where
961 C: ModelColumn<E>,
962 V: IntoSqlValue,
963 {
964 self.push_logical_or(col, "$betw", [min, max].into_sql_value())
965 }
966
967 #[inline]
969 pub fn or_like<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
970 self.push_logical_or(col, "$like", value.into_sql_value())
971 }
972
973 #[inline]
975 pub fn or_ilike<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
976 self.push_logical_or(col, "$ilike", value.into_sql_value())
977 }
978
979 #[inline]
981 pub fn or_rlike<C: ModelColumn<E>>(self, col: C, value: String) -> Self {
982 self.push_logical_or(col, "$rlike", value.into_sql_value())
983 }
984
985 #[inline]
987 pub fn or_contains<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
988 let value = ["%", value, "%"].concat();
989 self.push_logical_or(col, "$like", value.into_sql_value())
990 }
991
992 #[inline]
994 pub fn or_starts_with<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
995 let value = [value, "%"].concat();
996 self.push_logical_or(col, "$like", value.into_sql_value())
997 }
998
999 #[inline]
1001 pub fn or_ends_with<C: ModelColumn<E>>(self, col: C, value: &str) -> Self {
1002 let value = ["%", value].concat();
1003 self.push_logical_or(col, "$like", value.into_sql_value())
1004 }
1005
1006 #[inline]
1008 pub fn or_null<C: ModelColumn<E>>(self, col: C) -> Self {
1009 self.or_filter(col, JsonValue::Null)
1010 }
1011
1012 #[inline]
1014 pub fn or_not_null<C: ModelColumn<E>>(self, col: C) -> Self {
1015 self.or_filter(col, "not_null")
1016 }
1017
1018 #[inline]
1020 pub fn or_empty<C: ModelColumn<E>>(self, col: C) -> Self {
1021 self.or_filter(col, "empty")
1022 }
1023
1024 #[inline]
1026 pub fn or_nonempty<C: ModelColumn<E>>(self, col: C) -> Self {
1027 self.or_filter(col, "nonempty")
1028 }
1029
1030 pub fn or_overlaps<L, R, V>(mut self, cols: (L, R), values: (V, V)) -> Self
1032 where
1033 L: ModelColumn<E>,
1034 R: ModelColumn<E>,
1035 V: IntoSqlValue,
1036 {
1037 let mut condition = Map::new();
1038 condition.upsert(
1039 cols.0.into_column_expr(),
1040 Map::from_entry("$le", values.1.into_sql_value()),
1041 );
1042 condition.upsert(
1043 cols.1.into_column_expr(),
1044 Map::from_entry("$ge", values.0.into_sql_value()),
1045 );
1046 self.logical_or.push(condition);
1047 self
1048 }
1049
1050 #[inline]
1052 pub fn order_by<C: ModelColumn<E>>(mut self, col: C, descending: bool) -> Self {
1053 self.sort_order
1054 .push(QueryOrder::new(col.into_column_expr(), descending));
1055 self
1056 }
1057
1058 #[inline]
1060 pub fn order_by_with_nulls<C: ModelColumn<E>>(
1061 mut self,
1062 col: C,
1063 descending: bool,
1064 nulls_first: bool,
1065 ) -> Self {
1066 let mut order = QueryOrder::new(col.into_column_expr(), descending);
1067 if nulls_first {
1068 order.set_nulls_first();
1069 } else {
1070 order.set_nulls_last();
1071 }
1072 self.sort_order.push(order);
1073 self
1074 }
1075
1076 #[inline]
1078 pub fn order_asc<C: ModelColumn<E>>(mut self, col: C) -> Self {
1079 self.sort_order
1080 .push(QueryOrder::new(col.into_column_expr(), false));
1081 self
1082 }
1083
1084 #[inline]
1086 pub fn order_desc<C: ModelColumn<E>>(mut self, col: C) -> Self {
1087 self.sort_order
1088 .push(QueryOrder::new(col.into_column_expr(), true));
1089 self
1090 }
1091
1092 #[inline]
1094 pub fn offset(mut self, offset: usize) -> Self {
1095 self.offset = offset;
1096 self
1097 }
1098
1099 #[inline]
1101 pub fn limit(mut self, limit: usize) -> Self {
1102 self.limit = limit;
1103 self
1104 }
1105
1106 pub fn build(mut self) -> Query {
1108 let mut filters = self.filters;
1109 let group_by_fields = self.group_by_fields;
1110 let having_conditions = self.having_conditions;
1111 let logical_and = self.logical_and;
1112 let logical_or = self.logical_or;
1113 if !group_by_fields.is_empty() {
1114 filters.upsert("$group", group_by_fields);
1115 }
1116 if !having_conditions.is_empty() {
1117 filters.upsert("$having", having_conditions);
1118 }
1119 if !logical_and.is_empty() {
1120 filters.upsert("$and", logical_and);
1121 }
1122 if !logical_or.is_empty() {
1123 filters.upsert("$or", logical_or);
1124 }
1125
1126 let mut query = Query::new(filters);
1127 query.set_fields(self.fields);
1128 query.set_order(self.sort_order);
1129 query.set_offset(self.offset);
1130 query.set_limit(self.limit);
1131 query.append_extra_flags(&mut self.extra);
1132 query
1133 }
1134
1135 fn push_having_condition(
1137 mut self,
1138 aggregation: Aggregation<E>,
1139 operator: &str,
1140 value: JsonValue,
1141 ) -> Self {
1142 let condition = Map::from_entry(operator, value);
1143 self.having_conditions
1144 .push(Map::from_entry(aggregation.expr(), condition));
1145 self
1146 }
1147
1148 fn push_logical_and<C: ModelColumn<E>>(
1150 mut self,
1151 col: C,
1152 operator: &str,
1153 value: JsonValue,
1154 ) -> Self {
1155 let condition = Map::from_entry(operator, value);
1156 self.logical_and
1157 .push(Map::from_entry(col.into_column_expr(), condition));
1158 self
1159 }
1160
1161 fn push_logical_or<C: ModelColumn<E>>(
1163 mut self,
1164 col: C,
1165 operator: &str,
1166 value: JsonValue,
1167 ) -> Self {
1168 let condition = Map::from_entry(operator, value);
1169 self.logical_or
1170 .push(Map::from_entry(col.into_column_expr(), condition));
1171 self
1172 }
1173}
1174
1175impl<E: Entity + Schema> QueryBuilder<E> {
1176 #[inline]
1178 pub fn build_subquery(self) -> String {
1179 let query = self.build();
1180 let table_name = query.format_table_name::<E>();
1181 let projection = query.format_table_fields::<E>();
1182 let filters = query.format_filters::<E>();
1183 let sort = query.format_sort();
1184 let pagination = query.format_pagination();
1185 format!("(SELECT {projection} FROM {table_name} {filters} {sort} {pagination})")
1186 }
1187}
1188
1189impl<E: Entity> Default for QueryBuilder<E> {
1190 #[inline]
1191 fn default() -> Self {
1192 Self::new()
1193 }
1194}
1195
1196pub(super) trait QueryExt<DB> {
1198 type QueryResult;
1200
1201 fn parse_query_result(query_result: Self::QueryResult) -> (Option<i64>, u64);
1203
1204 fn query_fields(&self) -> &[String];
1206
1207 fn query_filters(&self) -> ⤅
1209
1210 fn query_order(&self) -> &[QueryOrder];
1212
1213 fn query_offset(&self) -> usize;
1215
1216 fn query_limit(&self) -> usize;
1218
1219 fn placeholder(n: usize) -> SharedString;
1221
1222 fn prepare_query<'a>(
1224 query: &'a str,
1225 params: Option<&'a Map>,
1226 ) -> (Cow<'a, str>, Vec<&'a JsonValue>);
1227
1228 fn format_field(field: &str) -> Cow<'_, str>;
1230
1231 fn format_table_fields<M: Schema>(&self) -> Cow<'_, str>;
1233
1234 fn format_table_name<M: Schema>(&self) -> String;
1236
1237 fn escape_table_name(table_name: &str) -> String;
1239
1240 fn parse_text_search(filter: &Map) -> Option<String>;
1242
1243 #[inline]
1245 fn escape_string(value: impl Display) -> String {
1246 format!("'{}'", value.to_string().replace('\'', "''"))
1247 }
1248
1249 fn format_projection(&self) -> Cow<'_, str> {
1251 let fields = self.query_fields();
1252 if fields.is_empty() {
1253 "*".into()
1254 } else {
1255 fields
1256 .iter()
1257 .map(|field| {
1258 if let Some((alias, expr)) = field.split_once(':') {
1259 let alias = Self::format_field(alias.trim());
1260 format!(r#"{expr} AS {alias}"#).into()
1261 } else {
1262 Self::format_field(field)
1263 }
1264 })
1265 .collect::<Vec<_>>()
1266 .join(", ")
1267 .into()
1268 }
1269 }
1270
1271 fn format_filters<M: Schema>(&self) -> String {
1273 let filters = self.query_filters();
1274 if filters.is_empty() {
1275 return String::new();
1276 }
1277
1278 let mut expression = String::new();
1279 let mut logical_and_conditions = Vec::with_capacity(filters.len());
1280 for (key, value) in filters {
1281 match key.as_str() {
1282 "$and" => {
1283 if let Some(filters) = value.as_array() {
1284 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1285 logical_and_conditions.push(condition);
1286 }
1287 }
1288 "$not" => {
1289 if let Some(filters) = value.as_array() {
1290 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1291 logical_and_conditions.push(format!("(NOT {condition})"));
1292 }
1293 }
1294 "$or" => {
1295 if let Some(filters) = value.as_array() {
1296 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1297 logical_and_conditions.push(condition);
1298 }
1299 }
1300 "$rand" => {
1301 if let Some(Ok(value)) = value.parse_f64() {
1302 let condition = if cfg!(any(
1303 feature = "orm-mariadb",
1304 feature = "orm-mysql",
1305 feature = "orm-tidb"
1306 )) {
1307 format!("rand() < {value}")
1308 } else if cfg!(feature = "orm-postgres") {
1309 format!("random() < {value}")
1310 } else {
1311 let value = (value * i64::MAX as f64) as i64;
1312 format!("abs(random()) < {value}")
1313 };
1314 logical_and_conditions.push(condition);
1315 }
1316 }
1317 "$text" => {
1318 if let Some(condition) = value.as_object().and_then(Self::parse_text_search) {
1319 logical_and_conditions.push(condition);
1320 }
1321 }
1322 _ => {
1323 if let Some(col) = M::get_column(key) {
1324 let condition = if let Some(subquery) =
1325 value.as_object().and_then(|m| m.get_str("$subquery"))
1326 {
1327 let key = Self::format_field(key);
1328 format!(r#"{key} = {subquery}"#)
1329 } else {
1330 col.format_filter(key, value)
1331 };
1332 if !condition.is_empty() {
1333 logical_and_conditions.push(condition);
1334 }
1335 } else if key.contains('.') {
1336 let condition = Self::format_query_filter::<M>(key, value);
1337 if !condition.is_empty() {
1338 logical_and_conditions.push(condition);
1339 }
1340 }
1341 }
1342 }
1343 }
1344 if !logical_and_conditions.is_empty() {
1345 expression += &format!("WHERE {}", logical_and_conditions.join(" AND "));
1346 };
1347 if let Some(groups) = filters.parse_str_array("$group") {
1348 let groups = groups
1349 .into_iter()
1350 .map(Self::format_field)
1351 .collect::<Vec<_>>()
1352 .join(", ");
1353 expression += &format!(" GROUP BY {groups}");
1354 if let Some(filters) = filters.get_array("$having") {
1355 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1356 expression += &format!(" HAVING {condition}");
1357 }
1358 }
1359 expression
1360 }
1361
1362 fn format_logical_filters<M: Schema>(filters: &[JsonValue], operator: &str) -> String {
1364 let mut conditions = Vec::with_capacity(filters.len());
1365 for filter in filters {
1366 if let JsonValue::Object(filter) = filter {
1367 let mut logical_and_conditions = Vec::with_capacity(filter.len());
1368 for (key, value) in filter {
1369 match key.as_str() {
1370 "$and" => {
1371 if let Some(filters) = value.as_array() {
1372 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1373 logical_and_conditions.push(condition);
1374 }
1375 }
1376 "$not" => {
1377 if let Some(filters) = value.as_array() {
1378 let condition = Self::format_logical_filters::<M>(filters, " AND ");
1379 logical_and_conditions.push(format!("(NOT {condition})"));
1380 }
1381 }
1382 "$nor" => {
1383 if let Some(filters) = value.as_array() {
1384 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1385 logical_and_conditions.push(format!("(NOT {condition})"));
1386 }
1387 }
1388 "$or" => {
1389 if let Some(filters) = value.as_array() {
1390 let condition = Self::format_logical_filters::<M>(filters, " OR ");
1391 logical_and_conditions.push(condition);
1392 }
1393 }
1394 _ => {
1395 if let Some(col) = M::get_column(key) {
1396 let condition = if let Some(subquery) =
1397 value.as_object().and_then(|m| m.get_str("$subquery"))
1398 {
1399 let key = Self::format_field(key);
1400 format!(r#"{key} = {subquery}"#)
1401 } else {
1402 col.format_filter(key, value)
1403 };
1404 if !condition.is_empty() {
1405 logical_and_conditions.push(condition);
1406 }
1407 } else if key.contains('.') {
1408 let condition = Self::format_query_filter::<M>(key, value);
1409 if !condition.is_empty() {
1410 logical_and_conditions.push(condition);
1411 }
1412 }
1413 }
1414 }
1415 }
1416 if !logical_and_conditions.is_empty() {
1417 let condition = Self::join_conditions(logical_and_conditions, " AND ");
1418 conditions.push(condition);
1419 }
1420 }
1421 }
1422 Self::join_conditions(conditions, operator)
1423 }
1424
1425 fn format_query_filter<M: Schema>(key: &str, value: &JsonValue) -> String {
1427 let json_field = key.split_once('.').and_then(|(key, path)| {
1428 M::get_column(key)
1429 .filter(|col| col.type_name() == "Map")
1430 .map(|col| {
1431 let key = [M::model_name(), ".", col.name()].concat();
1432 let field = Self::format_field(&key);
1433 if cfg!(feature = "orm-postgres") {
1434 let path = path.replace('.', ", ");
1435 format!(r#"({field} #> '{{{path}}}')"#)
1436 } else {
1437 format!(r#"json_extract({field}, '$.{path}')"#)
1438 }
1439 })
1440 });
1441 let requires_json_value = json_field.is_some();
1442 let field = json_field
1443 .map(|s| s.into())
1444 .unwrap_or_else(|| Self::format_field(key));
1445 if let Some(filter) = value.as_object() {
1446 let mut conditions = Vec::with_capacity(filter.len());
1447 for (name, value) in filter {
1448 let operator = match name.as_str() {
1449 "$eq" => "=",
1450 "$ne" => "<>",
1451 "$lt" => "<",
1452 "$le" => "<=",
1453 "$gt" => ">",
1454 "$ge" => ">=",
1455 "$in" => "IN",
1456 "$nin" => "NOT IN",
1457 _ => "=",
1458 };
1459 let condition = if let Some(subquery) =
1460 value.as_object().and_then(|m| m.get_str("$subquery"))
1461 {
1462 format!(r#"{field} {operator} {subquery}"#)
1463 } else if requires_json_value {
1464 Self::format_json_filter(&field, operator, value)
1465 } else if let Some(s) = value.as_str() {
1466 if name == "$subquery" {
1467 format!(r#"{field} {operator} {s}"#)
1468 } else {
1469 let value = Self::escape_string(s);
1470 format!(r#"{field} {operator} {value}"#)
1471 }
1472 } else {
1473 format!(r#"{field} {operator} {value}"#)
1474 };
1475 conditions.push(condition);
1476 }
1477 Self::join_conditions(conditions, " AND ")
1478 } else if requires_json_value {
1479 Self::format_json_filter(&field, "=", value)
1480 } else if let Some(s) = value.as_str() {
1481 let value = Self::escape_string(s);
1482 format!(r#"{field} = {value}"#)
1483 } else {
1484 format!(r#"{field} = {value}"#)
1485 }
1486 }
1487
1488 fn format_json_filter(field: &str, operator: &str, value: &JsonValue) -> String {
1490 match value {
1491 JsonValue::Null => format!(r#"{field} IS NULL"#),
1492 JsonValue::Bool(b) => {
1493 let value = if *b { "TRUE" } else { "FALSE" };
1494 if cfg!(feature = "orm-postgres") {
1495 format!(r#"({field})::boolean IS {value}"#)
1496 } else {
1497 format!(r#"{field} = {value}"#)
1498 }
1499 }
1500 JsonValue::Number(n) => {
1501 if cfg!(feature = "orm-postgres") {
1502 format!(r#"{field} {operator} '{n}'"#)
1503 } else {
1504 format!(r#"{field} {operator} {n}"#)
1505 }
1506 }
1507 JsonValue::String(s) => {
1508 if s == "null" {
1509 format!(r#"{field} IS NULL"#)
1510 } else if s == "not_null" {
1511 format!(r#"{field} IS NOT NULL"#)
1512 } else if s == "true" || s == "false" {
1513 if cfg!(feature = "orm-postgres") {
1514 format!(r#"({field})::boolean IS {s}"#)
1515 } else {
1516 format!(r#"{field} = {s}"#)
1517 }
1518 } else if let Ok(n) = s.parse::<serde_json::Number>() {
1519 if cfg!(feature = "orm-postgres") {
1520 format!(r#"{field} {operator} '{n}'"#)
1521 } else {
1522 format!(r#"{field} {operator} {n}"#)
1523 }
1524 } else {
1525 let value = if cfg!(feature = "orm-postgres") {
1526 Self::escape_string(value)
1527 } else {
1528 Self::escape_string(s)
1529 };
1530 format!(r#"{field} {operator} {value}"#)
1531 }
1532 }
1533 _ => {
1534 let value = Self::escape_string(value);
1535 format!(r#"{field} {operator} {value}"#)
1536 }
1537 }
1538 }
1539
1540 fn format_sort(&self) -> String {
1542 let sort_order = self.query_order();
1543 if sort_order.is_empty() {
1544 String::new()
1545 } else {
1546 let sort_order = sort_order
1547 .iter()
1548 .map(|order| {
1549 let sort_field = Self::format_field(order.field());
1550 let mut expr = if order.is_descending() {
1551 format!("{sort_field} DESC")
1552 } else {
1553 format!("{sort_field} ASC")
1554 };
1555 if order.nulls_first() {
1556 expr.push_str(" NULLS FIRST");
1557 } else if order.nulls_last() {
1558 expr.push_str(" NULLS LAST");
1559 }
1560 expr
1561 })
1562 .collect::<Vec<_>>();
1563 format!("ORDER BY {}", sort_order.join(", "))
1564 }
1565 }
1566
1567 fn format_pagination(&self) -> String {
1569 let limit = self.query_limit();
1570 if limit == 0 || limit == usize::MAX {
1571 return String::new();
1572 }
1573
1574 let offset = self.query_offset();
1575 format!("LIMIT {limit} OFFSET {offset}")
1576 }
1577
1578 fn join_conditions(mut conditions: Vec<String>, operator: &str) -> String {
1580 match conditions.len() {
1581 0 => String::new(),
1582 1 => conditions.remove(0),
1583 _ => format!("({})", conditions.join(operator)),
1584 }
1585 }
1586}
1587
1588pub(crate) fn format_query<'a>(query: &'a str, params: Option<&'a Map>) -> Cow<'a, str> {
1593 if let Some(params) = params.filter(|_| query.contains('$')) {
1594 INTERPOLATION_PATTERN.replace_all(query, |captures: &Captures| {
1595 let key = &captures[1];
1596 params
1597 .get(key)
1598 .map(|value| match value {
1599 JsonValue::String(s) => s.to_owned(),
1600 _ => value.to_string(),
1601 })
1602 .unwrap_or_else(|| ["${", key, "}"].concat())
1603 })
1604 } else {
1605 Cow::Borrowed(query)
1606 }
1607}
1608
1609pub(crate) fn prepare_sql_query<'a>(
1615 query: &'a str,
1616 params: Option<&'a Map>,
1617 placeholder: char,
1618) -> (Cow<'a, str>, Vec<&'a JsonValue>) {
1619 let sql = format_query(query, params);
1620 if let Some(params) = params.filter(|_| sql.contains('#')) {
1621 let mut values = Vec::new();
1622 let sql = STATEMENT_PATTERN.replace_all(&sql, |captures: &Captures| {
1623 let key = &captures[1];
1624 let value = params.get(key).unwrap_or(&JsonValue::Null);
1625 values.push(value);
1626 if placeholder == '$' {
1627 Cow::Owned(format!("${}", values.len()))
1628 } else {
1629 Cow::Borrowed("?")
1630 }
1631 });
1632 (sql.into_owned().into(), values)
1633 } else {
1634 (sql, Vec::new())
1635 }
1636}
1637
1638static INTERPOLATION_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1640 Regex::new(r"\$\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1641 .expect("fail to create a regex for the interpolation parameter")
1642});
1643
1644static STATEMENT_PATTERN: LazyLock<Regex> = LazyLock::new(|| {
1646 Regex::new(r"\#\{\s*([a-zA-Z]+[\w\.]*)\s*\}")
1647 .expect("fail to create a regex for the prepared statement")
1648});
1649
1650#[cfg(test)]
1651mod tests {
1652 use zino_core::{Map, extension::JsonObjectExt};
1653
1654 #[test]
1655 fn it_formats_query_params() {
1656 let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1657 let mut params = Map::new();
1658 params.upsert("fields", "id, name, age");
1659 params.upsert("age", 18);
1660
1661 let sql = super::format_query(query, Some(¶ms));
1662 assert_eq!(
1663 sql,
1664 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= #{age};"
1665 );
1666 }
1667
1668 #[test]
1669 fn it_formats_sql_query_params() {
1670 let query = "SELECT ${fields} FROM users WHERE name = 'alice' AND age >= #{age};";
1671 let mut params = Map::new();
1672 params.upsert("fields", "id, name, age");
1673 params.upsert("age", 18);
1674
1675 let (sql, values) = super::prepare_sql_query(query, Some(¶ms), '?');
1676 assert_eq!(
1677 sql,
1678 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= ?;"
1679 );
1680 assert_eq!(values[0], 18);
1681
1682 let (sql, values) = super::prepare_sql_query(query, Some(¶ms), '$');
1683 assert_eq!(
1684 sql,
1685 "SELECT id, name, age FROM users WHERE name = 'alice' AND age >= $1;"
1686 );
1687 assert_eq!(values[0], 18);
1688 }
1689}