sync_engine/search/
sql_translator.rs

1//! SQL Translator
2//!
3//! Translates Query AST to SQL WHERE clauses for JSON column queries.
4//! Uses MySQL JSON_EXTRACT syntax for querying JSON documents.
5//!
6//! # SQL Syntax Generated
7//!
8//! ```sql
9//! JSON_EXTRACT(data, '$.field') = 'value'              -- Exact match
10//! JSON_EXTRACT(data, '$.field') LIKE '%value%'         -- Contains
11//! JSON_EXTRACT(data, '$.age') BETWEEN 25 AND 40        -- Range
12//! JSON_EXTRACT(data, '$.field') LIKE 'prefix%'         -- Prefix
13//! JSON_CONTAINS(data->'$.tags', '"value"')             -- Tag membership
14//! ```
15
16use super::query_builder::{FieldOperator, FieldQuery, Query, QueryNode, QueryValue};
17
18/// SQL query translator for JSON column queries
19pub struct SqlTranslator;
20
21/// SQL query result with parameterized placeholders
22#[derive(Debug, Clone)]
23pub struct SqlQuery {
24    /// The WHERE clause (without "WHERE" keyword)
25    pub clause: String,
26    /// The parameter values in order
27    pub params: Vec<SqlParam>,
28}
29
30/// SQL parameter value
31#[derive(Debug, Clone, PartialEq)]
32pub enum SqlParam {
33    Text(String),
34    Numeric(f64),
35    Boolean(bool),
36}
37
38impl SqlTranslator {
39    /// Translate Query AST to parameterized SQL WHERE clause
40    ///
41    /// Uses `?` placeholders for parameters (MySQL style)
42    pub fn translate(query: &Query, json_column: &str) -> SqlQuery {
43        let mut params = Vec::new();
44        let clause = Self::translate_node(&query.root, json_column, &mut params);
45        SqlQuery { clause, params }
46    }
47
48    /// Translate Query AST to SQL WHERE clause with inline values
49    ///
50    /// Warning: Only use for debugging, not for actual queries (SQL injection risk)
51    pub fn translate_inline(query: &Query, json_column: &str) -> String {
52        let mut params = Vec::new();
53        let clause = Self::translate_node(&query.root, json_column, &mut params);
54
55        // Replace placeholders with actual values
56        let mut result = clause;
57        for param in params {
58            let value = match param {
59                SqlParam::Text(s) => format!("'{}'", s.replace('\'', "''")),
60                SqlParam::Numeric(n) => n.to_string(),
61                SqlParam::Boolean(b) => if b { "TRUE" } else { "FALSE" }.to_string(),
62            };
63            result = result.replacen('?', &value, 1);
64        }
65        result
66    }
67
68    fn translate_node(node: &QueryNode, json_col: &str, params: &mut Vec<SqlParam>) -> String {
69        match node {
70            QueryNode::Field(field_query) => Self::translate_field(field_query, json_col, params),
71            QueryNode::And(nodes) => {
72                let parts: Vec<String> = nodes
73                    .iter()
74                    .map(|n| Self::translate_node(n, json_col, params))
75                    .collect();
76                if parts.len() == 1 {
77                    parts[0].clone()
78                } else {
79                    format!("({})", parts.join(" AND "))
80                }
81            }
82            QueryNode::Or(nodes) => {
83                let parts: Vec<String> = nodes
84                    .iter()
85                    .map(|n| Self::translate_node(n, json_col, params))
86                    .collect();
87                if parts.len() == 1 {
88                    parts[0].clone()
89                } else {
90                    format!("({})", parts.join(" OR "))
91                }
92            }
93            QueryNode::Not(inner) => {
94                format!("NOT ({})", Self::translate_node(inner, json_col, params))
95            }
96        }
97    }
98
99    fn translate_field(
100        field: &FieldQuery,
101        json_col: &str,
102        params: &mut Vec<SqlParam>,
103    ) -> String {
104        let json_path = Self::json_path(&field.field);
105
106        match (&field.operator, &field.value) {
107            (FieldOperator::Equals, QueryValue::Text(text)) => {
108                params.push(SqlParam::Text(text.clone()));
109                format!("JSON_UNQUOTE(JSON_EXTRACT({}, '{}')) = ?", json_col, json_path)
110            }
111            (FieldOperator::Equals, QueryValue::Numeric(num)) => {
112                params.push(SqlParam::Numeric(*num));
113                format!("JSON_EXTRACT({}, '{}') = ?", json_col, json_path)
114            }
115            (FieldOperator::Equals, QueryValue::Boolean(b)) => {
116                params.push(SqlParam::Boolean(*b));
117                format!("JSON_EXTRACT({}, '{}') = ?", json_col, json_path)
118            }
119            (FieldOperator::Contains, QueryValue::Text(text)) => {
120                params.push(SqlParam::Text(format!("%{}%", text)));
121                format!(
122                    "JSON_UNQUOTE(JSON_EXTRACT({}, '{}')) LIKE ?",
123                    json_col, json_path
124                )
125            }
126            (FieldOperator::Range, QueryValue::NumericRange { min, max }) => {
127                match (min, max) {
128                    (Some(min_val), Some(max_val)) => {
129                        params.push(SqlParam::Numeric(*min_val));
130                        params.push(SqlParam::Numeric(*max_val));
131                        format!(
132                            "JSON_EXTRACT({}, '{}') BETWEEN ? AND ?",
133                            json_col, json_path
134                        )
135                    }
136                    (Some(min_val), None) => {
137                        params.push(SqlParam::Numeric(*min_val));
138                        format!("JSON_EXTRACT({}, '{}') >= ?", json_col, json_path)
139                    }
140                    (None, Some(max_val)) => {
141                        params.push(SqlParam::Numeric(*max_val));
142                        format!("JSON_EXTRACT({}, '{}') <= ?", json_col, json_path)
143                    }
144                    (None, None) => "1=1".to_string(), // Always true - no bounds
145                }
146            }
147            (FieldOperator::In, QueryValue::Tags(tags)) => {
148                // Use JSON_CONTAINS for tag membership
149                // Check if any of the tags are in the array
150                let conditions: Vec<String> = tags
151                    .iter()
152                    .map(|tag| {
153                        params.push(SqlParam::Text(format!("\"{}\"", tag)));
154                        format!("JSON_CONTAINS({}->'{}', ?)", json_col, json_path)
155                    })
156                    .collect();
157
158                if conditions.len() == 1 {
159                    conditions[0].clone()
160                } else {
161                    format!("({})", conditions.join(" OR "))
162                }
163            }
164            (FieldOperator::Prefix, QueryValue::Text(text)) => {
165                params.push(SqlParam::Text(format!("{}%", text)));
166                format!(
167                    "JSON_UNQUOTE(JSON_EXTRACT({}, '{}')) LIKE ?",
168                    json_col, json_path
169                )
170            }
171            (FieldOperator::Fuzzy, QueryValue::Text(text)) => {
172                // SQL doesn't have native fuzzy matching
173                // Fallback to contains for now
174                params.push(SqlParam::Text(format!("%{}%", text)));
175                format!(
176                    "JSON_UNQUOTE(JSON_EXTRACT({}, '{}')) LIKE ?",
177                    json_col, json_path
178                )
179            }
180            _ => {
181                // Fallback - always false for unsupported combinations
182                "1=0".to_string()
183            }
184        }
185    }
186
187    fn json_path(field: &str) -> String {
188        // Support dot notation for nested fields
189        // e.g., "user.name" -> "$.user.name"
190        if field.starts_with('$') {
191            field.to_string()
192        } else {
193            format!("$.{}", field)
194        }
195    }
196}
197
198#[cfg(test)]
199mod tests {
200    use super::*;
201
202    #[test]
203    fn test_simple_field_query() {
204        let query = Query::field_eq("name", "Alice");
205        let sql = SqlTranslator::translate(&query, "data");
206        assert_eq!(sql.clause, "JSON_UNQUOTE(JSON_EXTRACT(data, '$.name')) = ?");
207        assert_eq!(sql.params, vec![SqlParam::Text("Alice".to_string())]);
208    }
209
210    #[test]
211    fn test_inline_simple_field() {
212        let query = Query::field_eq("name", "Alice");
213        let sql = SqlTranslator::translate_inline(&query, "data");
214        assert_eq!(sql, "JSON_UNQUOTE(JSON_EXTRACT(data, '$.name')) = 'Alice'");
215    }
216
217    #[test]
218    fn test_numeric_range() {
219        let query = Query::numeric_range("age", Some(25.0), Some(40.0));
220        let sql = SqlTranslator::translate(&query, "data");
221        assert_eq!(sql.clause, "JSON_EXTRACT(data, '$.age') BETWEEN ? AND ?");
222        assert_eq!(
223            sql.params,
224            vec![SqlParam::Numeric(25.0), SqlParam::Numeric(40.0)]
225        );
226    }
227
228    #[test]
229    fn test_numeric_range_unbounded_min() {
230        let query = Query::numeric_range("age", None, Some(40.0));
231        let sql = SqlTranslator::translate(&query, "data");
232        assert_eq!(sql.clause, "JSON_EXTRACT(data, '$.age') <= ?");
233        assert_eq!(sql.params, vec![SqlParam::Numeric(40.0)]);
234    }
235
236    #[test]
237    fn test_numeric_range_unbounded_max() {
238        let query = Query::numeric_range("score", Some(100.0), None);
239        let sql = SqlTranslator::translate(&query, "data");
240        assert_eq!(sql.clause, "JSON_EXTRACT(data, '$.score') >= ?");
241        assert_eq!(sql.params, vec![SqlParam::Numeric(100.0)]);
242    }
243
244    #[test]
245    fn test_tag_query() {
246        let query = Query::tags("tags", vec!["rust".to_string(), "database".to_string()]);
247        let sql = SqlTranslator::translate(&query, "data");
248        assert_eq!(
249            sql.clause,
250            "(JSON_CONTAINS(data->'$.tags', ?) OR JSON_CONTAINS(data->'$.tags', ?))"
251        );
252        assert_eq!(
253            sql.params,
254            vec![
255                SqlParam::Text("\"rust\"".to_string()),
256                SqlParam::Text("\"database\"".to_string())
257            ]
258        );
259    }
260
261    #[test]
262    fn test_and_query() {
263        let query =
264            Query::field_eq("name", "Alice").and(Query::numeric_range("age", Some(25.0), Some(40.0)));
265        let sql = SqlTranslator::translate(&query, "data");
266        assert_eq!(
267            sql.clause,
268            "(JSON_UNQUOTE(JSON_EXTRACT(data, '$.name')) = ? AND JSON_EXTRACT(data, '$.age') BETWEEN ? AND ?)"
269        );
270        assert_eq!(
271            sql.params,
272            vec![
273                SqlParam::Text("Alice".to_string()),
274                SqlParam::Numeric(25.0),
275                SqlParam::Numeric(40.0)
276            ]
277        );
278    }
279
280    #[test]
281    fn test_or_query() {
282        let query =
283            Query::field_eq("status", "active").or(Query::field_eq("status", "pending"));
284        let sql = SqlTranslator::translate(&query, "data");
285        assert_eq!(
286            sql.clause,
287            "(JSON_UNQUOTE(JSON_EXTRACT(data, '$.status')) = ? OR JSON_UNQUOTE(JSON_EXTRACT(data, '$.status')) = ?)"
288        );
289    }
290
291    #[test]
292    fn test_not_query() {
293        let query = Query::field_eq("deleted", "true").negate();
294        let sql = SqlTranslator::translate(&query, "data");
295        assert_eq!(
296            sql.clause,
297            "NOT (JSON_UNQUOTE(JSON_EXTRACT(data, '$.deleted')) = ?)"
298        );
299    }
300
301    #[test]
302    fn test_contains_query() {
303        let query = Query::text_search("description", "database");
304        let sql = SqlTranslator::translate(&query, "data");
305        assert_eq!(
306            sql.clause,
307            "JSON_UNQUOTE(JSON_EXTRACT(data, '$.description')) LIKE ?"
308        );
309        assert_eq!(sql.params, vec![SqlParam::Text("%database%".to_string())]);
310    }
311
312    #[test]
313    fn test_prefix_query() {
314        let query = Query::prefix("email", "admin");
315        let sql = SqlTranslator::translate(&query, "data");
316        assert_eq!(
317            sql.clause,
318            "JSON_UNQUOTE(JSON_EXTRACT(data, '$.email')) LIKE ?"
319        );
320        assert_eq!(sql.params, vec![SqlParam::Text("admin%".to_string())]);
321    }
322
323    #[test]
324    fn test_nested_field() {
325        let query = Query::field_eq("user.profile.name", "Alice");
326        let sql = SqlTranslator::translate(&query, "data");
327        assert_eq!(
328            sql.clause,
329            "JSON_UNQUOTE(JSON_EXTRACT(data, '$.user.profile.name')) = ?"
330        );
331    }
332
333    #[test]
334    fn test_complex_query() {
335        let alice_query =
336            Query::field_eq("name", "Alice").and(Query::numeric_range("age", Some(25.0), Some(40.0)));
337
338        let bob_query = Query::field_eq("name", "Bob")
339            .and(Query::tags("tags", vec!["rust".to_string()]));
340
341        let query = alice_query.or(bob_query);
342        let sql = SqlTranslator::translate(&query, "data");
343
344        // Should be ((name=Alice AND age BETWEEN) OR (name=Bob AND tags CONTAINS))
345        assert!(sql.clause.starts_with("(("));
346        assert!(sql.clause.contains(" AND "));
347        assert!(sql.clause.contains(" OR "));
348    }
349}