Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add procedure support #41

Merged
merged 35 commits into from
May 11, 2016
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
35 commits
Select commit Hold shift + click to select a range
9c0e9d8
Add sample procedures to forum example
calebmer Apr 30, 2016
9f632b2
Add procedures to catalog
calebmer Apr 30, 2016
6c452cd
Change how types are handled
calebmer Apr 30, 2016
474ea66
Move table sql utility function
calebmer Apr 30, 2016
daf8129
Clean up catalog API
calebmer May 1, 2016
0c9e177
Give get table sql function its own file
calebmer May 1, 2016
5a1dfb7
Add another exapmle function
calebmer May 1, 2016
16a74a1
Make internal lookup more explicit
calebmer May 1, 2016
773d93a
Memoize expensive getters
calebmer May 1, 2016
f5edb30
Add initial procedure support
calebmer May 1, 2016
06af8cc
Add procedure mutation field
calebmer May 1, 2016
b70b683
Use min reporter for watching tests
calebmer May 1, 2016
3b0f530
Use search procedure for example
calebmer May 1, 2016
aa73dcf
Fix client mutation id in procedures
calebmer May 1, 2016
a7ebf31
docs(examples): typo in comment
tobiasmuehl May 4, 2016
4ec2c38
Add procedure queries
calebmer May 6, 2016
f9c5764
1.3.0-beta.0
calebmer May 6, 2016
2bf395c
Add table name prefix to computed columns
calebmer May 7, 2016
2c6280b
Rename mutation payload output field name
calebmer May 7, 2016
6398494
Add headline search to search posts procedure
calebmer May 8, 2016
ee64b16
Add computed column functionality
calebmer May 8, 2016
07fc9ec
Make row table identifier property a symbol
calebmer May 8, 2016
5abfe71
Add basic computed column test
calebmer May 8, 2016
23352ba
Add TODO note
calebmer May 8, 2016
3d9c286
Fix error when returning null for a table
calebmer May 8, 2016
ce0d6c2
Fix computed column with arguments
calebmer May 8, 2016
4de8486
1.3.0-beta.1
calebmer May 8, 2016
59dd4ef
Make start script take a schema argument
calebmer May 9, 2016
1c82ef1
Fix compound key single selection bug
calebmer May 9, 2016
c2377ed
Migrate tests to a kitchen sink example
calebmer May 9, 2016
11cae7b
Refactor sql module to SQLBuilder class
calebmer May 10, 2016
c2cbc70
Add new test case
calebmer May 10, 2016
7edce19
Fix SQLBuilder regex
calebmer May 10, 2016
b8ecbda
Use connections for procedures returning setof
calebmer May 10, 2016
7a76c2f
Add documentation for procedures
calebmer May 10, 2016
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 2 additions & 1 deletion .babelrc
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
{
"presets": ["modern-node/4.0"]
"presets": ["modern-node/4.0"],
"sourceMaps": true
}
37 changes: 37 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -72,6 +72,43 @@ Can query relations like so:
}
```

### Procedures for Mutations, Advanced Queries, and Computed Columns
Procedures in PostgreSQL are powerful for writing business logic in your database schema, and PostGraphQL allows you to access those procedures through a GraphQL interface. Create a custom mutation, write an advanced SQL query, or even extend your tables with computed columns! Procedures allow you to write logic for your app in SQL instead of in the client all while being accessible through the GraphQL interface.

So a search query could be written like this:

```sql
create function search_posts(search text) returns setof post as $$
select *
from post
where
headline ilike ('%' || search || '%') or
body ilike ('%' || search || '%')
$$ language sql stable;
```

And queried through GraphQL like this:

```graphql
{
searchPosts(search: "Hello world", first: 5) {
pageInfo {
hasNextPage
}
totalCount
nodes {
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Should this be edges { node { headline, body } }?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

nodes is a little simpler and less intimidating for the README I think.

Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Ah, but returns the same? I've not checked the implementation yet

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yep, it only returns the list, it's a shortcut if you're not interested in the cursors.

headline
body
}
}
}
```

For more information, check out our [procedure documentation][] and our [advanced queries documentation][].

[procedure documentation]: https://github.com/calebmer/postgraphql/blob/master/docs/procedures.md
[advanced queries documentation]: https://github.com/calebmer/postgraphql/blob/master/docs/advanced-queries.md

### Fully Documented APIs
Introspection of a GraphQL schema is powerful for developer tooling and one element of introspection is that every type in GraphQL has an associated `description` field. As PostgreSQL allows you to document your database objects, naturally PostGraphQL exposes these documentation comments through GraphQL.

Expand Down
58 changes: 58 additions & 0 deletions docs/advanced-queries.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
# Advanced Queries
PostGraphQL, by default only allows you to query the entirety of rows in a table with fields like `personNodes` or `postNodes`. This may change in the future when PostGraphQL collaborators find a good way to represent complex queries across multiple columns with multiple operators in the GraphQL type system. Advanced queries allow you to write a query for your app in SQL, not the client, while still using the powerful GraphQL interface.

In the mean time there is another (arguably better) way to specify your own advanced queries with custom logic. By using [procedures][]!

So let’s write a search query for our [forum example][] using the PostgreSQL [`LIKE`][] operator (we’ll actually use `ILIKE` because it is case insensitive). The custom query we create is included in the forum example’s schema, so if you want to run that example locally you can try it out.

The procedure would look like the following. Indentation is non-standard so we can fit in comments to explain what’s going on.

```sql
-- Our `post` table is created with the following columns. Columns unnecessary
-- to this demo were omitted. You can find the full table in our forum example.
create table post (
headline text not null,
body text,
);

-- Create the function named `search_posts` with a text argument named `search`.
create function search_posts(search text)
-- This function will return a set of posts from the `post` table. The
-- `setof` part is important to PostGraphQL, check out our procedure docs to
-- learn why.
returns setof post as $$
-- Write our advanced query as a SQL query!
select *
from post
where
-- Use the `ILIKE` operator on both the `headline` and `body` columns. If
-- either return true, return the post.
headline ilike ('%' || search || '%') or
body ilike ('%' || search || '%')
-- End the function declaring the language we used as SQL and add the
-- `STABLE` marker so PostGraphQL knows its a query and not a mutation.
$$ language sql stable;
```

And that’s it! You can now use this function in your GraphQL like so:

```graphql
{
searchPosts(search: "Hello world", first: 5) {
pageInfo {
hasNextPage
}
totalCount
nodes {
headline
body
}
}
}
```

[procedures]: https://github.com/calebmer/postgraphql/blob/master/docs/procedures.md
[forum example]: https://github.com/calebmer/postgraphql/tree/master/examples/forum
[`LIKE`]: http://www.postgresql.org/docs/current/static/functions-matching.html
234 changes: 234 additions & 0 deletions docs/procedures.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,234 @@
# Procedures
Procedures in PostgreSQL are very important to understand in order to make the most powerful PostGraphQL server you can. Procedures allow you to define business logic in the database in SQL or one of many other scripting languages. Often putting your business logic in the database will be more performant as PostgreSQL is already finely tuned to be highly performant and scale for data intensive uses.

There are a few ways procedures in PostGraphQL can be used. All of these will be covered in their own section.

1. As [mutations](#mutation-procedure).
2. As [queries](#query-procedure).
3. As [connections](#connection-procedure) (list of nodes, like `postNodes`).
4. As [computed columns](#computed-columns).

For an example of what procedures look like, see the [forum example SQL schema][].

[forum example SQL schema]: https://github.com/calebmer/postgraphql/blob/master/examples/forum/schema.sql

## Recommended Reading
- PostgreSQL [`CREATE FUNCTION`][] documentation for actually creating procedures.
- PostgreSQL [`CREATE TRIGGER`][] documentation.
- StackOverflow answer describing [computed columns in PostgreSQL][].

[`CREATE FUNCTION`]: http://www.postgresql.org/docs/current/static/sql-createfunction.html
[`CREATE TRIGGER`]: http://www.postgresql.org/docs/current/static/sql-createtrigger.html
[computed columns in PostgreSQL]: http://stackoverflow.com/a/11166268/1568890

## Scripting Languages
Procedures in PostgreSQL require you to use a scripting language. The two most common procedure languages for PostgreSQL are SQL and [PL/pgSQL][PL/pgSQL]. SQL is probably the easiest to use as you are most likely already familiar with it. PL/pgSQL is PostgreSQL’s custom scripting language which is fairly easy to find plenty of StackOverflow and other resources on with a few search engine queries. You’ll need to learn PL/pgSQL if you want to write any triggers, because SQL can’t be used for triggers. But again, don’t worry, you can definetly make awesome applications without know PL/pgSQL as well as other languages you are familiar with as long as you defer to the internet.

A simple procedure written with SQL looks like this:

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

The samle procedure with PL/pgSQL would look like this:

```sql
create function add(a int, b int) returns int as $$
begin
return a + b;
end;
$$ language plpgsql immutable strict;
```

If you don’t want to use PL/pgSQL or SQL, many popular scripting languages can be used *inside* PostgreSQL to write your procedures! You can see a few of these projects here:

- [JavaScript (plv8)][]
- [Ruby (plruby)][]

A procedure defined using JavaScript (for example) would look like:

```sql
-- This does look the exact same as the PL/pgSQL example…
create function add(a int, b int) returns int as $$
return a + b;
$$ language plv8 immutable strict;

-- Here’s a better example from the plv8 repo…
create function plv8_test(keys text[], vals text[]) returns text as $$
var object = {}
for (var i = 0; i < keys.length; i++) {
object[keys[i]] = vals[i]
}
return JSON.stringify(object)
$$ language plv8 immutable strict;
```

[PL/pgSQL]: http://www.postgresql.org/docs/current/static/plpgsql.html
[JavaScript (plv8)]: https://github.com/plv8/plv8
[Ruby (plruby)]: https://github.com/knu/postgresql-plruby

## Named Arguments
PostgreSQL allows you to mix named and positional (unnamed) arguments for your procedures. However, GraphQL will *only* allow named arguments. So if you don’t name an argument, PostGraphQL will give it a name like `arg1`, `arg2`, `arg3`, and so on. An example of a function with unnamed arguments is as follows:

```sql
create function add(int, int) returns int as $$
select $1 + $2;
$$ language sql immutable strict;
```

Whereas named arguments look like:

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

## Mutation Procedures
By default, a procedure is “volatile” and PostGraphQL will treat it as a mutation. So for example, a procedure defined as:

```sql
CREATE FUNCTION my_function(a int, b int) RETURNS int AS $$ … $$ LANGUAGE SQL;
```

Is equivalent to a procedure defined as:

```sql
CREATE FUNCTION my_function(a int, b int) RETURNS int AS $$ … $$ LANGUAGE SQL VOLATILE;
```

From the PostgreSQL docs:

> `VOLATILE` indicates that the function value can change even within a single table scan, so no optimizations can be made…But note that any function that has side-effects must be classified volatile, even if its result is quite predictable, to prevent calls from being optimized away; an example is `setval()`.

In simpler terms `VOLATILE` basically means you are changing your data.

Anyone familiar with HTTP could compare a `VOLATILE` procedure to “unsafe” HTTP methods like `POST`, `PUT`, and `DELETE`.

All mutative procedures will be represented in the GraphQL type system by PostGraphQL in a way that is Relay compatible with a single input object. You would execute a procedure similar to this one like so:

```graphql
mutation {
myFunction(input: { a: 1, b: 2 }) {
output
}
}
```

Always look at the documentation in GraphiQL to find all the parameters you may use!

## Query Procedures
Similar to how you use `VOLATILE` to specify a mutative procedure, a query procedure can be specified using `IMMUTABLE` or `STABLE` identifiers. For example:

```sql
CREATE FUNCTION my_function(a int, b int) RETURNS int AS $$ … $$ LANGUAGE SQL STABLE;

-- or…

CREATE FUNCTION my_function(a int, b int) RETURNS int AS $$ … $$ LANGUAGE SQL IMMUTABLE;

-- or if you wanted to return a row from a table…

CREATE FUNCTION my_function(a int, b int) RETURNS my_table AS $$ … $$ LANGUAGE SQL STABLE;
```

From the PostgreSQL docs:

> `IMMUTABLE` indicates that the function cannot modify the database and always returns the same result when given the same argument values; that is, it does not do database lookups or otherwise use information not directly present in its argument list. If this option is given, any call of the function with all-constant arguments can be immediately replaced with the function value.

and…

> `STABLE` indicates that the function cannot modify the database, and that within a single table scan it will consistently return the same result for the same argument values, but that its result could change across SQL statements. This is the appropriate selection for functions whose results depend on database lookups, parameter variables (such as the current time zone), etc. (It is inappropriate for AFTER triggers that wish to query rows modified by the current command).

To use the HTTP analogy again, `IMMUTABLE` and `STABLE` are comparable to “safe” HTTP methods like `GET` and `HEAD`.

To query such a procedure in PostGraphQL you would do the following:

```graphql
{
# For a procedure without arguments
myFunction

# For a procedure with arguments
myFunction(a: 1, b: 2)

# For a procedure that returns a row
myFunction(a: 1, b: 2) {
id
}
}
```

## Connection Procedures
A connection query can be made from any function that returns a `setof` with a table type. This feature is also significant in that it gives you the ability to create complex queries over a set of data. Queries that connections (like `personNodes`) in PostGraphQL do not support.

To create a function that returns a connection, use the following SQL:

```sql
-- Assuming we already have a table named `person`…

CREATE FUNCTION my_function(a int, b int) RETURNS SETOF person AS $$ … $$ LANGUAGE SQL;
```

To query a set in PostGraphQL, you would use all of the connection arguments you are familiar with in addition to the arguments to your procedure. For example:

```graphql
{
myFunction(a: 1, b: 2, first: 2) {
pageInfo {
hasNextPage
hasPrevPage
}
edges {
cursor
node {
id
}
}
}
}
```

For more information on constructing advanced queries, read [this article][advanced-queries].

[advanced-queries]: https://github.com/calebmer/postgraphql/blob/master/docs/advanced-queries.md

## Computed Columns
PostGraphQL also provides support for computed columns. In order to define a computed column, just write a function that is `STABLE` or `IMMUTABLE` and has a table in your schema as its first argument. For example:

```sql
CREATE FUNCTION full_name(person person) RETURNS text AS $$
select person.given_name || ' ' || person.family_name
$$ LANGUAGE SQL;
```

Will create a computed column for your table named `person`. If you want, you can also prefix your computed procedure’s name with your table name. This is helpful when you want to avoid namespacing clashes but it is not required.

```sql
-- PostGraphQL will treat this the same as the procedure above.

CREATE FUNCTION person_full_name(person person) RETURNS text AS $$
select person.given_name || ' ' || person.family_name
$$ LANGUAGE SQL;
```

To query these in the PostGraphQL schema, its pretty intuitive:

```graphql
{
person(id: …) {
givenName
familyName
fullName # A computed column, but the client doesn’t even know!
myFunction(a: 1, b: 2) # A computed column with arguments.
}
}
```

* * *

For ideas on how to use procedures in PostGraphQL, remember to check out the [forum example SQL schema][]!

[forum example SQL schema]: https://github.com/calebmer/postgraphql/blob/master/examples/forum/schema.sql
8 changes: 8 additions & 0 deletions examples/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
# Examples
This directory contains examples of PostGraphQL for people looking to learn it or looking for a good PostGraphQL reference.

If you are new to the PostGraphQL project, definetly go to the forum example!

- **`forum`**: The forum example is the best for beginners and people looking to spin up a PostGraphQL server to see what’s up. It contains the schema for a basic forum with users, posts, and comments.

- **`kitchen-sink`**: This example is used in integration testing for testing all the features of PostGraphQL. This example is also a good reference for writing a PostgreSQL schema.
Loading