Skip to content

Enable indexing on eql_v2_encrypted columns without needing function helpers #118

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 16 commits into from
Jun 25, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
61 changes: 61 additions & 0 deletions src/blake3/compare.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
-- REQUIRE: src/schema.sql
-- REQUIRE: src/blake3/types.sql
-- REQUIRE: src/blake3/functions.sql


CREATE FUNCTION eql_v2.compare_blake3(a eql_v2_encrypted, b eql_v2_encrypted)
RETURNS integer
IMMUTABLE STRICT PARALLEL SAFE
AS $$
DECLARE
a_term eql_v2.blake3;
b_term eql_v2.blake3;
BEGIN

IF a IS NULL AND b IS NULL THEN
RETURN 0;
END IF;

IF a IS NULL THEN
RETURN -1;
END IF;

IF b IS NULL THEN
RETURN 1;
END IF;

IF eql_v2.has_blake3(a) THEN
a_term = eql_v2.blake3(a);
END IF;

IF eql_v2.has_blake3(b) THEN
b_term = eql_v2.blake3(b);
END IF;

IF a_term IS NULL AND b_term IS NULL THEN
RETURN 0;
END IF;

IF a_term IS NULL THEN
RETURN -1;
END IF;

IF b_term IS NULL THEN
RETURN 1;
END IF;

-- Using the underlying text type comparison
IF a_term = b_term THEN
RETURN 0;
END IF;

IF a_term < b_term THEN
RETURN -1;
END IF;

IF a_term > b_term THEN
RETURN 1;
END IF;

END;
$$ LANGUAGE plpgsql;
26 changes: 26 additions & 0 deletions src/blake3/compare_test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
\set ON_ERROR_STOP on

DO $$
DECLARE
a eql_v2_encrypted;
b eql_v2_encrypted;
c eql_v2_encrypted;
BEGIN
a := create_encrypted_json(1, 'b3');
b := create_encrypted_json(2, 'b3');
c := create_encrypted_json(3, 'b3');

ASSERT eql_v2.compare_blake3(a, a) = 0;
ASSERT eql_v2.compare_blake3(a, b) = -1;
ASSERT eql_v2.compare_blake3(a, c) = -1;

ASSERT eql_v2.compare_blake3(b, b) = 0;
ASSERT eql_v2.compare_blake3(b, a) = 1;
ASSERT eql_v2.compare_blake3(b, c) = -1;

ASSERT eql_v2.compare_blake3(c, c) = 0;
ASSERT eql_v2.compare_blake3(c, b) = 1;
ASSERT eql_v2.compare_blake3(c, a) = 1;
END;
$$ LANGUAGE plpgsql;

42 changes: 42 additions & 0 deletions src/encrypted/compare.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
-- REQUIRE: src/schema.sql
-- REQUIRE: src/encrypted/types.sql

--
-- Compare two eql_v2_encrypted values as literal jsonb values
-- Used as a fallback when no suitable search term is available
--
CREATE FUNCTION eql_v2.compare_literal(a eql_v2_encrypted, b eql_v2_encrypted)
RETURNS integer
IMMUTABLE STRICT PARALLEL SAFE
AS $$
DECLARE
a_data jsonb;
b_data jsonb;
BEGIN

IF a IS NULL AND b IS NULL THEN
RETURN 0;
END IF;

IF a IS NULL THEN
RETURN -1;
END IF;

IF b IS NULL THEN
RETURN 1;
END IF;

a_data := a.data;
b_data := b.data;

IF a_data < b_data THEN
RETURN -1;
END IF;

IF a_data > b_data THEN
RETURN 1;
END IF;

RETURN 0;
END;
$$ LANGUAGE plpgsql;
61 changes: 61 additions & 0 deletions src/hmac_256/compare.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,61 @@
-- REQUIRE: src/schema.sql
-- REQUIRE: src/hmac_256/types.sql
-- REQUIRE: src/hmac_256/functions.sql


CREATE FUNCTION eql_v2.compare_hmac_256(a eql_v2_encrypted, b eql_v2_encrypted)
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

What's the difference between this and blake3?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The types are different, although both resolve to text.
The implementation pattern is the same for every type of index for consistency.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Sorry I mean what do we use them for? HMAC and Blake are essentially the same thing.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@coderdan Blake3 is used in the SteVec implementation. I've followed the cipherstash-client implementation

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

RETURNS integer
IMMUTABLE STRICT PARALLEL SAFE
AS $$
DECLARE
a_term eql_v2.hmac_256;
b_term eql_v2.hmac_256;
BEGIN

IF a IS NULL AND b IS NULL THEN
RETURN 0;
END IF;

IF a IS NULL THEN
RETURN -1;
END IF;

IF b IS NULL THEN
RETURN 1;
END IF;

IF eql_v2.has_hmac_256(a) THEN
a_term = eql_v2.hmac_256(a);
END IF;

IF eql_v2.has_hmac_256(b) THEN
b_term = eql_v2.hmac_256(b);
END IF;

IF a_term IS NULL AND b_term IS NULL THEN
RETURN 0;
END IF;

IF a_term IS NULL THEN
RETURN -1;
END IF;

IF b_term IS NULL THEN
RETURN 1;
END IF;

-- Using the underlying text type comparison
IF a_term = b_term THEN
RETURN 0;
END IF;

IF a_term < b_term THEN
RETURN -1;
END IF;

IF a_term > b_term THEN
RETURN 1;
END IF;

END;
$$ LANGUAGE plpgsql;
26 changes: 26 additions & 0 deletions src/hmac_256/compare_test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
\set ON_ERROR_STOP on

DO $$
DECLARE
a eql_v2_encrypted;
b eql_v2_encrypted;
c eql_v2_encrypted;
BEGIN
a := create_encrypted_json(1, 'hm');
b := create_encrypted_json(2, 'hm');
c := create_encrypted_json(3, 'hm');

ASSERT eql_v2.compare_hmac_256(a, a) = 0;
ASSERT eql_v2.compare_hmac_256(a, b) = -1;
ASSERT eql_v2.compare_hmac_256(a, c) = -1;

ASSERT eql_v2.compare_hmac_256(b, b) = 0;
ASSERT eql_v2.compare_hmac_256(b, a) = 1;
ASSERT eql_v2.compare_hmac_256(b, c) = -1;

ASSERT eql_v2.compare_hmac_256(c, c) = 0;
ASSERT eql_v2.compare_hmac_256(c, b) = 1;
ASSERT eql_v2.compare_hmac_256(c, a) = 1;
END;
$$ LANGUAGE plpgsql;

40 changes: 4 additions & 36 deletions src/operators/<.sql
Original file line number Diff line number Diff line change
@@ -1,50 +1,18 @@
-- REQUIRE: src/schema.sql
-- REQUIRE: src/ore_block_u64_8_256/types.sql
-- REQUIRE: src/ore_block_u64_8_256/functions.sql
-- REQUIRE: src/ore_block_u64_8_256/operators.sql
-- REQUIRE: src/encrypted/types.sql
-- REQUIRE: src/operators/compare.sql


-- Operators for < less than comparisons of eql_v2_encrypted types
--
-- Support for the following comparisons:
-- Uses `eql_v2.compare` for the actual comparison logic.
--
-- eql_v2_encrypted = eql_v2_encrypted
-- eql_v2_encrypted = jsonb
-- jsonb = eql_v2_encrypted
--
-- There are multiple index terms that provide equality comparisons
-- - ore_block_u64_8_256
-- - ore_cllw_8_v2
--
-- We check these index terms in this order and use the first one that exists for both parameters
--
--


CREATE FUNCTION eql_v2.lt(a eql_v2_encrypted, b eql_v2_encrypted)
RETURNS boolean
AS $$
BEGIN

BEGIN
RETURN eql_v2.ore_cllw_u64_8(a) < eql_v2.ore_cllw_u64_8(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lt no ore_cllw_u64_8 index');
END;

BEGIN
RETURN eql_v2.ore_cllw_var_8(a) < eql_v2.ore_cllw_var_8(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lt no ore_cllw_var_8 index');
END;

BEGIN
RETURN eql_v2.ore_block_u64_8_256(a) < eql_v2.ore_block_u64_8_256(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lt no ore_block_u64_8_256 index');
END;

RETURN false;
RETURN eql_v2.compare(a, b) = -1;
END;
$$ LANGUAGE plpgsql;

Expand Down
42 changes: 5 additions & 37 deletions src/operators/<=.sql
Original file line number Diff line number Diff line change
@@ -1,50 +1,18 @@
-- REQUIRE: src/schema.sql
-- REQUIRE: src/encrypted/types.sql
-- REQUIRE: src/ore_block_u64_8_256/types.sql
-- REQUIRE: src/ore_block_u64_8_256/functions.sql
-- REQUIRE: src/ore_block_u64_8_256/operators.sql
-- REQUIRE: src/operators/compare.sql


-- Operators for < less than comparisons of eql_v2_encrypted types
-- Operators for <= less than or equal to comparisons of eql_v2_encrypted types
--
-- Support for the following comparisons:
-- Uses `eql_v2.compare` for the actual comparison logic.
--
-- eql_v2_encrypted = eql_v2_encrypted
-- eql_v2_encrypted = jsonb
-- jsonb = eql_v2_encrypted
--
-- There are multiple index terms that provide equality comparisons
-- - ore_block_u64_8_256
-- - ore_cllw_8_v2
--
-- We check these index terms in this order and use the first one that exists for both parameters
--
--


CREATE FUNCTION eql_v2.lte(a eql_v2_encrypted, b eql_v2_encrypted)
RETURNS boolean
AS $$
BEGIN

BEGIN
RETURN eql_v2.ore_cllw_u64_8(a) <= eql_v2.ore_cllw_u64_8(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lte no ore_cllw_u64_8 index');
END;

BEGIN
RETURN eql_v2.ore_cllw_var_8(a) <= eql_v2.ore_cllw_var_8(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lte no ore_cllw_var_8 index');
END;

BEGIN
RETURN eql_v2.ore_block_u64_8_256(a) <= eql_v2.ore_block_u64_8_256(b);
EXCEPTION WHEN OTHERS THEN
-- PERFORM eql_v2.log('eql_v2.lte no ore_block_u64_8_256 index');
END;

RETURN false;
RETURN eql_v2.compare(a, b) <= 0;
END;
$$ LANGUAGE plpgsql;

Expand Down
57 changes: 57 additions & 0 deletions src/operators/<=_ore_cllw_u64_8_test.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
\set ON_ERROR_STOP on

SELECT create_table_with_encrypted();
SELECT seed_encrypted_json();


-- ========================================================================


-- ------------------------------------------------------------------------
-- ------------------------------------------------------------------------
--
-- ore_cllw_u64_8 less than or equal to <=
--
-- Test data is in form '{"hello": "{one | two | three}", "n": {10 | 20 | 30} }'
--
-- Paths
-- $ -> bca213de9ccce676fa849ff9c4807963
-- $.hello -> a7cea93975ed8c01f861ccb6bd082784
-- $.n -> 2517068c0d1f9d4d41d2c666211f785e
--
--
DO $$
DECLARE
sv eql_v2_encrypted;
term eql_v2_encrypted;
BEGIN

-- This extracts the data associated with the field from the test eql_v2_encrypted
-- json n: 10
sv := get_numeric_ste_vec_20()::eql_v2_encrypted;
-- extract the term at $.n returned as eql_v2_encrypted
term := sv->'2517068c0d1f9d4d41d2c666211f785e'::text;

-- -- -- -- $.n
PERFORM assert_result(
format('eql_v2_encrypted <= eql_v2_encrypted with ore_cllw_u64_8 index term'),
format('SELECT e FROM encrypted WHERE (e->''2517068c0d1f9d4d41d2c666211f785e''::text) <= %L::eql_v2_encrypted', term));

PERFORM assert_count(
format('eql_v2_encrypted <= eql_v2_encrypted with ore index term'),
format('SELECT e FROM encrypted WHERE e->''2517068c0d1f9d4d41d2c666211f785e''::text <= %L::eql_v2_encrypted', term),
2);

-- Check the $.hello path
-- Returned encrypted does not have ore_cllw_u64_8
-- Falls back to jsonb literal comparison
PERFORM assert_no_result(
format('eql_v2_encrypted <= eql_v2_encrypted with ore index term'),
format('SELECT e FROM encrypted WHERE e->''a7cea93975ed8c01f861ccb6bd082784''::text <= %L::eql_v2_encrypted', term));

END;
$$ LANGUAGE plpgsql;



SELECT drop_table_with_encrypted();
Loading