Skip to content

Commit

Permalink
Add base datatype API doc and examples. (#220)
Browse files Browse the repository at this point in the history
* Add base datatype API doc and examples.

* Minor updates to datatype doc

* Minor updates to datatype doc

* Minor update is->are

* Add datatype examples in plpgsql examples doc.

* Fix minor typos

---------

Co-authored-by: Lyu Pan <[email protected]>
  • Loading branch information
lyupan and Lyu Pan authored Jul 24, 2023
1 parent 02e72af commit 7c06d9c
Show file tree
Hide file tree
Showing 4 changed files with 555 additions and 0 deletions.
2 changes: 2 additions & 0 deletions docs/00_intro.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,8 @@ Trusted Language Extensions for PostgreSQL, or `pg_tle`, is an extension to help

`pg_tle` also exposes additional PostgreSQL functionality for extension building through an API, including PostgreSQL [hooks](./04_hooks.md).

`pg_tle` also supports creating [base data types](./09_datatypes.md) using "trusted languages" through a set of APIs.

While `pg_tle` is designed for systems that have restricted filesystem access, it can be used on any PostgreSQL installation. `pg_tle` allows for PostgreSQL administrators to delegate extension management to unprivileged users using the trusted systems within PostgreSQL. `pg_tle` also provides an access control system that allows PostgreSQL administrators to apply finer-grained permissions on who can manage `pg_tle` compatible extensions.

## Next steps
Expand Down
2 changes: 2 additions & 0 deletions docs/03_managing_extensions.md
Original file line number Diff line number Diff line change
Expand Up @@ -422,3 +422,5 @@ SELECT pgtle.unregister_feature_if_exists('pw_hook', 'passcheck');
## Next steps

Learn how you can use [hooks](./04_hooks.md) to use more PostgreSQL capabilities in your Trusted Language Extensions.

Learn how you can create [base data types](./09_datatypes.md) to use more PostgreSQL capabilities in your Trusted Language Extensions.
161 changes: 161 additions & 0 deletions docs/06_plpgsql_examples.md
Original file line number Diff line number Diff line change
Expand Up @@ -122,3 +122,164 @@ DROP EXTENSION my_password_check_rules;

SELECT pgtle.uninstall_extension('my_password_check_rules');
```

## Example: new data type `test_citext`

```sql
-- 1. Create shell type
SELECT pgtle.create_shell_type('public', 'test_citext');

-- 2. Create I/O functions
CREATE FUNCTION public.test_citext_in(input text) RETURNS bytea AS
$$
BEGIN
RETURN pg_catalog.convert_to(input, 'UTF8');
END
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_out(input bytea) RETURNS text AS
$$
BEGIN
SELECT pg_catalog.convert_from(input, 'UTF8');
END
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

-- 3. Create base type
SELECT pgtle.create_base_type('public', 'test_citext', 'test_citext_in(text)'::regprocedure, 'test_citext_out(bytea)'::regprocedure, -1);

-- 4. Create operator functions
CREATE FUNCTION public.test_citext_cmp(l test_citext, r test_citext)
RETURNS int AS
$$
BEGIN
RETURN pg_catalog.bttextcmp(pg_catalog.lower(pg_catalog.convert_from(l::bytea, 'UTF8')), pg_catalog.lower(pg_catalog.convert_from(r::bytea, 'UTF8')));
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_eq(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) == 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_ne(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) != 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_lt(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) < 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_le(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) <= 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_gt(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) > 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

CREATE FUNCTION public.test_citext_ge(l test_citext, r test_citext)
RETURNS boolean AS
$$
BEGIN
RETURN public.test_citext_cmp(l, r) >= 0;
END;
$$ IMMUTABLE STRICT LANGUAGE plpgsql;

-- 5. Create operators and operator class
CREATE OPERATOR < (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = >,
NEGATOR = >=,
RESTRICT = scalarltsel,
JOIN = scalarltjoinsel,
PROCEDURE = public.test_citext_lt
);

CREATE OPERATOR <= (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = >=,
NEGATOR = >,
RESTRICT = scalarltsel,
JOIN = scalarltjoinsel,
PROCEDURE = public.test_citext_le
);

CREATE OPERATOR = (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = =,
NEGATOR = <>,
RESTRICT = eqsel,
JOIN = eqjoinsel,
HASHES,
MERGES,
PROCEDURE = public.test_citext_eq
);

CREATE OPERATOR <> (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = <>,
NEGATOR = =,
RESTRICT = neqsel,
JOIN = neqjoinsel,
PROCEDURE = public.test_citext_ne
);

CREATE OPERATOR > (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = <,
NEGATOR = <=,
RESTRICT = scalargtsel,
JOIN = scalargtjoinsel,
PROCEDURE = public.test_citext_gt
);

CREATE OPERATOR >= (
LEFTARG = public.test_citext,
RIGHTARG = public.test_citext,
COMMUTATOR = <=,
NEGATOR = <,
RESTRICT = scalargtsel,
JOIN = scalargtjoinsel,
PROCEDURE = public.test_citext_ge
);
-- Superuser privilege might be required
CREATE OPERATOR CLASS public.test_citext_ops
DEFAULT FOR TYPE public.test_citext USING btree AS
OPERATOR 1 < ,
OPERATOR 2 <= ,
OPERATOR 3 = ,
OPERATOR 4 > ,
OPERATOR 5 >= ,
FUNCTION 1 public.test_citext_cmp(public.test_citext, public.test_citext);

-- 6. Use the new type
CREATE TABLE IF NOT EXISTS public.test_dt;
CREATE TABLE public.test_dt(c1 test_citext PRIMARY KEY);
INSERT INTO test_dt VALUES ('SELECT'), ('INSERT'), ('UPDATE'), ('DELETE');
-- ERROR: duplicate key value violates unique constraint "test_dt_pkey"
INSERT INTO test_dt VALUES ('select');
```
Loading

0 comments on commit 7c06d9c

Please sign in to comment.