Skip to content

Commit

Permalink
Merge pull request #393 from imor/expose_udfs
Browse files Browse the repository at this point in the history
Support for UDFs as GraphQL queries/mutations
  • Loading branch information
olirice authored Sep 26, 2023
2 parents e91e915 + fbdcb2b commit e81046c
Show file tree
Hide file tree
Showing 16 changed files with 4,282 additions and 104 deletions.
5 changes: 4 additions & 1 deletion docs/changelog.md
Original file line number Diff line number Diff line change
Expand Up @@ -36,10 +36,13 @@
- bugfix: foreign keys on non-null columns produce non-null GraphQL relationships

## 1.3.0
- rename enum variants with comment directive `@graphql({"mappings": "sql-value": "graphql_value""})`
- feature: rename enum variants with comment directive `@graphql({"mappings": "sql-value": "graphql_value""})`
- bugfix: query with more than 50 fields fails
- bugfix: @skip and @include directives missing from introspection schema
- feature: Support for `and`, `or` and `not` operators in filters
- bugfix: queries failed to run if the database was in read-only replica mode

## master
- feature: citext type represented as a GraphQL String
- feature: Support for Postgres 16
- feature: Support for user defined function
245 changes: 245 additions & 0 deletions docs/functions.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,245 @@
Functions can be exposed by pg_graphql to allow running custom queries or mutations.

## Query vs Mutation

For example, a function to add two numbers will be available on the query type as a field:

=== "Function"

```sql
create function "addNums"(a int, b int)
returns int
immutable
language sql
as $$ select a + b; $$;
```

=== "QueryType"

```graphql
type Query {
addNums(a: Int, b: Int): Int
}
```


=== "Query"

```graphql
query {
addNums(a: 2, b: 3)
}
```

=== "Response"

```json
{
"data": {
"addNums": 5
}
}
```

Functions marked `immutable` or `stable` are available on the query type. Functions marked with the default `volatile` category are available on the mutation type:

=== "Function"

```sql
create table account(
id serial primary key,
email varchar(255) not null
);

create function "addAccount"(email text)
returns int
volatile
language sql
as $$ insert into account (email) values (email) returning id; $$;
```

=== "MutationType"

```graphql
type Mutation {
addAccount(email: String): Int
}
```

=== "Query"

```graphql
mutation {
addAccount(email: "email@example.com")
}
```

=== "Response"

```json
{
"data": {
"addAccount": 1
}
}
```


## Supported Return Types


Built-in GraphQL scalar types `Int`, `Float`, `String`, `Boolean` and [custom scalar types](/pg_graphql/api/#custom-scalars) are supported as function arguments and return types. Function types returning a table or view are supported as well:

=== "Function"

```sql
create table account(
id serial primary key,
email varchar(255) not null
);

insert into account(email)
values
('a@example.com'),
('b@example.com');

create function "accountById"("accountId" int)
returns account
stable
language sql
as $$ select id, email from account where id = "accountId"; $$;
```

=== "MutationType"

```graphql
type Mutation {
addAccount(email: String): Int
}
```

=== "Query"

```graphql
query {
accountById(accountId: 1) {
id
email
}
}
```

=== "Response"

```json
{
"data": {
"accountById": {
"id": 1,
"email": "a@example.com"
}
}
}
```

Functions returning multiple rows of a table or view are exposed as [collections](/pg_graphql/api/#collections).

=== "Function"

```sql
create table "Account"(
id serial primary key,
email varchar(255) not null
);

insert into "Account"(email)
values
('a@example.com'),
('a@example.com'),
('b@example.com');

create function "accountsByEmail"("emailToSearch" text)
returns setof "Account"
stable
language sql
as $$ select id, email from "Account" where email = "emailToSearch"; $$;
```

=== "QueryType"

```graphql
type Query {
accountsByEmail(
emailToSearch: String

"""Query the first `n` records in the collection"""
first: Int

"""Query the last `n` records in the collection"""
last: Int

"""Query values in the collection before the provided cursor"""
before: Cursor

"""Query values in the collection after the provided cursor"""
after: Cursor

"""Filters to apply to the results set when querying from the collection"""
filter: AccountFilter

"""Sort order to apply to the collection"""
orderBy: [AccountOrderBy!]
): AccountConnection
}
```

=== "Query"

```graphql
query {
accountsByEmail(emailToSearch: "a@example.com", first: 1) {
edges {
node {
id
email
}
}
}
}
```

=== "Response"

```json
{
"data": {
"accountsByEmail": {
"edges": [
{
"node": {
"id": 1,
"email": "a@example.com"
}
}
]
}
}
}
```

!!! note

A set returning function with any of its argument names clashing with argument names of a collection (`first`, `last`, `before`, `after`, `filter`, or `orderBy`) will not be exposed.

## Limitations

The following features are not yet supported. Any function using these features is not exposed in the API:

* Functions that return a record type
* Functions that accept a table's tuple type
* Overloaded functions
* Functions with a nameless argument
* Functions with a default argument
* Functions returning void
* Variadic functions
* Function that accept or return an array type
1 change: 1 addition & 0 deletions mkdocs.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ nav:
- SQL Interface: 'sql_interface.md'
- API: 'api.md'
- Views: 'views.md'
- Functions: 'functions.md'
- Computed Fields: 'computed_fields.md'
- Security: 'security.md'
- Configuration: 'configuration.md'
Expand Down
100 changes: 53 additions & 47 deletions sql/load_sql_context.sql
Original file line number Diff line number Diff line change
Expand Up @@ -210,6 +210,7 @@ select
'oid', pc.oid::int,
'name', pc.relname::text,
'relkind', pc.relkind::text,
'reltype', pc.reltype::int,
'schema', schemas_.name,
'schema_oid', pc.relnamespace::int,
'comment', pg_catalog.obj_description(pc.oid, 'pg_class'),
Expand All @@ -235,53 +236,6 @@ select
from
directives d
),
'functions', coalesce(
(
select
jsonb_agg(
jsonb_build_object(
'oid', pp.oid::int,
'name', pp.proname::text,
'type_oid', pp.prorettype::oid::int,
'type_name', pp.prorettype::regtype::text,
'schema_oid', pronamespace::int,
'schema_name', pronamespace::regnamespace::text,
-- Functions may be defined as "returns sefof <entity> rows 1"
-- those should return a single record, not a connection
-- this is important because set returning functions are inlined
-- and returning a single record isn't.
'is_set_of', pp.proretset::bool and pp.prorows <> 1,
'n_rows', pp.prorows::int,
'comment', pg_catalog.obj_description(pp.oid, 'pg_proc'),
'directives', (
with directives(directive) as (
select graphql.comment_directive(pg_catalog.obj_description(pp.oid, 'pg_proc'))
)
select
jsonb_build_object(
'name', d.directive ->> 'name',
'description', d.directive ->> 'description'
)
from
directives d
),
'permissions', jsonb_build_object(
'is_executable', pg_catalog.has_function_privilege(
current_user,
pp.oid,
'EXECUTE'
)
)
)
)
from
pg_catalog.pg_proc pp
where
pp.pronargs = 1 -- one argument
and pp.proargtypes[0] = pc.reltype -- first argument is table type
),
jsonb_build_array()
),
'indexes', coalesce(
(
select
Expand Down Expand Up @@ -411,6 +365,58 @@ select
)
),
jsonb_build_object()
),
'functions', coalesce(
(
select
jsonb_agg(
jsonb_build_object(
'oid', pp.oid::int,
'name', pp.proname::text,
'type_oid', pp.prorettype::oid::int,
'type_name', pp.prorettype::regtype::text,
'schema_oid', pronamespace::int,
'schema_name', pronamespace::regnamespace::text,
'arg_types', proargtypes::int[],
'arg_names', proargnames::text[],
'num_args', pronargs,
'num_default_args', pronargdefaults,
'arg_type_names', pp.proargtypes::regtype[]::text[],
'volatility', pp.provolatile,
-- Functions may be defined as "returns sefof <entity> rows 1"
-- those should return a single record, not a connection
-- this is important because set returning functions are inlined
-- and returning a single record isn't.
'is_set_of', pp.proretset::bool and pp.prorows <> 1,
'n_rows', pp.prorows::int,
'comment', pg_catalog.obj_description(pp.oid, 'pg_proc'),
'directives', (
with directives(directive) as (
select graphql.comment_directive(pg_catalog.obj_description(pp.oid, 'pg_proc'))
)
select
jsonb_build_object(
'name', d.directive ->> 'name',
'description', d.directive ->> 'description'
)
from
directives d
),
'permissions', jsonb_build_object(
'is_executable', pg_catalog.has_function_privilege(
current_user,
pp.oid,
'EXECUTE'
)
)
)
)
from
pg_catalog.pg_proc pp
join search_path_oids spo
on pp.pronamespace = spo.schema_oid
),
jsonb_build_array()
)

)
Loading

0 comments on commit e81046c

Please sign in to comment.