Skip to content

Commit

Permalink
Beginning of new class on functions (#36)
Browse files Browse the repository at this point in the history
* up to date (#1)

* Cleanup

* Use latest version of docker

* Remove Docker first

* Remove more of Docker

* Start Docker after installing

* fixed misspecification

* breaking apart the workshop

* beginning

* finished first page and added to the dir

* more scaffolding

* more progress

* mid progress in page 3

* a little more

* done for now
  • Loading branch information
thesteve0 authored Jul 11, 2019
1 parent e2a604a commit 486092d
Show file tree
Hide file tree
Showing 19 changed files with 664 additions and 1 deletion.
8 changes: 7 additions & 1 deletion basic-postgresql-devel-pathway.json
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@
{
"external_link": "https://crunchydata.katacoda.com/basic-postgresql-devel/runcontainers/",
"course_id": "runcontainers",
"title": "Quick Intro To PostgreSQL in Containers"
"title": "Quick Intro. To PostgreSQL in Containers"
}, {
"external_link": "https://crunchydata.katacoda.com/basic-postgresql-devel/qftextintro/",
"course_id": "qftextintro",
Expand All @@ -14,8 +14,14 @@
"external_link": "https://crunchydata.katacoda.com/basic-postgresql-devel/qjsonintro/",
"course_id": "qjsonintro",
"title": "Quick Intro To JSON in PostgreSQL"
},
{
"external_link": "https://crunchydata.katacoda.com/basic-postgresql-devel/basicfunctions",
"course_id": "basicfunctions",
"title": "Basics of Writing PostgreSQL Functions"
}


]

}
70 changes: 70 additions & 0 deletions basic-postgresql-devel/basicfunctions/01-first-function.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,70 @@
# Our First Function

Let's lay a little groundwork so we can write our first function. There are some basic pieces all functions, regardless
of programming language, need in order to work.

## Basic Pieces of Every Function

Just like functions in other languages, PostgreSQL functions has certain structure and syntax. Let's avoid dealing
with parameters for the time being and just make the simplest function possible. We are just going to make a simple
function that returns, get ready for it, the string "hello world".

### The Declaration - the name and parameters

Let's go to terminal, which is already at the psql interactive prompt. To being with we need to start the opening
block of the function and give it a name. Please note the capitalization for SQL reserved words is optional but done
here for clarity.

```
CREATE FUNCTION brilliance()
```{{execute}}
We are declaring a function named "brilliance" and saying it doesn't accept any parameters. We will return to cover this
declaration in more depth later in the scenario.
### Return Declaration
We already stated we are going to return a string so let's go ahead and set that up. In later scenarios we will explore
other return types.
```
RETURNS VARCHAR AS
```{{execute}}
### Function Body
Now we can write our function body. We demarcate the begin and end of the code with $$ symbol. We use $$ rather than " or
' so that we don't have to bother escaping strings in our code. When using SQL as our programming language only the last
executed line (ending in a ;) will be returned. We also *can't* use RETURN to specify which result we want to return.
```
$$
SELECT 'hello world';
$$
```{{execute}}
Notice we use the SQL ';' delimeters at the the end of each SQL statement.
### Language Specification
Finally, we need to tell PostgreSQL what programming language we used in our function. In this case we are just going
to use SQL.
```
LANGUAGE sql;
```{{execute}}
## Calling our New Function
Now to use our brand new shiny function
```
select brilliance();
```{{execute}}
Now any time we want to say "Hello World" in the _workshop_ database all we have to do is call our function.
I know this wasn't that exciting yet but hopefully, now you see the basic structure of PostgreSQL function. As mentioned
in the intro., functions form the bases for most every extra functionality we want to create, such a stored procedures.
## Wrap Up
We just finished the basic skeleton of a function: declaration, function name, parameters, return type, code block, and
language used. In our next exercise we will explore doing more with the function declaration and parameters.
119 changes: 119 additions & 0 deletions basic-postgresql-devel/basicfunctions/02-name-parameters.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,119 @@
# Function Declarations and Parameters

While our function is amazing, perhaps we do want to do a bit of editing to it. Maybe accept some parameters or change
the code.

## Create versus Replace

Functions are immutable, there is no way to edit them in place. So while we used CREATE in our first example, the
recommended pattern is to instead say "CREATE or REPLACE FUNCTION"

This tells PostgreSQL if this function doesn't exist then create it otherwise, replace the one that is there. From now on
we are going to use this so we can keep iterating on our function.

## Parameterising Our Function

You know the next step in our function right? Of course we need to get it so say "Hello <your name>". Let's start with the
simplest way possible

```
CREATE OR REPLACE FUNCTION brilliance(varchar)
RETURNS VARCHAR AS
```{{execute}}
We are saying that this function requires the caller to pass in a string along with the function call. From the PostgreSQL
documentation:
The argument types can be base, composite, or domain types, or can reference the type of a table column.
Just use the type as if you were defining a column in a table.
### Referencing the Parameter in the Code
Now we can use this parameter in the code.
```
$$
SELECT 'hello ' || $1;
$$
LANGUAGE sql;
```{{execute}}
If we had used more parameters we would keep incrementing the $number for each new parameter. The '||' is the concatenation
operator per the SQL standard.
Let's go ahead and use our cool new function!
'''
select brilliance('student');
'''{{execute}}
Go ahead and change the name to anything else you want to try.
## Better Parameter Names
While it was easy to just put in 'varchar' for the parameter, that is not as easy to use and read in the body of our code.
Let's clean this up and make more literate code. You can give a name to the parameter and it appears right before the type
declaration. We will also add another parameter so you can see how to handle passing in multiple named variables.
```
CREATE OR REPLACE FUNCTION brilliance(name varchar, rank int)
RETURNS VARCHAR AS
$$
SELECT 'hello ' || name || '! You are number ' || rank;
$$
LANGUAGE sql;
```{{execute}}
This code is much more readable and maintainable. We also got to see that the '||' operator will work with non-string types
as long as there is one string type in the concatenation.
Time to exercise our function again:
'''
select brilliance('student', 1);
'''{{execute}}
## Default Values for Parameters
It is also possible to specify default values for parameters for when the function is called without a value for a parameter.
**Note**, if you have a list of parameters, once you specify a default value for a parameter ALL following parameters must
have default values as well.
Let's go ahead and specify default values for both parameters in our great new function.
```
CREATE OR REPLACE FUNCTION brilliance(name varchar = 'Jorge', rank int = 7)
RETURNS VARCHAR AS
$$
SELECT 'hello ' || name || '! You are number ' || rank;
$$
LANGUAGE sql;
```{{execute}}
And now if we call our function we will get those values if we don't specify a value
'''
select brilliance();
'''{{execute}}
But we can also specify only one parameter and use the parameter name. Read more in the [official docs](https://www.postgresql.org/docs/11/sql-syntax-calling-funcs.html) about how
to call functions:
'''
select brilliance(rank => 1);
'''{{execute}}
## Wrap Up
**NOTE** No two functions can have the same name UNLESS they have different parameter signatures.
For example, you can't have two functions named _myfunction_ unless one is myfunction()
and the other is myfunction(myparam varchar). What this also means is that you can overload a function to
do different behavior depending on the types passed in. Keep this in mind if you run into an error or trying to determine
how to architect your functions.
Though we covered the basics of adding parameters to your functions we will return to this as we move on to the next section.
In the next exercise we will cover different ways to return values and how to handle different return types.
133 changes: 133 additions & 0 deletions basic-postgresql-devel/basicfunctions/03-return-types.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,133 @@
# Return Types

For this final section we are going to cover all the ways you can return data from your functions as well how to handle
different data return types. Let's move on from just returning a single value and perhaps throw in a little Pl/PGSQL the
procedural language included with PostgreSQL.

We will start by showing how the actual RETURN statement is not necessary.

## IN, OUT, and INOUT Paremeters

PostgreSQL allows you to specify the "direction" data flows into a function based on how you declare the parameter. By
default all parameters are specified as IN parameters, meaning data is only passed into the function with the parameter.

If you declare a parameter as OUT then data will be returned. You can have more than one OUT parameter in a function. Using a
RETURNS <type> AS statement when you have OUT parameters is optional. If you
use the RETURNS <type> AS statement with your function, it's type must match the type of our OUT parameters.

An INOUT parameter means it will be used to pass data in and then return data through this parameter name as well

For our function let's rid of the RETURNS <type> AS statement and add another OUT parameter

```
CREATE OR REPLACE FUNCTION
brilliance(name varchar = 'Jorge', rank int = 7, out greetings varchar, out word_count int)
AS
```{{execute}}
We left the original signature in place but now we added two OUT parameters: 1) greetings which will hold the full statement
and 2) word_count which will hold the count of characters in the greetings parameter.
Now let's alter the body of the text.
```
$$
BEGIN
greetings := (SELECT 'hello ' || name || '! You are number ' || rank);
word_count := length(greetings);
END;
$$
LANGUAGE plpgsql;

```{{execute}}
Remember that if we left the language as SQL it would only return the final value and we couldn't really do the assignment of
values to parameters. So we change the language to Pl/PGSQL. Now we get access to the **:=** [assignment operator}(https://www.postgresql.org/docs/11/plpgsql-statements.html).
Because we are using PL/PGSQL we also need to wrap out code in BEGIN and END; statements. Finally, the := operator can only be used
for assignment of a single value or a single row we need to wrap our select statement in ( ) to coerce to a single value.
### Using this new and improved function:
When we use this function:
'''
select brilliance();
'''{{execute}}
Notice we get a different type of result:
```
workshop=> select brilliance();
brilliance
--------------------------------------
("hello Jorge! You are number 7",29)
(1 row)

```
We get a single column result with a name matching the function name. For the value we get an array containing our two values.
You can think of this as PostgreSQL coercing all our OUT variables into an array. It would continue appending to
the array for every OUT or INOUT variable we declared. Technically what happened is the our result is actually created an
anonymous record type to hold the output.
Let's make it a bit nicer to read:
'''
select * from brilliance();
'''{{execute}}
Which should give you a result like this:
```
workshop=> select * from brilliance();
greetings | word_count
-------------------------------+------------
hello Jorge! You are number 7 | 29
(1 row)

```
Now we get a row result but the column names match the OUT variable names. Again if we add more OUT variables the result
would just have more columns.
## Different Data Types to Return
So far all we have returning simple values that match base types in SQL. As mentioned earlier you can
return anything you can use to define a column in a table, even your custom defined type.
Quite often you are going to want to return a row in a table or perhaps a whole table (or use them as OUT parameters):
1. RETURNS RECORD - A record can be thought of as a single row in an arbitrary table.
1. RETURNS <tablename> - If you want a row to obey the schema of a table you can just pass in the table name.
1. RETURNS SETOF RECORD - By adding the SETOF to the statement you can now return multiple records (rows)
1. RETURNS SETOF <tablename> - And by extension, this will return multiple rows with a schema that obeys the table schema
Specific to the RETURNS X AS, you can actually define a table in the place of X. For example:
```
CREATE FUNCTION my-little-table()
RETURNS TABLE (id int, name text, quarter tsrange)
As $$
```
## Clean up
To get rid of our functions we can just do:
'''
DROP FUNCTION brilliance;
```


## Wrap Up

With that we have concluded our basic introduction to PostgreSQL functions. We did not actually go into specifics of PL/PGSQL
or PL/Python nor did we cover any of the more advanced ways of working with function results like Lateral Joins and such.
Those will be topics for later classes.

The main goal was really to get you to understand the basic structure of functions, how to pass data in and out, and get
your hands dirty. Hopefully you now have a good foundation for diving into [more of](https://www.postgresql.org/docs/current/plpgsql.html)
the [core documentation](https://www.postgresql.org/docs/current/extend.html).
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
3 changes: 3 additions & 0 deletions basic-postgresql-devel/basicfunctions/env-init.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
#!/usr/bin/bash

# nothing for now
22 changes: 22 additions & 0 deletions basic-postgresql-devel/basicfunctions/finish.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
# Final Notes

**NOTE**: All the programming langauges we used in these exercises are considered "trusted" by PostgreSQL. Trusted means the language does not give the developer access to the operating system file system and are much harder to do "bad things" with them. Because of this, functions written in trusted langauges can be written and used by non-superusers.

If we had done this class in, say Pl/Python, PostgreSQL would have prevented us from making functions since Python is an untrusted language.
While we are not going to cover how to developer with an untrusted in this course, you need to be aware of this restriction.


I hope this scenario helped:
1. Give you an idea how easy it is to get started with functions in PostgreSQL
1. Get your hands dirty with some basic functions
1. You understand how functions can help you produce better applications

The best way to get better at functions is to keep writing them and playing.
The container used in this class is available
[in Dockerhub](https://cloud.docker.com/u/thesteve0/repository/docker/thesteve0/postgres-appdev).
As long as you have Docker on your machine you can use the same version of PostgreSQL as the workshop. All the
[data from the](https://github.com/CrunchyData/crunchy-demo-data/releases/tag/v0.1) workshop was intentionally chosen
from public domain or permissive licenses so that you can use it for commercial and non-commercial purposes. Feel free
to download it and play some more at your own pace on your own machine.

And with that, we are finished.
Loading

0 comments on commit 486092d

Please sign in to comment.