From c8b395e60e97af973ae37c6fde7b2c9c80a35177 Mon Sep 17 00:00:00 2001 From: "kingsley.hendrickse" Date: Mon, 30 Dec 2024 12:51:04 +0000 Subject: [PATCH] add better date filtering --- Cargo.lock | 2 +- Cargo.toml | 2 +- README.md | 181 ++++++++++++++++++++++++++++---- src/lib/filtering.rs | 240 +++++++++++++++++++++++++++++++++++++++++-- 4 files changed, 399 insertions(+), 26 deletions(-) diff --git a/Cargo.lock b/Cargo.lock index 721b833..7567d5e 100644 --- a/Cargo.lock +++ b/Cargo.lock @@ -1114,7 +1114,7 @@ checksum = "e3148f5046208a5d56bcfc03053e3ca6334e51da8dfb19b6cdc8b306fae3283e" [[package]] name = "pg_filters" -version = "0.1.16" +version = "0.1.17" dependencies = [ "chrono", "deadpool", diff --git a/Cargo.toml b/Cargo.toml index f5d6fe6..8c0f79e 100644 --- a/Cargo.toml +++ b/Cargo.toml @@ -1,6 +1,6 @@ [package] name = "pg_filters" -version = "0.1.16" +version = "0.1.17" edition = "2021" authors = ["Kingsley Hendrickse "] description = "A simple rust helper to generate postgres sql for pagination, sorting and filtering" diff --git a/README.md b/README.md index cac8ad4..fbdcc81 100644 --- a/README.md +++ b/README.md @@ -220,24 +220,61 @@ The filtering supports various operators for different column types: ### Filtering Operators -Can be upper or lower case: - -* "=" -* "!=" -* ">" -* ">=" -* "<" -* "<=" -* "LIKE" -* "NOT LIKE" -* "IN" -* "NOT IN" -* "IS NULL" -* "IS NOT NULL" -* "STARTS WITH" -* "ENDS WITH" -* "CONTAINS" (for array types) -* "OVERLAPS" (for array types) +All operators can be upper or lower case. Here are the supported operators by type: + +#### Standard Comparison Operators +* "=" - Equal to +* "!=" - Not equal to +* ">" - Greater than +* ">=" - Greater than or equal to +* "<" - Less than +* "<=" - Less than or equal to + +#### Text Search Operators +* "LIKE" - Pattern matching +* "NOT LIKE" - Negative pattern matching +* "STARTS WITH" - Starts with pattern +* "ENDS WITH" - Ends with pattern + +#### Null Check Operators +* "IS NULL" - Check for null values +* "IS NOT NULL" - Check for non-null values + +#### Collection Operators +* "IN" - Value in list +* "NOT IN" - Value not in list + +#### Array Operators +* "CONTAINS" - Array contains all specified values (@>) +* "OVERLAPS" - Array contains any of specified values (&&) + +#### Date Operators +* "DATE_ONLY" - Match entire day +* "DATE_RANGE" - Match date range (requires start,end format) +* "RELATIVE" - Use relative date expression + +Example usage for each operator type: +```rust +// Standard comparison +"f": "=", "v": "value" + +// Text search +"f": "LIKE", "v": "%pattern%" + +// Null check +"f": "IS NULL", "v": "" + +// Collection +"f": "IN", "v": "value1,value2,value3" + +// Array +"f": "CONTAINS", "v": "item1,item2" + +// Date +"f": "DATE_ONLY", "v": "2024-12-29" +"f": "DATE_RANGE", "v": "2024-12-29 00:00:00,2024-12-29 23:59:59" +"f": "RELATIVE", "v": "now() - interval '1 day'" +``` ### Array Filtering @@ -295,6 +332,114 @@ services @> ARRAY['EPC','Search']::text[] services && ARRAY['EPC','Search']::text[] ``` +### Date Filtering + +PG Filters provides sophisticated date filtering capabilities with support for exact timestamps, date-only matching, ranges, and relative dates. + +```rust +let columns = setup_columns(); + +// Using JSON filters: + +// 1. Exact timestamp matching +let exact_filter = JsonFilter { + n: "created_at".to_string(), + f: "=".to_string(), + v: "2024-12-29 15:30:00".to_string(), + c: None, +}; + +// 2. Date-only matching (matches full day) +let date_only_filter = JsonFilter { + n: "created_at".to_string(), + f: "DATE_ONLY".to_string(), + v: "2024-12-29".to_string(), + c: None, +}; + +// 3. Date range matching +let range_filter = JsonFilter { + n: "created_at".to_string(), + f: "DATE_RANGE".to_string(), + v: "2024-12-29 00:00:00,2024-12-29 23:59:59".to_string(), + c: None, +}; + +// 4. Relative date matching +let relative_filter = JsonFilter { + n: "created_at".to_string(), + f: "RELATIVE".to_string(), + v: "now() - interval '1 day'".to_string(), + c: None, +}; + +// Using direct conditions: +let date_only_condition = FilterCondition::date_only( + "created_at", + "2024-12-29" +); + +let range_condition = FilterCondition::date_range( + "created_at", + "2024-12-29 00:00:00", + "2024-12-29 23:59:59" +); + +let relative_condition = FilterCondition::relative_date( + "created_at", + "now() - interval '1 day'" +); +``` + +Date filtering supports several operations: +* `DATE_ONLY` - Matches an entire day (from 00:00:00 to 23:59:59) +* `DATE_RANGE` - Custom date range with start and end timestamps +* `RELATIVE` - PostgreSQL relative date expressions +* Standard operators (`=`, `>`, `<`, etc.) - For exact timestamp matching + +### Date Filtering SQL Examples + +```sql +-- Exact timestamp match +created_at = '2024-12-29 15:30:00' + +-- Date-only match (entire day) +created_at >= '2024-12-29 00:00:00' AND created_at < ('2024-12-29')::date + interval '1 day' + +-- Date range +created_at BETWEEN '2024-12-29 00:00:00' AND '2024-12-29 23:59:59' + +-- Relative date +created_at > now() - interval '1 day' +``` + +### Common Relative Date Expressions + +You can use PostgreSQL's interval syntax for relative dates: + +```rust +// Last hour +"now() - interval '1 hour'" + +// Last 24 hours +"now() - interval '24 hours'" + +// Last 7 days +"now() - interval '7 days'" + +// Last month +"now() - interval '1 month'" + +// Start of current day +"date_trunc('day', now())" + +// Start of current week +"date_trunc('week', now())" + +// Start of current month +"date_trunc('month', now())" +``` + ### Case Sensitivity By default, text searches are case-insensitive. You can make them case-sensitive using: diff --git a/src/lib/filtering.rs b/src/lib/filtering.rs index 8afda16..5309f3f 100644 --- a/src/lib/filtering.rs +++ b/src/lib/filtering.rs @@ -48,6 +48,9 @@ pub enum FilterOperator { EndsWith, Contains, Overlaps, + DateEqual, + DateRange, + RelativeDate, } impl FilterOperator { @@ -69,6 +72,9 @@ impl FilterOperator { FilterOperator::EndsWith => "LIKE", FilterOperator::Contains => "@>", FilterOperator::Overlaps => "&&", + FilterOperator::DateEqual => "=", + FilterOperator::DateRange => "BETWEEN", + FilterOperator::RelativeDate => ">", } } @@ -177,6 +183,18 @@ impl fmt::Display for FilterExpression { } } +#[derive(Debug, Clone, PartialEq)] +pub enum DateRangeType { + /// Exact timestamp match + Exact(String), + /// Match entire day + DateOnly(String), + /// Custom date range + Range { start: String, end: String }, + /// Relative date expression + Relative(String), +} + #[derive(Debug, Clone, PartialEq)] pub enum FilterCondition { // Character Types @@ -196,6 +214,12 @@ pub enum FilterCondition { value: Option, }, + // Date ranges + DateRange { + column: String, + range_type: DateRangeType, + }, + // Multi-value conditions for IN/NOT IN InValues { column: String, @@ -406,6 +430,18 @@ impl FilterCondition { None => Ok(format!("{} {}", column, operator.as_sql())), }, + FilterCondition::DateRange { column, range_type } => match range_type { + DateRangeType::Exact(timestamp) => Ok(format!("{} = '{}'", column, timestamp)), + DateRangeType::DateOnly(date) => Ok(format!( + "{} >= '{} 00:00:00' AND {} < ('{}')::date + interval '1 day'", + column, date, column, date + )), + DateRangeType::Range { start, end } => { + Ok(format!("{} BETWEEN '{}' AND '{}'", column, start, end)) + } + DateRangeType::Relative(expr) => Ok(format!("{} {} {}", column, ">", expr)), + }, + FilterCondition::ArrayContains { column, operator: _, @@ -649,6 +685,37 @@ impl FilterCondition { value: value.map(ToString::to_string), } } + + pub fn date_exact(column: &str, timestamp: &str) -> Self { + FilterCondition::DateRange { + column: column.to_string(), + range_type: DateRangeType::Exact(timestamp.to_string()), + } + } + + pub fn date_only(column: &str, date: &str) -> Self { + FilterCondition::DateRange { + column: column.to_string(), + range_type: DateRangeType::DateOnly(date.to_string()), + } + } + + pub fn date_range(column: &str, start: &str, end: &str) -> Self { + FilterCondition::DateRange { + column: column.to_string(), + range_type: DateRangeType::Range { + start: start.to_string(), + end: end.to_string(), + }, + } + } + + pub fn relative_date(column: &str, expr: &str) -> Self { + FilterCondition::DateRange { + column: column.to_string(), + range_type: DateRangeType::Relative(expr.to_string()), + } + } } impl fmt::Display for FilterCondition { @@ -748,6 +815,28 @@ impl FilterBuilder { value: filter.v.clone(), }, }, + Some(ColumnDef::Timestamp(name)) => { + // Handle special date filter formats + match filter.f.to_uppercase().as_str() { + "DATE_ONLY" => FilterCondition::date_only(name, &filter.v), + "DATE_RANGE" => { + // Expect format: "start,end" + let parts: Vec<&str> = filter.v.split(',').collect(); + if parts.len() == 2 { + FilterCondition::date_range(name, parts[0], parts[1]) + } else { + FilterCondition::date_exact(name, &filter.v) + } + } + "RELATIVE" => FilterCondition::relative_date(name, &filter.v), + // Default timestamp handling for standard operators + _ => FilterCondition::timestamp( + name, + parse_operator(&filter.f), + Some(&filter.v), + ), + } + } Some(ColumnDef::Uuid(_)) => { FilterCondition::uuid(&filter.n, parse_operator(&filter.f), Some(&filter.v)) } @@ -787,11 +876,6 @@ impl FilterBuilder { FilterCondition::text(&filter.n, parse_operator(&filter.f), Some(&filter.v)) } } - Some(ColumnDef::Timestamp(_)) => FilterCondition::timestamp( - &filter.n, - parse_operator(&filter.f), - Some(&filter.v), - ), Some(ColumnDef::Text(_)) | Some(ColumnDef::Varchar(_)) => { FilterCondition::text(&filter.n, parse_operator(&filter.f), Some(&filter.v)) } @@ -881,7 +965,7 @@ impl FilterBuilder { } fn parse_operator(op: &str) -> FilterOperator { - match op { + match op.to_uppercase().as_str() { "LIKE" => FilterOperator::Like, "=" => FilterOperator::Equal, "!=" => FilterOperator::NotEqual, @@ -897,6 +981,9 @@ fn parse_operator(op: &str) -> FilterOperator { "ENDS WITH" => FilterOperator::EndsWith, "CONTAINS" => FilterOperator::Contains, "OVERLAPS" => FilterOperator::Overlaps, + "DATE_ONLY" => FilterOperator::DateEqual, + "DATE_RANGE" => FilterOperator::DateRange, + "RELATIVE" => FilterOperator::RelativeDate, _ => FilterOperator::Equal, } } @@ -1375,4 +1462,145 @@ mod tests { Ok(()) } + + #[test] + fn test_date_exact_filter() -> Result<()> { + let mut columns = setup_test_columns(); + columns.insert("created_at", ColumnDef::Timestamp("created_at")); + + let filters = vec![JsonFilter { + n: "created_at".to_string(), + f: "=".to_string(), + v: "2024-12-29 15:30:00".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!(sql, " WHERE created_at = '2024-12-29 15:30:00'"); + Ok(()) + } + + #[test] + fn test_date_only_filter() -> Result<()> { + let mut columns = setup_test_columns(); + columns.insert("created_at", ColumnDef::Timestamp("created_at")); + + let filters = vec![JsonFilter { + n: "created_at".to_string(), + f: "DATE_ONLY".to_string(), + v: "2024-12-29".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!( + sql, + " WHERE created_at >= '2024-12-29 00:00:00' AND created_at < ('2024-12-29')::date + interval '1 day'" + ); + Ok(()) + } + + #[test] + fn test_date_range_filter() -> Result<()> { + let mut columns = setup_test_columns(); + columns.insert("created_at", ColumnDef::Timestamp("created_at")); + + let filters = vec![JsonFilter { + n: "created_at".to_string(), + f: "DATE_RANGE".to_string(), + v: "2024-12-29 00:00:00,2024-12-29 23:59:59".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!( + sql, + " WHERE created_at BETWEEN '2024-12-29 00:00:00' AND '2024-12-29 23:59:59'" + ); + Ok(()) + } + + #[test] + fn test_relative_date_filter() -> Result<()> { + let mut columns = setup_test_columns(); + columns.insert("created_at", ColumnDef::Timestamp("created_at")); + + let filters = vec![JsonFilter { + n: "created_at".to_string(), + f: "RELATIVE".to_string(), + v: "now() - interval '1 day'".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!(sql, " WHERE created_at > now() - interval '1 day'"); + Ok(()) + } + + #[test] + fn test_combined_date_filters() -> Result<()> { + let mut columns = setup_test_columns(); + columns.insert("created_at", ColumnDef::Timestamp("created_at")); + columns.insert("updated_at", ColumnDef::Timestamp("updated_at")); + + let filters = vec![ + JsonFilter { + n: "created_at".to_string(), + f: "DATE_ONLY".to_string(), + v: "2024-12-29".to_string(), + c: None, + }, + JsonFilter { + n: "updated_at".to_string(), + f: "RELATIVE".to_string(), + v: "now() - interval '1 hour'".to_string(), + c: Some("AND".to_string()), + }, + ]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!( + sql, + " WHERE (created_at >= '2024-12-29 00:00:00' AND created_at < ('2024-12-29')::date + interval '1 day' AND updated_at > now() - interval '1 hour')" + ); + Ok(()) + } + + #[test] + fn test_case_insensitive_operators() -> Result<()> { + let mut columns = setup_test_columns(); + + // Test different case variations of LIKE + let operators = vec!["LIKE", "like", "Like", "LiKe"]; + + for op in operators { + let filters = vec![JsonFilter { + n: "name".to_string(), + f: op.to_string(), + v: "%John%".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!(sql, " WHERE LOWER(name) LIKE LOWER('%John%')"); + } + + // Test different case variations of CONTAINS for array + let operators = vec!["CONTAINS", "contains", "Contains", "CoNtAiNs"]; + columns.insert("services", ColumnDef::TextArray("services")); + + for op in operators { + let filters = vec![JsonFilter { + n: "services".to_string(), + f: op.to_string(), + v: "EPC".to_string(), + c: None, + }]; + + let sql = FilterBuilder::from_json_filters(&filters, true, &columns)?.build()?; + assert_eq!(sql, " WHERE services @> ARRAY['EPC']::text[]"); + } + + Ok(()) + } }