From b67bc571480da3cbe48e4e8aff9e99071778db2f Mon Sep 17 00:00:00 2001 From: Prashant Pandey Date: Fri, 2 Jan 2026 16:16:52 +0530 Subject: [PATCH 1/4] Handle nested null arrays correctly --- .../documentstore/DocStoreQueryV1Test.java | 64 +++++++++++++++++++ .../query/pg_flat_collection_insert.json | 2 +- .../PostgresFilterTypeExpressionVisitor.java | 9 +-- .../PostgresFromTypeExpressionVisitor.java | 8 ++- 4 files changed, 76 insertions(+), 7 deletions(-) diff --git a/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java b/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java index 1024f0e2..08591b0d 100644 --- a/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java +++ b/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java @@ -1915,6 +1915,27 @@ void testNotContainsAndUnnestFilters(String dataStoreName) throws IOException { dataStoreName, iterator, "query/unwind_not_contains_filter_response.json", 2); } + @ParameterizedTest + @ArgumentsSource(PostgresProvider.class) + public void testUnnestTopLevelArrayWithNullValue(String dataStoreName) throws IOException { + Collection collection = getFlatCollection(dataStoreName); + + // Row 9 (Bottle) has categoryTags as NULL + org.hypertrace.core.documentstore.query.Query query = + org.hypertrace.core.documentstore.query.Query.builder() + .addSelection(IdentifierExpression.of("item")) + .addSelection(IdentifierExpression.of("categoryTags")) + .addFromClause(UnnestExpression.of(IdentifierExpression.of("categoryTags"), true)) + .setFilter( + RelationalExpression.of( + IdentifierExpression.of("item"), EQ, ConstantExpression.of("Bottle"))) + .build(); + + Iterator iterator = collection.aggregate(query); + assertDocsAndSizeEqualWithoutOrder( + dataStoreName, iterator, "query/unnest_null_top_level_array_response.json", 1); + } + @ParameterizedTest @ArgumentsSource(AllProvider.class) public void testQueryV1DistinctCountWithSortingSpecs(String dataStoreName) throws IOException { @@ -5575,6 +5596,49 @@ void testNotInOnUnnestedArray(String dataStoreName) throws Exception { assertEquals(12, count, "Should return unnested locations not matching the filter"); } + @ParameterizedTest + @ArgumentsSource(PostgresProvider.class) + public void testUnnestNestedArrayWithNullValue(String dataStoreName) throws IOException { + Collection collection = getFlatCollection(dataStoreName); + + Query query = + Query.builder() + .addSelection(IdentifierExpression.of("item")) + .addFromClause( + UnnestExpression.of(JsonIdentifierExpression.of("props", "source-loc"), true)) + .setFilter( + RelationalExpression.of( + IdentifierExpression.of("_id"), EQ, ConstantExpression.of(1))) + .build(); + + Iterator iterator = collection.aggregate(query); + assertDocsAndSizeEqualWithoutOrder( + dataStoreName, iterator, "query/unnest_null_nested_array_response.json", 2); + } + + @ParameterizedTest + @ArgumentsSource(PostgresProvider.class) + public void testArrayFilterAnyWithJsonNullArray(String dataStoreName) { + Collection collection = getFlatCollection(dataStoreName); + + Query query = + Query.builder() + .addSelection(IdentifierExpression.of("item")) + .setFilter( + ArrayRelationalFilterExpression.builder() + .operator(ArrayOperator.ANY) + .filter( + RelationalExpression.of( + JsonIdentifierExpression.of("props", "colors"), + EQ, + ConstantExpression.of("Blue"))) + .build()) + .build(); + + long count = collection.count(query); + assertEquals(2, count, "Should find 2 items with 'Blue' color"); + } + @ParameterizedTest @ArgumentsSource(PostgresProvider.class) void testExistsOnArrays(String dataStoreName) throws JsonProcessingException { diff --git a/document-store/src/integrationTest/resources/query/pg_flat_collection_insert.json b/document-store/src/integrationTest/resources/query/pg_flat_collection_insert.json index 73f65f9d..2ca68949 100644 --- a/document-store/src/integrationTest/resources/query/pg_flat_collection_insert.json +++ b/document-store/src/integrationTest/resources/query/pg_flat_collection_insert.json @@ -6,7 +6,7 @@ "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n4, 'Shampoo', 5, 20, '2014-04-04T11:21:39.736Z', false,\n'{\"hair-care\", \"budget\", \"bulk\"}',\n'{\"HairCare\"}',\nNULL,\nNULL,\n'{1, 2}',\n'{5.0, 10.0}',\n'{true, true}'\n)", "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n5, 'Soap', 20, 5, '2014-04-04T21:23:13.331Z', true,\n'{\"hygiene\", \"antibacterial\", \"family-pack\"}',\n'{\"Hygiene\"}',\n'{\"colors\": [\"Orange\", \"Blue\"], \"brand\": \"Lifebuoy\", \"size\": \"S\", \"product-code\": \"SOAP-LIF-005\", \"source-loc\": [\"warehouse-C\"], \"seller\": {\"name\": \"Hans and Co.\", \"address\": {\"city\": \"Kolkata\", \"pincode\": 700007}}}',\nNULL,\n'{3, 6, 9}',\n'{7.5}',\n'{false}'\n)", "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n6, 'Comb', 7.5, 5, '2015-06-04T05:08:13Z', true,\n'{\"grooming\", \"plastic\", \"essential\"}',\n'{\"Grooming\"}',\nNULL,\nNULL,\n'{20, 30}',\n'{6.0, 8.0}',\n'{true, false}'\n)", - "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n7, 'Comb', 7.5, 10, '2015-09-10T08:43:00Z', false,\n'{\"grooming\", \"bulk\", \"wholesale\"}',\n'{\"Grooming\"}',\n'{\"colors\": [], \"product-code\": null, \"source-loc\": [], \"seller\": {\"name\": \"Go Go Plastics\", \"address\": {\"city\": \"Kolkata\", \"pincode\": 700007}}}',\nNULL,\n'{10}',\n'{3.0}',\n'{false, false, false}'\n)", + "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n7, 'Comb', 7.5, 10, '2015-09-10T08:43:00Z', false,\n'{\"grooming\", \"bulk\", \"wholesale\"}',\n'{\"Grooming\"}',\n'{\"colors\": [], \"product-code\": null, \"source-loc\": null, \"seller\": {\"name\": \"Go Go Plastics\", \"address\": {\"city\": \"Kolkata\", \"pincode\": 700007}}}',\nNULL,\n'{10}',\n'{3.0}',\n'{false, false, false}'\n)", "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n8, 'Soap', 10, 5, '2016-02-06T20:20:13Z', true,\n'{\"hygiene\", \"budget\", \"basic\"}',\n'{\"Hygiene\"}',\nNULL,\nNULL,\n'{1, 10, 20}',\n'{2.5, 5.0}',\n'{true}'\n)", "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n9, 'Bottle', 15, 3, '2016-03-01T10:00:00Z', false,\nNULL,\nNULL,\nNULL,\nNULL,\nNULL,\nNULL,\nNULL\n)", "INSERT INTO \"myTestFlat\" (\n\"_id\", \"item\", \"price\", \"quantity\", \"date\", \"in_stock\", \"tags\", \"categoryTags\", \"props\", \"sales\", \"numbers\", \"scores\", \"flags\"\n) VALUES (\n10, 'Cup', 8, 2, '2016-04-01T10:00:00Z', true,\n'{}',\n'{}',\nNULL,\nNULL,\nNULL,\nNULL,\nNULL\n)" diff --git a/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFilterTypeExpressionVisitor.java b/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFilterTypeExpressionVisitor.java index 3704a33e..41ffebf1 100644 --- a/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFilterTypeExpressionVisitor.java +++ b/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFilterTypeExpressionVisitor.java @@ -222,8 +222,8 @@ private String getFilterStringForAnyOperator(final ArrayRelationalFilterExpressi } else { // For nested collections OR JSONB arrays in flat collections, use jsonb_array_elements() return String.format( - "EXISTS (SELECT 1 FROM jsonb_array_elements(COALESCE(%s, '[]'::jsonb)) AS \"%s\" WHERE %s)", - parsedLhs, alias, parsedFilter); + "EXISTS (SELECT 1 FROM jsonb_array_elements(CASE WHEN jsonb_typeof(%s) = 'array' THEN %s ELSE '[]'::jsonb END) AS \"%s\" WHERE %s)", + parsedLhs, parsedLhs, alias, parsedFilter); } } @@ -331,9 +331,10 @@ private String getFilterStringForAnyOperator(final DocumentArrayFilterExpression parsedLhs, arrayTypeCast, alias, parsedFilter); } else { // For nested collections OR JSONB arrays in flat collections, use jsonb_array_elements() + // Use jsonb_typeof() to handle JSON null values - COALESCE only handles SQL NULL return String.format( - "EXISTS (SELECT 1 FROM jsonb_array_elements(COALESCE(%s, '[]'::jsonb)) AS \"%s\" WHERE %s)", - parsedLhs, alias, parsedFilter); + "EXISTS (SELECT 1 FROM jsonb_array_elements(CASE WHEN jsonb_typeof(%s) = 'array' THEN %s ELSE '[]'::jsonb END) AS \"%s\" WHERE %s)", + parsedLhs, parsedLhs, alias, parsedFilter); } } } diff --git a/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFromTypeExpressionVisitor.java b/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFromTypeExpressionVisitor.java index 9cdf3c8c..640637bf 100644 --- a/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFromTypeExpressionVisitor.java +++ b/document-store/src/main/java/org/hypertrace/core/documentstore/postgres/query/v1/vistors/PostgresFromTypeExpressionVisitor.java @@ -24,7 +24,8 @@ public class PostgresFromTypeExpressionVisitor implements FromTypeExpressionVisi "%s as (SELECT * from %s %s, %s %s)"; private static final String PRESERVE_NULL_AND_EMPTY_TABLE_QUERY_FMT = "%s as (SELECT * from %s %s LEFT JOIN LATERAL %s %s on TRUE)"; - private static final String JSONB_UNWIND_EXP_FMT = "jsonb_array_elements(%s)"; + private static final String JSONB_UNWIND_EXP_FMT = + "jsonb_array_elements(CASE WHEN jsonb_typeof(%s) = 'array' THEN %s ELSE '[]'::jsonb END)"; private static final String NATIVE_UNWIND_EXP_FMT = "unnest(%s)"; private static final String UNWIND_EXP_ALIAS_FMT = "p%s(%s)"; @@ -80,7 +81,10 @@ public String visit(UnnestExpression unnestExpression) { String preTable = "table" + preIndex; String newTable = "table" + nextIndex; String tableAlias = "t" + preIndex; - String unwindExpr = String.format(unnestFunction, transformedFieldName); + String unwindExpr = + unnestFunction.equals(JSONB_UNWIND_EXP_FMT) + ? String.format(unnestFunction, transformedFieldName, transformedFieldName) + : String.format(unnestFunction, transformedFieldName); // we'll quote the col name to prevent folding to lower case for top-level array fields String unwindExprAlias = From fe5d919b4b1bb1cce8d57dab05cc4c1355febc0a Mon Sep 17 00:00:00 2001 From: Prashant Pandey Date: Fri, 2 Jan 2026 16:17:40 +0530 Subject: [PATCH 2/4] WIP --- .../hypertrace/core/documentstore/DocStoreQueryV1Test.java | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java b/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java index 08591b0d..a0c5a1e0 100644 --- a/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java +++ b/document-store/src/integrationTest/java/org/hypertrace/core/documentstore/DocStoreQueryV1Test.java @@ -1920,9 +1920,8 @@ void testNotContainsAndUnnestFilters(String dataStoreName) throws IOException { public void testUnnestTopLevelArrayWithNullValue(String dataStoreName) throws IOException { Collection collection = getFlatCollection(dataStoreName); - // Row 9 (Bottle) has categoryTags as NULL - org.hypertrace.core.documentstore.query.Query query = - org.hypertrace.core.documentstore.query.Query.builder() + Query query = + Query.builder() .addSelection(IdentifierExpression.of("item")) .addSelection(IdentifierExpression.of("categoryTags")) .addFromClause(UnnestExpression.of(IdentifierExpression.of("categoryTags"), true)) From d29c4e4f7e6f160278c4549bc9417ee5f95cb617 Mon Sep 17 00:00:00 2001 From: Prashant Pandey Date: Fri, 2 Jan 2026 16:26:15 +0530 Subject: [PATCH 3/4] Fix failing test cases --- .../query/v1/PostgresQueryParserTest.java | 42 +++++++++---------- 1 file changed, 21 insertions(+), 21 deletions(-) diff --git a/document-store/src/test/java/org/hypertrace/core/documentstore/postgres/query/v1/PostgresQueryParserTest.java b/document-store/src/test/java/org/hypertrace/core/documentstore/postgres/query/v1/PostgresQueryParserTest.java index 74999e39..5a42e1cd 100644 --- a/document-store/src/test/java/org/hypertrace/core/documentstore/postgres/query/v1/PostgresQueryParserTest.java +++ b/document-store/src/test/java/org/hypertrace/core/documentstore/postgres/query/v1/PostgresQueryParserTest.java @@ -708,8 +708,8 @@ void testUnnestWithoutPreserveNullAndEmptyArrays() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0, jsonb_array_elements(document->'sales') p1(\"sales\")),\n" - + "table2 as (SELECT * from table1 t1, jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\"))\n" + + "table1 as (SELECT * from table0 t0, jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\")),\n" + + "table2 as (SELECT * from table1 t1, jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\"))\n" + "SELECT document->'item' AS \"item\", " + "document->'price' AS \"price\", " + "sales->'city' AS \"sales_dot_city\", " @@ -740,8 +740,8 @@ void testUnnestWithPreserveNullAndEmptyArrays() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", " + "document->'price' AS \"price\", " + "sales->'city' AS \"sales_dot_city\", " @@ -784,8 +784,8 @@ void testUnnestWithoutPreserveNullAndEmptyArraysWithFilters() { "With \n" + "table0 as (SELECT * from \"testCollection\" " + "WHERE CAST (document->>'quantity' AS NUMERIC) != ?),\n" - + "table1 as (SELECT * from table0 t0, jsonb_array_elements(document->'sales') p1(\"sales\")),\n" - + "table2 as (SELECT * from table1 t1, jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\"))\n" + + "table1 as (SELECT * from table0 t0, jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\")),\n" + + "table2 as (SELECT * from table1 t1, jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\"))\n" + "SELECT document->'item' AS \"item\", " + "sales->'city' AS \"sales_dot_city\", " + "sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" " @@ -829,8 +829,8 @@ void testUnnestWithRegularFilterAtSecondLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\" WHERE CAST (document->>'quantity' AS NUMERIC) > ?),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'price' AS \"price\", sales->'city' AS \"sales_dot_city\", sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" FROM table2 WHERE sales_dot_medium->>'type' = ?", sql); @@ -869,8 +869,8 @@ void testUnnestWithRegularORFilterAtSecondLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'price' AS \"price\", sales->'city' AS \"sales_dot_city\", sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" FROM table2 WHERE (CAST (document->>'quantity' AS NUMERIC) > ?) OR (sales_dot_medium->>'type' = ?)", sql); @@ -918,8 +918,8 @@ void testUnnestWithRegularAndORFilterAtSecondLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\" WHERE CAST (document->>'price' AS NUMERIC) > ?),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'price' AS \"price\", sales->'city' AS \"sales_dot_city\", sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" FROM table2 WHERE (CAST (document->>'quantity' AS NUMERIC) > ?) OR (sales_dot_medium->>'type' = ?)", sql); @@ -967,8 +967,8 @@ void testUnnestWithRegularAndUnnestFilterAtSecondLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\" WHERE CAST (document->>'quantity' AS NUMERIC) > ?),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'quantity' AS \"quantity\", sales->'city' AS \"sales_dot_city\", sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" FROM table2 WHERE (sales_dot_medium->>'type' = ?) AND (sales_dot_medium->>'type' = ?)", sql); @@ -1016,8 +1016,8 @@ void testUnnestWithRegularAndDifferentUnnestFilterAtSecondLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\" WHERE CAST (document->>'quantity' AS NUMERIC) > ?),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'quantity' AS \"quantity\", sales->'city' AS \"sales_dot_city\", sales_dot_medium->'type' AS \"sales_dot_medium_dot_type\" FROM table2 WHERE (sales_dot_medium->>'type' = ?) AND (sales_dot_medium->>'channel' = ?)", sql); @@ -1064,8 +1064,8 @@ void testUnnestWithRegularAndDifferentUnnestFilterAtFirstLevelArray() { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\" WHERE CAST (document->>'quantity' AS NUMERIC) > ?),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(document->'sales') p1(\"sales\") on TRUE),\n" - + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(sales->'medium') p2(\"sales_dot_medium\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\") on TRUE),\n" + + "table2 as (SELECT * from table1 t1 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(sales->'medium') = 'array' THEN sales->'medium' ELSE '[]'::jsonb END) p2(\"sales_dot_medium\") on TRUE)\n" + "SELECT document->'item' AS \"item\", document->'quantity' AS \"quantity\", sales->'city' AS \"sales_dot_city\" FROM table2 WHERE (sales->>'channel' = ?) AND (sales->>'city' = ?)", sql); @@ -1380,7 +1380,7 @@ void testContainsAndUnnestFilters() throws IOException { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0, jsonb_array_elements(document->'sales') p1(\"sales\"))\n" + + "table1 as (SELECT * from table0 t0, jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\"))\n" + "SELECT document->'item' AS \"item\", sales->'medium' AS \"sales_dot_medium\" FROM table1 WHERE sales->'medium' @> ?::jsonb", sql); @@ -1415,7 +1415,7 @@ void testNotContainsAndUnnestFilters() throws IOException { assertEquals( "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0, jsonb_array_elements(document->'sales') p1(\"sales\"))\n" + + "table1 as (SELECT * from table0 t0, jsonb_array_elements(CASE WHEN jsonb_typeof(document->'sales') = 'array' THEN document->'sales' ELSE '[]'::jsonb END) p1(\"sales\"))\n" + "SELECT document->'item' AS \"item\", sales->'medium' AS \"sales_dot_medium\" FROM table1 WHERE sales->'medium' IS NULL OR NOT sales->'medium' @> ?::jsonb", sql); @@ -1799,7 +1799,7 @@ void testFlatCollectionWithHyphenatedJsonbArrayFieldInUnnest() { String expectedSql = "With \n" + "table0 as (SELECT * from \"testCollection\"),\n" - + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(\"customAttribute\"->'dev-ops-owner') p1(\"customAttribute_dot_dev-ops-owner\") on TRUE)\n" + + "table1 as (SELECT * from table0 t0 LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(\"customAttribute\"->'dev-ops-owner') = 'array' THEN \"customAttribute\"->'dev-ops-owner' ELSE '[]'::jsonb END) p1(\"customAttribute_dot_dev-ops-owner\") on TRUE)\n" + "SELECT \"id\" AS \"id\", \"customAttribute_dot_dev-ops-owner\" AS \"customAttribute_dot_dev-ops-owner\" " + "FROM table1 WHERE \"customAttribute_dot_dev-ops-owner\" = ?"; From 38c7705102024bb58156a90dc1240c3f2c902b03 Mon Sep 17 00:00:00 2001 From: Prashant Pandey Date: Mon, 5 Jan 2026 11:29:54 +0530 Subject: [PATCH 4/4] Push missed files --- .../query/unnest_null_nested_array_response.json | 8 ++++++++ .../query/unnest_null_top_level_array_response.json | 5 +++++ 2 files changed, 13 insertions(+) create mode 100644 document-store/src/integrationTest/resources/query/unnest_null_nested_array_response.json create mode 100644 document-store/src/integrationTest/resources/query/unnest_null_top_level_array_response.json diff --git a/document-store/src/integrationTest/resources/query/unnest_null_nested_array_response.json b/document-store/src/integrationTest/resources/query/unnest_null_nested_array_response.json new file mode 100644 index 00000000..2505c62b --- /dev/null +++ b/document-store/src/integrationTest/resources/query/unnest_null_nested_array_response.json @@ -0,0 +1,8 @@ +[ + { + "item": "Soap" + }, + { + "item": "Soap" + } +] diff --git a/document-store/src/integrationTest/resources/query/unnest_null_top_level_array_response.json b/document-store/src/integrationTest/resources/query/unnest_null_top_level_array_response.json new file mode 100644 index 00000000..68f98c16 --- /dev/null +++ b/document-store/src/integrationTest/resources/query/unnest_null_top_level_array_response.json @@ -0,0 +1,5 @@ +[ + { + "item": "Bottle" + } +]