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