This repository has been archived by the owner on Feb 24, 2024. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 163
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
1a9e105
commit a89eebe
Showing
3 changed files
with
183 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 the data in different formats. | ||
|
||
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``). | ||
|
||
Domain Request Body Format | ||
========================== | ||
|
||
For accepting a JSON request body with the shortened format, create a ``json`` to ``app_uuid`` conversion. | ||
|
||
.. 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``). | ||
|
||
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. | ||
|
||
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. | ||
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. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -16,6 +16,7 @@ Cardano | |
cd | ||
centric | ||
changelog | ||
coercible | ||
Cloudfare | ||
config | ||
CORS | ||
|