|
| 1 | +DROP DOMAIN IF EXISTS cs_match_index_v1; |
| 2 | +CREATE DOMAIN cs_match_index_v1 AS smallint[]; |
| 3 | + |
| 4 | +DROP DOMAIN IF EXISTS cs_unique_index_v1; |
| 5 | +CREATE DOMAIN cs_unique_index_v1 AS text; |
| 6 | + |
| 7 | + |
| 8 | +-- cs_encrypted_v1 is a column type and cannot be dropped if in use |
| 9 | +DO $$ |
| 10 | +BEGIN |
| 11 | + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'cs_encrypted_v1') THEN |
| 12 | + CREATE DOMAIN cs_encrypted_v1 AS JSONB; |
| 13 | + END IF; |
| 14 | +END |
| 15 | +$$; |
| 16 | + |
| 17 | + |
| 18 | +-- Should include a kind field |
| 19 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_k(jsonb); |
| 20 | +CREATE FUNCTION _cs_encrypted_check_k(val jsonb) |
| 21 | + RETURNS boolean |
| 22 | +AS $$ |
| 23 | + BEGIN |
| 24 | + IF (val->>'k' = ANY('{ct, sv}')) THEN |
| 25 | + RETURN true; |
| 26 | + END IF; |
| 27 | + RAISE 'Invalid kind (%) in Encrypted column. Kind should be one of {ct, sv}', val; |
| 28 | + END; |
| 29 | +$$ LANGUAGE plpgsql; |
| 30 | + |
| 31 | + |
| 32 | +-- |
| 33 | +-- CT payload should include a c field |
| 34 | +-- |
| 35 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_k_ct(jsonb); |
| 36 | +CREATE FUNCTION _cs_encrypted_check_k_ct(val jsonb) |
| 37 | + RETURNS boolean |
| 38 | +AS $$ |
| 39 | + BEGIN |
| 40 | + IF (val->>'k' = 'ct') THEN |
| 41 | + IF (val ? 'c') THEN |
| 42 | + RETURN true; |
| 43 | + END IF; |
| 44 | + RAISE 'Encrypted column kind (k) of "ct" missing data field (c): %', val; |
| 45 | + END IF; |
| 46 | + RETURN true; |
| 47 | + END; |
| 48 | +$$ LANGUAGE plpgsql; |
| 49 | + |
| 50 | + |
| 51 | +-- |
| 52 | +-- SV payload should include an sv field |
| 53 | +-- |
| 54 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_k_sv(jsonb); |
| 55 | +CREATE FUNCTION _cs_encrypted_check_k_sv(val jsonb) |
| 56 | + RETURNS boolean |
| 57 | +AS $$ |
| 58 | + BEGIN |
| 59 | + IF (val->>'k' = 'sv') THEN |
| 60 | + IF (val ? 'sv') THEN |
| 61 | + RETURN true; |
| 62 | + END IF; |
| 63 | + RAISE 'Encrypted column kind (k) of "sv" missing data field (sv): %', val; |
| 64 | + END IF; |
| 65 | + RETURN true; |
| 66 | + END; |
| 67 | +$$ LANGUAGE plpgsql; |
| 68 | + |
| 69 | + |
| 70 | +-- Plaintext field should never be present in an encrypted column |
| 71 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_p(jsonb); |
| 72 | +CREATE FUNCTION _cs_encrypted_check_p(val jsonb) |
| 73 | + RETURNS boolean |
| 74 | +AS $$ |
| 75 | + BEGIN |
| 76 | + IF NOT val ? 'p' THEN |
| 77 | + RETURN true; |
| 78 | + END IF; |
| 79 | + RAISE 'Encrypted column includes plaintext (p) field: %', val; |
| 80 | + END; |
| 81 | +$$ LANGUAGE plpgsql; |
| 82 | + |
| 83 | +-- Should include an ident field |
| 84 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_i(jsonb); |
| 85 | +CREATE FUNCTION _cs_encrypted_check_i(val jsonb) |
| 86 | + RETURNS boolean |
| 87 | +AS $$ |
| 88 | + BEGIN |
| 89 | + IF val ? 'i' THEN |
| 90 | + RETURN true; |
| 91 | + END IF; |
| 92 | + RAISE 'Encrypted column missing ident (i) field: %', val; |
| 93 | + END; |
| 94 | +$$ LANGUAGE plpgsql; |
| 95 | + |
| 96 | +-- Query field should never be present in an encrypted column |
| 97 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_q(jsonb); |
| 98 | +CREATE FUNCTION _cs_encrypted_check_q(val jsonb) |
| 99 | + RETURNS boolean |
| 100 | +AS $$ |
| 101 | + BEGIN |
| 102 | + IF val ? 'q' THEN |
| 103 | + RAISE 'Encrypted column includes query (q) field: %', val; |
| 104 | + END IF; |
| 105 | + RETURN true; |
| 106 | + END; |
| 107 | +$$ LANGUAGE plpgsql; |
| 108 | + |
| 109 | +-- Ident field should include table and column |
| 110 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_i_ct(jsonb); |
| 111 | +CREATE FUNCTION _cs_encrypted_check_i_ct(val jsonb) |
| 112 | + RETURNS boolean |
| 113 | +AS $$ |
| 114 | + BEGIN |
| 115 | + IF (val->'i' ?& array['t', 'c']) THEN |
| 116 | + RETURN true; |
| 117 | + END IF; |
| 118 | + RAISE 'Encrypted column ident (i) missing table (t) or column (c) fields: %', val; |
| 119 | + END; |
| 120 | +$$ LANGUAGE plpgsql; |
| 121 | + |
| 122 | +-- Should include a version field |
| 123 | +DROP FUNCTION IF EXISTS _cs_encrypted_check_v(jsonb); |
| 124 | +CREATE FUNCTION _cs_encrypted_check_v(val jsonb) |
| 125 | + RETURNS boolean |
| 126 | +AS $$ |
| 127 | + BEGIN |
| 128 | + IF (val ? 'v') THEN |
| 129 | + RETURN true; |
| 130 | + END IF; |
| 131 | + RAISE 'Encrypted column missing version (v) field: %', val; |
| 132 | + END; |
| 133 | +$$ LANGUAGE plpgsql; |
| 134 | + |
| 135 | + |
| 136 | +DROP FUNCTION IF EXISTS cs_check_encrypted_v1(val jsonb); |
| 137 | + |
| 138 | +CREATE FUNCTION cs_check_encrypted_v1(val jsonb) |
| 139 | + RETURNS BOOLEAN |
| 140 | +LANGUAGE sql IMMUTABLE STRICT PARALLEL SAFE |
| 141 | +BEGIN ATOMIC |
| 142 | + RETURN ( |
| 143 | + _cs_encrypted_check_v(val) AND |
| 144 | + _cs_encrypted_check_i(val) AND |
| 145 | + _cs_encrypted_check_k(val) AND |
| 146 | + _cs_encrypted_check_k_ct(val) AND |
| 147 | + _cs_encrypted_check_k_sv(val) AND |
| 148 | + _cs_encrypted_check_q(val) AND |
| 149 | + _cs_encrypted_check_p(val) |
| 150 | + ); |
| 151 | +END; |
| 152 | + |
| 153 | +ALTER DOMAIN cs_encrypted_v1 DROP CONSTRAINT IF EXISTS cs_encrypted_v1_check; |
| 154 | + |
| 155 | +ALTER DOMAIN cs_encrypted_v1 |
| 156 | + ADD CONSTRAINT cs_encrypted_v1_check CHECK ( |
| 157 | + cs_check_encrypted_v1(VALUE) |
| 158 | +); |
| 159 | + |
0 commit comments