mirror of
https://github.com/hasura/graphql-engine.git
synced 2024-12-21 22:41:43 +03:00
185 lines
5.0 KiB
ReStructuredText
185 lines
5.0 KiB
ReStructuredText
.. meta::
|
|
:description: Set default field values using SQL functions
|
|
:keywords: hasura, docs, schema, default value, sql function, stored procedure
|
|
|
|
.. _sql_functions_as_default:
|
|
|
|
Setting values of fields using SQL functions
|
|
============================================
|
|
|
|
.. contents:: Table of contents
|
|
:backlinks: none
|
|
:depth: 1
|
|
:local:
|
|
|
|
Introduction
|
|
------------
|
|
|
|
Let's say you want to set the value of some fields as the output of some `custom SQL functions <https://www.postgresql.org/docs/current/sql-createfunction.html>`__
|
|
(a.k.a. stored procedures). This is useful to set values of fields which depend on other fields passed in the input. E.g. set
|
|
``submission_time`` of an online quiz as 1 hour from the ``start_time``.
|
|
|
|
This can be achieved by:
|
|
|
|
#. Modifying the table to allow the columns we want to be set by the SQL functions to be nullable (to allow the initial
|
|
insert before the SQL function is run).
|
|
#. Creating an insert/update trigger on the table that calls your SQL function and sets the output values in the output
|
|
columns.
|
|
#. Making your mutation requests without setting the SQL function output columns.
|
|
|
|
.. note::
|
|
|
|
This approach enforces the value set in the field to always be the result of the defined SQL function even if a
|
|
value is explicitly passed in the insert object.
|
|
|
|
**For example**, say we have a table ``sql_function_table`` with columns ``input`` and ``output`` and we would like
|
|
to set the value of the ``output`` column as the uppercased value of the string received in the ``input`` field.
|
|
|
|
Step 1: Modify the table
|
|
------------------------
|
|
|
|
Modify the table ``sql_function_table`` and make its ``output`` column nullable.
|
|
|
|
.. rst-class:: api_tabs
|
|
.. tabs::
|
|
|
|
.. tab:: Console
|
|
|
|
Open the console and head to ``Data -> [sql_function_table] -> Modify``:
|
|
|
|
.. thumbnail:: /img/graphql/core/schema/modify-sql-fn-table.png
|
|
:alt: Modify the table
|
|
|
|
.. tab:: CLI
|
|
|
|
:ref:`Create a migration manually <manual_migrations>` and add the following SQL statement to the ``up.sql`` file:
|
|
|
|
.. code-block:: SQL
|
|
|
|
ALTER TABLE "public"."sql_function_table" ALTER COLUMN "output" DROP NOT NULL;
|
|
|
|
Add the following statement to the ``down.sql`` file in case you need to :ref:`roll back <roll_back_migrations>` the above statement:
|
|
|
|
.. code-block:: sql
|
|
|
|
ALTER TABLE "public"."sql_function_table" ALTER COLUMN "output" SET NOT NULL;
|
|
|
|
Apply the migration by running:
|
|
|
|
.. code-block:: bash
|
|
|
|
hasura migrate apply
|
|
|
|
.. tab:: API
|
|
|
|
You can modify a table column by using the :ref:`run_sql metadata API <run_sql>`:
|
|
|
|
.. code-block:: http
|
|
|
|
POST /v1/query HTTP/1.1
|
|
Content-Type: application/json
|
|
X-Hasura-Role: admin
|
|
|
|
{
|
|
"type": "run_sql",
|
|
"args": {
|
|
"sql": "ALTER TABLE sql_function_table ALTER COLUMN output DROP NOT NULL;"
|
|
}
|
|
}
|
|
|
|
Step 2: Create a trigger
|
|
------------------------
|
|
|
|
The below SQL defines a ``trigger`` which will simply uppercase the value passed in the ``input`` field and set it to
|
|
the ``output`` field whenever an insert or update is made to the ``sql_function_table``:
|
|
|
|
.. code-block:: plpgsql
|
|
|
|
CREATE FUNCTION test_func() RETURNS trigger AS $emp_stamp$
|
|
BEGIN
|
|
NEW.output := UPPER(NEW.input);
|
|
RETURN NEW;
|
|
END;
|
|
$emp_stamp$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER test_trigger BEFORE INSERT OR UPDATE ON sql_function_table
|
|
FOR EACH ROW EXECUTE PROCEDURE test_func();
|
|
|
|
.. rst-class:: api_tabs
|
|
.. tabs::
|
|
|
|
.. tab:: Console
|
|
|
|
Head to ``Data -> SQL`` and run the above SQL:
|
|
|
|
.. thumbnail:: /img/graphql/core/schema/create-trigger.png
|
|
:alt: Create a trigger with SQL
|
|
|
|
.. tab:: CLI
|
|
|
|
:ref:`Create a migration manually <manual_migrations>` and add the above SQL to the ``up.sql`` file. Also, add a statement to revert the previous statement to the ``down.sql``.
|
|
|
|
Apply the migration by running:
|
|
|
|
.. code-block:: bash
|
|
|
|
hasura migrate apply
|
|
|
|
.. tab:: API
|
|
|
|
You can create a trigger by using the :ref:`run_sql metadata API <run_sql>`:
|
|
|
|
.. code-block:: http
|
|
|
|
POST /v1/query HTTP/1.1
|
|
Content-Type: application/json
|
|
X-Hasura-Role: admin
|
|
|
|
{
|
|
"type": "run_sql",
|
|
"args": {
|
|
"sql": "<above SQL>"
|
|
}
|
|
}
|
|
|
|
Step 3: Run an insert mutation
|
|
------------------------------
|
|
|
|
Run a mutation to insert an object with (input = "yabba dabba doo!", output=null) and you'll see the output
|
|
value (output="YABBA DABBA DOO!") will be set automatically.
|
|
|
|
.. graphiql::
|
|
:view_only:
|
|
:query:
|
|
mutation {
|
|
insert_sql_function_table (
|
|
objects: [
|
|
{input: "yabba dabba doo!"}
|
|
]
|
|
) {
|
|
returning {
|
|
input
|
|
output
|
|
}
|
|
}
|
|
}
|
|
:response:
|
|
{
|
|
"data": {
|
|
"insert_sql_function_table": {
|
|
"returning": [
|
|
{
|
|
"input": "yabba dabba doo!",
|
|
"output": "YABBA DABBA DOO!"
|
|
}
|
|
]
|
|
}
|
|
}
|
|
}
|
|
|
|
Also see
|
|
--------
|
|
|
|
- :ref:`postgres_defaults`
|
|
- :ref:`column_presets`
|