diff --git a/src/encrypted/casts.sql b/src/encrypted/casts.sql index 158b49a..7a5e047 100644 --- a/src/encrypted/casts.sql +++ b/src/encrypted/casts.sql @@ -9,6 +9,10 @@ CREATE FUNCTION eql_v2.to_encrypted(data jsonb) RETURNS public.eql_v2_encrypted AS $$ BEGIN + IF data IS NULL THEN + RETURN NULL; + END IF; + RETURN ROW(data)::public.eql_v2_encrypted; END; $$ LANGUAGE plpgsql; @@ -28,6 +32,10 @@ CREATE CAST (jsonb AS public.eql_v2_encrypted) CREATE FUNCTION eql_v2.to_encrypted(data text) RETURNS public.eql_v2_encrypted AS $$ BEGIN + IF data IS NULL THEN + RETURN NULL; + END IF; + RETURN ROW(data::jsonb)::public.eql_v2_encrypted; END; $$ LANGUAGE plpgsql; @@ -48,6 +56,10 @@ CREATE CAST (text AS public.eql_v2_encrypted) CREATE FUNCTION eql_v2.to_jsonb(e public.eql_v2_encrypted) RETURNS jsonb AS $$ BEGIN + IF e IS NULL THEN + RETURN NULL; + END IF; + RETURN e.data; END; $$ LANGUAGE plpgsql; diff --git a/src/operators/operator_class.sql b/src/operators/operator_class.sql index ef86e70..74cfe6c 100644 --- a/src/operators/operator_class.sql +++ b/src/operators/operator_class.sql @@ -22,6 +22,18 @@ AS $$ a_ore := eql_v2.ore_block_u64_8_256(a); b_ore := eql_v2.ore_block_u64_8_256(b); + IF a_ore IS NULL AND b_ore IS NULL THEN + RETURN 0; + END IF; + + IF a_ore IS NULL THEN + RETURN -1; + END IF; + + IF b_ore IS NULL THEN + RETURN 1; + END IF; + RETURN eql_v2.compare_ore_array(a_ore.terms, b_ore.terms); END; $$ LANGUAGE plpgsql; diff --git a/src/operators/order_by_test.sql b/src/operators/order_by_test.sql index 32ee978..0cc23f9 100644 --- a/src/operators/order_by_test.sql +++ b/src/operators/order_by_test.sql @@ -72,4 +72,76 @@ DECLARE '43'); END; -$$ LANGUAGE plpgsql; \ No newline at end of file +$$ LANGUAGE plpgsql; + + +SELECT create_table_with_encrypted(); + +-- +-- ORE - ORDER BY NULL handling +-- +DO $$ +DECLARE + e eql_v2_encrypted; + ore_term eql_v2_encrypted; + BEGIN + + -- Insert records with NULL values + -- record with ID=1 and e=NULL + INSERT INTO encrypted(e) VALUES (NULL::jsonb::eql_v2_encrypted); + + + -- Pull records from the ore table and insert + SELECT ore.e FROM ore WHERE id = 42 INTO ore_term; + -- record with ID=2 and e=42 + INSERT INTO encrypted(e) VALUES (ore_term); + + + SELECT ore.e FROM ore WHERE id = 3 INTO ore_term; + -- record with ID=3 and e=3 + INSERT INTO encrypted(e) VALUES (ore_term); + + + -- record with ID=4 and e=NULL + INSERT INTO encrypted(e) VALUES (NULL::jsonb::eql_v2_encrypted); + + PERFORM assert_result( + 'ORDER BY encrypted', + format('SELECT id FROM encrypted ORDER BY e'), + '3'); + + PERFORM assert_result( + 'ORDER BY encrypted ASC', + format('SELECT id FROM encrypted ORDER BY e ASC'), + '3'); + + PERFORM assert_result( + 'ORDER BY eql_v2.order_by(e) ASC NULLS FIRST', + format('SELECT id FROM encrypted ORDER BY e ASC NULLS FIRST'), + '1'); + + PERFORM assert_result( + 'ORDER BY eql_v2.order_by(e) ASC NULLS LAST', + format('SELECT id FROM encrypted ORDER BY e ASC NULLS LAST'), + '3'); + + -- NULLS FIRST when DESC + PERFORM assert_result( + 'ORDER BY encrypted DESC', + format('SELECT id FROM encrypted ORDER BY e DESC'), + '1'); + + PERFORM assert_result( + 'ORDER BY eql_v2.order_by(e) DESC NULLS FIRST', + format('SELECT id FROM encrypted ORDER BY e DESC NULLS FIRST'), + '1'); + + PERFORM assert_result( + 'ORDER BY eql_v2.order_by(e) DESC NULLS LAST', + format('SELECT id FROM encrypted ORDER BY e DESC NULLS LAST'), + '2'); + + END; +$$ LANGUAGE plpgsql; + +PERFORM drop_table_with_encrypted(); \ No newline at end of file diff --git a/src/ore_block_u64_8_256/functions.sql b/src/ore_block_u64_8_256/functions.sql index 061bbc3..0b1ea87 100644 --- a/src/ore_block_u64_8_256/functions.sql +++ b/src/ore_block_u64_8_256/functions.sql @@ -54,6 +54,10 @@ CREATE FUNCTION eql_v2.ore_block_u64_8_256(val jsonb) IMMUTABLE STRICT PARALLEL SAFE AS $$ BEGIN + IF val IS NULL THEN + RETURN NULL; + END IF; + IF val ? 'ob' THEN RETURN eql_v2.jsonb_array_to_ore_block_u64_8_256(val->'ob'); END IF;