From 3b118c47e9e173f30568a6074b2a3493bfa7a3c7 Mon Sep 17 00:00:00 2001 From: Toby Hede Date: Thu, 11 Dec 2025 19:07:43 +1100 Subject: [PATCH 1/2] refactor: convert plpgsql functions to SQL for inlining Convert 7 simple wrapper functions from plpgsql to SQL language to enable PostgreSQL query planner to inline them, improving performance. Functions converted: - eql_v2.to_encrypted(jsonb) - cast JSONB to encrypted type - eql_v2.to_encrypted(text) - cast text to encrypted type - eql_v2.to_jsonb(eql_v2_encrypted) - extract JSONB from encrypted type - eql_v2.ciphertext(eql_v2_encrypted) - extract ciphertext wrapper - eql_v2.meta_data(jsonb) - extract metadata from JSONB - eql_v2.meta_data(eql_v2_encrypted) - extract metadata wrapper - eql_v2.compare_literal() - literal comparison for btree fallback All functions are marked STRICT, making NULL checks in plpgsql code redundant. SQL language functions are eligible for inlining by the query planner, while plpgsql functions are always treated as opaque function calls. Files modified: - src/encrypted/casts.sql (3 functions) - src/encrypted/functions.sql (3 functions) - src/encrypted/compare.sql (1 function) --- src/encrypted/casts.sql | 33 +++++++++----------------------- src/encrypted/compare.sql | 38 +++++++------------------------------ src/encrypted/functions.sql | 24 +++++++++-------------- 3 files changed, 25 insertions(+), 70 deletions(-) diff --git a/src/encrypted/casts.sql b/src/encrypted/casts.sql index 2a5e1802..8282a3d1 100644 --- a/src/encrypted/casts.sql +++ b/src/encrypted/casts.sql @@ -15,15 +15,10 @@ CREATE FUNCTION eql_v2.to_encrypted(data jsonb) RETURNS public.eql_v2_encrypted IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ -BEGIN - IF data IS NULL THEN - RETURN NULL; - END IF; - - RETURN ROW(data)::public.eql_v2_encrypted; -END; -$$ LANGUAGE plpgsql; + SELECT ROW(data)::public.eql_v2_encrypted; +$$; --! @brief Implicit cast from JSONB to encrypted type @@ -49,15 +44,10 @@ CREATE CAST (jsonb AS public.eql_v2_encrypted) CREATE FUNCTION eql_v2.to_encrypted(data text) RETURNS public.eql_v2_encrypted IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ -BEGIN - IF data IS NULL THEN - RETURN NULL; - END IF; - - RETURN eql_v2.to_encrypted(data::jsonb); -END; -$$ LANGUAGE plpgsql; + SELECT eql_v2.to_encrypted(data::jsonb); +$$; --! @brief Implicit cast from text to encrypted type @@ -84,15 +74,10 @@ CREATE CAST (text AS public.eql_v2_encrypted) CREATE FUNCTION eql_v2.to_jsonb(e public.eql_v2_encrypted) RETURNS jsonb IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ -BEGIN - IF e IS NULL THEN - RETURN NULL; - END IF; - - RETURN e.data; -END; -$$ LANGUAGE plpgsql; + SELECT e.data; +$$; --! @brief Implicit cast from encrypted type to JSONB --! diff --git a/src/encrypted/compare.sql b/src/encrypted/compare.sql index aff99d6b..dc2e20d9 100644 --- a/src/encrypted/compare.sql +++ b/src/encrypted/compare.sql @@ -21,35 +21,11 @@ CREATE FUNCTION eql_v2.compare_literal(a eql_v2_encrypted, b eql_v2_encrypted) RETURNS integer IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL 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; + SELECT CASE + WHEN a.data < b.data THEN -1 + WHEN a.data > b.data THEN 1 + ELSE 0 + END; +$$; diff --git a/src/encrypted/functions.sql b/src/encrypted/functions.sql index fe639dd4..3c6e6f27 100644 --- a/src/encrypted/functions.sql +++ b/src/encrypted/functions.sql @@ -48,11 +48,10 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION eql_v2.ciphertext(val eql_v2_encrypted) RETURNS text IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ - BEGIN - RETURN eql_v2.ciphertext(val.data); - END; -$$ LANGUAGE plpgsql; + SELECT eql_v2.ciphertext(val.data); +$$; --! @brief State transition function for grouped_value aggregate --! @internal @@ -172,14 +171,10 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION eql_v2.meta_data(val jsonb) RETURNS jsonb IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ - BEGIN - RETURN jsonb_build_object( - 'i', val->'i', - 'v', val->'v' - ); - END; -$$ LANGUAGE plpgsql; + SELECT jsonb_build_object('i', val->'i', 'v', val->'v'); +$$; --! @brief Extract metadata from encrypted column value --! @@ -200,9 +195,8 @@ $$ LANGUAGE plpgsql; CREATE FUNCTION eql_v2.meta_data(val eql_v2_encrypted) RETURNS jsonb IMMUTABLE STRICT PARALLEL SAFE + LANGUAGE SQL AS $$ - BEGIN - RETURN eql_v2.meta_data(val.data); - END; -$$ LANGUAGE plpgsql; + SELECT eql_v2.meta_data(val.data); +$$; From 37e925f5e00864ddf58f5987e8441d8c520c4ff8 Mon Sep 17 00:00:00 2001 From: Toby Hede Date: Thu, 11 Dec 2025 19:47:34 +1100 Subject: [PATCH 2/2] docs: add function language choice guidelines to CLAUDE.md Document when to use LANGUAGE SQL vs LANGUAGE plpgsql for PostgreSQL functions. SQL is preferred for simple functions due to inlining benefits and better index performance. PL/pgSQL should be used when procedural features (variables, exception handling, loops, dynamic SQL) are needed. --- CLAUDE.md | 24 ++++++++++++++++++++++++ 1 file changed, 24 insertions(+) diff --git a/CLAUDE.md b/CLAUDE.md index 14dc677a..8fabea08 100644 --- a/CLAUDE.md +++ b/CLAUDE.md @@ -175,3 +175,27 @@ HTML output is also generated in `docs/api/html/` for local preview only. - Build system uses `tsort` to resolve dependency order - Supabase build excludes operator classes (not supported) - **Documentation**: All functions/types must have Doxygen comments (see Documentation Standards above) + +### Function Language Choice (SQL vs PL/pgSQL) + +Prefer `LANGUAGE SQL` over `LANGUAGE plpgsql` unless you need procedural features. + +| Aspect | LANGUAGE SQL | LANGUAGE plpgsql | +|-------------------|-----------------------------------|-------------------------| +| Inlining | ✅ Can be inlined by planner | ❌ Never inlined | +| Call overhead | Lower (can be optimized away) | Higher (context switch) | +| Index performance | Better for GIN index expressions | Worse | +| Control flow | CASE expression | IF/THEN/ELSE | + +**Why SQL wins for simple functions:** + +1. **Inlining** - PostgreSQL can inline simple SQL functions into the calling query, eliminating function call overhead entirely. PL/pgSQL functions are never inlined. +2. **Index context** - Functions used in index expressions (e.g., `CREATE INDEX ... USING GIN (eql_v2.jsonb_array(col))`) are called on every row insertion/update. Inlining matters. +3. **Simple logic** - A CASE expression is a single statement. PL/pgSQL's procedural features aren't needed. + +**When PL/pgSQL is appropriate:** + +- Multiple statements with intermediate variables +- Exception handling (`BEGIN...EXCEPTION...END`) +- Complex control flow (loops, early returns) +- Dynamic SQL (`EXECUTE`)