mirror of
https://github.com/postgres/postgres.git
synced 2025-12-19 17:02:53 +03:00
Add transforms feature
This provides a mechanism for specifying conversions between SQL data types and procedural languages. As examples, there are transforms for hstore and ltree for PL/Perl and PL/Python. reviews by Pavel Stěhule and Andres Freund
This commit is contained in:
@@ -79,6 +79,7 @@ Complete list of usable sgml source files in this directory.
|
||||
<!ENTITY createTable SYSTEM "create_table.sgml">
|
||||
<!ENTITY createTableAs SYSTEM "create_table_as.sgml">
|
||||
<!ENTITY createTableSpace SYSTEM "create_tablespace.sgml">
|
||||
<!ENTITY createTransform SYSTEM "create_transform.sgml">
|
||||
<!ENTITY createTrigger SYSTEM "create_trigger.sgml">
|
||||
<!ENTITY createTSConfig SYSTEM "create_tsconfig.sgml">
|
||||
<!ENTITY createTSDictionary SYSTEM "create_tsdictionary.sgml">
|
||||
@@ -120,6 +121,7 @@ Complete list of usable sgml source files in this directory.
|
||||
<!ENTITY dropServer SYSTEM "drop_server.sgml">
|
||||
<!ENTITY dropTable SYSTEM "drop_table.sgml">
|
||||
<!ENTITY dropTableSpace SYSTEM "drop_tablespace.sgml">
|
||||
<!ENTITY dropTransform SYSTEM "drop_transform.sgml">
|
||||
<!ENTITY dropTrigger SYSTEM "drop_trigger.sgml">
|
||||
<!ENTITY dropTSConfig SYSTEM "drop_tsconfig.sgml">
|
||||
<!ENTITY dropTSDictionary SYSTEM "drop_tsdictionary.sgml">
|
||||
|
||||
@@ -52,6 +52,7 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
|
||||
TEXT SEARCH DICTIONARY <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TEXT SEARCH PARSER <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TEXT SEARCH TEMPLATE <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TRANSFORM FOR <replaceable>type_name</replaceable> LANGUAGE <replaceable>lang_name</replaceable> |
|
||||
TYPE <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
VIEW <replaceable class="PARAMETER">object_name</replaceable>
|
||||
|
||||
@@ -259,6 +260,26 @@ ALTER EXTENSION <replaceable class="PARAMETER">name</replaceable> DROP <replacea
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>type_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the data type of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>lang_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the language of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
@@ -55,6 +55,7 @@ COMMENT ON
|
||||
TEXT SEARCH DICTIONARY <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TEXT SEARCH PARSER <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TEXT SEARCH TEMPLATE <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
TRANSFORM FOR <replaceable>type_name</replaceable> LANGUAGE <replaceable>lang_name</replaceable> |
|
||||
TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable> ON <replaceable class="PARAMETER">table_name</replaceable> |
|
||||
TYPE <replaceable class="PARAMETER">object_name</replaceable> |
|
||||
VIEW <replaceable class="PARAMETER">object_name</replaceable>
|
||||
@@ -225,6 +226,26 @@ COMMENT ON
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>type_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the data type of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>lang_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the language of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">text</replaceable></term>
|
||||
<listitem>
|
||||
@@ -305,6 +326,7 @@ COMMENT ON TEXT SEARCH CONFIGURATION my_config IS 'Special word filtering';
|
||||
COMMENT ON TEXT SEARCH DICTIONARY swedish IS 'Snowball stemmer for Swedish language';
|
||||
COMMENT ON TEXT SEARCH PARSER my_parser IS 'Splits text into words';
|
||||
COMMENT ON TEXT SEARCH TEMPLATE snowball IS 'Snowball stemmer';
|
||||
COMMENT ON TRANSFORM FOR hstore LANGUAGE plpythonu IS 'Transform between hstore and Python dict';
|
||||
COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for RI';
|
||||
COMMENT ON TYPE complex IS 'Complex number data type';
|
||||
COMMENT ON VIEW my_view IS 'View of departmental costs';
|
||||
|
||||
@@ -25,6 +25,7 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
[ RETURNS <replaceable class="parameter">rettype</replaceable>
|
||||
| RETURNS TABLE ( <replaceable class="parameter">column_name</replaceable> <replaceable class="parameter">column_type</replaceable> [, ...] ) ]
|
||||
{ LANGUAGE <replaceable class="parameter">lang_name</replaceable>
|
||||
| TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ]
|
||||
| WINDOW
|
||||
| IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
|
||||
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
|
||||
@@ -260,6 +261,23 @@ CREATE [ OR REPLACE ] FUNCTION
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>TRANSFORM { FOR TYPE <replaceable class="parameter">type_name</replaceable> } [, ... ] }</literal></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
Lists which transforms a call to the function should apply. Transforms
|
||||
convert between SQL types and language-specific data types;
|
||||
see <xref linkend="sql-createtransform">. Procedural language
|
||||
implementations usually have hardcoded knowledge of the built-in types,
|
||||
so those don't need to be listed here. If a procedural language
|
||||
implementation does not know how to handle a type and no transform is
|
||||
supplied, it will fall back to a default behavior for converting data
|
||||
types, but this depends on the implementation.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>WINDOW</literal></term>
|
||||
|
||||
|
||||
207
doc/src/sgml/ref/create_transform.sgml
Normal file
207
doc/src/sgml/ref/create_transform.sgml
Normal file
@@ -0,0 +1,207 @@
|
||||
<!-- doc/src/sgml/ref/create_transform.sgml -->
|
||||
|
||||
<refentry id="SQL-CREATETRANSFORM">
|
||||
<indexterm zone="sql-createtransform">
|
||||
<primary>CREATE TRANSFORM</primary>
|
||||
</indexterm>
|
||||
|
||||
<refmeta>
|
||||
<refentrytitle>CREATE TRANSFORM</refentrytitle>
|
||||
<manvolnum>7</manvolnum>
|
||||
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
||||
</refmeta>
|
||||
|
||||
<refnamediv>
|
||||
<refname>CREATE TRANSFORM</refname>
|
||||
<refpurpose>define a new transform</refpurpose>
|
||||
</refnamediv>
|
||||
|
||||
<refsynopsisdiv>
|
||||
<synopsis>
|
||||
CREATE [ OR REPLACE ] TRANSFORM FOR <replaceable>type_name</replaceable> LANGUAGE <replaceable>lang_name</replaceable> (
|
||||
FROM SQL WITH FUNCTION <replaceable>from_sql_function_name</replaceable> (<replaceable>argument_type</replaceable> [, ...]),
|
||||
TO SQL WITH FUNCTION <replaceable>to_sql_function_name</replaceable> (<replaceable>argument_type</replaceable> [, ...])
|
||||
);
|
||||
</synopsis>
|
||||
</refsynopsisdiv>
|
||||
|
||||
<refsect1 id="sql-createtransform-description">
|
||||
<title>Description</title>
|
||||
|
||||
<para>
|
||||
<command>CREATE TRANSFORM</command> defines a new transform.
|
||||
<command>CREATE OR REPLACE TRANSFORM</command> will either create a new
|
||||
transform, or replace an existing definition.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A transform specifies how to adapt a data type to a procedural language.
|
||||
For example, when writing a function in PL/Python using
|
||||
the <type>hstore</type> type, PL/Python has no prior knowledge how to
|
||||
present <type>hstore</type> values in the Python environment. Language
|
||||
implementations usually default to using the text representation, but that
|
||||
is inconvenient when, for example, an associative array or a list would be
|
||||
more appropriate.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
A transform specifies two functions:
|
||||
<itemizedlist>
|
||||
<listitem>
|
||||
<para>
|
||||
A <quote>from SQL</quote> function that converts the type from the SQL
|
||||
environment to the language. This function will be invoked on the
|
||||
arguments of a function written in the language.
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
A <quote>to SQL</quote> function that converts the type from the
|
||||
language to the SQL environment. This function will be invoked on the
|
||||
return value of a function written in the language.
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
It is not necessary to provide both of these functions. If one is not
|
||||
specified, the language-specific default behavior will be used if
|
||||
necessary. (To prevent a transformation in a certain direction from
|
||||
happening at all, you could also write a transform function that always
|
||||
errors out.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To be able to create a transform, you must own and
|
||||
have <literal>USAGE</literal> privilege on the type, have
|
||||
<literal>USAGE</literal> privilege on the language, and own and
|
||||
have <literal>EXECUTE</literal> privilege on the from-SQL and to-SQL
|
||||
functions, if specified.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
<title>Parameters</title>
|
||||
|
||||
<variablelist>
|
||||
<varlistentry>
|
||||
<term><replaceable>type_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the data type of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>lang_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the language of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>from_sql_function_name</replaceable>(<replaceable>argument_type</replaceable> [, ...])</term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the function for converting the type from the SQL
|
||||
environment to the language. It must take one argument of
|
||||
type <type>internal</type> and return type <type>internal</type>. The
|
||||
actual argument will be of the type for the transform, and the function
|
||||
should be coded as if it were. (But it is not allowed to declare an
|
||||
SQL-level function function returning <type>internal</type> without at
|
||||
least one argument of type <type>internal</type>.) The actual return
|
||||
value will be something specific to the language implementation.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>to_sql_function_name</replaceable>(<replaceable>argument_type</replaceable> [, ...])</term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the function for converting the type from the language to
|
||||
the SQL environment. It must take one argument of type
|
||||
<type>internal</type> and return the type that is the type for the
|
||||
transform. The actual argument value will be something specific to the
|
||||
language implementation.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-createtransform-notes">
|
||||
<title>Notes</title>
|
||||
|
||||
<para>
|
||||
Use <xref linkend="sql-droptransform"> to remove transforms.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-createtransform-examples">
|
||||
<title>Examples</title>
|
||||
|
||||
<para>
|
||||
To create a transform for type <type>hstore</type> and language
|
||||
<literal>plpythonu</literal>, first set up the type and the language:
|
||||
<programlisting>
|
||||
CREATE TYPE hstore ...;
|
||||
|
||||
CREATE LANGUAGE plpythonu ...;
|
||||
</programlisting>
|
||||
Then create the necessary functions:
|
||||
<programlisting>
|
||||
CREATE FUNCTION hstore_to_plpython(val internal) RETURNS internal
|
||||
LANGUAGE C STRICT IMMUTABLE
|
||||
AS ...;
|
||||
|
||||
CREATE FUNCTION plpython_to_hstore(val internal) RETURNS hstore
|
||||
LANGUAGE C STRICT IMMUTABLE
|
||||
AS ...;
|
||||
</programlisting>
|
||||
And finally create the transform to connect them all together:
|
||||
<programlisting>
|
||||
CREATE TRANSFORM FOR hstore LANGUAGE plpythonu (
|
||||
FROM SQL WITH FUNCTION hstore_to_plpython(internal),
|
||||
TO SQL WITH FUNCTION plpython_to_hstore(internal)
|
||||
);
|
||||
</programlisting>
|
||||
In practice, these commands would be wrapped up in extensions.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <filename>contrib</filename> section contains a number of extensions
|
||||
that provide transforms, which can serve as real-world examples.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-createtransform-compat">
|
||||
<title>Compatibility</title>
|
||||
|
||||
<para>
|
||||
This form of <command>CREATE TRANSFORM</command> is a
|
||||
<productname>PostgreSQL</productname> extension. There is a <command>CREATE
|
||||
TRANSFORM</command> command in the <acronym>SQL</acronym> standard, but it
|
||||
is for adapting data types to client languages. That usage is not supported
|
||||
by <productname>PostgreSQL</productname>.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-createtransform-seealso">
|
||||
<title>See Also</title>
|
||||
|
||||
<para>
|
||||
<xref linkend="sql-createfunction">,
|
||||
<xref linkend="sql-createlanguage">,
|
||||
<xref linkend="sql-createtype">,
|
||||
<xref linkend="sql-droptransform">
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
</refentry>
|
||||
123
doc/src/sgml/ref/drop_transform.sgml
Normal file
123
doc/src/sgml/ref/drop_transform.sgml
Normal file
@@ -0,0 +1,123 @@
|
||||
<!-- doc/src/sgml/ref/drop_transform.sgml -->
|
||||
|
||||
<refentry id="SQL-DROPTRANSFORM">
|
||||
<indexterm zone="sql-droptransform">
|
||||
<primary>DROP TRANSFORM</primary>
|
||||
</indexterm>
|
||||
|
||||
<refmeta>
|
||||
<refentrytitle>DROP TRANSFORM</refentrytitle>
|
||||
<manvolnum>7</manvolnum>
|
||||
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
||||
</refmeta>
|
||||
|
||||
<refnamediv>
|
||||
<refname>DROP TRANSFORM</refname>
|
||||
<refpurpose>remove a transform</refpurpose>
|
||||
</refnamediv>
|
||||
|
||||
<refsynopsisdiv>
|
||||
<synopsis>
|
||||
DROP TRANSFORM [ IF EXISTS ] FOR <replaceable>type_name</replaceable> LANGUAGE <replaceable>lang_name</replaceable>
|
||||
</synopsis>
|
||||
</refsynopsisdiv>
|
||||
|
||||
<refsect1 id="sql-droptransform-description">
|
||||
<title>Description</title>
|
||||
|
||||
<para>
|
||||
<command>DROP TRANSFORM</command> removes a previously defined transform.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To be able to drop a transform, you must own the type and the language.
|
||||
These are the same privileges that are required to create a transform.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
<title>Parameters</title>
|
||||
|
||||
<variablelist>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>IF EXISTS</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Do not throw an error if the transform does not exist. A notice is issued
|
||||
in this case.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>type_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the data type of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable>lang_name</replaceable></term>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
The name of the language of the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>CASCADE</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Automatically drop objects that depend on the transform.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>RESTRICT</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Refuse to drop the transform if any objects depend on it. This is the
|
||||
default.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-droptransform-examples">
|
||||
<title>Examples</title>
|
||||
|
||||
<para>
|
||||
To drop the transform for type <type>hstore</type> and language
|
||||
<literal>plpythonu</literal>:
|
||||
<programlisting>
|
||||
DROP TRANSFORM FOR hstore LANGUAGE plpythonu;
|
||||
</programlisting></para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1 id="sql-droptransform-compat">
|
||||
<title>Compatibility</title>
|
||||
|
||||
<para>
|
||||
This form of <command>DROP TRANSFORM</command> is a
|
||||
<productname>PostgreSQL</productname> extension. See <xref
|
||||
linkend="sql-createtransform"> for details.
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
<title>See Also</title>
|
||||
|
||||
<simplelist type="inline">
|
||||
<member><xref linkend="sql-createtransform"></member>
|
||||
</simplelist>
|
||||
</refsect1>
|
||||
|
||||
</refentry>
|
||||
Reference in New Issue
Block a user