From 9995c6c7eb8d36b95fc8534f2d1ab17b341a69bf Mon Sep 17 00:00:00 2001 From: CJ Brewer Date: Wed, 2 Oct 2024 17:20:25 -0600 Subject: [PATCH 1/4] feat: organize and update readme --- README.md | 327 ++++++------ src/install.sql | 1258 +++++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 1439 insertions(+), 146 deletions(-) create mode 100644 src/install.sql diff --git a/README.md b/README.md index 8c34b176..fec26d91 100644 --- a/README.md +++ b/README.md @@ -1,36 +1,49 @@ # CipherStash Encrypt Query Language (EQL) - Encrypt Query Language (EQL) is a set of abstractions for transmitting, storing & interacting with encrypted data and indexes in PostgreSQL. -EQL provides: +EQL provides a data format for transmitting and storing encrypted data & indexes, and database types & functions to interact with the encrypted material. -- a data format for transmitting and storing encrypted data & indexes -- database types & functions to interact with the encrypted material +## 1. Encryption in use -EQL relies on [Cipherstash Encrypt](https://cipherstash.com/docs/getting-started/cipherstash-encrypt) and [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) for low-latency encryption & decryption. +EQL enables encryption in use, without significant changes to your application code. +A variety of searchable encryption techniques are available, including: -As well as basic encryption of data, Cipherstash Proxy supports a variety of encrypted indexes that enable: +- Matching (`a == b` or `a LIKE b`) +- Comparison using order revealing encryption (`a < b`) +- Enforcing unique constraints (`there is only a`) -- matching (`a == b` or `a LIKE b`) -- comparison using order revealing encryption (`a < b`) -- enforcing unique constraints (`there is only a`) +### 1.1 What is encryption in use? +Encryption in use is the practice of keeping data encrypted even while it's being processed or queried in the database. +Unlike traditional encryption methods that secure data only at rest (on disk) or in transit (over the network), encryption in use keeps the data encrypted while operations are being performed on the data. +This provides an additional layer of security against unauthorized access — an adversary needs access to the encrypted data _and_ encryption keys. -Example SQL statements using EQL: -```SQL --- select using an encrypted match comparison -SELECT cs_ciphertext_v1(name) -FROM users -WHERE cs_match_v1(name) @> $2; +### 1.2 Why use encryption in use? --- insert using jsonb payload -INSERT INTO users (name) VALUES ({"p": "plaintext"}); -``` +While encryption at rest and in transit are essential, they don't protect data when the database server itself is compromised. +Encryption in use mitigates this risk by ensuring that: + +- **Data remains secure**: Even if the database server is breached, the data remains encrypted and unreadable without the proper keys. +- **Compliance controls are stronger**: When you need stronger data security controls than what SOC2/SOC3 or ISO27001 mandate, encryption in use helps you meet those stringent requirements. + +## 2. CipherStash Proxy +### 2.1 Overview +CipherStash Proxy is a transparent proxy that sits between your application and your PostgreSQL database. +It intercepts SQL queries and handles the encryption and decryption of data on-the-fly. +This enables encryption in use without significant changes to your application code. -## How EQL works with CipherStash Proxy +### 2.2 How it works + +- **Intercepts queries**: CipherStash Proxy captures SQL statements from the client application. +- **Encrypts data**: For write operations, it encrypts the plaintext data before sending it to the database. +- **Decrypts data**: For read operations, it decrypts the encrypted data retrieved from the database before returning it to the client. +- **Maintains searchability**: Ensures that the encrypted data is searchable and retrievable without sacrificing performance or application functionality. +- **Manages encryption keys**: Securely handles encryption keys required for encrypting and decrypting data. + +### 2.3 How EQL works with CipherStash Proxy EQL uses **CipherStash Proxy** to mediate access to your PostgreSQL database and provide low-latency encryption & decryption. @@ -40,112 +53,59 @@ At a high level: - references to the column in sql statements are wrapped in a helper function - Cipherstash Proxy transparently encrypts and indexes data - - -### Writes +#### 2.3.1 Writes 1. Database client sends `plaintext` data encoded as `jsonb` 2. CipherStash Proxy encrypts the `plaintext` and encodes the `ciphertext` value and associated indexes into the `jsonb` payload 3. The data is written to the encrypted column - ![Insert](/diagrams/overview-insert.drawio.svg) - - -### Reads +#### 2.3.2 Reads 1. Wrap references to the encrypted column in the appropriate EQL function 3. CipherStash Proxy encrypts the `plaintext` 4. PostgreSQL executes the SQL statement 5. CipherStash Proxy decrypts any returned `ciphertext` data and returns to client - ![Select](/diagrams/overview-select.drawio.svg) +## 3. Encrypt Query Language (EQL) -## Getting started - +Before you get started, it's important to understand some of the key components of EQL. -1. Setup - 1. Configure & run [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) - 2. Install EQL -2. Add an index -3. Add an encrypted column -6. Run Cipherstash Proxy +### 3.1 Encrypted columns +Encrypted columns are defined using the `cs_encrypted_v1` domain type, which extends the `jsonb` type with additional constraints to ensure data integrity. -### Add an index - -Cipherstash Proxy supports three types of indexes: - -- match -- ore (order revealing encryption) -- unique - -Indexes are managed using EQL functions and can be baked into an existing database migration process. +**Example table definition:** ```sql - --- Add an ore index to users.name -cs_add_index('users', 'name', 'ore'); - --- Remove an ore index from users.name -cs_remove_index('users', 'name', 'ore'); -``` - - -Adding the index to your configuration does not *encrypt* the data. - -The encryption process needs to update every row in the target table. -Depending on the size of the target table, this process can be long-running. - -{{LINK TO MIGRATOR DETAILS HERE}} - - -### Add an encrypted column - - -```SQL --- Alter tables from the configuration -cs_create_encrypted_columns_v1() - --- Explicit alter table -ALTER TABLE users ADD column name_encrypted cs_encrypted_v1; -``` - - - -## Components - -### Encrypted columns - -An encrypted column should be defined as the `cs_encrypted_v1` [Domain Type](https://www.postgresql.org/docs/current/domains.html). - -The `cs_encrypted_v1` type is based on the PostgreSQL `jsonb` type and adds a check constraint to verify the schema (see below for details). - -Example table definition: - -```SQL -CREATE TABLE users -( - id bigint GENERATED ALWAYS AS IDENTITY, - name_encrypted cs_encrypted_v1, - PRIMARY KEY(id) +CREATE TABLE users ( + id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, + name_encrypted cs_encrypted_v1 ); ``` +### 3.2 EQL functions +EQL provides specialized functions to interact with encrypted data: +- **`cs_ciphertext_v1(val JSONB)`**: Extracts the ciphertext for decryption by CipherStash Proxy. +- **`cs_match_v1(val JSONB)`**: Retrieves the match index for equality comparisons. +- **`cs_unique_v1(val JSONB)`**: Retrieves the unique index for enforcing uniqueness. +- **`cs_ore_v1(val JSONB)`**: Retrieves the Order-Revealing Encryption index for range queries. -### Index Functions +#### 3.2.1 Index functions -Functions expect a `jsonb` value that conforms to the storage schema. +These Functions expect a `jsonb` value that conforms to the storage schema. +##### 3.2.1.1 cs_add_index -```SQL +```sql cs_add_index(table_name text, column_name text, index_name text, cast_as text, opts jsonb) ``` + | Parameter | Description | Notes | ------------- | -------------------------------------------------- | ------------------------------------ | table_name | Name of target table | Required @@ -155,7 +115,7 @@ cs_add_index(table_name text, column_name text, index_name text, cast_as text, o | opts | Index options | Optional for `match` indexes (see below) -#### cast_as +###### cast_as Supported types: - text @@ -166,7 +126,7 @@ Supported types: - date -#### match opts +###### match opts Default Match index options: @@ -185,59 +145,94 @@ Default Match index options: } ``` +##### 3.2.1.2 cs_modify_index -```SQL +```sql cs_modify_index(table_name text, column_name text, index_name text, cast_as text, opts jsonb) ``` + Modifies an existing index configuration. Accepts the same parameters as `cs_add_index` +##### 3.2.1.3 cs_remove_index -```SQL +```sql cs_remove_index(table_name text, column_name text, index_name text) ``` -Removes an index configuration from the column. - - +Removes an index configuration from the column. -### Query Functions +### 3.3 Query Functions -Functions expect a `jsonb` value that conforms to the storage schema. +These Functions expect a `jsonb` value that conforms to the storage schema, and are used to perform search operations. +#### 3.3.1 cs_ciphertext_v1 -```SQL +```sql cs_ciphertext_v1(val jsonb) ``` + Extracts the ciphertext from the `jsonb` value. Ciphertext values are transparently decrypted in transit by Cipherstash Proxy. +#### 3.3.2 cs_match_v1 -```SQL +```sql cs_match_v1(val jsonb) ``` + Extracts a match index from the `jsonb` value. Returns `null` if no match index is present. +#### 3.3.3 cs_unique_v1 -```SQL +```sql cs_unique_v1(val jsonb) ``` + Extracts a unique index from the `jsonb` value. Returns `null` if no unique index is present. +#### 3.3.4 cs_ore_v1 -```SQL +```sql cs_ore_v1(val jsonb) ``` + Extracts an ore index from the `jsonb` value. Returns `null` if no ore index is present. +### 3.4 Data Format + +Encrypted data is stored as `jsonb` with a specific schema: +- **Plaintext Payload (Client Side):** -### Data format + ```json + { + "v": 1, + "k": "pt", + "p": "plaintext value", + "e": { + "t": "table_name", + "c": "column_name" + } + } + ``` -Encrypted columns should be defined as the `cs_encrypted_v1` Domain Type and encrypted data and index values are stored as `jsonb`. +- **Encrypted Payload (Database Side):** + + ```json + { + "v": 1, + "k": "ct", + "c": "ciphertext value", + "e": { + "t": "table_name", + "c": "column_name" + } + } + ``` The format is defined as a [JSON Schema](src/cs_encrypted_v1.schema.json). @@ -257,45 +252,85 @@ Cipherstash proxy handles the encoding, and EQL provides the functions. | o.1 | ORE index | Ciphertext index value. Encrypted by proxy. | u.1 | Uniqueindex | Ciphertext index value. Encrypted by proxy. +#### 3.4.1 Helper packages -```json -// Plaintext -// Sent by client -{ - "v": 1, - "k": "pt", - "p": "column value as plaintext", - "i": { - "t": "users", - "c": "name_encrypted" - } -} - -// Ciphertext -// Encoded for storage by proxy -{ - "v": 1, - "k": "ct", - "c": "XvfWQUrSxKNhkOxiMXvgvkwxIYFfnYTb", - "i": { - "t": "users", - "c": "name_encrypted" - } -} - -// Encryptindexing -// Includes both plaintext and ciphertext -// So original column is kept in sync during initial encryption & migration -{ - "v": 1, - "k": "et", - "p": "plaintext name", - "c": "XvfWQUrSxKNhkOxiMXvgvkwxIYFfnYTb", - "i": { - "t": "users", - "c": "name_encrypted" - } -} +We have created a few langague specific packages to help you interact with the payloads: + +- [@cipherstash/eql](https://github.com/cipherstash/encrypt-query-language/tree/main/javascript/packages/eql): This is a TypeScript implementation of EQL. + +## 4. Getting started + +### 4.1 Prerequisites + +- [PostgreSQL 14+](https://www.postgresql.org/download/) +- [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) +- [Cipherstash Encrypt](https://cipherstash.com/docs/getting-started/cipherstash-encrypt) + +EQL relies on [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) and [Cipherstash Encrypt](https://cipherstash.com/docs/getting-started/cipherstash-encrypt) for low-latency encryption & decryption. +We plan to support direct language integration in the future. + +> Note: An example `dataset.yml` file is provided in the `cipherstash` directory for Encrypt configuration, along with a `start.sh` script to run Cipherstash Proxy locally. +You will need to modify the `dataset.yml` file to match your environment, and copy the `cipherstash/cipherstash-proxy.toml.example` file to `cipherstash/cipherstash-proxy.toml` before running the script. + +### 4.2 Installation + +In order to use EQL, you must first install the EQL extension in your PostgreSQL database. +You can do this by running the following command, which will execute the SQL from the `src/install.sql` file: + +Update the database credentials based on your environment. + +```bash +psql -U postgres -d postgres -f src/install.sql ``` +### 4.3 Add a table with encrypted columns + +Create a table with encrypted columns. +For this example, we'll use the `users` table, with a plaintext `email` column and an encrypted `email_encrypted` column. + +```sql +CREATE TABLE IF NOT EXISTS "users" ( + "id" serial PRIMARY KEY NOT NULL, + "email" varchar, + "email_encrypted" "cs_encrypted_v1" +); +``` + +### 4.4 Add an index for searchability + +EQL supports three types of indexes: + +- match +- ore (order revealing encryption) +- unique + +Indexes are managed using EQL functions and can be baked into an existing database migration process. + +```sql +-- Add an ore index to users.name +cs_add_index('users', 'name', 'ore'); + +-- Remove an ore index from users.name +cs_remove_index('users', 'name', 'ore'); +``` + +Adding the index to your configuration does not *encrypt* the data. + +The encryption process needs to update every row in the target table. +Depending on the size of the target table, this process can be long-running. + +{{LINK TO MIGRATOR DETAILS HERE}} + +### Add an encrypted column + +TODO: Do we need this? + +```SQL +-- Alter tables from the configuration +cs_create_encrypted_columns_v1() + +-- Explicit alter table +ALTER TABLE users ADD column name_encrypted cs_encrypted_v1; +``` +.... more to come \ No newline at end of file diff --git a/src/install.sql b/src/install.sql new file mode 100644 index 00000000..a9a7661e --- /dev/null +++ b/src/install.sql @@ -0,0 +1,1258 @@ +-- +-- PostgreSQL CipherStash Extension +-- + +-- +-- Name: pgcrypto; Type: EXTENSION; Schema: -; Owner: - +-- + +-- CREATE EXTENSION IF NOT EXISTS pgcrypto WITH SCHEMA public; + + +-- +-- Name: ore_64_8_v1_term; Type: TYPE; Schema: public; +-- + +CREATE TYPE public.ore_64_8_v1_term AS ( + bytes bytea +); + +-- +-- Name: ore_64_8_v1; Type: TYPE; Schema: public; +-- + +CREATE TYPE public.ore_64_8_v1 AS ( + terms public.ore_64_8_v1_term[] +); + +-- +-- Name: compare_ore_64_8_v1(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.compare_ore_64_8_v1(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS integer + LANGUAGE plpgsql + AS $$ + DECLARE + cmp_result integer; + BEGIN + -- Recursively compare blocks bailing as soon as we can make a decision + RETURN compare_ore_array(a.terms, b.terms); + END +$$; + +-- +-- Name: compare_ore_64_8_v1_term(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.compare_ore_64_8_v1_term(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS integer + LANGUAGE plpgsql + AS $$ + DECLARE + eq boolean := true; + unequal_block smallint := 0; + hash_key bytea; + target_block bytea; + + left_block_size CONSTANT smallint := 16; + right_block_size CONSTANT smallint := 32; + right_offset CONSTANT smallint := 136; -- 8 * 17 + + indicator smallint := 0; + 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 bit_length(a.bytes) != bit_length(b.bytes) THEN + RAISE EXCEPTION 'Ciphertexts are different lengths'; + END IF; + + FOR block IN 0..7 LOOP + -- Compare each PRP (byte from the first 8 bytes) and PRF block (8 byte + -- chunks of the rest of the value). + -- NOTE: + -- * Substr is ordinally indexed (hence 1 and not 0, and 9 and not 8). + -- * We are not worrying about timing attacks here; don't fret about + -- the OR or !=. + IF + substr(a.bytes, 1 + block, 1) != substr(b.bytes, 1 + block, 1) + OR substr(a.bytes, 9 + left_block_size * block, left_block_size) != substr(b.bytes, 9 + left_block_size * BLOCK, left_block_size) + THEN + -- set the first unequal block we find + IF eq THEN + unequal_block := block; + END IF; + eq = false; + END IF; + END LOOP; + + IF eq THEN + RETURN 0::integer; + END IF; + + -- Hash key is the IV from the right CT of b + hash_key := substr(b.bytes, right_offset + 1, 16); + + -- first right block is at right offset + nonce_size (ordinally indexed) + target_block := substr(b.bytes, right_offset + 17 + (unequal_block * right_block_size), right_block_size); + + indicator := ( + get_bit( + encrypt( + substr(a.bytes, 9 + (left_block_size * unequal_block), left_block_size), + hash_key, + 'aes-ecb' + ), + 0 + ) + get_bit(target_block, get_byte(a.bytes, unequal_block))) % 2; + + IF indicator = 1 THEN + RETURN 1::integer; + ELSE + RETURN -1::integer; + END IF; + END; +$$; + + +-- +-- Name: compare_ore_array(public.ore_64_8_v1_term[], public.ore_64_8_v1_term[]); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.compare_ore_array(a public.ore_64_8_v1_term[], b public.ore_64_8_v1_term[]) RETURNS integer + LANGUAGE plpgsql + AS $$ + DECLARE + cmp_result integer; + BEGIN + IF (array_length(a, 1) = 0 OR a IS NULL) AND (array_length(b, 1) = 0 OR b IS NULL) THEN + RETURN 0; + END IF; + IF array_length(a, 1) = 0 OR a IS NULL THEN + RETURN -1; + END IF; + IF array_length(b, 1) = 0 OR a IS NULL THEN + RETURN 1; + END IF; + + cmp_result := compare_ore_64_8_v1_term(a[1], b[1]); + IF cmp_result = 0 THEN + -- Removes the first element in the array, and calls this fn again to compare the next element/s in the array. + RETURN compare_ore_array(a[2:array_length(a,1)], b[2:array_length(b,1)]); + END IF; + + RETURN cmp_result; + END +$$; + + +-- +-- Name: ore_64_8_v1_eq(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_eq(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) = 0 +$$; + + +-- +-- Name: ore_64_8_v1_gt(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_gt(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) = 1 +$$; + + +-- +-- Name: ore_64_8_v1_gte(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_gte(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) != -1 +$$; + + +-- +-- Name: ore_64_8_v1_lt(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_lt(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) = -1 +$$; + + +-- +-- Name: ore_64_8_v1_lte(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_lte(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) != 1 +$$; + + +-- +-- Name: ore_64_8_v1_neq(public.ore_64_8_v1, public.ore_64_8_v1); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_neq(a public.ore_64_8_v1, b public.ore_64_8_v1) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1(a, b) <> 0 +$$; + + +-- +-- Name: ore_64_8_v1_term_eq(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_eq(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) = 0 +$$; + + +-- +-- Name: ore_64_8_v1_term_gt(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_gt(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) = 1 +$$; + + +-- +-- Name: ore_64_8_v1_term_gte(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_gte(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) != -1 +$$; + + +-- +-- Name: ore_64_8_v1_term_lt(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_lt(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) = -1 +$$; + + +-- +-- Name: ore_64_8_v1_term_lte(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_lte(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) != 1 +$$; + + +-- +-- Name: ore_64_8_v1_term_neq(public.ore_64_8_v1_term, public.ore_64_8_v1_term); Type: FUNCTION; Schema: public; +-- + +CREATE FUNCTION public.ore_64_8_v1_term_neq(a public.ore_64_8_v1_term, b public.ore_64_8_v1_term) RETURNS boolean + LANGUAGE sql + AS $$ + SELECT compare_ore_64_8_v1_term(a, b) <> 0 +$$; + + +-- +-- Name: <; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.< ( + FUNCTION = public.ore_64_8_v1_term_lt, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + COMMUTATOR = OPERATOR(public.>), + NEGATOR = OPERATOR(public.>=), + RESTRICT = scalarltsel, + JOIN = scalarltjoinsel +); + + +-- +-- Name: <; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.< ( + FUNCTION = public.ore_64_8_v1_lt, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + COMMUTATOR = OPERATOR(public.>), + NEGATOR = OPERATOR(public.>=), + RESTRICT = scalarltsel, + JOIN = scalarltjoinsel +); + + +-- +-- Name: <=; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.<= ( + FUNCTION = public.ore_64_8_v1_term_lte, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + COMMUTATOR = OPERATOR(public.>=), + NEGATOR = OPERATOR(public.>), + RESTRICT = scalarlesel, + JOIN = scalarlejoinsel +); + + +-- +-- Name: <=; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.<= ( + FUNCTION = public.ore_64_8_v1_lte, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + COMMUTATOR = OPERATOR(public.>=), + NEGATOR = OPERATOR(public.>), + RESTRICT = scalarlesel, + JOIN = scalarlejoinsel +); + + +-- +-- Name: <>; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.<> ( + FUNCTION = public.ore_64_8_v1_term_neq, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + NEGATOR = OPERATOR(public.=), + MERGES, + HASHES, + RESTRICT = eqsel, + JOIN = eqjoinsel +); + + +-- +-- Name: <>; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.<> ( + FUNCTION = public.ore_64_8_v1_neq, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + NEGATOR = OPERATOR(public.=), + MERGES, + HASHES, + RESTRICT = eqsel, + JOIN = eqjoinsel +); + + +-- +-- Name: =; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.= ( + FUNCTION = public.ore_64_8_v1_term_eq, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + NEGATOR = OPERATOR(public.<>), + MERGES, + HASHES, + RESTRICT = eqsel, + JOIN = eqjoinsel +); + + +-- +-- Name: =; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.= ( + FUNCTION = public.ore_64_8_v1_eq, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + NEGATOR = OPERATOR(public.<>), + MERGES, + HASHES, + RESTRICT = eqsel, + JOIN = eqjoinsel +); + +-- +-- Name: >; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.> ( + FUNCTION = public.ore_64_8_v1_term_gt, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + COMMUTATOR = OPERATOR(public.<), + NEGATOR = OPERATOR(public.<=), + RESTRICT = scalargtsel, + JOIN = scalargtjoinsel +); + + +-- +-- Name: >; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.> ( + FUNCTION = public.ore_64_8_v1_gt, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + COMMUTATOR = OPERATOR(public.<), + NEGATOR = OPERATOR(public.<=), + RESTRICT = scalargtsel, + JOIN = scalargtjoinsel +); + + +-- +-- Name: >=; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.>= ( + FUNCTION = public.ore_64_8_v1_term_gte, + LEFTARG = public.ore_64_8_v1_term, + RIGHTARG = public.ore_64_8_v1_term, + COMMUTATOR = OPERATOR(public.<=), + NEGATOR = OPERATOR(public.<), + RESTRICT = scalarlesel, + JOIN = scalarlejoinsel +); + + +-- +-- Name: >=; Type: OPERATOR; Schema: public; +-- + +CREATE OPERATOR public.>= ( + FUNCTION = public.ore_64_8_v1_gte, + LEFTARG = public.ore_64_8_v1, + RIGHTARG = public.ore_64_8_v1, + COMMUTATOR = OPERATOR(public.<=), + NEGATOR = OPERATOR(public.<), + RESTRICT = scalarlesel, + JOIN = scalarlejoinsel +); + +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; + +-- 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; + +-- 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_1, ore_1, ore_1_term, unique_1}'); +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}'); +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['s', '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_config_default(); +DROP FUNCTION IF EXISTS _cs_config_match_1_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('s', 1, 'tables', '{}') 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_build_object(table_name, '{}') into tbl; + SELECT jsonb_set(config, array['tables'], tbl) 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(column_name, + jsonb_build_object('indexes', json_build_object())) into col; + SELECT jsonb_set(config, array['tables', table_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_1 index +-- +CREATE FUNCTION _cs_config_match_1_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_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}') 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_1' AND opts = '{}' THEN + SELECT _cs_config_match_1_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; + +-- 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; From 87fdc5ff41fdad51e946a93dc9050eee08d22f52 Mon Sep 17 00:00:00 2001 From: CJ Brewer Date: Wed, 2 Oct 2024 19:19:16 -0600 Subject: [PATCH 2/4] feat: add basic getting started guide --- README.md | 112 +++++++++++++++++++++++++++++++++++-------- javascript/bun.lockb | Bin 89496 -> 89496 bytes 2 files changed, 93 insertions(+), 19 deletions(-) diff --git a/README.md b/README.md index fec26d91..ef977f85 100644 --- a/README.md +++ b/README.md @@ -4,6 +4,31 @@ Encrypt Query Language (EQL) is a set of abstractions for transmitting, storing EQL provides a data format for transmitting and storing encrypted data & indexes, and database types & functions to interact with the encrypted material. +## Table of Contents + +- [1. Encryption in use](#1-encryption-in-use) + - [1.1 What is encryption in use?](#11-what-is-encryption-in-use) + - [1.2 Why use encryption in use?](#12-why-use-encryption-in-use) +- [2. CipherStash Proxy](#2-cipherstash-proxy) + - [2.1 Overview](#21-overview) + - [2.2 How it works](#22-how-it-works) + - [2.3 How EQL works with CipherStash Proxy](#23-how-eql-works-with-cipherstash-proxy) + - [2.3.1 Writes](#231-writes) + - [2.3.2 Reads](#232-reads) +- [3. Encrypt Query Language (EQL)](#3-encrypt-query-language-eql) + - [3.1 Encrypted columns](#31-encrypted-columns) + - [3.2 EQL functions](#32-eql-functions) + - [3.3 Index functions](#321-index-functions) + - [3.3 Query Functions](#33-query-functions) + - [3.4 Data Format](#34-data-format) + - [3.4.1 Helper packages](#341-helper-packages) +- [4. Getting started](#4-getting-started) + - [4.1 Prerequisites](#41-prerequisites) + - [4.2 Installation](#42-installation) + - [4.3 Add a table with encrypted columns](#43-add-a-table-with-encrypted-columns) + - [4.4 Inserting data](#44-inserting-data) + - [4.5 Querying data](#45-querying-data) + ## 1. Encryption in use EQL enables encryption in use, without significant changes to your application code. @@ -96,11 +121,11 @@ EQL provides specialized functions to interact with encrypted data: - **`cs_unique_v1(val JSONB)`**: Retrieves the unique index for enforcing uniqueness. - **`cs_ore_v1(val JSONB)`**: Retrieves the Order-Revealing Encryption index for range queries. -#### 3.2.1 Index functions +### 3.3 Index functions These Functions expect a `jsonb` value that conforms to the storage schema. -##### 3.2.1.1 cs_add_index +#### 3.3.1 cs_add_index ```sql cs_add_index(table_name text, column_name text, index_name text, cast_as text, opts jsonb) @@ -145,7 +170,7 @@ Default Match index options: } ``` -##### 3.2.1.2 cs_modify_index +#### 3.3.2 cs_modify_index ```sql cs_modify_index(table_name text, column_name text, index_name text, cast_as text, opts jsonb) @@ -154,7 +179,7 @@ cs_modify_index(table_name text, column_name text, index_name text, cast_as text Modifies an existing index configuration. Accepts the same parameters as `cs_add_index` -##### 3.2.1.3 cs_remove_index +#### 3.3.3 cs_remove_index ```sql cs_remove_index(table_name text, column_name text, index_name text) @@ -260,17 +285,20 @@ We have created a few langague specific packages to help you interact with the p ## 4. Getting started +The following guide assumes you have the prerequisites installed and running, and are running the SQL statements through your CipherStash Proxy instance. + ### 4.1 Prerequisites - [PostgreSQL 14+](https://www.postgresql.org/download/) - [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) - [Cipherstash Encrypt](https://cipherstash.com/docs/getting-started/cipherstash-encrypt) + - It's important to have your dataset configured for encryption before you start using EQL. + - You can use the `cipherstash/dataset.yml` file in the `cipherstash` directory as a starting point. EQL relies on [Cipherstash Proxy](https://cipherstash.com/docs/getting-started/cipherstash-proxy) and [Cipherstash Encrypt](https://cipherstash.com/docs/getting-started/cipherstash-encrypt) for low-latency encryption & decryption. We plan to support direct language integration in the future. -> Note: An example `dataset.yml` file is provided in the `cipherstash` directory for Encrypt configuration, along with a `start.sh` script to run Cipherstash Proxy locally. -You will need to modify the `dataset.yml` file to match your environment, and copy the `cipherstash/cipherstash-proxy.toml.example` file to `cipherstash/cipherstash-proxy.toml` before running the script. +> Note: You will need to copy the `cipherstash/cipherstash-proxy.toml.example` file to `cipherstash/cipherstash-proxy.toml` and update the values to match your environment before running the script. ### 4.2 Installation @@ -296,7 +324,65 @@ CREATE TABLE IF NOT EXISTS "users" ( ); ``` -### 4.4 Add an index for searchability +### 4.4 Inserting data + +When inserting data into the encrypted column, you must wrap the plaintext in the appropriate EQL payload. + +```sql +INSERT INTO users (name_encrypted) VALUES ('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); +``` + +For reference, the EQL payload is defined as a `jsonb` with a specific schema: + +```json +{ + "v": 1, + "k": "pt", + "p": "test@test.com", + "i": { + "t": "users", + "c": "email_encrypted" + } +} +``` + +### 4.5 Querying data + +When querying data, you must wrap the encrypted column in the appropriate EQL payload. + +```sql +SELECT cs_ciphertext_v1(name_encrypted) +FROM users +WHERE cs_match_v1(name_encrypted) @> cs_match_v1('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); +``` + +For reference, the EQL payload is defined as a `jsonb` with a specific schema: + +```json +{ + "v": 1, + "k": "ct", + "c": "test@test.com", + "i": { + "t": "users", + "c": "email_encrypted" + } +} +``` + +## TODO: Add an encrypted column + +TODO: Do we need this? + +```SQL +-- Alter tables from the configuration +cs_create_encrypted_columns_v1() + +-- Explicit alter table +ALTER TABLE users ADD column name_encrypted cs_encrypted_v1; +``` + +## TODO Add an index for searchability EQL supports three types of indexes: @@ -321,16 +407,4 @@ Depending on the size of the target table, this process can be long-running. {{LINK TO MIGRATOR DETAILS HERE}} -### Add an encrypted column - -TODO: Do we need this? - -```SQL --- Alter tables from the configuration -cs_create_encrypted_columns_v1() - --- Explicit alter table -ALTER TABLE users ADD column name_encrypted cs_encrypted_v1; -``` - .... more to come \ No newline at end of file diff --git a/javascript/bun.lockb b/javascript/bun.lockb index eb19c74051806accb8f39d2d507324ae05d952b0..c30670db4120e84a6ff0df2c2ae64bd5d3376247 100755 GIT binary patch delta 22 ecmbQSn{~!+)(y3v*csyt^(^&_H@AEe$p!#wUU~|hSk!%27o(F*d From 3c86d1af7438cb7f892539b47b5d76c5de463127 Mon Sep 17 00:00:00 2001 From: CJ Brewer Date: Thu, 3 Oct 2024 13:52:59 -0600 Subject: [PATCH 3/4] Update README.md Co-authored-by: Drew Thomas --- README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/README.md b/README.md index ef977f85..c3d7930f 100644 --- a/README.md +++ b/README.md @@ -101,7 +101,7 @@ Before you get started, it's important to understand some of the key components ### 3.1 Encrypted columns -Encrypted columns are defined using the `cs_encrypted_v1` domain type, which extends the `jsonb` type with additional constraints to ensure data integrity. +Encrypted columns are defined using the `cs_encrypted_v1` [domain type](https://www.postgresql.org/docs/current/domains.html), which extends the `jsonb` type with additional constraints to ensure data integrity. **Example table definition:** From 3bc845739af1198c113df4a52123c7f6bc5bfa7d Mon Sep 17 00:00:00 2001 From: CJ Brewer Date: Thu, 3 Oct 2024 13:55:46 -0600 Subject: [PATCH 4/4] feat(js): add full text search drizzle example --- README.md | 26 ++++++------ cipherstash/README.md | 1 + javascript/README.md | 14 +++++++ javascript/apps/drizzle/package.json | 3 +- javascript/apps/drizzle/src/insert.ts | 41 +++++++------------ javascript/apps/drizzle/src/select.ts | 23 ++++++++--- javascript/apps/prisma/src/insert.ts | 24 +++-------- javascript/bun.lockb | Bin 94056 -> 94568 bytes javascript/packages/eql/package.json | 7 +++- javascript/packages/eql/src/drizzle/index.ts | 26 ++++++++++++ javascript/packages/eql/src/index.ts | 4 +- javascript/packages/eql/tsup.config.ts | 2 +- javascript/packages/utils/README.md | 15 +++++++ javascript/packages/utils/package.json | 26 ++++++++++++ javascript/packages/utils/src/index.ts | 20 +++++++++ javascript/packages/utils/tsconfig.json | 27 ++++++++++++ javascript/packages/utils/tsup.config.ts | 8 ++++ 17 files changed, 200 insertions(+), 67 deletions(-) create mode 100644 cipherstash/README.md create mode 100644 javascript/packages/eql/src/drizzle/index.ts create mode 100644 javascript/packages/utils/README.md create mode 100644 javascript/packages/utils/package.json create mode 100644 javascript/packages/utils/src/index.ts create mode 100644 javascript/packages/utils/tsconfig.json create mode 100644 javascript/packages/utils/tsup.config.ts diff --git a/README.md b/README.md index ef977f85..90341491 100644 --- a/README.md +++ b/README.md @@ -34,9 +34,9 @@ EQL provides a data format for transmitting and storing encrypted data & indexes EQL enables encryption in use, without significant changes to your application code. A variety of searchable encryption techniques are available, including: -- Matching (`a == b` or `a LIKE b`) -- Comparison using order revealing encryption (`a < b`) -- Enforcing unique constraints (`there is only a`) +- **Matching** - Equality or partial matches +- **Ordering** - comparison operations using order revealing encryption +- **Uniqueness** - enforcing unique constraints ### 1.1 What is encryption in use? @@ -108,7 +108,7 @@ Encrypted columns are defined using the `cs_encrypted_v1` domain type, which ext ```sql CREATE TABLE users ( id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, - name_encrypted cs_encrypted_v1 + email_encrypted cs_encrypted_v1 ); ``` @@ -117,7 +117,7 @@ CREATE TABLE users ( EQL provides specialized functions to interact with encrypted data: - **`cs_ciphertext_v1(val JSONB)`**: Extracts the ciphertext for decryption by CipherStash Proxy. -- **`cs_match_v1(val JSONB)`**: Retrieves the match index for equality comparisons. +- **`cs_match_v1(val JSONB)`**: Enables basic full-text search. - **`cs_unique_v1(val JSONB)`**: Retrieves the unique index for enforcing uniqueness. - **`cs_ore_v1(val JSONB)`**: Retrieves the Order-Revealing Encryption index for range queries. @@ -329,7 +329,7 @@ CREATE TABLE IF NOT EXISTS "users" ( When inserting data into the encrypted column, you must wrap the plaintext in the appropriate EQL payload. ```sql -INSERT INTO users (name_encrypted) VALUES ('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); +INSERT INTO users (email_encrypted) VALUES ('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); ``` For reference, the EQL payload is defined as a `jsonb` with a specific schema: @@ -351,9 +351,7 @@ For reference, the EQL payload is defined as a `jsonb` with a specific schema: When querying data, you must wrap the encrypted column in the appropriate EQL payload. ```sql -SELECT cs_ciphertext_v1(name_encrypted) -FROM users -WHERE cs_match_v1(name_encrypted) @> cs_match_v1('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); +SELECT email_encrypted FROM users WHERE cs_match_v1(email_encrypted) @> cs_match_v1('{"v":1,"k":"pt","p":"test@test.com","i":{"t":"users","c":"email_encrypted"}}'); ``` For reference, the EQL payload is defined as a `jsonb` with a specific schema: @@ -370,7 +368,11 @@ For reference, the EQL payload is defined as a `jsonb` with a specific schema: } ``` -## TODO: Add an encrypted column +--- + +In progress... + +## Add an encrypted column TODO: Do we need this? @@ -379,10 +381,10 @@ TODO: Do we need this? cs_create_encrypted_columns_v1() -- Explicit alter table -ALTER TABLE users ADD column name_encrypted cs_encrypted_v1; +ALTER TABLE users ADD column email_encrypted cs_encrypted_v1; ``` -## TODO Add an index for searchability +## Add an index for searchability EQL supports three types of indexes: diff --git a/cipherstash/README.md b/cipherstash/README.md new file mode 100644 index 00000000..c651c27c --- /dev/null +++ b/cipherstash/README.md @@ -0,0 +1 @@ +psql -h localhost -p 6432 -U postgres.wvhsiwlbufuixlvdunxr -d postgres diff --git a/javascript/README.md b/javascript/README.md index b2a8c89b..e75d4689 100644 --- a/javascript/README.md +++ b/javascript/README.md @@ -14,6 +14,20 @@ The following examples are available: - [drizzle-eql](https://github.com/cipherstash/encrypt-query-language/tree/main/apps/drizzle): This is an example using the [drizzle-orm](https://drizzle-orm.com/) library to insert and select encrypted data from a PostgreSQL database using EQL and [CipherStash Proxy](https://docs.cipherstash.com/reference/proxy). +## Development + +1. Run the install script to install the dependencies: + +```bash +bun install +``` + +2. Listen for local package changes and rebuild the packages: + +```bash +bun dev +``` + ## License This project is licensed under the MIT License. diff --git a/javascript/apps/drizzle/package.json b/javascript/apps/drizzle/package.json index b516e590..b3330c2b 100644 --- a/javascript/apps/drizzle/package.json +++ b/javascript/apps/drizzle/package.json @@ -12,7 +12,8 @@ }, "peerDependencies": { "typescript": "^5.0.0", - "@cipherstash/eql": "workspace:*" + "@cipherstash/eql": "workspace:*", + "@cipherstash/utils": "workspace:*" }, "dependencies": { "drizzle-orm": "^0.33.0", diff --git a/javascript/apps/drizzle/src/insert.ts b/javascript/apps/drizzle/src/insert.ts index 01225edf..f99d2768 100644 --- a/javascript/apps/drizzle/src/insert.ts +++ b/javascript/apps/drizzle/src/insert.ts @@ -1,39 +1,28 @@ -import { parseArgs } from 'node:util' +import { getEmailArg } from '@cipherstash/utils' import { eqlPayload } from '@cipherstash/eql' import { db } from './db' import { users } from './schema' -const { values, positionals } = parseArgs({ - args: Bun.argv, - options: { - email: { - type: 'string', - }, - }, - strict: true, - allowPositionals: true, +const email = getEmailArg({ + required: true, }) -const email = values.email - -if (!email) { - throw new Error('[ERROR] the email command line argument is required') -} +const sql = db.insert(users).values({ + email: email, + email_encrypted: eqlPayload({ + plaintext: email, + table: 'users', + column: 'email_encrypted', + }), +}) -await db - .insert(users) - .values({ - email, - email_encrypted: eqlPayload({ - plaintext: email, - table: 'users', - column: 'email_encrypted', - }), - }) - .execute() +const sqlResult = sql.toSQL() +console.log('[INFO] SQL statement:', sqlResult) +await sql.execute() console.log( "[INFO] You've inserted a new user with an encrypted email from the plaintext", email, ) + process.exit(0) diff --git a/javascript/apps/drizzle/src/select.ts b/javascript/apps/drizzle/src/select.ts index 8a5680cb..f293ae8e 100644 --- a/javascript/apps/drizzle/src/select.ts +++ b/javascript/apps/drizzle/src/select.ts @@ -1,24 +1,35 @@ -import { getPlaintext } from '@cipherstash/eql' +import { getEmailArg } from '@cipherstash/utils' +import { cs_match_v1 } from '@cipherstash/eql/drizzle' import { db } from './db' import { users } from './schema' -const sqlResult = db +const email = getEmailArg({ + required: false, +}) + +const sql = db .select({ email: users.email_encrypted, }) .from(users) - .toSQL() -const data = await db.select().from(users).execute() +if (email) { + sql.where(cs_match_v1(users, users.email_encrypted, email)) +} + +const sqlResult = sql.toSQL() +console.log('[INFO] SQL statement:', sqlResult) -console.log('[INFO] SQL statement:', sqlResult.sql) +const data = await sql.execute() console.log('[INFO] All emails have been decrypted by CipherStash Proxy') console.log( 'Emails:', JSON.stringify( - data.map((row) => getPlaintext(row.email_encrypted)), + // data.map((row) => getPlaintext(row.email_encrypted)), + data, null, 2, ), ) + process.exit(0) diff --git a/javascript/apps/prisma/src/insert.ts b/javascript/apps/prisma/src/insert.ts index e9a09177..45728606 100644 --- a/javascript/apps/prisma/src/insert.ts +++ b/javascript/apps/prisma/src/insert.ts @@ -1,28 +1,14 @@ -import { parseArgs } from 'node:util' +import { getEmailArg } from '@cipherstash/utils' import { eqlPayload } from '@cipherstash/eql' -import type { InputJsonValue } from '@prisma/client/runtime/library' import { prisma } from './db' -const { values, positionals } = parseArgs({ - args: Bun.argv, - options: { - email: { - type: 'string', - }, - }, - strict: true, - allowPositionals: true, +const email = getEmailArg({ + required: true, }) -const email = values.email - -if (!email) { - throw new Error('[ERROR] the email command line argument is required') -} - await prisma.user.create({ data: { - email, + email: email ?? 'test@test.com', email_encrypted: eqlPayload({ plaintext: email, table: 'users', @@ -35,4 +21,6 @@ console.log( "[INFO] You've inserted a new user with an encrypted email from the plaintext", email, ) + +await prisma.$disconnect() process.exit(0) diff --git a/javascript/bun.lockb b/javascript/bun.lockb index 5e6302cc8a0fef762605c1d81c8594921728b7c3..3c42d2c2ec28e35689dc98df64e91ad6447bc5f8 100755 GIT binary patch delta 13131 zcmeHO30PD|w!YPL1C6qS&~zgpiVKJ!AS%nnxJO077)3=yBtl$3Kod0yO^k`r__9>A zg1eb4<7kY=IA+GgbuuO-j+(`Y2A90#jYh|eBCZkNf9l@bI2mV>$@^x$?|onH=ehqm zr%r9Bs!r8y$}=Y{XTGvL7vK50?fVZ{uIxF!$=S5AY0}as$LITAdAR(uiKRKu7Wggh zIQ3{bQ|P(!{OE}4)s2$ZU#%3ySv9L-QW@mdunL5H1AGAREYKfV5A*}p0eyk*0)2p$ zI_`E;lyJze0`0&hz);{rz&5}MKpSu%Fr*qxH{HOd8|t&o=h$rGR8)f)JOu16)Z=T()n%E2lTsDzg4{#TS88-nVEC*}n&*?kqy{y@ujJZO zc+pyH?5KI*2xRKegJo#{3`M~VD8kB6{5mV~($KB5R>0LxS^?*DG$zq$$W*{lUSp1^ zp4e4$=)FJ;rZZW`wmN$1cqvXxZvc{iKLpZL-=^a_9hc}hN5^6vb9Btmu?rC0>g^2C z7^hjsi?LdNPXa0S9MExxj_Y+4JkQdx+L5Bo7atwp0%8t3-GHrtrIlUfqN>55Q>QD6 z3nx!5ttj8+t$DL>#+>PeRYfI}Dhi9RV3k)>HM?^_S`ZmMHM^q1BKTNQK4`7!8=*%L zCg(`b+`Cnu?xp$sAdnip5lEB3oUW~}k;qET83UPcn2yPrn)f#VQL^(Ykk;Lcy8b0q zE6t<0N~cX$^wF#SPY>GEMPEXZ;V?&n*AJ6gU+>R__7^hbP7lbjQr)LB0ShZ>!3 zJjySX4dL}|RQ43Ng{YR_VKwHEwaKd$UmlXl2J`w5mA%Amp(^^F7pj^fTJz>^QfzQ>_`;w(plkQX4rWauUjdbXb?*B$VvH zCP=+OzmdCy=S8d5SD@4CE(}k#o`6KPd2o`#!i>5}x*t*&(ky&kL@IlQ*S1%!XP~3n zth^9Dj^VZrs&z7ULMl-k7&xYb$`W}!-t)OFMzx-GXluxg%CRP4k0*a)P&=g3$id=| z(79S+iE2x$ufc|O2rhv)IMS@Ez|lyU_&R&4^>ax2R0yF~g^(uT4-b58=R(%~vI)S>6XXRC50D2AA*R z*1NbS7uTm7rUlPWN@v~p@+1}SV|XX-N(a_CzaUX#jpj8d0 z5SMP&nKa8P7x&-b`bo2nNyO!MPd7`3n*XMYYm{6=ayqZ?LGi!#V(&s1zAtn3LPm zRLh&t_2Uh3X(pu?U!Im}&A~Bf9E^NrP-=#xR~4Mfdhon-mCfL_>8j-|l+=Ugho@Q3 zfFm0%yhQT643&-NwHd1QWz6(RNNL5RLQ+kE={zhmlMNJyXRuVcl@;;YOqCtx^>`2A zHdSTYd7i3TJ#b{A5RTXxm&%6odZhe@+p@5AWbv_Cnbu59X7VAEG3gOrpQT#fh7Q|i zR+`1FkK9W8r<*kfs#PxTTNjs#^?_X&sgHvjEV++dTu@&_m+#_Ub8+8kT)%WP+^c1+ z(YQWRHBgr3-(OKQZj6gtb^yZtKx13ObYuU;Z39)y zAE6u0!w05Wg5j=VJbY-nS!1Aj)5U%7;sy_ngV!3~yNgNuv7B-M0fF76!{$A-w% zA?ap~K_Oh@21(UGSz7c^>N3^vpo`n$;;w<~FHIL}-)+Ari=5V#wt~NDad<%7>8bF>(rZ zBo{=_ok$HE1tPoqbsUYLBA?NBK^m5PT~A0A7U(je8*j)Csixv4>)Jb!tRK+zcOuzO z0TGty>4aqepe_?q?d2e9b|r}Ht3dP+lKvrl>61*1d%4R{hn8J-5wLrD5XB;dId10b)I+Mj`1|9?itpHQI% zHtTe|yP*|nFXRMqM-G1Sz_UTOy%VX^8+AQlC|{Kq!Z+r5{yWGE8omFZ}zm*z!g?}#?6zO z^evv2&(V9*oRpflw>&Mr*oNp+Puj4V{C961H$`}FUAEPW;g{fbZ;$i-Ee^n5ID_v7 z`fbg5XTFI~-10UR;AQ+RFeGAY_B$__*r=_ie?Q;Nb`O5Pz>msKa&>t{aaC1mam5Ab z{7_GqasZ(|HZSA3i_dvAsoh1Q}AycF1Y)5H3L3FaARWlAm&*vaY zqqEE{Are4%0_2e&wSdJr(>uCms4N@EnMo7YefR zrI#bZ1Hn=6s72IU>K!$NS|7^~Uyf#{c++LIb6?1ws1Z|F@d7y@hl6539YJxRuAr}Y zep5*2@!$@EPJ?J5-UsameE|9pR0sM9^asAGsetX{x0<4@>mk!O+aliiidww_+yc-L z&`?k|XgG+@CpjSaO&JWLVWb-!^gBWXC=wI}qQg=Ns1)=7s2KDq=m2N~r~ot(R0w(! z^b}|z$O)>UERTc91&svV2cjXT?}-P&PXo;WO#yudDgsRcJq?-||=1O05! zBcM4TnyU|i=zH3O=Ug4#PK9L_XaY3!)pQ6%lWr=ICQzBe>#pYZj)AHph`zFDy37Jq zg33WORcLCE?9$U*!sBeFsbM9yJ*a8x%xm0@HEm_zPi1t|K)S61aC0+WcwUO&vv0-l zwYS2Cr$7uq5yoHtBHd}MF*%*&mR3M7v9~Px>&xdO-3LO0sp%w-V+J|XKficoPPy;n zk?zznvaRIb-Ab~*3yDgo_f0>z_mt&;nRSm(jHlUJ$1|F3c3OLWNDnxhyT1P;VoXc= zSw6GbhF|#>H`^S>EuO`5%`bg6ASt}X%I3y*H;1Mew{H&j*m}>dKV6z&W{L5=;*(Ig zyr6>$d>h5Gh|Gg)TT&))@7p%JaiQm%>q%3;j&?J(q%YxpZrj+ad>r1p`K;SXcH{2N znhwsm*agLt64->4_=NZb%neavVmAKe?J&D>QOEbqW06BXpEtV`n~N`~mhV7HN__Vo@yW^(F${hFQKztxVucAk{y-cwv4iZ0SmTCVr!aW} z(W2qk_icOEJZZU!P3QqvVq!FkPu*Bjpm9&&>+`=4+Z}o9u!-FkHZzMd1$&EhGYhpF z_m;XW-}KxobEnNi3FuNhf?y|6W=7Yu#M5Tfn=jrY*d;EKa+hdjLG{Mvn-#&^zYSaP z?o?z>h)<%-uM5=z^Ub2t0x#|ndtlBMisO{axa5@k^pQ<%$K30MT*+Fa*9u>E7Hd6= zs7<^!ry#q;hce2~}xup2j|Yykn&?u+*QOt-`2 zDiSAQUcL_&vVs&P43!%BSXQ3+ODCj2O-?Tsw>;1W{8`v6Y)n2CG*SW^BmB$BMT~iKITB7Kpw6XOtu4A2_Ja$w=`tE*u7m-!F`Gp%V zWr=T3yHKO{l}TEaq=}UxXg&c?1@zT4zjcMf+B)yUDk$7z1SE#Nt+%OC@4g zD+Gf1*jBMkIJezCf5|JXu7jB+$9IRb6~(yam9zZ9g{-xQn_E(L3h&lvzi};WYX@_F z!kGnuEe1D59~hXzBE|UDaASI;cBSargxbfFSJvHbF)R?z!Z77g7~r2Xwc{H-yWc!C zpv7Pn)Y#XYFVr~l9-H0NsU>BPXrM-%gnz1ejiBZbx*@?I5>`k-**g4?UhR-d;-PV6HMid*s&i*P^GZrqwXKL3FMiOY`dX)#zLa$vyLiK%2~+`8jw=c6B7vV38S-G?G4 z+*NslIE~8NX&p3f@a1M6igkqhzuuC^v#Yq^hb|d+{x%FK&96{9u57VL7E%7F{a%qq zFj0*1XDb|TIQr0;W%ZLg`u_Ts&uem%lQG&SMYIlJp(aO)hzY=Ic}wI4V71hUB>~93 zOY8|?LGE&qO5R3>Um}CuxPF(>xO+>TUrGsvHdQ+YoD;r*=(uqouS>T<-(MRSbV(Y> z$6IbA#w#6p>-6`O)s za>@^natW@Z+>f1M?8b$@=);?*FS>uqB%EI`u@D86G20V^nH#geoUWZFc6hJoJo}SMb7_bI$j_l6C4x6p>y^psI@T?s$uEp+#hzLO& zyfU=eKW?+e!~jH z#oX0tEoF}t>tMjj#16813U>Imat`)YUKkOxWu{&bIY)kiM0hx??-pz|1L;s&T?n&5qB@*e9CwSdnlYm6+VFo6Wi<=K$I?#| z#b2oMAB#NgjsKCr>*^M5w8mUR0KPc)NMaE-$=6qKTnMU+#>T|Dke$AG&Q0#$O@9qdL6q=5Yn)k}+4Ux7C$P|!j zLPq)A4oW^T7_uMa_j?tLRA=}8;%KB+bLTP<7Qu!^mKPRHEu2zZ*=<%;>9oqMqSEq` z;)=?u!pag&vwcbg3(NK@Dbun&TqYJzXI%q~PwL&eKC+xTViyh5*+}}i%xgrsmZ7|y oGIS6HGnmbl>m5DusGe)p3>F=3e1RL^+vt_-iTq~AuXg-@0Up+KrvLx| delta 13318 zcmeHOdwfk-_CNdP-Xu3c61nn@#9I;~H*fMd-a(7TqlzjKDVMxRDC3dKFskb3v8#Jp z>d}r8sx2AQ2kJGQ@tS&#Qd(1Vh9Ffc-sJaP`<#=j{iQSWo1fpzKRqAoeAn80?X~w_ zd+o=$*)E>5Ts&i06dRR&^T@*Ga|Sm0Y~Gq!FTbzW=O68u^3v!fRVQ9NJm}n<+i52Y znLc?o{7r*E<*OkRzA(m- zI|h1=lDx@zz`4kWsWRsfj2am%&M6(!c3j?+)_Q>sXqD`qqtH>DQ&JLvbdtYAItn_w zHPZYXpr@aKOcfsilD++C4e7rDr0!0HKM2P{CO5gmmw`%|;=G3pYGJI7SCK&mGBNB_ z;2#;96rwfc$9CqzL)3s`AWS=NVpM5hzru?mYIB$#QG1bqMmsO-1G60QNEKfNQYe>B zNK7Ud7f&pll3O$??;O&pffI`I^J!@PnrIw0CshsxojN@sFK5&!$AsdQ za52SGPT`b-oYLGeBPZnKV!|qOQZ&5-K!lnzJXO=n&B=w26=hvLE&UkMVZ!80;LN>U z*{=4Q&))-5qhAJ65PXxS&94L$rRJojYuHvtTc+my`9N59o&eIkE7j8{tC~F{nomF` zJ9#A|Cpz*+Df;M@{kw8=Wjgt*FHViSRUo8T52%deRx~nG)r%$C{If6HE_KocOG01$;DvX>n^$R z;JOmWKH-&qs%1Mi#=*SGFU=BQR+NE~8wakh8YFifjkoxx5_jb-XfIHJz)^qeC)T zd+rEP*%n@ow>z&4Q7!4%#MoJ$Hy zvD&bfb=UGBjfO;Zx$$d|${}I7&^%%~>(8SjGFcbyh)~%KUXJ(gcx8lYt%0X?6JaUV z{#azYq7ajn2}m8JiSZFBrf(bZOOct@IIP!{=qXih=#q!5vpqIRtT9e^ehtRTbjd;z z+sdPws@8Dq%uh>`)W#A>Rbp5x8NJs{-ec z+|yX`b0qfxI4#%KTv0~Lw5j0oB=F0Njvsya#<(=g8gNfa?piIE5o@H)tL2W@a!uON3R{(wZU)ms7Okk| z?$vT#;wZNuKApw!_3a@ZH4kj> z8uvskw@~Ba)6GT_3*?o_w3bArsMd*aKRE-dWYZMu21w)#H$EP5>4h^4O?_?k=%Y*8 z5WEGc7xGMUW>!JUge2#dH3kOBrkQVoOUHptrya$*7M#oaUm$6NLUSM(=Nv81o`T_q zq{Rg+SQkRl<`YH97m%n`at*PzL?N;wR~t5hN2RIOg-Fvif>KOhr}Fh_nN~YaLPMeG zBNwSNko4*rrLX|*NLN`OUY@R6mcUvvF9=Vw?gd9W+H#|CM~2GMd3lCvorTCBi5zck z4@@zApT?szGc5>nrJlCA`FdhmEzeZhCSHkm43AP(Cb&aYtry@XTGcUcf>KyJUWuHS zcvMI1DJmb^G1J-@flaPta+!LTS9Vk_uOJN@X~#6nd2rZV!NqklxapEB=$dY>O$x+Z z!M+T&k>GktZbL11qn69)V&wj+mOE6-1;L40*_>K#J-94s@0!MSNjG;hlFDkiKY;5d z)x5DfcH;$|(#?{gHZ3(cc8ZsG#}1HX>~x4aR>-5WRLk2)>&x3_rCF-M^_E;`I8Ngh zN^WDXbaQP|R8Q(M6(|MQQ*zsDId{aWme#kH`*kgMww8;2!q6+J<+g##lJ?x5lpLzn z7*w{nmOBZqn^X($P29$;bhBirO>1kpD>|3Jzw}+ z30OhpLr4l(Dy1Q;T=MvbNRSU9H4MWmA41Z{Fe=oMY!E$4a3_bGl4O26I4Ua3o0K;eF}1Bt^*uk#-&lcpgR4ejY?P8bl8v={rckLrAq3 zfvA=VAkr@Z(L+e-lSshx2$o637m!E=CQ~jRLMkv7MCsE&^bk_I76yMGNpBX29ztsH zY!dLe5SFNdIUp+VB8VPBN}oppo=34EJJv-2kR-A*lbLH!97H&e0smY9Ey#j zAWA)^fXIRYUUZ*ScI6GG5g$kl*j;Sw=zjjjl;Z)8-P0mM#mbHv_40 zRD(B=T2zl-I#PNAJ>OSPe-s0d-%?Mn1GR9gBZKV!y@HP^Uk~@c*8u8aYxE!xsOmj= zY*_ZV4gQ2Zau-cUA{t_2i!3vke+K`LdnKyX_E_3s^sTZ?GSp}aICAy>-(IQN|KV1N z@&C8&mFOHjKiDd9JeCPGCO_|$Xt+il>U~Rc& z=UQ3%0;@ITW~x|zppzS3Z_(>WE3b>!wE=5=gRlEOo%gM_7NGC5s{X+`cweVH4w4zpfVOjHmFb3LOQ18gDC9=i1g}#3h{HUOss}LmDC5( zXC4{34I;$`pkfdexC5dzI9wSIqO`jpN_&PZvM^|@=GBB&BX zZ6{CBH;Ol3P#wW6d}DQ>B^vSxzOT9&OW;-2YMDFidVoAZbkYd}wE(pQ#emv?&VuN0 zFbMPvXfTMpKNR#C=xY!i`hO3i5%?o$FK8cVKWGnV1Lz&lM$o&U_dxICqhiC&o@^Db zzS+#W3@P(K^Ldk7YT0aXy+BWZdV~6a`huPUWr2EtXiU98bTUIE)8D|AND!T*MuWzH z@<5|NM?nWc>p}F5KO8gyGzau6&|DC$BTmpvV(Ax#exUv!3IO`XaDX2NDgZqXqA#G4 zpd8SPpjn^+Ao}i@4x9m+2$~9-45Cn-1bP8PAx)?EC{Q#g2Gj=B78J|)klUS`4ujfZ z&>;}T=fjN&>EpCX`zSCtaWK!QTXASpd{n!&O4_9l6KwfbHvQ-vF&52amMAIBgqw=cYJpJ zIaf}rrQs|%)VK|_{hc0a*r3#vuKYnuvso}JSUL_`#$BS1U(XB5dS&b$m)5GKD_H`| z5R2WQoFzI1uwdcNSP07&O&F5$MH*whS-hCXp!cCrO)zKN3~EsJLD1~zDfuRr6dNBG z8>c8=h-)YnYFsI5|8AEqzNVKKnpl;G_V*FZf^LZYLv;_az=Y~E#A(!Pl!_ESXl;^l zt>~=-zn-#k>`{k_%}9++inYfn#s#Fs?S?F9xh11La?m_`d~E7wF$_gR|EEGUd`-^} zJi!vgr*7!>I&sI19ZE88jg-vm@$k26nol#a=j^ett0+4WG5#3fzIXO)*=8R3I&zY= zoMYmFnI-recMra~@^Q${$OlJE>@T8=g*6E??mi`yZnYf=XmtlA<6;p*bUR8oEi5S1 zv%Yr!>tO59vsJwothce}QeqQeUWpVH7CCqq2v&+vcXZ9TlreC`m72SYa&AIBA#&QZ z$mbG^MPDeexx(QN^+np5 zDO)4!>;c;>#EYYgSBG)lFI>&j?O_&DyocElrv(e6|FTcVLixa?-w`idI|~% zB~n;`jm8&VxP5o(nBC93vc|+FAq6{+^9|9?8=lw(u>r(UgZJ!S;j_wOVr!Ao2r2u; zSFjy=0U`#`Y4^HzIl8;eY+}cdf?hdeg`XE(I#$F0LXC@I;Z4sr+i7k35!yge1iwra z!=aG$6AB0x73)YE%w+*%vLmY?o^Yh|(CNEp%-O!orC3~$7(aSLtmACmiB>UHM|6t&S(_KHpL z8~aKeAom%!(C+xa$yjj#hA^E2i5*6cKnqTmzBIt1H=P0TN(z$Ta zryh$pT@4qrfGkaHsmBtMjQe3*Z2=93Eqra3nI*=?Cz6MAv9;o4;M`Jk<+@kM{uZvB zG7(-M%`~o@xtAUtmH*lICYQoCkqrfQT8tw-m3^!!8-=^YdE8n9)dAGVgqKj-Ity05*w@GMPH3JSPmmr#As z)}NTEv@u~nqmA>EevUn+hsPG7Xab5N=YUv%qRGb1xk-cK!xv2JvmXj@GzFY-w{Fd= zE3Q}~M|6_4Vj-pLcj8MQ_GFTAE$Gad9dB%i-`?KL5IG4{*0{Ll_$Yl{qI<#LTsh0c zFkf`txaqd*uZ!3D2WH)JDeMr7p}>xa4S+D?rrew5Gsb@F+2W{6?^cZX+82w7e!0%+ z>6aPvA$#SZOT)N+x7Xt-(fwk7x6b6eND6j%Cm0+gG zY0UgRw5}}`*Fu?pnkE=G1NYu^Mojz7K<=_&+#OsI8u#(B%G@EYoTK6aj3ybE4eJMX ztz7Z$q(8b8jO&OSx;utVP+Ki`<=Dg%4bg7n{$jk}^rz2$+;5~yp`)-zFn_V6A$!qu zK2e1Ev!F2Jx?oqI_t%y#IQ$arvRE=Pj`tJAQ~sEBOT;hzSwg6BZ_w+Fv!`ZzoKMgP z9K*R%9Px)AB-liaKeL1yml3DA4_lV;@|r?DuwZqLh_Io5#;rp0Gw}odC?sit zW!y82Zr9`f?V+~o$kCUBW1_%@edT4b8Wz}lVn-vuE^*w(4uu-m3#UF`bUS_Gmj zog!K4(c$Bf!x3vMhT@FGQa_j&z}#5UtaNP(ZLPm7YS7+uU2M!aNkn3LSTRGUUK#zT z7aLw~>dKifHU`4muc9bzuOW?E_|0tA|DcU!X4q3PwUjr-Sty{L_ejsUzkPjdpCyrV z&+l{@+Ai7!VX7T~Av%O^Ke(m4=WE@Ex)e?!#}_%12DGuX_-xL9Q5A8q*!h%8>0(9@ zR_XiDpq;2&w;nG~vzf28dwdBB zw-8ie+yQ;n*V!py*t^}J5C;qKb|_?ruwc{WdLlmr{-|q#v8Up6t1J^Mp;+evqbbM* z#@|B|j)*E~C)KsgXbQ%a-51U8j2Z6NVKU7%Eyqiwg`%RmRvAsfE{aH@u2n`;kgJT* zk^-?E+S*!UbC+F_OHD8<7v5p8Q`d^3**PjyDAc*4XbN?$C|Zt9EI?5v*A1K48piC+ z^0KrEQP=8jZ;#`-GEey6n$pA*TzG1 zY|Pw4jl12^4O=I$`R7-=%FEp#n90GhiG_`^7}m87Xsy{U-fN7hZ`>&Fmw7lQEZh%Y zmPS|W+6J_u58H@`jnP%(mU{k(H)}p${81-YSvhLKUQac~cQ+p22=R+z7Am$!U^TcH z!Q$`@5FE)Onmnn0_U!*&WX#w#ofS?GocfzV z8zO_lA=AP)GjL#o8e8I-D9E%*ecFC_e|1ua6CES8ddC-t&5^A42N6wJNFT5F3$)Y^ z3q*7=YtiuV@GsV>=Y1P0`hUlXE7V%~MiJ}pH9}9ETu929UORR9q*TgmWPIft-}Gpn Iya2`j8(y1yzW@LL diff --git a/javascript/packages/eql/package.json b/javascript/packages/eql/package.json index 6444f881..80fae734 100644 --- a/javascript/packages/eql/package.json +++ b/javascript/packages/eql/package.json @@ -26,6 +26,11 @@ "types": "./dist/index.d.ts", "import": "./dist/index.js", "require": "./dist/index.cjs" + }, + "./drizzle": { + "types": "./dist/drizzle/index.d.ts", + "import": "./dist/drizzle/index.js", + "require": "./dist/drizzle/index.cjs" } }, "scripts": { @@ -42,6 +47,6 @@ "typescript": "^5.0.0" }, "publishConfig": { - "access": "restricted" + "access": "public" } } \ No newline at end of file diff --git a/javascript/packages/eql/src/drizzle/index.ts b/javascript/packages/eql/src/drizzle/index.ts new file mode 100644 index 00000000..01e4fa8d --- /dev/null +++ b/javascript/packages/eql/src/drizzle/index.ts @@ -0,0 +1,26 @@ +import { sql } from 'drizzle-orm' +import { + type PgTable, + getTableConfig, + type PgColumn, +} from 'drizzle-orm/pg-core' +import { eqlPayload } from '../' + +export const cs_match_v1 = ( + table: PgTable, + column: PgColumn, + plaintext: string, +) => { + const tableName = getTableConfig(table)?.name + const columnName = column.name + + const payload = JSON.stringify( + eqlPayload({ + plaintext, + table: tableName, + column: columnName, + }), + ) + + return sql`cs_match_v1(${column}) @> cs_match_v1(${payload})` +} diff --git a/javascript/packages/eql/src/index.ts b/javascript/packages/eql/src/index.ts index bf96c80b..8e2ca884 100644 --- a/javascript/packages/eql/src/index.ts +++ b/javascript/packages/eql/src/index.ts @@ -2,7 +2,7 @@ export * from './cs_encrypted_v1' import type { CsEncryptedV1Schema } from './cs_encrypted_v1' type EqlPayload = { - plaintext: string + plaintext: string | undefined table: string column: string version?: number @@ -19,7 +19,7 @@ export const eqlPayload = ({ v: version, s: 1, k: 'pt', - p: plaintext, + p: plaintext ?? '', i: { t: table, c: column, diff --git a/javascript/packages/eql/tsup.config.ts b/javascript/packages/eql/tsup.config.ts index 0ced0a35..b6a53f7d 100644 --- a/javascript/packages/eql/tsup.config.ts +++ b/javascript/packages/eql/tsup.config.ts @@ -1,7 +1,7 @@ import { defineConfig } from 'tsup' export default defineConfig({ - entry: ['src/index.ts'], + entry: ['src/index.ts', 'src/drizzle/index.ts'], format: ['cjs', 'esm'], sourcemap: true, dts: true, diff --git a/javascript/packages/utils/README.md b/javascript/packages/utils/README.md new file mode 100644 index 00000000..25e82062 --- /dev/null +++ b/javascript/packages/utils/README.md @@ -0,0 +1,15 @@ +# @cipehrstash/utils + +To install dependencies: + +```bash +bun install +``` + +To run: + +```bash +bun run index.ts +``` + +This project was created using `bun init` in bun v1.1.12. [Bun](https://bun.sh) is a fast all-in-one JavaScript runtime. diff --git a/javascript/packages/utils/package.json b/javascript/packages/utils/package.json new file mode 100644 index 00000000..50b7f30b --- /dev/null +++ b/javascript/packages/utils/package.json @@ -0,0 +1,26 @@ +{ + "name": "@cipherstash/utils", + "version": "0.0.0", + "description": "CipherStash shared utility functions", + "license": "MIT", + "author": "CipherStash ", + "type": "module", + "exports": { + ".": { + "types": "./dist/index.d.ts", + "import": "./dist/index.js", + "require": "./dist/index.cjs" + } + }, + "scripts": { + "build": "tsup", + "dev": "tsup --watch" + }, + "devDependencies": { + "@types/bun": "latest", + "tsup": "^8.3.0" + }, + "peerDependencies": { + "typescript": "^5.0.0" + } +} \ No newline at end of file diff --git a/javascript/packages/utils/src/index.ts b/javascript/packages/utils/src/index.ts new file mode 100644 index 00000000..84ce5876 --- /dev/null +++ b/javascript/packages/utils/src/index.ts @@ -0,0 +1,20 @@ +import { parseArgs } from 'node:util' + +export const getEmailArg = ({ required = true }: { required: boolean }) => { + const { values, positionals } = parseArgs({ + args: Bun.argv, + options: { + email: { + type: 'string', + }, + }, + strict: true, + allowPositionals: true, + }) + + if (!values.email && required) { + throw new Error('[ERROR] the email command line argument is required') + } + + return values.email +} diff --git a/javascript/packages/utils/tsconfig.json b/javascript/packages/utils/tsconfig.json new file mode 100644 index 00000000..238655f2 --- /dev/null +++ b/javascript/packages/utils/tsconfig.json @@ -0,0 +1,27 @@ +{ + "compilerOptions": { + // Enable latest features + "lib": ["ESNext", "DOM"], + "target": "ESNext", + "module": "ESNext", + "moduleDetection": "force", + "jsx": "react-jsx", + "allowJs": true, + + // Bundler mode + "moduleResolution": "bundler", + "allowImportingTsExtensions": true, + "verbatimModuleSyntax": true, + "noEmit": true, + + // Best practices + "strict": true, + "skipLibCheck": true, + "noFallthroughCasesInSwitch": true, + + // Some stricter flags (disabled by default) + "noUnusedLocals": false, + "noUnusedParameters": false, + "noPropertyAccessFromIndexSignature": false + } +} diff --git a/javascript/packages/utils/tsup.config.ts b/javascript/packages/utils/tsup.config.ts new file mode 100644 index 00000000..0ced0a35 --- /dev/null +++ b/javascript/packages/utils/tsup.config.ts @@ -0,0 +1,8 @@ +import { defineConfig } from 'tsup' + +export default defineConfig({ + entry: ['src/index.ts'], + format: ['cjs', 'esm'], + sourcemap: true, + dts: true, +})