Skip to content
This repository has been archived by the owner on Feb 24, 2024. It is now read-only.

add domain representations #655

Merged
merged 11 commits into from
Jul 2, 2023
1 change: 1 addition & 0 deletions docs/references/api.rst
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@ PostgREST exposes three database objects of a schema as resources: tables, views
api/stored_procedures.rst
api/schemas.rst
api/computed_fields.rst
api/domain_representations.rst
api/resource_embedding.rst
api/resource_representation.rst
api/openapi.rst
Expand Down
181 changes: 181 additions & 0 deletions docs/references/api/domain_representations.rst
Original file line number Diff line number Diff line change
@@ -0,0 +1,181 @@
.. _domain_reps:

Domain Representations
######################

Domain Representations separates "how the data is presented" from "how the data is stored". It works by creating `domains <https://www.postgresql.org/docs/current/sql-createdomain.html>`_ and `casts <https://www.postgresql.org/docs/current/sql-createcast.html>`_, the latter act on the former to present and receive the data in different formats.
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nicely done! I struggled with coming up with a concise way to describe the feature.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Thanks! Actually I stole some phrases from your opening issue 😃

I wanted to remove the "latter/former" words but I found it hard. Although it seems ok leaving it this way.

I've just addressed your latest reviews. LMK if you approve and I'll merge 🚀.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Also clarified the advantages (focusing on views) and "why not create a type?".


For example, suppose you want to use a ``uuid`` type for a primary key and want to present it shortened to web users.

.. code-block:: postgres

-- for this, let's create a domain based on uuid
create domain app_uuid as uuid;

-- and use it as our table PK.
create table profiles(
id app_uuid
, name text
);

-- some data for the example
insert into profiles values ('846c4ffd-92ce-4de7-8d11-8e29929f4ec4', 'John Doe');

Domain Response Format
======================

We can shorten the ``uuid`` with ``base64`` encoding. Let's use JSON as our response format for this example.

To change the domain format for JSON, create a function that converts ``app_uuid`` to ``json``.

.. code-block:: postgres

-- the name of the function is arbitrary
CREATE OR REPLACE FUNCTION json(app_uuid) RETURNS json AS $$
select to_json(encode(uuid_send($1),'base64'));
$$ LANGUAGE SQL IMMUTABLE;

-- check it works
select json('846c4ffd-92ce-4de7-8d11-8e29929f4ec4'::app_uuid);
json
----------------------------
"hGxP/ZLOTeeNEY4pkp9OxA=="

Then create a CAST to tell PostgREST to convert it automatically whenever a JSON response is requested.

.. code-block:: postgres

CREATE CAST (app_uuid AS json) WITH FUNCTION json(app_uuid) AS IMPLICIT;

With this you can obtain the data in the shortened format.

.. tabs::

.. code-tab:: http

GET /profiles HTTP/1.1
Accept: application/json

.. code-tab:: bash Curl

curl "http://localhost:3000/profiles" \
-H "Accept: application/json"

.. code-block:: json

[{"id":"hGxP/ZLOTeeNEY4pkp9OxA==","name":"John Doe"}]

.. note::

- Casts on domains are ignored by PostgreSQL, their interpretation is left to the application. We're discussing the possibility of including the Domain Representations behavior on `pgsql-hackers <https://www.postgresql.org/message-id/flat/CAGRrpzZKa%2BGu91j1SOvN3tM1f-7Gh_w441c5nAX1QqdH3Q31Lg%40mail.gmail.com>`_.
- It would make more sense to use ``base58`` encoding as it's URL friendly but for simplicity we use ``base64`` (supported natively in PostgreSQL).

Domain Filter Format
====================

For :ref:`h_filter` to work with the shortened format, you need a different conversion.

PostgREST considers the URL query string to be, in the most generic sense, ``text``. So let's create a function that converts ``text`` to ``app_uuid``.

.. code-block:: postgres

-- the name of the function is arbitrary
CREATE OR REPLACE FUNCTION app_uuid(text) RETURNS app_uuid AS $$
select substring(decode($1,'base64')::text from 3)::uuid;
$$ LANGUAGE SQL IMMUTABLE;

-- plus a CAST to tell PostgREST to use this function
CREATE CAST (text AS app_uuid) WITH FUNCTION app_uuid(text) AS IMPLICIT;

Now you can filter as usual.

.. tabs::

.. code-tab:: http

GET /profiles?id=eq.hGxP/ZLOTeeNEY4pkp9OxA== HTTP/1.1
Accept: application/json

.. code-tab:: bash Curl

curl "http://localhost:3000/profiles?id=eq.ZLOTeeNEY4pkp9OxA==" \
-H "Accept: application/json"

.. code-block:: json

[{"id":"hGxP/ZLOTeeNEY4pkp9OxA==","name":"John Doe"}]

.. note::

If there's no CAST from ``text`` to ``app_uuid`` defined, the filter will still work the native uuid format (``846c4ffd-92ce-4de7-8d11-8e29929f4ec4``).
steve-chavez marked this conversation as resolved.
Show resolved Hide resolved

Domain Request Body Format
==========================

For accepting a JSON request body with the shortened format, create a ``json`` to ``app_uuid`` conversion.
steve-chavez marked this conversation as resolved.
Show resolved Hide resolved

.. code-block:: postgres

-- the name of the function is arbitrary
CREATE OR REPLACE FUNCTION app_uuid(json) RETURNS public.app_uuid AS $$
-- here we reuse the previous app_uuid(text) function
select app_uuid($1 #>> '{}');
$$ LANGUAGE SQL IMMUTABLE;

CREATE CAST (json AS public.app_uuid) WITH FUNCTION app_uuid(json) AS IMPLICIT;

Now we can :ref:`insert` (or :ref:`update`) as usual.

.. tabs::

.. code-tab:: http

POST /profiles HTTP/1.1
Content-Type: application/json
Prefer: return=representation

{"id":"zH7HbFJUTfy/GZpwuirpuQ==","name":"Jane Doe"}

.. code-tab:: bash Curl

curl "http://localhost:3000/profiles" \
-H "Prefer: return=representation" \
-H "Content-Type: application/json" \
-d @- <<JSON

{"id":"zH7HbFJUTfy/GZpwuirpuQ==","name":"Jane Doe"}

JSON

The response:

.. code-block:: json

[{"id":"zH7HbFJUTfy/GZpwuirpuQ==","name":"Jane Doe"}]

Note that on the database side we have our regular ``uuid`` format.

.. code-block:: postgres

select * from profiles;

id | name
--------------------------------------+----------
846c4ffd-92ce-4de7-8d11-8e29929f4ec4 | John Doe
cc7ec76c-5254-4dfc-bf19-9a70ba2ae9b9 | Jane Doe
(2 rows)

.. note::

If there's no CAST from ``json`` to ``app_uuid`` defined, the requesty body will still work the native uuid format (``cc7ec76c-5254-4dfc-bf19-9a70ba2ae9b9``).
steve-chavez marked this conversation as resolved.
Show resolved Hide resolved

Advantages over Views and Computed Fields
=========================================

:ref:`Views <tables_views>` and :ref:`computed_cols` also allow us to change the the format of the underlying type. However they come with drawbacks that can be worked around at some complexity costs.
steve-chavez marked this conversation as resolved.
Show resolved Hide resolved

1) Computed fields makes the column not updatable since Postgres doesn't know how to reverse the transform. This can be worked around using INSTEAD OF triggers.
steve-chavez marked this conversation as resolved.
Show resolved Hide resolved
2) When filtering by this column, we get full table scans for the same reason. The performance loss here can be avoided with a computed index, or using a materialized generated column.
3) If the formatted column is used as a foreign key, PostgREST can no longer detect that relationship and :ref:`resource_embedding` breaks. This can be worked around with :ref:`computed_relationships`.

Domain Representations avoid all the above drawbacks. Their only drawback is that for existing tables, you have to change the column types. But this should be a fast operation since domains are binary coercible with their underlying types. A table rewrite won't be required.
1 change: 1 addition & 0 deletions postgrest.dict
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,7 @@ Cardano
cd
centric
changelog
coercible
Cloudfare
config
CORS
Expand Down