diff --git a/README.md b/README.md index c37dfc9..a307819 100644 --- a/README.md +++ b/README.md @@ -7,9 +7,10 @@ _It's designed to be simple, secure, and free of dependencies._ When filtering data based on user-generated inputs, you need a syntax that's both intuitive and reliable. MongoDB's query filter is an excellent choice because it's simple, widely understood, and battle-tested in real-world applications. Although this package doesn't interact with MongoDB, it uses the same syntax to simplify filtering. ### Supported Features: -- Basics: `$eq`, `$ne`, `$gt`, `$gte`, `$lt`, `$lte`, `$regex` -- Logical operators: `$and`, `$or` -- Array operators: `$in` +- Basics: `$eq`, `$ne`, `$gt`, `$gte`, `$lt`, `$lte`, `$regex`, `$exists` +- Logical operators: `$and`, `$or`, `$not`, `$nor` +- Array operators: `$in`, `$nin`, `$elemMatch` +- Field comparison: `$field` (see [#difference-with-mongodb](#difference-with-mongodb)) This package is intended for use with PostgreSQL drivers like [github.com/lib/pq](https://github.com/lib/pq) and [github.com/jackc/pgx](https://github.com/jackc/pgx). However, it can work with any driver that supports the database/sql package. @@ -92,6 +93,18 @@ values := []any{"aztec", "nuke", "", 2, 10} (given "customdata" is configured with `filter.WithNestedJSONB("customdata", "password", "playerCount")`) +## Difference with MongoDB + +The MongoDB query filters don't have the option to compare fields with each other. This package adds the `$field` operator to compare fields with each other. + +For example: +```json5 +{ + "playerCount": { "$lt": { "$field": "maxPlayers" } } +} +``` + + ## Contributing If you have a feature request or discovered a bug, we'd love to hear from you! Please open an issue or submit a pull request. This project adheres to the [Poki Vulnerability Disclosure Policy](https://poki.com/en/c/vulnerability-disclosure-policy). diff --git a/filter/converter.go b/filter/converter.go index a17eced..70a2584 100644 --- a/filter/converter.go +++ b/filter/converter.go @@ -235,6 +235,13 @@ func (c *Converter) convertFilter(filter map[string]any, paramIndex int) (string inner = append(inner, fmt.Sprintf("EXISTS (SELECT 1 FROM unnest(%s) AS %s WHERE %s)", c.columnName(key), c.placeholderName, innerConditions)) } values = append(values, innerValues...) + case "$field": + vv, ok := v[operator].(string) + if !ok { + return "", nil, fmt.Errorf("invalid value for $field operator (must be string): %v", v[operator]) + } + + inner = append(inner, fmt.Sprintf("(%s = %s)", c.columnName(key), c.columnName(vv))) default: value := v[operator] isNumericOperator := false @@ -247,19 +254,48 @@ func (c *Converter) convertFilter(filter map[string]any, paramIndex int) (string isNumericOperator = true } - // Prevent cryptic errors like: - // unexpected error: sql: converting argument $1 type: unsupported type []interface {}, a slice of interface - if !isScalar(value) { - return "", nil, fmt.Errorf("invalid comparison value (must be a primitive): %v", value) - } - - if isNumericOperator && isNumeric(value) && c.isNestedColumn(key) { - inner = append(inner, fmt.Sprintf("((%s)::numeric %s $%d)", c.columnName(key), op, paramIndex)) + // If the value is a map with a $field key, we need to compare the column to another column. + if vv, ok := value.(map[string]any); ok { + if field, ok := vv["$field"].(string); ok { + if isNumericOperator { + if c.isNestedColumn(key) { + if c.isNestedColumn(field) { + // (a->>b)::numeric > (c->>d)::numeric + inner = append(inner, fmt.Sprintf("((%s)::numeric %s (%s)::numeric)", c.columnName(key), op, c.columnName(field))) + } else { + // (a->>b)::numeric > c + inner = append(inner, fmt.Sprintf("((%s)::numeric %s %s)", c.columnName(key), op, c.columnName(field))) + } + } else { + if c.isNestedColumn(field) { + // a > (c->>d)::numeric + inner = append(inner, fmt.Sprintf("(%s %s (%s)::numeric)", c.columnName(key), op, c.columnName(field))) + } else { + // a > c + inner = append(inner, fmt.Sprintf("(%s %s %s)", c.columnName(key), op, c.columnName(field))) + } + } + } else { + inner = append(inner, fmt.Sprintf("(%s %s %s)", c.columnName(key), op, c.columnName(field))) + } + } else { + return "", nil, fmt.Errorf("invalid value for %s operator (must be object with $field key): %v", operator, value) + } } else { - inner = append(inner, fmt.Sprintf("(%s %s $%d)", c.columnName(key), op, paramIndex)) + // Prevent cryptic errors like: + // unexpected error: sql: converting argument $1 type: unsupported type []interface {}, a slice of interface + if !isScalar(value) { + return "", nil, fmt.Errorf("invalid comparison value (must be a primitive): %v", value) + } + + if isNumericOperator && isNumeric(value) && c.isNestedColumn(key) { + inner = append(inner, fmt.Sprintf("((%s)::numeric %s $%d)", c.columnName(key), op, paramIndex)) + } else { + inner = append(inner, fmt.Sprintf("(%s %s $%d)", c.columnName(key), op, paramIndex)) + } + paramIndex++ + values = append(values, value) } - paramIndex++ - values = append(values, value) } } innerResult := strings.Join(inner, " AND ") diff --git a/filter/converter_test.go b/filter/converter_test.go index d7b182a..7b3434d 100644 --- a/filter/converter_test.go +++ b/filter/converter_test.go @@ -382,6 +382,46 @@ func TestConverter_Convert(t *testing.T) { nil, fmt.Errorf("invalid comparison value (must be a primitive): [1 2]"), }, + { + "compare two fields", + nil, + `{"playerCount": {"$lt": {"$field": "maxPlayers"}}}`, + `("playerCount" < "maxPlayers")`, + nil, + nil, + }, + { + "compare two jsonb fields", + filter.WithNestedJSONB("meta"), + `{"foo": {"$eq": {"$field": "bar"}}}`, + `("meta"->>'foo' = "meta"->>'bar')`, + nil, + nil, + }, + { + "compare two jsonb fields with numeric comparison", + filter.WithNestedJSONB("meta"), + `{"foo": {"$lt": {"$field": "bar"}}}`, + `(("meta"->>'foo')::numeric < ("meta"->>'bar')::numeric)`, + nil, + nil, + }, + { + "compare two fields with simple expression", + filter.WithNestedJSONB("meta", "foo"), + `{"foo": {"$field": "bar"}}`, + `("foo" = "meta"->>'bar')`, + nil, + nil, + }, + { + "compare with invalid object", + nil, + `{"name": {"$eq": {"foo": "bar"}}}`, + ``, + nil, + fmt.Errorf("invalid value for $eq operator (must be object with $field key): map[foo:bar]"), + }, } for _, tt := range tests { diff --git a/integration/postgres_test.go b/integration/postgres_test.go index d2a72c1..9ec14ac 100644 --- a/integration/postgres_test.go +++ b/integration/postgres_test.go @@ -399,6 +399,48 @@ func TestIntegration_BasicOperators(t *testing.T) { []int{}, nil, }, + { + "string order comparison", + `{"pet": {"$lt": "dog"}}`, + []int{2, 4, 6, 8}, + nil, + }, + { + "compare two fields", + `{"level": {"$lt": { "$field": "guild_id" }}}`, + []int{1}, + nil, + }, + { + "compare two string fields", + `{"name": {"$field": "pet"}}`, + []int{}, + nil, + }, + { + "compare two string fields with jsonb", + `{"pet": {"$field": "class"}}`, + []int{3}, + nil, + }, + { + // This converts to: ("level" = "metadata"->>'guild_id') + // This currently doesn't work, because we don't know the type of the columns. + // 'level' is an integer column, 'guild_id' is a jsonb column which always gets converted to a string. + "compare two numeric fields", + `{"level": {"$field": "guild_id"}}`, + nil, + errors.New(`pq: operator does not exist: integer = text`), + }, + { + // This converts to: (("metadata"->>'pet')::numeric < "class") + // This currently doesn't work, because we always convert < etc to a numeric comparison. + // We don't know the type of the columns, so we can't convert it to a string comparison. + "string order comparison with two fields", + `{"pet": {"$lt": {"$field": "class"}}}`, + nil, + errors.New(`pq: operator does not exist: numeric < text`), + }, } for _, tt := range tests { diff --git a/integration/setup_test.go b/integration/setup_test.go index c12bed4..9e07e57 100644 --- a/integration/setup_test.go +++ b/integration/setup_test.go @@ -127,7 +127,7 @@ func createPlayersTable(t *testing.T, db *sql.DB) { ("id", "name", "metadata", "level", "class", "mount", "items", "parents") VALUES (1, 'Alice', '{"guild_id": 20, "pet": "dog" }', 10, 'warrior', 'horse', '{}', '{40, 60}'), (2, 'Bob', '{"guild_id": 20, "pet": "cat", "keys": [1, 3] }', 20, 'mage', 'horse', '{}', '{20, 30}'), - (3, 'Charlie', '{"guild_id": 30, "pet": "dog", "keys": [4, 6] }', 30, 'rogue', NULL, '{}', '{30, 50}'), + (3, 'Charlie', '{"guild_id": 30, "pet": "dog", "keys": [4, 6] }', 30, 'dog', NULL, '{}', '{30, 50}'), (4, 'David', '{"guild_id": 30, "pet": "cat" }', 40, 'warrior', NULL, '{}', '{}'), (5, 'Eve', '{"guild_id": 40, "pet": "dog", "hats": ["helmet"]}', 50, 'mage', 'griffon', '{"staff", "cloak"}', '{}'), (6, 'Frank', '{"guild_id": 40, "pet": "cat", "hats": ["cap"] }', 60, 'rogue', 'griffon', '{"dagger"}', '{}'),