diff --git a/.gitignore b/.gitignore index 893e4e74..32632401 100644 --- a/.gitignore +++ b/.gitignore @@ -179,4 +179,4 @@ dist cipherstash-proxy.toml # turbo repo -.turbo \ No newline at end of file +.turbo diff --git a/justfile b/justfile new file mode 100644 index 00000000..9ce3537e --- /dev/null +++ b/justfile @@ -0,0 +1,38 @@ +set dotenv-load +set positional-arguments + + +test_dsl: + #!/usr/bin/env bash + set -euxo pipefail + + PGPASSWORD=$CS_DATABASE__PASSWORD dropdb --force --if-exists --username $CS_DATABASE__USERNAME --port $CS_DATABASE__PORT cs_migrator_test + PGPASSWORD=$CS_DATABASE__PASSWORD createdb --username $CS_DATABASE__USERNAME --port $CS_DATABASE__PORT cs_migrator_test + + connection_url=postgresql://$CS_DATABASE__USERNAME:@localhost:$CS_DATABASE__PORT/cs_migrator_test + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f sql/dsl-core.sql + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f sql/dsl-config-schema.sql + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f sql/dsl-config-functions.sql + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f sql/dsl-encryptindex.sql + + # tests + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f tests/core.sql + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f tests/config.sql + PGPASSWORD=$CS_DATABASE__PASSWORD psql $connection_url -f tests/encryptindex.sql + + dropdb --username $CS_DATABASE__USERNAME --port $CS_DATABASE__PORT cs_migrator_test + + +build: + #!/usr/bin/env bash + set -euxo pipefail + + cat sql/dsl-core.sql sql/dsl-config-schema.sql sql/dsl-config-functions.sql sql/dsl-encryptindex.sql > release/cipherstash-encrypt-dsl.sql + + +psql: + psql postgresql://$CS_USERNAME:$CS_PASSWORD@localhost:$CS_PORT/$CS_DATABASE__NAME + + +psql_direct: + psql --user $CS_DATABASE__USERNAME --dbname $CS_DATABASE__NAME --port $CS_DATABASE__PORT diff --git a/languages/go/xorm/cipherstash-encrypt-dsl.sql b/languages/go/xorm/cipherstash-encrypt-dsl.sql index 4acdba50..4e949ce2 100644 --- a/languages/go/xorm/cipherstash-encrypt-dsl.sql +++ b/languages/go/xorm/cipherstash-encrypt-dsl.sql @@ -130,7 +130,7 @@ BEGIN ATOMIC RETURN cs_unique_v1_v0_0(col); END; --- extracts json containment index from an encrypted column +-- extracts json ste_vec index from an encrypted column CREATE OR REPLACE FUNCTION cs_ste_vec_v1_v0_0(col jsonb) RETURNS cs_ste_vec_index_v1 LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE @@ -233,7 +233,7 @@ CREATE FUNCTION _cs_config_check_indexes(val jsonb) RETURNS BOOLEAN LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE BEGIN ATOMIC - SELECT jsonb_object_keys(jsonb_path_query(val, '$.tables.*.*.indexes')) = ANY('{match, ore, unique, json}'); + SELECT jsonb_object_keys(jsonb_path_query(val, '$.tables.*.*.indexes')) = ANY('{match, ore, unique, ste_vec}'); END; @@ -299,7 +299,7 @@ DROP FUNCTION IF EXISTS cs_discard_v1(); DROP FUNCTION IF EXISTS cs_refresh_encrypt_config(); DROP FUNCTION IF EXISTS _cs_config_default(); -DROP FUNCTION IF EXISTS _cs_config_match_1_default(); +DROP FUNCTION IF EXISTS _cs_config_match_default(); DROP FUNCTION IF EXISTS _cs_config_add_table(text, json); DROP FUNCTION IF EXISTS _cs_config_add_column(text, text, json); @@ -328,8 +328,7 @@ AS $$ tbl jsonb; BEGIN IF NOT config #> array['tables'] ? table_name THEN - SELECT jsonb_build_object(table_name, jsonb_build_object()) into tbl; - SELECT jsonb_set(config, array['tables'], tbl) INTO config; + SELECT jsonb_insert(config, array['tables', table_name], jsonb_build_object()) INTO config; END IF; RETURN config; END; @@ -377,9 +376,9 @@ $$ LANGUAGE plpgsql; -- --- Default options for match_1 index +-- Default options for match index -- -CREATE FUNCTION _cs_config_match_1_default() +CREATE FUNCTION _cs_config_match_default() RETURNS jsonb LANGUAGE sql STRICT PARALLEL SAFE BEGIN ATOMIC @@ -425,7 +424,7 @@ AS $$ -- set default options for index if opts empty IF index_name = 'match' AND opts = '{}' THEN - SELECT _cs_config_match_1_default() INTO opts; + SELECT _cs_config_match_default() INTO opts; END IF; SELECT _cs_config_add_index(table_name, column_name, index_name, opts, _config) INTO _config; diff --git a/release/cipherstash-encrypt-dsl.sql b/release/cipherstash-encrypt-dsl.sql new file mode 100644 index 00000000..01085c77 --- /dev/null +++ b/release/cipherstash-encrypt-dsl.sql @@ -0,0 +1,819 @@ +DROP CAST IF EXISTS (text AS ore_64_8_v1_term); + +DROP FUNCTION IF EXISTS cs_match_v1; +DROP FUNCTION IF EXISTS cs_match_v1_v0; +DROP FUNCTION IF EXISTS cs_match_v1_v0_0; + +DROP FUNCTION IF EXISTS cs_unique_v1; +DROP FUNCTION IF EXISTS cs_unique_v1_v0; +DROP FUNCTION IF EXISTS cs_unique_v1_v0_0; + +DROP FUNCTION IF EXISTS cs_ore_64_8_v1; +DROP FUNCTION IF EXISTS cs_ore_64_8_v1_v0; +DROP FUNCTION IF EXISTS cs_ore_64_8_v1_v0_0; + +DROP FUNCTION IF EXISTS _cs_text_to_ore_64_8_v1_term_v1_0; + +DROP DOMAIN IF EXISTS cs_match_index_v1; +DROP DOMAIN IF EXISTS cs_unique_index_v1; + +CREATE DOMAIN cs_match_index_v1 AS smallint[]; +CREATE DOMAIN cs_unique_index_v1 AS text; +CREATE DOMAIN cs_ste_vec_index_v1 AS text[]; + +-- cs_encrypted_v1 is a column type and cannot be dropped if in use +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_encrypted_v1') THEN + CREATE DOMAIN cs_encrypted_v1 AS JSONB; + END IF; +END +$$; + +DROP FUNCTION IF EXISTS _cs_encrypted_check_kind(jsonb); +CREATE FUNCTION _cs_encrypted_check_kind(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN (val->>'k' = 'ct' AND val ? 'c') AND NOT val ? 'p'; +END; + + +-- drop and reset the check constraint +ALTER DOMAIN cs_encrypted_v1 DROP CONSTRAINT IF EXISTS cs_encrypted_v1_check; + +ALTER DOMAIN cs_encrypted_v1 + ADD CONSTRAINT cs_encrypted_v1_check CHECK ( + -- version and source are required + VALUE ?& array['v'] AND + + -- table and column + VALUE->'i' ?& array['t', 'c'] AND + + -- plaintext or ciphertext for kind + _cs_encrypted_check_kind(VALUE) + +); + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1_v0_0(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN col->>'c'; +END; + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1_v0(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ciphertext_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ciphertext_v1_v0_0(col); +END; + +-- extracts match index from an emcrypted column +CREATE OR REPLACE FUNCTION cs_match_v1_v0_0(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT ARRAY(SELECT jsonb_array_elements(col->'m'))::cs_match_index_v1; +END; + +CREATE OR REPLACE FUNCTION cs_match_v1_v0(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_match_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_match_v1(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_match_v1_v0_0(col); +END; + +-- extracts unique index from an encrypted column +CREATE OR REPLACE FUNCTION cs_unique_v1_v0_0(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN col->>'u'; +END; + +CREATE OR REPLACE FUNCTION cs_unique_v1_v0(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_unique_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_unique_v1(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_unique_v1_v0_0(col); +END; + +-- extracts json ste_vec index from an encrypted column +CREATE OR REPLACE FUNCTION cs_ste_vec_v1_v0_0(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT ARRAY(SELECT jsonb_array_elements(col->'sv'))::cs_ste_vec_index_v1; +END; + +CREATE OR REPLACE FUNCTION cs_ste_vec_v1_v0(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ste_vec_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_ste_vec_v1(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ste_vec_v1_v0_0(col); +END; + +-- casts text to ore_64_8_v1_term (bytea) +CREATE FUNCTION _cs_text_to_ore_64_8_v1_term_v1_0(t text) + RETURNS ore_64_8_v1_term + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN t::bytea; +END; + +-- cast to cleanup ore_64_8_v1 extraction +CREATE CAST (text AS ore_64_8_v1_term) + WITH FUNCTION _cs_text_to_ore_64_8_v1_term_v1_0(text) AS IMPLICIT; + +-- extracts ore index from an encrypted column +CREATE FUNCTION cs_ore_64_8_v1_v0_0(val jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT (val->>'o')::ore_64_8_v1; +END; + +CREATE FUNCTION cs_ore_64_8_v1_v0(col jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ore_64_8_v1_v0_0(col); +END; + +CREATE FUNCTION cs_ore_64_8_v1(col jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ore_64_8_v1_v0_0(col); +END; +-- +-- Configuration Schema +-- +-- Defines core config state and storage types +-- Creates the cs_configuration_v1 table with constraint and unique indexes +-- +-- + + +-- +-- cs_configuration_data_v1 is a jsonb column that stores the actuak configuration +-- +-- For some reason CREATE DFOMAIN and CREATE TYPE do not support IF NOT EXISTS +-- Types cannot be dropped if used by a table, and we never drop the configuration table +-- DOMAIN constraints are added separately and not tied to DOMAIN creation +-- +DO $$ + BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_configuration_data_v1') THEN + CREATE DOMAIN cs_configuration_data_v1 AS JSONB; + END IF; + END +$$; + +-- +-- cs_configuration_state_v1 is an ENUM that defines the valid configuration states +-- +DO $$ + BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_configuration_state_v1') THEN + CREATE TYPE cs_configuration_state_v1 AS ENUM ('active', 'inactive', 'encrypting', 'pending'); + END IF; + END +$$; + +-- +-- _cs_check_config_indexes returns true if the table configuration only includes valid index types +-- +-- Used by the cs_configuration_data_v1_check constraint +-- +-- Function types cannot be changed after creation so we always DROP & CREATE for flexibility +-- +DROP FUNCTION IF EXISTS _cs_config_check_indexes(text, text); + +CREATE FUNCTION _cs_config_check_indexes(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_object_keys(jsonb_path_query(val, '$.tables.*.*.indexes')) = ANY('{match, ore, unique, ste_vec}'); +END; + + +CREATE FUNCTION _cs_config_check_cast(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_array_elements_text(jsonb_path_query_array(val, '$.tables.*.*.cast_as')) = ANY('{text, int, small_int, big_int, real, double, boolean, date, jsonb}'); +END; + + +-- +-- Drop and reset the check constraint +-- +ALTER DOMAIN cs_configuration_data_v1 DROP CONSTRAINT IF EXISTS cs_configuration_data_v1_check; + +ALTER DOMAIN cs_configuration_data_v1 + ADD CONSTRAINT cs_configuration_data_v1_check CHECK ( + VALUE ?& array['v', 'tables'] AND + VALUE->'tables' <> '{}'::jsonb AND + _cs_config_check_cast(VALUE) AND + _cs_config_check_indexes(VALUE) +); + + +-- +-- CREATE the cs_configuration_v1 TABLE +-- +CREATE TABLE IF NOT EXISTS cs_configuration_v1 +( + id bigint GENERATED ALWAYS AS IDENTITY, + state cs_configuration_state_v1 NOT NULL DEFAULT 'pending', + data cs_configuration_data_v1, + created_at timestamptz not null default current_timestamp, + PRIMARY KEY(id) +); + +-- +-- Define partial indexes to ensure that there is only one active, pending and encrypting config at a time +-- +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_active ON cs_configuration_v1 (state) WHERE state = 'active'; +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_pending ON cs_configuration_v1 (state) WHERE state = 'pending'; +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_encrypting ON cs_configuration_v1 (state) WHERE state = 'encrypting'; +-- +-- Configuration functions +-- +-- + + +-- DROP and CREATE functions +-- Function types cannot be changed after creation so we DROP for flexibility + +DROP FUNCTION IF EXISTS cs_add_column_v1(text, text); +DROP FUNCTION IF EXISTS cs_remove_column_v1(text, text); +DROP FUNCTION IF EXISTS cs_add_index_v1(text, text, text, jsonb); +DROP FUNCTION IF EXISTS cs_remove_index_v1(text, text, text); +DROP FUNCTION IF EXISTS cs_modify_index_v1(text, text, text, jsonb); + +DROP FUNCTION IF EXISTS cs_encrypt_v1(); +DROP FUNCTION IF EXISTS cs_activate_v1(); +DROP FUNCTION IF EXISTS cs_discard_v1(); + +DROP FUNCTION IF EXISTS cs_refresh_encrypt_config(); + +DROP FUNCTION IF EXISTS _cs_config_default(); +DROP FUNCTION IF EXISTS _cs_config_match_default(); + +DROP FUNCTION IF EXISTS _cs_config_add_table(text, json); +DROP FUNCTION IF EXISTS _cs_config_add_column(text, text, json); +DROP FUNCTION IF EXISTS _cs_config_add_cast(text, text, text, json); +DROP FUNCTION IF EXISTS _cs_config_add_index(text, text, text, json, json); + + +CREATE FUNCTION _cs_config_default(config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + IF config IS NULL THEN + SELECT jsonb_build_object('v', 1, 'tables', jsonb_build_object()) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION _cs_config_add_table(table_name text, config jsonb) + RETURNS jsonb + -- IMMUTABLE PARALLEL SAFE +AS $$ + DECLARE + tbl jsonb; + BEGIN + IF NOT config #> array['tables'] ? table_name THEN + SELECT jsonb_insert(config, array['tables', table_name], jsonb_build_object()) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- Add the column if it doesn't exist +CREATE FUNCTION _cs_config_add_column(table_name text, column_name text, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + DECLARE + col jsonb; + BEGIN + IF NOT config #> array['tables', table_name] ? column_name THEN + SELECT jsonb_build_object('indexes', jsonb_build_object()) into col; + SELECT jsonb_set(config, array['tables', table_name, column_name], col) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + +-- Set the cast +CREATE FUNCTION _cs_config_add_cast(table_name text, column_name text, cast_as text, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + SELECT jsonb_set(config, array['tables', table_name, column_name, 'cast_as'], to_jsonb(cast_as)) INTO config; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- Add the column if it doesn't exist +CREATE FUNCTION _cs_config_add_index(table_name text, column_name text, index_name text, opts jsonb, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + SELECT jsonb_insert(config, array['tables', table_name, column_name, 'indexes', index_name], opts) INTO config; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- +-- Default options for match index +-- +CREATE FUNCTION _cs_config_match_default() + RETURNS jsonb +LANGUAGE sql STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_build_object( + 'k', 6, + 'm', 2048, + 'include_original', true, + 'tokenizer', json_build_object('kind', 'ngram', 'token_length', 3), + 'token_filters', json_build_array(json_build_object('kind', 'downcase'))); +END; + +-- +-- +-- +CREATE FUNCTION cs_add_index_v1(table_name text, column_name text, index_name text, cast_as text DEFAULT 'text', opts jsonb DEFAULT '{}') + RETURNS jsonb +AS $$ + DECLARE + o jsonb; + _config jsonb; + BEGIN + + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if index exists + IF _config #> array['tables', table_name, column_name, 'indexes'] ? index_name THEN + RAISE EXCEPTION '% index exists for column: % %', index_name, table_name, column_name; + END IF; + + IF NOT cast_as = ANY('{text, int, small_int, big_int, real, double, boolean, date, jsonb}') THEN + RAISE EXCEPTION '% is not a valid cast type', cast_as; + END IF; + + -- set default config + SELECT _cs_config_default(_config) INTO _config; + + SELECT _cs_config_add_table(table_name, _config) INTO _config; + + SELECT _cs_config_add_column(table_name, column_name, _config) INTO _config; + + SELECT _cs_config_add_cast(table_name, column_name, cast_as, _config) INTO _config; + + -- set default options for index if opts empty + IF index_name = 'match' AND opts = '{}' THEN + SELECT _cs_config_match_default() INTO opts; + END IF; + + SELECT _cs_config_add_index(table_name, column_name, index_name, opts, _config) INTO _config; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO UPDATE + SET data = _config; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_remove_index_v1(table_name text, column_name text, index_name text) + RETURNS jsonb +AS $$ + DECLARE + _config jsonb; + BEGIN + + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if no config + IF _config IS NULL THEN + RAISE EXCEPTION 'No active or pending configuration exists'; + END IF; + + -- if the table doesn't exist + IF NOT _config #> array['tables'] ? table_name THEN + RAISE EXCEPTION 'No configuration exists for table: %', table_name; + END IF; + + -- if the index does not exist + -- IF NOT _config->key ? index_name THEN + IF NOT _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'No % index exists for column: % %', index_name, table_name, column_name; + END IF; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO NOTHING; + + -- remove the index + SELECT _config #- array['tables', table_name, column_name, 'indexes', index_name] INTO _config; + + -- if column is now empty, remove the column + IF _config #> array['tables', table_name, column_name, 'indexes'] = '{}' THEN + SELECT _config #- array['tables', table_name, column_name] INTO _config; + END IF; + + -- if table is now empty, remove the table + IF _config #> array['tables', table_name] = '{}' THEN + SELECT _config #- array['tables', table_name] INTO _config; + END IF; + + -- if config empty delete + -- or update the config + IF _config #> array['tables'] = '{}' THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + ELSE + UPDATE cs_configuration_v1 SET data = _config WHERE state = 'pending'; + END IF; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_modify_index_v1(table_name text, column_name text, index_name text, cast_as text DEFAULT 'text', opts jsonb DEFAULT '{}') + RETURNS jsonb +AS $$ + BEGIN + PERFORM cs_remove_index_v1(table_name, column_name, index_name); + RETURN cs_add_index_v1(table_name, column_name, index_name, cast_as, opts); + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_encrypt_v1() + RETURNS boolean +AS $$ + BEGIN + -- IF NOT cs_ready_for_encryption_v1() THEN + -- RAISE EXCEPTION 'Some pending columns do not have an encrypted target'; + -- END IF; + + IF NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending') THEN + RAISE EXCEPTION 'No pending configuration exists to encrypt'; + END IF; + + UPDATE cs_configuration_v1 SET state = 'encrypting' WHERE state = 'pending'; + RETURN true; + END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION cs_activate_v1() + RETURNS boolean +AS $$ + BEGIN + + IF EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'encrypting') THEN + UPDATE cs_configuration_v1 SET state = 'inactive' WHERE state = 'active'; + UPDATE cs_configuration_v1 SET state = 'active' WHERE state = 'encrypting'; + RETURN true; + ELSE + RAISE EXCEPTION 'No encrypting configuration exists to activate'; + END IF; + END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION cs_discard_v1() + RETURNS boolean +AS $$ + BEGIN + IF EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending') THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + RETURN true; + ELSE + RAISE EXCEPTION 'No pending configuration exists to discard'; + END IF; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_add_column_v1(table_name text, column_name text) + RETURNS jsonb +AS $$ + DECLARE + key text; + _config jsonb; + BEGIN + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- set default config + SELECT _cs_config_default(_config) INTO _config; + + -- if index exists + IF _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'Config exists for column: % %', table_name, column_name; + END IF; + + SELECT _cs_config_add_table(table_name, _config) INTO _config; + + SELECT _cs_config_add_column(table_name, column_name, _config) INTO _config; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO UPDATE + SET data = _config; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_remove_column_v1(table_name text, column_name text) + RETURNS jsonb +AS $$ + DECLARE + key text; + _config jsonb; + BEGIN + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if no config + IF _config IS NULL THEN + RAISE EXCEPTION 'No active or pending configuration exists'; + END IF; + + -- if the table doesn't exist + IF NOT _config #> array['tables'] ? table_name THEN + RAISE EXCEPTION 'No configuration exists for table: %', table_name; + END IF; + + -- if the column does not exist + IF NOT _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'No configuration exists for column: % %', table_name, column_name; + END IF; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO NOTHING; + + -- remove the column + SELECT _config #- array['tables', table_name, column_name] INTO _config; + + -- if table is now empty, remove the table + IF _config #> array['tables', table_name] = '{}' THEN + SELECT _config #- array['tables', table_name] INTO _config; + END IF; + + -- if config empty delete + -- or update the config + IF _config #> array['tables'] = '{}' THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + ELSE + UPDATE cs_configuration_v1 SET data = _config WHERE state = 'pending'; + END IF; + + -- exeunt + RETURN _config; + + END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION cs_refresh_encrypt_config() + RETURNS void +LANGUAGE sql STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN NULL; +END; + +-- DROP and CREATE functions +-- Function types cannot be changed after creation so we DROP for flexibility +DROP FUNCTION IF EXISTS cs_select_pending_columns_v1; +DROP FUNCTION IF EXISTS cs_select_target_columns_v1; +DROP FUNCTION IF EXISTS cs_count_encrypted_with_active_config_v1; +DROP FUNCTION IF EXISTS cs_create_encrypted_columns_v1(); +DROP FUNCTION IF EXISTS cs_rename_encrypted_columns_v1(); + +DROP FUNCTION IF EXISTS _cs_diff_config_v1; +DROP FUNCTION IF EXISTS _cs_table_from_config_key; +DROP FUNCTION IF EXISTS _cs_column_from_config_key; + + +-- Return the diff of two configurations +-- Returns the set of keys in a that have different values to b +-- The json comparison is on object values held by the key +CREATE OR REPLACE FUNCTION _cs_diff_config_v1(a JSONB, b JSONB) + RETURNS TABLE(table_name TEXT, column_name TEXT) +IMMUTABLE STRICT PARALLEL SAFE +AS $$ + BEGIN + RETURN QUERY + WITH table_keys AS ( + SELECT jsonb_object_keys(a->'tables') AS key + UNION + SELECT jsonb_object_keys(b->'tables') AS key + ), + column_keys AS ( + SELECT tk.key AS table_key, jsonb_object_keys(a->'tables'->tk.key) AS column_key + FROM table_keys tk + UNION + SELECT tk.key AS table_key, jsonb_object_keys(b->'tables'->tk.key) AS column_key + FROM table_keys tk + ) + SELECT + ck.table_key AS table_name, + ck.column_key AS column_name + FROM + column_keys ck + WHERE + (a->'tables'->ck.table_key->ck.column_key IS DISTINCT FROM b->'tables'->ck.table_key->ck.column_key); + END; +$$ LANGUAGE plpgsql; + + +-- Returns the set of columns with pending configuration changes +-- Compares the columns in pending configuration that do not match the active config +CREATE FUNCTION cs_select_pending_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT) +AS $$ + DECLARE + active JSONB; + pending JSONB; + config_id BIGINT; + BEGIN + SELECT data INTO active FROM cs_configuration_v1 WHERE state = 'active'; + + -- set default config + IF active IS NULL THEN + active := '{}'; + END IF; + + SELECT id, data INTO config_id, pending FROM cs_configuration_v1 WHERE state = 'pending'; + + -- set default config + IF config_id IS NULL THEN + RAISE EXCEPTION 'No pending configuration exists to encrypt'; + END IF; + + RETURN QUERY + SELECT d.table_name, d.column_name FROM _cs_diff_config_v1(active, pending) as d; + END; +$$ LANGUAGE plpgsql; + +-- +-- Returns the target columns with pending configuration +-- +-- A `pending` column may be either a plaintext variant or cs_encrypted_v1. +-- A `target` column is always of type cs_encrypted_v1 +-- +-- On initial encryption from plaintext the target column will be `{column_name}_encrypted ` +-- OR NULL if the column does not exist +-- +CREATE FUNCTION cs_select_target_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT, target_column TEXT) + STABLE STRICT PARALLEL SAFE +AS $$ + SELECT + c.table_name, + c.column_name, + s.column_name as target_column + FROM + cs_select_pending_columns_v1() c + LEFT JOIN information_schema.columns s ON + s.table_name = c.table_name AND + (s.column_name = c.table_name OR s.column_name = c.column_name || '_encrypted') AND + s.domain_name = 'cs_encrypted_v1'; +$$ LANGUAGE sql; + + +-- +-- Returns true if all pending columns have a target (encrypted) column +CREATE FUNCTION cs_ready_for_encryption_v1() + RETURNS BOOLEAN + STABLE STRICT PARALLEL SAFE +AS $$ + SELECT EXISTS ( + SELECT * + FROM cs_select_target_columns_v1() AS c + WHERE c.target_column IS NOT NULL); +$$ LANGUAGE sql; + + +-- +-- Creates cs_encrypted_v1 columns for any plaintext columns with pending configuration +-- The new column name is `{column_name}_encrypted` +-- +-- Executes the ALTER TABLE statement +-- `ALTER TABLE {target_table} ADD COLUMN {column_name}_encrypted cs_encrypted_v1;` +-- +CREATE FUNCTION cs_create_encrypted_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT) +AS $$ + BEGIN + FOR table_name, column_name IN + SELECT c.table_name, (c.column_name || '_encrypted') FROM cs_select_target_columns_v1() AS c WHERE c.target_column IS NULL + LOOP + EXECUTE format('ALTER TABLE %I ADD column %I cs_encrypted_v1', table_name, column_name); + RETURN NEXT; + END LOOP; + END; +$$ LANGUAGE plpgsql; + + +-- +-- Renames plaintext and cs_encrypted_v1 columns created for the initial encryption. +-- The source plaintext column is renamed to `{column_name}_plaintext` +-- The target encrypted column is renamed from `{column_name}_encrypted` to `{column_name}` +-- +-- Executes the ALTER TABLE statements +-- `ALTER TABLE {target_table} RENAME COLUMN {column_name} TO {column_name}_plaintext; +-- `ALTER TABLE {target_table} RENAME COLUMN {column_name}_encrypted TO {column_name};` +-- +CREATE FUNCTION cs_rename_encrypted_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT, target_column TEXT) +AS $$ + BEGIN + FOR table_name, column_name, target_column IN + SELECT * FROM cs_select_target_columns_v1() as c WHERE c.target_column = c.column_name || '_encrypted' + LOOP + EXECUTE format('ALTER TABLE %I RENAME %I TO %I;', table_name, column_name, column_name || '_plaintext'); + EXECUTE format('ALTER TABLE %I RENAME %I TO %I;', table_name, target_column, column_name); + RETURN NEXT; + END LOOP; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_count_encrypted_with_active_config_v1(table_name TEXT, column_name TEXT) + RETURNS BIGINT +AS $$ +DECLARE + result BIGINT; +BEGIN + EXECUTE format( + 'SELECT COUNT(%I) FROM %s t WHERE %I->>%L = (SELECT id::TEXT FROM cs_configuration_v1 WHERE state = %L)', + column_name, table_name, column_name, 'v', 'active' + ) + INTO result; + RETURN result; +END; +$$ LANGUAGE plpgsql; + diff --git a/sql/cs_configuration_data_v1.schema.json b/sql/cs_configuration_data_v1.schema.json new file mode 100644 index 00000000..2520a2ce --- /dev/null +++ b/sql/cs_configuration_data_v1.schema.json @@ -0,0 +1,133 @@ +{ + "$schema": "http://json-schema.org/draft-07/schema#", + "type": "object", + "properties": { + "s": { + "title": "Schema version", + "description": "The schema version of this json document ", + "type": "integer", + "enum": [ + 1 + ] + }, + "tables": { + "type": "object", + "additionalProperties": { + "$ref": "#/$defs/table" + } + } + }, + "required": [ + "s", + "tables" + ], + "$defs": { + "table": { + "title": "Table configuration", + "type": "object", + "additionalProperties": { + "$ref": "#/$defs/column" + } + }, + "column": { + "title": "Column configuration", + "type": "object", + "properties": { + "cast_as": { + "title": "cast as type", + "description": "The type the decrypted column value will be cast as", + "type": "string", + "enum": [ + "text", + "int" + ] + }, + "indexes": { + "title": "Table configuration", + "type": "object", + "properties": { + "match_1": { + "$ref": "#/$defs/match_1" + }, + "ore_1": { + "$ref": "#/$defs/ore_1" + }, + "unique_1": { + "$ref": "#/$defs/unique_1" + } + }, + "additionalProperties": false + } + } + }, + "token_filters": { + "title": "Token filters", + "token_filters": { + "type": "object", + "properties": { + "kind": { + "type": "string", + "enum": [ + "downcase", + "upcase" + ] + } + } + } + }, + "ore_1": { + "title": "Index configuration", + "type": "object", + "additionalProperties": false + }, + "unique_1": { + "title": "Unique index v1", + "type": "object", + "properties": { + "token_filters": { + "$ref": "#/$defs/token_filters" + } + } + }, + "match_1": { + "title": "Index configuration", + "type": "object", + "properties": { + "k": { + "type": "integer" + }, + "m": { + "type": "integer" + }, + "tokenizer": { + "type": "object", + "properties": { + "kind": { + "type": "string", + "enum": [ + "edge-ngram", + "ngram" + ] + }, + "min_gram": { + "type": "integer" + }, + "max_gram": { + "type": "integer" + }, + "include_original": { + "type": "boolean" + } + } + }, + "token_filters": { + "$ref": "#/$defs/token_filters" + } + }, + "required": [ + "k", + "m" + ] + } + } +} \ No newline at end of file diff --git a/sql/cs_encrypted_v1.schema.json b/sql/cs_encrypted_v1.schema.json new file mode 100644 index 00000000..1cb12490 --- /dev/null +++ b/sql/cs_encrypted_v1.schema.json @@ -0,0 +1,113 @@ +{ + "$schema": "http://json-schema.org/draft-07/schema#", + "type": "object", + "properties": { + "s": { + "title": "Schema version", + "description": "The schema version of this json document ", + "type": "integer", + "enum": [ + 1 + ] + }, + "v": { + "title": "Configuration version", + "type": "integer" + }, + "k": { + "title": "kind", + "type": "string", + "enum": [ + "pt", + "ct", + "en" + ] + }, + "i": { + "title": "ident", + "type": "object", + "properties": { + "t": { + "title": "table", + "type": "string", + "pattern": "^[a-zA-Z_]{1}[0-9a-zA-Z_]*$" + }, + "c": { + "title": "column", + "type": "string", + "pattern": "^[a-zA-Z_]{1}[0-9a-zA-Z_]*$" + } + }, + "required": [ + "t", + "c" + ] + }, + "p": { + "title": "plaintext", + "type": "string" + }, + "c": { + "title": "ciphertext", + "type": "string" + }, + "u": { + "title": "unique index", + "type": "string" + }, + "o": { + "title": "ore index", + "type": "array", + "minItems": 1, + "items": { + "type": "string" + } + }, + "m": { + "title": "match index", + "type": "array", + "minItems": 1, + "items": { + "type": "number" + } + } + }, + "anyOf": [ + { + "properties": { + "k": { + "const": "pt" + } + }, + "required": [ + "p" + ] + }, + { + "properties": { + "k": { + "const": "ct" + } + }, + "required": [ + "c" + ] + }, + { + "properties": { + "k": { + "const": "en" + } + }, + "required": [ + "c", + "p" + ] + } + ], + "required": [ + "v", + "k", + "e" + ] +} \ No newline at end of file diff --git a/sql/dsl-config-functions.sql b/sql/dsl-config-functions.sql new file mode 100644 index 00000000..90e3a057 --- /dev/null +++ b/sql/dsl-config-functions.sql @@ -0,0 +1,376 @@ +-- +-- Configuration functions +-- +-- + + +-- DROP and CREATE functions +-- Function types cannot be changed after creation so we DROP for flexibility + +DROP FUNCTION IF EXISTS cs_add_column_v1(text, text); +DROP FUNCTION IF EXISTS cs_remove_column_v1(text, text); +DROP FUNCTION IF EXISTS cs_add_index_v1(text, text, text, jsonb); +DROP FUNCTION IF EXISTS cs_remove_index_v1(text, text, text); +DROP FUNCTION IF EXISTS cs_modify_index_v1(text, text, text, jsonb); + +DROP FUNCTION IF EXISTS cs_encrypt_v1(); +DROP FUNCTION IF EXISTS cs_activate_v1(); +DROP FUNCTION IF EXISTS cs_discard_v1(); + +DROP FUNCTION IF EXISTS cs_refresh_encrypt_config(); + +DROP FUNCTION IF EXISTS _cs_config_default(); +DROP FUNCTION IF EXISTS _cs_config_match_default(); + +DROP FUNCTION IF EXISTS _cs_config_add_table(text, json); +DROP FUNCTION IF EXISTS _cs_config_add_column(text, text, json); +DROP FUNCTION IF EXISTS _cs_config_add_cast(text, text, text, json); +DROP FUNCTION IF EXISTS _cs_config_add_index(text, text, text, json, json); + + +CREATE FUNCTION _cs_config_default(config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + IF config IS NULL THEN + SELECT jsonb_build_object('v', 1, 'tables', jsonb_build_object()) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION _cs_config_add_table(table_name text, config jsonb) + RETURNS jsonb + -- IMMUTABLE PARALLEL SAFE +AS $$ + DECLARE + tbl jsonb; + BEGIN + IF NOT config #> array['tables'] ? table_name THEN + SELECT jsonb_insert(config, array['tables', table_name], jsonb_build_object()) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- Add the column if it doesn't exist +CREATE FUNCTION _cs_config_add_column(table_name text, column_name text, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + DECLARE + col jsonb; + BEGIN + IF NOT config #> array['tables', table_name] ? column_name THEN + SELECT jsonb_build_object('indexes', jsonb_build_object()) into col; + SELECT jsonb_set(config, array['tables', table_name, column_name], col) INTO config; + END IF; + RETURN config; + END; +$$ LANGUAGE plpgsql; + +-- Set the cast +CREATE FUNCTION _cs_config_add_cast(table_name text, column_name text, cast_as text, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + SELECT jsonb_set(config, array['tables', table_name, column_name, 'cast_as'], to_jsonb(cast_as)) INTO config; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- Add the column if it doesn't exist +CREATE FUNCTION _cs_config_add_index(table_name text, column_name text, index_name text, opts jsonb, config jsonb) + RETURNS jsonb + IMMUTABLE PARALLEL SAFE +AS $$ + BEGIN + SELECT jsonb_insert(config, array['tables', table_name, column_name, 'indexes', index_name], opts) INTO config; + RETURN config; + END; +$$ LANGUAGE plpgsql; + + +-- +-- Default options for match index +-- +CREATE FUNCTION _cs_config_match_default() + RETURNS jsonb +LANGUAGE sql STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_build_object( + 'k', 6, + 'm', 2048, + 'include_original', true, + 'tokenizer', json_build_object('kind', 'ngram', 'token_length', 3), + 'token_filters', json_build_array(json_build_object('kind', 'downcase'))); +END; + +-- +-- +-- +CREATE FUNCTION cs_add_index_v1(table_name text, column_name text, index_name text, cast_as text DEFAULT 'text', opts jsonb DEFAULT '{}') + RETURNS jsonb +AS $$ + DECLARE + o jsonb; + _config jsonb; + BEGIN + + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if index exists + IF _config #> array['tables', table_name, column_name, 'indexes'] ? index_name THEN + RAISE EXCEPTION '% index exists for column: % %', index_name, table_name, column_name; + END IF; + + IF NOT cast_as = ANY('{text, int, small_int, big_int, real, double, boolean, date, jsonb}') THEN + RAISE EXCEPTION '% is not a valid cast type', cast_as; + END IF; + + -- set default config + SELECT _cs_config_default(_config) INTO _config; + + SELECT _cs_config_add_table(table_name, _config) INTO _config; + + SELECT _cs_config_add_column(table_name, column_name, _config) INTO _config; + + SELECT _cs_config_add_cast(table_name, column_name, cast_as, _config) INTO _config; + + -- set default options for index if opts empty + IF index_name = 'match' AND opts = '{}' THEN + SELECT _cs_config_match_default() INTO opts; + END IF; + + SELECT _cs_config_add_index(table_name, column_name, index_name, opts, _config) INTO _config; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO UPDATE + SET data = _config; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_remove_index_v1(table_name text, column_name text, index_name text) + RETURNS jsonb +AS $$ + DECLARE + _config jsonb; + BEGIN + + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if no config + IF _config IS NULL THEN + RAISE EXCEPTION 'No active or pending configuration exists'; + END IF; + + -- if the table doesn't exist + IF NOT _config #> array['tables'] ? table_name THEN + RAISE EXCEPTION 'No configuration exists for table: %', table_name; + END IF; + + -- if the index does not exist + -- IF NOT _config->key ? index_name THEN + IF NOT _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'No % index exists for column: % %', index_name, table_name, column_name; + END IF; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO NOTHING; + + -- remove the index + SELECT _config #- array['tables', table_name, column_name, 'indexes', index_name] INTO _config; + + -- if column is now empty, remove the column + IF _config #> array['tables', table_name, column_name, 'indexes'] = '{}' THEN + SELECT _config #- array['tables', table_name, column_name] INTO _config; + END IF; + + -- if table is now empty, remove the table + IF _config #> array['tables', table_name] = '{}' THEN + SELECT _config #- array['tables', table_name] INTO _config; + END IF; + + -- if config empty delete + -- or update the config + IF _config #> array['tables'] = '{}' THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + ELSE + UPDATE cs_configuration_v1 SET data = _config WHERE state = 'pending'; + END IF; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_modify_index_v1(table_name text, column_name text, index_name text, cast_as text DEFAULT 'text', opts jsonb DEFAULT '{}') + RETURNS jsonb +AS $$ + BEGIN + PERFORM cs_remove_index_v1(table_name, column_name, index_name); + RETURN cs_add_index_v1(table_name, column_name, index_name, cast_as, opts); + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_encrypt_v1() + RETURNS boolean +AS $$ + BEGIN + -- IF NOT cs_ready_for_encryption_v1() THEN + -- RAISE EXCEPTION 'Some pending columns do not have an encrypted target'; + -- END IF; + + IF NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending') THEN + RAISE EXCEPTION 'No pending configuration exists to encrypt'; + END IF; + + UPDATE cs_configuration_v1 SET state = 'encrypting' WHERE state = 'pending'; + RETURN true; + END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION cs_activate_v1() + RETURNS boolean +AS $$ + BEGIN + + IF EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'encrypting') THEN + UPDATE cs_configuration_v1 SET state = 'inactive' WHERE state = 'active'; + UPDATE cs_configuration_v1 SET state = 'active' WHERE state = 'encrypting'; + RETURN true; + ELSE + RAISE EXCEPTION 'No encrypting configuration exists to activate'; + END IF; + END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION cs_discard_v1() + RETURNS boolean +AS $$ + BEGIN + IF EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending') THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + RETURN true; + ELSE + RAISE EXCEPTION 'No pending configuration exists to discard'; + END IF; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_add_column_v1(table_name text, column_name text) + RETURNS jsonb +AS $$ + DECLARE + key text; + _config jsonb; + BEGIN + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- set default config + SELECT _cs_config_default(_config) INTO _config; + + -- if index exists + IF _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'Config exists for column: % %', table_name, column_name; + END IF; + + SELECT _cs_config_add_table(table_name, _config) INTO _config; + + SELECT _cs_config_add_column(table_name, column_name, _config) INTO _config; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO UPDATE + SET data = _config; + + -- exeunt + RETURN _config; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_remove_column_v1(table_name text, column_name text) + RETURNS jsonb +AS $$ + DECLARE + key text; + _config jsonb; + BEGIN + -- set the active config + SELECT data INTO _config FROM cs_configuration_v1 WHERE state = 'active' OR state = 'pending' ORDER BY state DESC; + + -- if no config + IF _config IS NULL THEN + RAISE EXCEPTION 'No active or pending configuration exists'; + END IF; + + -- if the table doesn't exist + IF NOT _config #> array['tables'] ? table_name THEN + RAISE EXCEPTION 'No configuration exists for table: %', table_name; + END IF; + + -- if the column does not exist + IF NOT _config #> array['tables', table_name] ? column_name THEN + RAISE EXCEPTION 'No configuration exists for column: % %', table_name, column_name; + END IF; + + -- create a new pending record if we don't have one + INSERT INTO cs_configuration_v1 (state, data) VALUES ('pending', _config) + ON CONFLICT (state) + WHERE state = 'pending' + DO NOTHING; + + -- remove the column + SELECT _config #- array['tables', table_name, column_name] INTO _config; + + -- if table is now empty, remove the table + IF _config #> array['tables', table_name] = '{}' THEN + SELECT _config #- array['tables', table_name] INTO _config; + END IF; + + -- if config empty delete + -- or update the config + IF _config #> array['tables'] = '{}' THEN + DELETE FROM cs_configuration_v1 WHERE state = 'pending'; + ELSE + UPDATE cs_configuration_v1 SET data = _config WHERE state = 'pending'; + END IF; + + -- exeunt + RETURN _config; + + END; +$$ LANGUAGE plpgsql; + +CREATE FUNCTION cs_refresh_encrypt_config() + RETURNS void +LANGUAGE sql STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN NULL; +END; diff --git a/sql/dsl-config-schema.sql b/sql/dsl-config-schema.sql new file mode 100644 index 00000000..fd6c3ca2 --- /dev/null +++ b/sql/dsl-config-schema.sql @@ -0,0 +1,92 @@ +-- +-- Configuration Schema +-- +-- Defines core config state and storage types +-- Creates the cs_configuration_v1 table with constraint and unique indexes +-- +-- + + +-- +-- cs_configuration_data_v1 is a jsonb column that stores the actuak configuration +-- +-- For some reason CREATE DFOMAIN and CREATE TYPE do not support IF NOT EXISTS +-- Types cannot be dropped if used by a table, and we never drop the configuration table +-- DOMAIN constraints are added separately and not tied to DOMAIN creation +-- +DO $$ + BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_configuration_data_v1') THEN + CREATE DOMAIN cs_configuration_data_v1 AS JSONB; + END IF; + END +$$; + +-- +-- cs_configuration_state_v1 is an ENUM that defines the valid configuration states +-- +DO $$ + BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_configuration_state_v1') THEN + CREATE TYPE cs_configuration_state_v1 AS ENUM ('active', 'inactive', 'encrypting', 'pending'); + END IF; + END +$$; + +-- +-- _cs_check_config_indexes returns true if the table configuration only includes valid index types +-- +-- Used by the cs_configuration_data_v1_check constraint +-- +-- Function types cannot be changed after creation so we always DROP & CREATE for flexibility +-- +DROP FUNCTION IF EXISTS _cs_config_check_indexes(text, text); + +CREATE FUNCTION _cs_config_check_indexes(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_object_keys(jsonb_path_query(val, '$.tables.*.*.indexes')) = ANY('{match, ore, unique, ste_vec}'); +END; + + +CREATE FUNCTION _cs_config_check_cast(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT jsonb_array_elements_text(jsonb_path_query_array(val, '$.tables.*.*.cast_as')) = ANY('{text, int, small_int, big_int, real, double, boolean, date, jsonb}'); +END; + + +-- +-- Drop and reset the check constraint +-- +ALTER DOMAIN cs_configuration_data_v1 DROP CONSTRAINT IF EXISTS cs_configuration_data_v1_check; + +ALTER DOMAIN cs_configuration_data_v1 + ADD CONSTRAINT cs_configuration_data_v1_check CHECK ( + VALUE ?& array['v', 'tables'] AND + VALUE->'tables' <> '{}'::jsonb AND + _cs_config_check_cast(VALUE) AND + _cs_config_check_indexes(VALUE) +); + + +-- +-- CREATE the cs_configuration_v1 TABLE +-- +CREATE TABLE IF NOT EXISTS cs_configuration_v1 +( + id bigint GENERATED ALWAYS AS IDENTITY, + state cs_configuration_state_v1 NOT NULL DEFAULT 'pending', + data cs_configuration_data_v1, + created_at timestamptz not null default current_timestamp, + PRIMARY KEY(id) +); + +-- +-- Define partial indexes to ensure that there is only one active, pending and encrypting config at a time +-- +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_active ON cs_configuration_v1 (state) WHERE state = 'active'; +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_pending ON cs_configuration_v1 (state) WHERE state = 'pending'; +CREATE UNIQUE INDEX IF NOT EXISTS cs_configuration_v1_index_encrypting ON cs_configuration_v1 (state) WHERE state = 'encrypting'; diff --git a/sql/dsl-core.sql b/sql/dsl-core.sql new file mode 100644 index 00000000..faadab81 --- /dev/null +++ b/sql/dsl-core.sql @@ -0,0 +1,177 @@ +DROP CAST IF EXISTS (text AS ore_64_8_v1_term); + +DROP FUNCTION IF EXISTS cs_match_v1; +DROP FUNCTION IF EXISTS cs_match_v1_v0; +DROP FUNCTION IF EXISTS cs_match_v1_v0_0; + +DROP FUNCTION IF EXISTS cs_unique_v1; +DROP FUNCTION IF EXISTS cs_unique_v1_v0; +DROP FUNCTION IF EXISTS cs_unique_v1_v0_0; + +DROP FUNCTION IF EXISTS cs_ore_64_8_v1; +DROP FUNCTION IF EXISTS cs_ore_64_8_v1_v0; +DROP FUNCTION IF EXISTS cs_ore_64_8_v1_v0_0; + +DROP FUNCTION IF EXISTS _cs_text_to_ore_64_8_v1_term_v1_0; + +DROP DOMAIN IF EXISTS cs_match_index_v1; +DROP DOMAIN IF EXISTS cs_unique_index_v1; + +CREATE DOMAIN cs_match_index_v1 AS smallint[]; +CREATE DOMAIN cs_unique_index_v1 AS text; +CREATE DOMAIN cs_ste_vec_index_v1 AS text[]; + +-- cs_encrypted_v1 is a column type and cannot be dropped if in use +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_encrypted_v1') THEN + CREATE DOMAIN cs_encrypted_v1 AS JSONB; + END IF; +END +$$; + +DROP FUNCTION IF EXISTS _cs_encrypted_check_kind(jsonb); +CREATE FUNCTION _cs_encrypted_check_kind(val jsonb) + RETURNS BOOLEAN +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN (val->>'k' = 'ct' AND val ? 'c') AND NOT val ? 'p'; +END; + + +-- drop and reset the check constraint +ALTER DOMAIN cs_encrypted_v1 DROP CONSTRAINT IF EXISTS cs_encrypted_v1_check; + +ALTER DOMAIN cs_encrypted_v1 + ADD CONSTRAINT cs_encrypted_v1_check CHECK ( + -- version and source are required + VALUE ?& array['v'] AND + + -- table and column + VALUE->'i' ?& array['t', 'c'] AND + + -- plaintext or ciphertext for kind + _cs_encrypted_check_kind(VALUE) + +); + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1_v0_0(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN col->>'c'; +END; + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1_v0(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ciphertext_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_ciphertext_v1(col jsonb) + RETURNS text + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ciphertext_v1_v0_0(col); +END; + +-- extracts match index from an emcrypted column +CREATE OR REPLACE FUNCTION cs_match_v1_v0_0(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT ARRAY(SELECT jsonb_array_elements(col->'m'))::cs_match_index_v1; +END; + +CREATE OR REPLACE FUNCTION cs_match_v1_v0(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_match_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_match_v1(col jsonb) + RETURNS cs_match_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_match_v1_v0_0(col); +END; + +-- extracts unique index from an encrypted column +CREATE OR REPLACE FUNCTION cs_unique_v1_v0_0(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN col->>'u'; +END; + +CREATE OR REPLACE FUNCTION cs_unique_v1_v0(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_unique_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_unique_v1(col jsonb) + RETURNS cs_unique_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_unique_v1_v0_0(col); +END; + +-- extracts json ste_vec index from an encrypted column +CREATE OR REPLACE FUNCTION cs_ste_vec_v1_v0_0(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT ARRAY(SELECT jsonb_array_elements(col->'sv'))::cs_ste_vec_index_v1; +END; + +CREATE OR REPLACE FUNCTION cs_ste_vec_v1_v0(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ste_vec_v1_v0_0(col); +END; + +CREATE OR REPLACE FUNCTION cs_ste_vec_v1(col jsonb) + RETURNS cs_ste_vec_index_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ste_vec_v1_v0_0(col); +END; + +-- casts text to ore_64_8_v1_term (bytea) +CREATE FUNCTION _cs_text_to_ore_64_8_v1_term_v1_0(t text) + RETURNS ore_64_8_v1_term + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN t::bytea; +END; + +-- cast to cleanup ore_64_8_v1 extraction +CREATE CAST (text AS ore_64_8_v1_term) + WITH FUNCTION _cs_text_to_ore_64_8_v1_term_v1_0(text) AS IMPLICIT; + +-- extracts ore index from an encrypted column +CREATE FUNCTION cs_ore_64_8_v1_v0_0(val jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT (val->>'o')::ore_64_8_v1; +END; + +CREATE FUNCTION cs_ore_64_8_v1_v0(col jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ore_64_8_v1_v0_0(col); +END; + +CREATE FUNCTION cs_ore_64_8_v1(col jsonb) + RETURNS ore_64_8_v1 + LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE +BEGIN ATOMIC + RETURN cs_ore_64_8_v1_v0_0(col); +END; diff --git a/sql/dsl-encryptindex.sql b/sql/dsl-encryptindex.sql new file mode 100644 index 00000000..30462811 --- /dev/null +++ b/sql/dsl-encryptindex.sql @@ -0,0 +1,174 @@ + +-- DROP and CREATE functions +-- Function types cannot be changed after creation so we DROP for flexibility +DROP FUNCTION IF EXISTS cs_select_pending_columns_v1; +DROP FUNCTION IF EXISTS cs_select_target_columns_v1; +DROP FUNCTION IF EXISTS cs_count_encrypted_with_active_config_v1; +DROP FUNCTION IF EXISTS cs_create_encrypted_columns_v1(); +DROP FUNCTION IF EXISTS cs_rename_encrypted_columns_v1(); + +DROP FUNCTION IF EXISTS _cs_diff_config_v1; +DROP FUNCTION IF EXISTS _cs_table_from_config_key; +DROP FUNCTION IF EXISTS _cs_column_from_config_key; + + +-- Return the diff of two configurations +-- Returns the set of keys in a that have different values to b +-- The json comparison is on object values held by the key +CREATE OR REPLACE FUNCTION _cs_diff_config_v1(a JSONB, b JSONB) + RETURNS TABLE(table_name TEXT, column_name TEXT) +IMMUTABLE STRICT PARALLEL SAFE +AS $$ + BEGIN + RETURN QUERY + WITH table_keys AS ( + SELECT jsonb_object_keys(a->'tables') AS key + UNION + SELECT jsonb_object_keys(b->'tables') AS key + ), + column_keys AS ( + SELECT tk.key AS table_key, jsonb_object_keys(a->'tables'->tk.key) AS column_key + FROM table_keys tk + UNION + SELECT tk.key AS table_key, jsonb_object_keys(b->'tables'->tk.key) AS column_key + FROM table_keys tk + ) + SELECT + ck.table_key AS table_name, + ck.column_key AS column_name + FROM + column_keys ck + WHERE + (a->'tables'->ck.table_key->ck.column_key IS DISTINCT FROM b->'tables'->ck.table_key->ck.column_key); + END; +$$ LANGUAGE plpgsql; + + +-- Returns the set of columns with pending configuration changes +-- Compares the columns in pending configuration that do not match the active config +CREATE FUNCTION cs_select_pending_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT) +AS $$ + DECLARE + active JSONB; + pending JSONB; + config_id BIGINT; + BEGIN + SELECT data INTO active FROM cs_configuration_v1 WHERE state = 'active'; + + -- set default config + IF active IS NULL THEN + active := '{}'; + END IF; + + SELECT id, data INTO config_id, pending FROM cs_configuration_v1 WHERE state = 'pending'; + + -- set default config + IF config_id IS NULL THEN + RAISE EXCEPTION 'No pending configuration exists to encrypt'; + END IF; + + RETURN QUERY + SELECT d.table_name, d.column_name FROM _cs_diff_config_v1(active, pending) as d; + END; +$$ LANGUAGE plpgsql; + +-- +-- Returns the target columns with pending configuration +-- +-- A `pending` column may be either a plaintext variant or cs_encrypted_v1. +-- A `target` column is always of type cs_encrypted_v1 +-- +-- On initial encryption from plaintext the target column will be `{column_name}_encrypted ` +-- OR NULL if the column does not exist +-- +CREATE FUNCTION cs_select_target_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT, target_column TEXT) + STABLE STRICT PARALLEL SAFE +AS $$ + SELECT + c.table_name, + c.column_name, + s.column_name as target_column + FROM + cs_select_pending_columns_v1() c + LEFT JOIN information_schema.columns s ON + s.table_name = c.table_name AND + (s.column_name = c.table_name OR s.column_name = c.column_name || '_encrypted') AND + s.domain_name = 'cs_encrypted_v1'; +$$ LANGUAGE sql; + + +-- +-- Returns true if all pending columns have a target (encrypted) column +CREATE FUNCTION cs_ready_for_encryption_v1() + RETURNS BOOLEAN + STABLE STRICT PARALLEL SAFE +AS $$ + SELECT EXISTS ( + SELECT * + FROM cs_select_target_columns_v1() AS c + WHERE c.target_column IS NOT NULL); +$$ LANGUAGE sql; + + +-- +-- Creates cs_encrypted_v1 columns for any plaintext columns with pending configuration +-- The new column name is `{column_name}_encrypted` +-- +-- Executes the ALTER TABLE statement +-- `ALTER TABLE {target_table} ADD COLUMN {column_name}_encrypted cs_encrypted_v1;` +-- +CREATE FUNCTION cs_create_encrypted_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT) +AS $$ + BEGIN + FOR table_name, column_name IN + SELECT c.table_name, (c.column_name || '_encrypted') FROM cs_select_target_columns_v1() AS c WHERE c.target_column IS NULL + LOOP + EXECUTE format('ALTER TABLE %I ADD column %I cs_encrypted_v1', table_name, column_name); + RETURN NEXT; + END LOOP; + END; +$$ LANGUAGE plpgsql; + + +-- +-- Renames plaintext and cs_encrypted_v1 columns created for the initial encryption. +-- The source plaintext column is renamed to `{column_name}_plaintext` +-- The target encrypted column is renamed from `{column_name}_encrypted` to `{column_name}` +-- +-- Executes the ALTER TABLE statements +-- `ALTER TABLE {target_table} RENAME COLUMN {column_name} TO {column_name}_plaintext; +-- `ALTER TABLE {target_table} RENAME COLUMN {column_name}_encrypted TO {column_name};` +-- +CREATE FUNCTION cs_rename_encrypted_columns_v1() + RETURNS TABLE(table_name TEXT, column_name TEXT, target_column TEXT) +AS $$ + BEGIN + FOR table_name, column_name, target_column IN + SELECT * FROM cs_select_target_columns_v1() as c WHERE c.target_column = c.column_name || '_encrypted' + LOOP + EXECUTE format('ALTER TABLE %I RENAME %I TO %I;', table_name, column_name, column_name || '_plaintext'); + EXECUTE format('ALTER TABLE %I RENAME %I TO %I;', table_name, target_column, column_name); + RETURN NEXT; + END LOOP; + END; +$$ LANGUAGE plpgsql; + + +CREATE FUNCTION cs_count_encrypted_with_active_config_v1(table_name TEXT, column_name TEXT) + RETURNS BIGINT +AS $$ +DECLARE + result BIGINT; +BEGIN + EXECUTE format( + 'SELECT COUNT(%I) FROM %s t WHERE %I->>%L = (SELECT id::TEXT FROM cs_configuration_v1 WHERE state = %L)', + column_name, table_name, column_name, 'v', 'active' + ) + INTO result; + RETURN result; +END; +$$ LANGUAGE plpgsql; + diff --git a/sql/dsl-example.sql b/sql/dsl-example.sql new file mode 100644 index 00000000..78362544 --- /dev/null +++ b/sql/dsl-example.sql @@ -0,0 +1,42 @@ +DROP TABLE IF EXISTS users CASCADE; + +CREATE TABLE users +( + id SERIAL, + name text, + name_encrypted cs_encrypted_v1, + PRIMARY KEY(id) +); + +INSERT INTO users (name_encrypted) VALUES (' +{ + "v": 1, + "s": { + "k": "ct", + "c": "ciphertext", + "e": { + "t": "table", + "c": "column" + }, + "m": [42], + "u": "unique", + "o": ["a","b","c"] + }, + "t": { + "k": "pt", + "p": "plaintext", + "e": { + "t": "table", + "c": "column" + }, + "m": [42], + "u": "unique" + } +}'::cs_encrypted_v1); + + +SELECT id, cs_ciphertext_v1(name_encrypted) FROM users +WHERE + cs_unique_v1(name_encrypted) = 'unique' AND + cs_match_v1(name_encrypted) @> '{42}'; + diff --git a/sql/payload-examples.md b/sql/payload-examples.md new file mode 100644 index 00000000..c9fb450a --- /dev/null +++ b/sql/payload-examples.md @@ -0,0 +1,87 @@ + +## Minimal Plaintext + +``` +{ + "v": 1, + "s": { + "k": "pt", + "p": "plaintext string", + "e": { + "t": "users", + "c": "name_encrypted" + } + } +} +``` + + +INSERT INTO users (name_encrypted) VALUES (' +{ + "v": 1, + "s": { + "k": "ct", + "c": "ciphertext", + "e": { + "t": "table", + "c": "column" + }, + "m": [42], + "u": "unique", + "o": ["a","b","c"] + }, + "t": { + "k": "pt", + "p": "plaintext", + "e": { + "t": "table", + "c": "column" + }, + "m": [42], + "u": "unique" + } +}'::cs_encrypted_v1); + + + + +## Minimal Ciphertext + +``` +{ + "v": 1, + "s": { + "k": "ct", + "c": "XvfWQUrSxKNhkOxiMXvgvkwxIYFfnYTb", + "e": { + "t": "users", + "c": "name_encrypted" + } + } +} +``` + + +## Embedded + +``` +{ + "v": 1, + "s": { + "k": "ct", + "c": "XvfWQUrSxKNhkOxiMXvgvkwxIYFfnYTb", + "e": { + "t": "users", + "c": "name_encrypted" + } + } + "t": { + "k": "pt", + "p": "plaintext string", + "e": { + "t": "users", + "c": "name" + } + } +} +``` \ No newline at end of file diff --git a/tests/config.sql b/tests/config.sql new file mode 100644 index 00000000..d094d6a8 --- /dev/null +++ b/tests/config.sql @@ -0,0 +1,285 @@ +\set ON_ERROR_STOP on + + + + +-- +-- Helper function for assertions +-- +DROP FUNCTION IF EXISTS _index_exists(text, text, text); +CREATE FUNCTION _index_exists(table_name text, column_name text, index_name text, state text DEFAULT 'pending') + RETURNS boolean +LANGUAGE sql STRICT PARALLEL SAFE +BEGIN ATOMIC + SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = state AND + c.data #> array['tables', table_name, column_name, 'indexes'] ? index_name); +END; + + +-- ----------------------------------------------- +-- Add and remove multiple indexes +-- +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + + +DO $$ + BEGIN + + -- Add indexes + PERFORM cs_add_index_v1('users', 'name', 'match'); + ASSERT (SELECT _index_exists('users', 'name', 'match')); + + -- Add index with cast + PERFORM cs_add_index_v1('users', 'name', 'unique', 'int'); + ASSERT (SELECT _index_exists('users', 'name', 'unique')); + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'users', 'name'] ? 'cast_as')); + + -- Match index removed + PERFORM cs_remove_index_v1('users', 'name', 'match'); + ASSERT NOT (SELECT _index_exists('users', 'name', 'match')); + + -- All indexes removed, delete the emtpty pending config + PERFORM cs_remove_index_v1('users', 'name', 'unique'); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + + END; +$$ LANGUAGE plpgsql; + + + +-- ----------------------------------------------- +-- Add and remove multiple indexes from multiple tables +-- +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + + +DO $$ + BEGIN + + -- Add indexes + PERFORM cs_add_index_v1('users', 'name', 'match'); + ASSERT (SELECT _index_exists('users', 'name', 'match')); + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'users', 'name', 'indexes'] ? 'match')); + + -- Add index with cast + PERFORM cs_add_index_v1('blah', 'vtha', 'unique', 'int'); + ASSERT (SELECT _index_exists('blah', 'vtha', 'unique')); + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'users', 'name', 'indexes'] ? 'match')); + + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'blah', 'vtha', 'indexes'] ? 'unique')); + + + -- Match index removed + PERFORM cs_remove_index_v1('users', 'name', 'match'); + ASSERT NOT (SELECT _index_exists('users', 'name', 'match')); + + -- Match index removed + PERFORM cs_remove_index_v1('blah', 'vtha', 'unique'); + ASSERT NOT (SELECT _index_exists('users', 'vtha', 'unique')); + + -- All indexes removed, delete the emtpty pending config + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + + END; +$$ LANGUAGE plpgsql; + +SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending'; + + +-- ----------------------------------------------- +-- Add & modify index +-- Pending configuration created and contains the path `user/name.match.option` +-- ----------------------------------------------- +-- TRUNCATE TABLE cs_configuration_v1; + + +DO $$ + BEGIN + PERFORM cs_add_index_v1('users', 'name', 'match'); + ASSERT (SELECT _index_exists('users', 'name', 'match')); + + -- Pending configuration contains the path `user/name.match.option` + PERFORM cs_modify_index_v1('users', 'name', 'match', 'int', '{"option": "value"}'::jsonb); + ASSERT (SELECT _index_exists('users', 'name', 'match')); + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'users', 'name', 'indexes', 'match'] ? 'option')); + + ASSERT (SELECT EXISTS (SELECT id FROM cs_configuration_v1 c + WHERE c.state = 'pending' AND + c.data #> array['tables', 'users', 'name'] ? 'cast_as')); + + -- All indexes removed, delete the emtpty pending config + PERFORM cs_remove_index_v1('users', 'name', 'match'); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + END; +$$ LANGUAGE plpgsql; + + +-- -- ----------------------------------------------- +-- -- With existing active config +-- -- Adding an index creates a new pending configuration +-- -- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +-- create an active configuration +INSERT INTO cs_configuration_v1 (state, data) VALUES ( + 'active', + '{ + "v": 1, + "tables": { + "users": { + "blah": { + "cast_as": "text", + "indexes": { + "match": {} + } + } + } + } + }'::jsonb +); + +-- An encrypting config should exist +DO $$ + BEGIN + ASSERT (SELECT _index_exists('users', 'blah', 'match', 'active')); + + PERFORM cs_add_index_v1('users', 'name', 'match'); + + -- index added to name + ASSERT (SELECT _index_exists('users', 'name', 'match' )); + + -- pending is a copy of the active config + -- and the active index still exists + ASSERT (SELECT _index_exists('users', 'blah', 'match')); + + END; +$$ LANGUAGE plpgsql; + + +-- -- ----------------------------------------------- +-- -- Add and remove column +-- -- +-- -- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; +DO $$ + BEGIN + -- Create pending configuration + PERFORM cs_add_column_v1('user', 'name'); + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + + PERFORM cs_remove_column_v1('user', 'name'); + + -- Config now empty and removed + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + END; +$$ LANGUAGE plpgsql; + +-- ----------------------------------------------- +--- +-- cs_configuration_v1 tyoe +-- Validate configuration schema +-- Try and insert many invalid configurations +-- None should exist +-- +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +\set ON_ERROR_STOP off +\set ON_ERROR_ROLLBACK on + +DO $$ + BEGIN + RAISE NOTICE 'Configuration tests: 4 errors expected'; + END; +$$ LANGUAGE plpgsql; +-- +-- No schema version +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "tables": { + "users": { + "blah": { + "cast_as": "text", + "indexes": {} + } + } + } + }'::jsonb +); + +-- +-- Empty tables +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "v": 1, + "tables": {} + }'::jsonb +); + + +-- +-- invalid cast +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "v": 1, + "tables": { + "users": { + "blah": { + "cast_as": "regex" + } + } + } + }'::jsonb +); + +-- +-- invalid index +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "v": 1, + "tables": { + "users": { + "blah": { + "cast_as": "text", + "indexes": { + "blah": {} + } + } + } + } + }'::jsonb +); + + +-- Pending configuration should not be created; +DO $$ + BEGIN + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + END; +$$ LANGUAGE plpgsql; + + +\set ON_ERROR_STOP on +\set ON_ERROR_ROLLBACK off + + + + diff --git a/tests/core.sql b/tests/core.sql new file mode 100644 index 00000000..5480512d --- /dev/null +++ b/tests/core.sql @@ -0,0 +1,179 @@ +\set ON_ERROR_STOP on + +-- Create a table with a plaintext column +DROP TABLE IF EXISTS users; +CREATE TABLE users +( + id bigint GENERATED ALWAYS AS IDENTITY, + name_encrypted cs_encrypted_v1, + PRIMARY KEY(id) +); + + +TRUNCATE TABLE users; + +-- no version +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "k": "ct", + "c": "ciphertext", + "i": { + "t": "users", + "c": "name" + }, + "m": [1, 1], + "u": "text", + "o": ["a"] + }'::jsonb +); + +DO $$ + BEGIN + + ASSERT (SELECT EXISTS (SELECT id FROM users WHERE cs_ciphertext_v1(name_encrypted) = 'ciphertext')); + + ASSERT (SELECT EXISTS (SELECT id FROM users WHERE cs_match_v1(name_encrypted) = '{1,1}')); + + ASSERT (SELECT EXISTS (SELECT id FROM users WHERE cs_unique_v1(name_encrypted) = 'text')); + + -- ORE PAYLOAD ABOUT TO CHANGE + -- ASSERT (SELECT EXISTS (SELECT id FROM users WHERE cs_ore_64_8_v1(name_encrypted) = '{a}')); + + END; +$$ LANGUAGE plpgsql; + + +TRUNCATE TABLE users; + +INSERT INTO users DEFAULT VALUES; + +SELECT id FROM users; + +DO $$ + BEGIN + ASSERT (SELECT EXISTS (SELECT id FROM users)); + END; +$$ LANGUAGE plpgsql; + + +-- ----------------------------------------------- +--- +-- cs_enncrypted)v1 tyoe +-- Validate configuration schema +-- Try and insert many invalid configurations +-- None should exist +-- +-- ----------------------------------------------- +TRUNCATE TABLE users; + +\set ON_ERROR_STOP off +\set ON_ERROR_ROLLBACK on + + +-- no version +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "k": "ct", + "c": "ciphertext", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + +-- no source detauils +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "k": "ct", + "c": "ciphertext" + }'::jsonb +); + +-- pt +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "v": 1, + "k": "pt", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + +--pt with ciphertext +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "v": 1, + "k": "pt", + "c": "ciphertext", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + + +-- ct without ciphertext +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "v": 1, + "k": "ct", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + + +-- ct with plaintext +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "v": 1, + "k": "ct", + "p": "plaintext", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + + +-- ciphertext without ct +INSERT INTO users (name_encrypted) VALUES ( + '{ + "v": 1, + "v": 1, + "c": "ciphertext", + "i": { + "t": "users", + "c": "name" + } + }'::jsonb +); + +-- Nothing should be in the DB +DO $$ + BEGIN + ASSERT (SELECT NOT EXISTS (SELECT * FROM users c)); + END; +$$ LANGUAGE plpgsql; + + +\set ON_ERROR_STOP on +\set ON_ERROR_ROLLBACK off + + + + diff --git a/tests/encryptindex.sql b/tests/encryptindex.sql new file mode 100644 index 00000000..38874e85 --- /dev/null +++ b/tests/encryptindex.sql @@ -0,0 +1,250 @@ +\set ON_ERROR_STOP on + +-- ----------------------------------------------- +-- +-- Alter table from config +-- +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +-- Create a table with a plaintext column +DROP TABLE IF EXISTS users; +CREATE TABLE users +( + id bigint GENERATED ALWAYS AS IDENTITY, + name TEXT, + PRIMARY KEY(id) +); + +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "v": 1, + "tables": { + "users": { + "name": { + "cast_as": "text", + "indexes": { + "ore": {} + } + } + } + } + }'::jsonb +); + +DO $$ + BEGIN + + -- the column is pending encryptindexing + ASSERT (SELECT EXISTS (SELECT * FROM cs_select_pending_columns_v1() AS c WHERE c.column_name = 'name')); + + -- the target column does not exist + ASSERT (SELECT EXISTS (SELECT * FROM cs_select_target_columns_v1() AS c WHERE c.target_column IS NULL)); + + -- Add the vtha_encrypted column to the table + PERFORM cs_create_encrypted_columns_v1(); + + ASSERT (SELECT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'name_encrypted')); + + -- rename columns + PERFORM cs_rename_encrypted_columns_v1(); + + ASSERT (SELECT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'name_plaintext')); + ASSERT (SELECT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'name' and s.domain_name = 'cs_encrypted_v1')); + ASSERT (SELECT NOT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'name_encrypted')); + END; +$$ LANGUAGE plpgsql; + + +-- ----------------------------------------------- +-- Create multiple columns +-- +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +-- Create a table with multiple plaintext columns +DROP TABLE IF EXISTS users; +CREATE TABLE users +( + id bigint GENERATED ALWAYS AS IDENTITY, + name TEXT, + email INT, + PRIMARY KEY(id) +); + +INSERT INTO cs_configuration_v1 (data) VALUES ( + '{ + "v": 1, + "tables": { + "users": { + "name": { + "cast_as": "text", + "indexes": { + "ore": {}, + "unique": {} + } + }, + "email": { + "cast_as": "text", + "indexes": { + "match": {} + } + } + } + } + }'::jsonb +); + +DO $$ + BEGIN + + -- the column is pending encryptindexing + ASSERT (SELECT EXISTS (SELECT * FROM cs_select_pending_columns_v1() AS c WHERE c.column_name = 'name')); + + -- the target column does not exisgt + ASSERT (SELECT EXISTS (SELECT * FROM cs_select_target_columns_v1() AS c WHERE c.target_column IS NULL)); + + -- create column + PERFORM cs_create_encrypted_columns_v1(); + + ASSERT (SELECT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'name_encrypted')); + ASSERT (SELECT EXISTS (SELECT * FROM information_schema.columns s WHERE s.column_name = 'email_encrypted')); + END; +$$ LANGUAGE plpgsql; + + +-- ----------------------------------------------- +-- Start encryptindexing +-- The schema is validated first. +-- The pending config should now be encrypting +-- ----------------------------------------------- +DROP TABLE IF EXISTS users; +TRUNCATE TABLE cs_configuration_v1; + +-- SELECT cs_add_index_v1('users', 'name', 'match'); +-- SELECT cs_encrypt_v1(); + +-- SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending'; + +DO $$ + BEGIN + PERFORM cs_add_index_v1('users', 'name', 'match'); + + BEGIN + PERFORM cs_encrypt_v1(); + ASSERT false; -- skipped by exception + EXCEPTION + WHEN OTHERS THEN + ASSERT true; + END; + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'encrypting')); + + END; +$$ LANGUAGE plpgsql; + + + +-- ----------------------------------------------- +-- With existing active config +-- and an updated schema +-- Start encryptindexing +-- The active config is unchanged +-- The pending config should now be encrypting +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +-- create an active configuration +INSERT INTO cs_configuration_v1 (state, data) VALUES ( + 'active', + '{ + "v": 1, + "tables": { + "users": { + "name": { + "cast_as": "text", + "indexes": { + "unique": {} + } + } + } + } + }'::jsonb +); + +-- Create a table with multiple plaintext columns +DROP TABLE IF EXISTS users; +CREATE TABLE users +( + id bigint GENERATED ALWAYS AS IDENTITY, + name TEXT, + name_encrypted cs_encrypted_v1, + PRIMARY KEY(id) +); + + +-- An encrypting config should exist +DO $$ + BEGIN + PERFORM cs_add_index_v1('users', 'name', 'match'); + PERFORM cs_encrypt_v1(); + + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'active')); + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'encrypting')); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + END; +$$ LANGUAGE plpgsql; + + +-- ----------------------------------------------- +-- With existing active config +-- Activate encrypting config +-- The active config is now inactive +-- The encrypting config should now be active +-- ----------------------------------------------- +TRUNCATE TABLE cs_configuration_v1; + +-- create an active configuration +INSERT INTO cs_configuration_v1 (state, data) VALUES ( + 'active', + '{ + "v": 1, + "tables": { + "users": { + "name": { + "cast_as": "text", + "indexes": { + "unique": {} + } + } + } + } + }'::jsonb +); + + +-- Create a table with multiple plaintext columns +DROP TABLE IF EXISTS users; +CREATE TABLE users +( + id bigint GENERATED ALWAYS AS IDENTITY, + name TEXT, + name_encrypted cs_encrypted_v1, + PRIMARY KEY(id) +); + +-- An encrypting config should exist +DO $$ + BEGIN + PERFORM cs_add_index_v1('users', 'name', 'match'); + + PERFORM cs_encrypt_v1(); -- need to encrypt first + PERFORM cs_activate_v1(); + + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'active')); + ASSERT (SELECT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'inactive')); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'encrypting')); + ASSERT (SELECT NOT EXISTS (SELECT FROM cs_configuration_v1 c WHERE c.state = 'pending')); + + END; +$$ LANGUAGE plpgsql;