Encrypt Query Language (EQL) is a set of abstractions for transmitting, storing, and interacting with encrypted data and indexes in PostgreSQL.
Tip
New to EQL? Start with the higher level helpers for EQL in Python, Go, or JavaScript and TypeScript, or the examples for those languages.
Store encrypted data alongside your existing data:
- Encrypted data is stored using a
jsonb
column type - Query encrypted data with specialized SQL functions
- Index encrypted columns to enable searchable encryption
- Integrate with CipherStash Proxy for transparent encryption/decryption.
- Installation
- Documentation
- Getting started
- Storing data
- Configuring indexes for searching data
- Searching data with EQL
- JSON and JSONB support
- Frequently Asked Questions
- Helper packages
- Releasing
The simplest way to get up and running with EQL is to execute the install SQL file directly in your PostgreSQL database.
-
Download the latest EQL install script:
curl -sLo cipherstash-encrypt.sql https://github.com/cipherstash/encrypt-query-language/releases/latest/download/cipherstash-encrypt.sql
-
Run this command to install the custom types and functions:
psql -f cipherstash-encrypt.sql
EQL relies on CipherStash Proxy for low-latency encryption & decryption. We plan to support direct language integration in the future.
If you want to use CipherStash Proxy with the below examples or the helper packages, you can use the playground environment.
You can read more about the EQL concepts and reference guides in the documentation directory.
Once the custom types and functions are installed in your PostgreSQL database, you can start using EQL in your queries.
Define encrypted columns using the cs_encrypted_v1
domain type, which extends the jsonb
type with additional constraints to ensure data integrity.
Example:
CREATE TABLE users (
id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
encrypted_email cs_encrypted_v1
);
Initialize the column using the cs_add_column_v1
function to enable encryption and decryption via CipherStash Proxy.
SELECT cs_add_column_v1('users', 'encrypted_email');
Note: This function allows you to encrypt and decrypt data but does not enable searchable encryption. See Querying Data with EQL for enabling searchable encryption.
After modifying configurations, activate them by running:
SELECT cs_encrypt_v1();
SELECT cs_activate_v1();
Important: These functions must be run after any modifications to the configuration.
CipherStash Proxy refreshes the configuration every 60 seconds. To force an immediate refresh, run:
SELECT cs_refresh_encrypt_config();
Note: This statement must be executed when connected to CipherStash Proxy. When connected to the database directly, it is a no-op.
Encrypted data is stored as jsonb
values in the PostgreSQL database, regardless of the original data type.
You can read more about the data format here.
When inserting data into the encrypted column, wrap the plaintext in the appropriate EQL payload. These statements must be run through the CipherStash Proxy to encrypt the data.
Example:
INSERT INTO users (encrypted_email) VALUES (
'{"v":1,"k":"pt","p":"[email protected]","i":{"t":"users","c":"encrypted_email"}}'
);
Data is stored in the PostgreSQL database as:
{
"c": "generated_ciphertext",
"i": {
"c": "encrypted_email",
"t": "users"
},
"k": "ct",
"m": null,
"o": null,
"u": null,
"v": 1
}
When querying data, select the encrypted column. CipherStash Proxy will decrypt the data automatically.
Example:
SELECT encrypted_email FROM users;
Data is returned as:
{
"k": "pt",
"p": "[email protected]",
"i": {
"t": "users",
"c": "encrypted_email"
},
"v": 1,
"q": null
}
Note: If you execute this query directly on the database, you will not see any plaintext data but rather the
jsonb
payload with the ciphertext.
In order to perform searchable operations on encrypted data, you must configure indexes for the encrypted columns.
IMPORTANT: If you have existing data that's encrypted and you add or modify an index, all the data will need to be re-encrypted. This is due to the way CipherStash Proxy handles searchable encryption operations.
Add an index to an encrypted column.
This function also behaves the same as cs_add_column_v1
but with the additional index configuration.
SELECT cs_add_index_v1(
'table_name', -- Name of the table
'column_name', -- Name of the column
'index_name', -- Index kind ('unique', 'match', 'ore', 'ste_vec')
'cast_as', -- PostgreSQL type to cast decrypted data ('text', 'int', etc.)
'opts' -- Index options as JSONB (optional)
);
You can read more about the index configuration options here.
Example (Unique index):
SELECT cs_add_index_v1(
'users',
'encrypted_email',
'unique',
'text'
);
After adding an index, you have to activate the configuration.
SELECT cs_encrypt_v1();
SELECT cs_activate_v1();
EQL provides specialized functions to interact with encrypted data, supporting operations like equality checks, range queries, and unique constraints.
In order to use the specialized functions, you must first configure the corresponding indexes.
Enable equality search on encrypted data.
Index configuration example:
SELECT cs_add_index_v1(
'users',
'encrypted_email',
'unique',
'text'
);
Example:
SELECT * FROM users
WHERE cs_unique_v1(encrypted_email) = cs_unique_v1(
'{"v":1,"k":"pt","p":"[email protected]","i":{"t":"users","c":"encrypted_email"},"q":"unique"}'
);
Equivalent plaintext query:
SELECT * FROM users WHERE email = '[email protected]';
Enables basic full-text search on encrypted data.
Index configuration example:
SELECT cs_add_index_v1(
'users',
'encrypted_email',
'match',
'text',
'{"token_filters": [{"kind": "downcase"}], "tokenizer": { "kind": "ngram", "token_length": 3 }}'
);
Example:
SELECT * FROM users
WHERE cs_match_v1(encrypted_email) @> cs_match_v1(
'{"v":1,"k":"pt","p":"test","i":{"t":"users","c":"encrypted_email"},"q":"match"}'
);
Equivalent plaintext query:
SELECT * FROM users WHERE email LIKE '%test%';
Enable range queries on encrypted data. Supports:
ORDER BY
WHERE
Example (Filtering):
SELECT * FROM users
WHERE cs_ore_64_8_v1(encrypted_date) < cs_ore_64_8_v1(
'{"v":1,"k":"pt","p":"2023-10-05","i":{"t":"users","c":"encrypted_date"},"q":"ore"}'
);
Equivalent plaintext query:
SELECT * FROM users WHERE date < '2023-10-05';
Example (Ordering):
SELECT id FROM users
ORDER BY cs_ore_64_8_v1(encrypted_field) DESC;
Equivalent plaintext query:
SELECT id FROM users ORDER BY field DESC;
Example (Grouping):
SELECT cs_grouped_value_v1(encrypted_field) COUNT(*)
FROM users
GROUP BY cs_ore_64_8_v1(encrypted_field)
Equivalent plaintext query:
SELECT field, COUNT(*) FROM users GROUP BY field;
EQL supports encrypting entire JSON and JSONB data sets. This warrants a separate section in the documentation. You can read more about the JSONB support in the JSONB reference guide.
Use CipherStash Proxy to intercept PostgreSQL queries and handle encryption and decryption automatically. The proxy interacts with the database using the EQL functions and types defined in this documentation.
Use the helper packages to integate EQL functions into your application.
No, CipherStash Proxy is required to handle the encryption and decryption operations based on the configurations and indexes defined.
Data is encrypted using CipherStash's cryptographic schemes and stored in the cs_encrypted_v1
column as a JSONB payload.
Encryption and decryption are handled by CipherStash Proxy.
We've created a few langauge specific packages to help you interact with the payloads:
Language | ORM | Example | Package |
---|---|---|---|
Go | Xorm | Go/Xorm examples | goeql |
TypeScript | Drizzle | Drizzle examples | jseql |
TypeScript | Prisma | Drizzle examples | jseql |
Python | SQL Alchemy | Python examples | eqlpy |
To cut a release of EQL:
- Draft a new release on GitHub.
- Choose a tag, and create a new one with the prefix
eql-
followed by a semver (for example,eql-1.2.3
). - Generate the release notes.
- Optionally set the release to be the latest (you can set a release to be latest later on if you are testing out a release first).
- Click
Publish release
.
This will trigger the Release EQL workflow, which will build and attach artifacts to the release.