Skip to content

Commit

Permalink
Merge pull request #349 from supabase/or/table_functions
Browse files Browse the repository at this point in the history
PostgREST compatible computed relationships
  • Loading branch information
olirice authored May 15, 2023
2 parents 22709c6 + de9992c commit 0c1af75
Show file tree
Hide file tree
Showing 11 changed files with 1,580 additions and 518 deletions.
1 change: 1 addition & 0 deletions docs/changelog.md
Original file line number Diff line number Diff line change
Expand Up @@ -24,3 +24,4 @@

## master
- feature: `String` type filters support `regex`, `iregex`
- feature: computed relationships via functions returning setof
240 changes: 236 additions & 4 deletions docs/computed_fields.md
Original file line number Diff line number Diff line change
@@ -1,4 +1,6 @@
## PostgreSQL Builtin (Preferred)
## Computed Values

### PostgreSQL Builtin (Preferred)

PostgreSQL has a builtin method for adding [generated columns](https://www.postgresql.org/docs/14/ddl-generated-columns.html) to tables. Generated columns are reflected identically to non-generated columns. This is the recommended approach to adding computed fields when your computation meets the restrictions. Namely:

Expand All @@ -11,13 +13,243 @@ For example:
```


## Extending Types with Functions
### Extending Types with Functions

For arbitrary computations that do not meet the requirements for [generated columns](https://www.postgresql.org/docs/14/ddl-generated-columns.html), a table's reflected GraphQL type can be extended by creating a function that:

- accepts a single parameter of the table's tuple type
- has a name starting with an underscore
- accepts a single argument of the table's tuple type

```sql
--8<-- "test/expected/extend_type_with_function.out"
```


## Computed Relationships

Computed relations can be helpful to express relationships:

- between entities that don't support foreign keys
- too complex to be expressed via a foreign key

If the relationship is simple, but involves an entity that does not support foreign keys e.g. Foreign Data Wrappers / Views, defining a comment directive is the easiest solution. See the [view doc](/pg_graphql/views) for a complete example. Note that for entities that do not support a primary key, like views, you must define one using a [comment directive](/pg_graphql/configuration/#comment-directives) to use them in a computed relationship.

Alternatively, if the relationship is complex, or you need compatibility with PostgREST, you can define a relationship using set returning functions.


### To-One

To One relationships can be defined using a function that returns `setof <entity> rows 1`

For example
```sql
create table "Person" (
id int primary key,
name text
);

create table "Address"(
id int primary key,
"isPrimary" bool not null default false,
"personId" int references "Person"(id),
address text
);

-- Example computed relation
create function "primaryAddress"("Person")
returns setof "Address" rows 1
language sql
as
$$
select addr
from "Address" addr
where $1.id = addr."personId"
and addr."isPrimary"
limit 1
$$;

insert into "Person"(id, name)
values (1, 'Foo Barington');

insert into "Address"(id, "isPrimary", "personId", address)
values (4, true, 1, '1 Main St.');
```

results in the GraphQL type

=== "Person"
```graphql
type Person implements Node {
"""Globally Unique Record Identifier"""
nodeId: ID!
...
primaryAddress: Address
}
```

and can be queried like a natively enforced relationship

=== "Query"

```graphql
{
personCollection {
edges {
node {
id
name
primaryAddress {
address
}
}
}

}
}
```

=== "Response"

```json
{
"data": {
"personCollection": {
"edges": [
{
"node": {
"id": 1,
"name": "Foo Barington",
"primaryAddress": {
"address": "1 Main St."
}
}
}
]
}
}
}
```



### To-Many

To-many relationships can be defined using a function that returns a `setof <entity>`


For example:
```sql
create table "Person" (
id int primary key,
name text
);

create table "Address"(
id int primary key,
address text
);

create table "PersonAtAddress"(
id int primary key,
"personId" int not null,
"addressId" int not null
);


-- Computed relation to bypass "PersonAtAddress" table for cleaner API
create function "addresses"("Person")
returns setof "Address"
language sql
as
$$
select
addr
from
"PersonAtAddress" pa
join "Address" addr
on pa."addressId" = "addr".id
where
pa."personId" = $1.id
$$;

insert into "Person"(id, name)
values (1, 'Foo Barington');

insert into "Address"(id, address)
values (4, '1 Main St.');

insert into "PersonAtAddress"(id, "personId", "addressId")
values (2, 1, 4);
```

results in the GraphQL type

=== "Person"
```graphql
type Person implements Node {
"""Globally Unique Record Identifier"""
nodeId: ID!
...
addresses(
first: Int
last: Int
before: Cursor
after: Cursor
filter: AddressFilter
orderBy: [AddressOrderBy!]
): AddressConnection
}
```

and can be queried like a natively enforced relationship

=== "Query"

```graphql
{
personCollection {
edges {
node {
id
name
addresses {
edges {
node {
id
address
}
}
}
}
}
}
}
```

=== "Response"

```json
{
"data": {
"personCollection": {
"edges": [
{
"node": {
"id": 1,
"name": "Foo Barington",
"addresses": {
"edges": [
{
"node": {
"id": 4,
"address": "1 Main St."
}
}
]
}
}
}
]
}
}
}
```
30 changes: 19 additions & 11 deletions sql/load_sql_context.sql
Original file line number Diff line number Diff line change
Expand Up @@ -53,8 +53,6 @@ select
pg_enum pe
join pg_type pt
on pt.oid = pe.enumtypid
join schemas_ spo
on pt.typnamespace = spo.oid
group by
pt.oid
)
Expand All @@ -74,14 +72,18 @@ select
'oid', pt.oid::int,
'schema_oid', pt.typnamespace::int,
'name', pt.typname,
-- if type is an array, points at the underlying element type
'category', case
when pt.typcategory = 'A' then 'Array'
when pt.typcategory = 'E' then 'Enum'
when pt.typcategory = 'C' then 'Composite'
when pt.typcategory = 'C'
and tabs.relkind in ('r', 't', 'v', 'm', 'f', 'p') then 'Table'
when pt.typcategory = 'C' and tabs.relkind = 'c' then 'Composite'
else 'Other'
end,
-- if category is 'Array', points at the underlying element type
'array_element_type_oid', nullif(pt.typelem::int, 0),
-- if category is 'Table' points to the table oid
'table_oid', tabs.oid::int,
'comment', pg_catalog.obj_description(pt.oid, 'pg_type'),
'directives', jsonb_build_object(
'name', graphql.comment_directive(pg_catalog.obj_description(pt.oid, 'pg_type')) ->> 'name'
Expand All @@ -93,8 +95,8 @@ select
)
from
pg_type pt
join schemas_ spo
on pt.typnamespace = spo.oid
left join pg_class tabs
on pt.typrelid = tabs.oid
),
jsonb_build_object()
),
Expand All @@ -109,10 +111,12 @@ select
)
from
pg_type pt
join schemas_ spo
on pt.typnamespace = spo.oid
join pg_class tabs
on pt.typrelid = tabs.oid
where
pt.typtype = 'c'
pt.typcategory = 'C'
and tabs.relkind = 'c'

),
jsonb_build_array()
),
Expand Down Expand Up @@ -244,6 +248,12 @@ select
'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 (
Expand Down Expand Up @@ -271,8 +281,6 @@ select
where
pp.pronargs = 1 -- one argument
and pp.proargtypes[0] = pc.reltype -- first argument is table type
and pp.proname like '\_%' -- starts with underscore
and not pp.proretset -- disallow set returning functions (for now)
),
jsonb_build_array()
),
Expand Down
Loading

0 comments on commit 0c1af75

Please sign in to comment.