Skip to content

Commit

Permalink
add an example todo application using postgres
Browse files Browse the repository at this point in the history
  • Loading branch information
lovasoa committed Jul 18, 2024
1 parent 664c99e commit 164b79f
Show file tree
Hide file tree
Showing 14 changed files with 288 additions and 43 deletions.
15 changes: 15 additions & 0 deletions examples/todo application (PostgreSQL)/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
# Todo app with SQLPage

This is a simple todo app implemented with SQLPage. It uses a PostgreSQL database to store the todo items.

![Screenshot](screenshot.png)

It is meant as an illustrative example of how to use SQLPage to create a simple CRUD application. See [the SQLite version](../todo%20application/README.md) for a more detailed explanation of the structure of the application.

## Differences from the SQLite version

- URL parameters that contain numeric identifiers are cast to integers using the [`::int`](https://www.postgresql.org/docs/16/sql-expressions.html#SQL-SYNTAX-TYPE-CASTS) operator
- the `printf` function is replaced with the [`format`](https://www.postgresql.org/docs/current/functions-string.html#FUNCTIONS-STRING-FORMAT) function
- primary keys are generated using the [`serial`](https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-SERIAL) type
- dates and times are formatted using the [`to_char`](https://www.postgresql.org/docs/current/functions-formatting.html#FUNCTIONS-FORMATTING-DATETIME-TABLE) function
- the `INSERT OR REPLACE` statement is replaced with the [`ON CONFLICT`](https://www.postgresql.org/docs/current/sql-insert.html#SQL-ON-CONFLICT) clause
30 changes: 30 additions & 0 deletions examples/todo application (PostgreSQL)/delete.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
-- We find the todo item with the id given in the URL (/delete.sql?todo_id=1)
-- and we check that the URL also contains a 'confirm' parameter set to 'yes' (/delete.sql?todo_id=1&confirm=yes)
-- If both conditions are met, we delete the todo item from the database
-- and redirect the user to the home page.
delete from todos
where id = $todo_id::int and $confirm = 'yes'
returning -- returning will return one row if an item was deleted, and zero rows if no item was deleted
'redirect' as component, -- if one item was deleted, we redirect the user to the home page, and skip the rest of the page
'/' as link;

-- If we are here, it means that the delete statement above did not delete anything
-- because the confirm parameter was not set to 'yes'.

-- We display the same header as in other pages, by including the shell.sql file.
select 'dynamic' as component, sqlpage.run_sql('shell.sql') as properties;

-- When the page is initially loaded, it will contain a todo_id parameter
-- but no confirm parameter, so the delete statement above will not delete anything
-- and the 'redirect' component will not be returned.
-- In this case, we display a confirmation message to the user.
select
'alert' as component, -- an alert is a message that is displayed to the user
'red' as color,
'Confirm deletion' as title,
'Are you sure you want to delete the following todo item ?
> ' || title as description_md, -- we include the text of the todo item in the markdown confirmation message
'?todo_id=' || $todo_id || '&confirm=yes' as link, -- When the user clicks on the 'Delete' button, the page will be reloaded with the confirm parameter set to 'yes', so that the delete statement above will delete the todo item
'Delete' as link_text
from todos where id = $todo_id::int; -- finds the todo item with the id given in the URL
21 changes: 21 additions & 0 deletions examples/todo application (PostgreSQL)/docker-compose.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
services:
web:
image: lovasoa/sqlpage:main # main is cutting edge, use lovasoa/sqlpage:latest for the latest stable version
ports:
- "8080:8080"
volumes:
- .:/var/www
- ./sqlpage:/etc/sqlpage
depends_on:
- db
environment:
DATABASE_URL: postgres://root:secret@db/sqlpage
db: # The DB environment variable can be set to "mariadb" or "postgres" to test the code with different databases
ports:
- "5432:5432"
- "3306:3306"
image: postgres
environment:
POSTGRES_USER: root
POSTGRES_DB: sqlpage
POSTGRES_PASSWORD: secret
21 changes: 21 additions & 0 deletions examples/todo application (PostgreSQL)/explanation_diagram.svg
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
20 changes: 20 additions & 0 deletions examples/todo application (PostgreSQL)/index.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
select 'dynamic' as component, sqlpage.run_sql('shell.sql') as properties;

select 'list' as component,
'Todo' as title,
'No todo yet...' as empty_title;

select
title,
'todo_form.sql?todo_id=' || id as edit_link,
'delete.sql?todo_id=' || id as delete_link
from todos;

select
'button' as component,
'center' as justify;
select
'todo_form.sql' as link,
'green' as color,
'Add new todo' as title,
'circle-plus' as icon;
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
6 changes: 6 additions & 0 deletions examples/todo application (PostgreSQL)/shell.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
select
'shell' as component,
format ('Todo list (%s)', count(*)) as title,
'timeline' as menu_item
from
todos;
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
create table
todos (
id serial primary key,
title text not null,
created_at timestamp default current_timestamp
);
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
# SQLPage migrations

SQLPage migrations are SQL scripts that you can use to create or update the database schema.
They are entirely optional: you can use SQLPage without them, and manage the database schema yourself with other tools.

If you are new to SQL migrations, please read our [**introduction to database migrations**](https://sql.ophir.dev/your-first-sql-website/migrations.sql).

## Creating a migration

To create a migration, create a file in the `sqlpage/migrations` directory with the following name:

```
<version>_<name>.sql
```

Where `<version>` is a number that represents the version of the migration, and `<name>` is a name for the migration.
For example, `001_initial.sql` or `002_add_users.sql`.

When you need to update the database schema, always create a **new** migration file with a new version number
that is greater than the previous one.
Use commands like `ALTER TABLE` to update the schema declaratively instead of modifying the existing `CREATE TABLE`
statements.

If you try to edit an existing migration, SQLPage will not run it again, will detect

## Running migrations

Migrations that need to be applied are run automatically when SQLPage starts.
You need to restart SQLPage each time you create a new migration.

## How does it work?

SQLPage keeps track of the migrations that have been applied in a table called `_sqlx_migrations`.
This table is created automatically when SQLPage starts for the first time, if you create migration files.
If you don't create any migration files, SQLPage will never touch the database schema on its own.

When SQLPage starts, it checks the `_sqlx_migrations` table to see which migrations have been applied.
It checks the `sqlpage/migrations` directory to see which migrations are available.
If the checksum of a migration file is different from the checksum of the migration that has been applied,
SQLPage will return an error and refuse to start.
If you end up in this situation, you can remove the `_sqlx_migrations` table: all your old migrations will be reapplied, and SQLPage will start again.
3 changes: 3 additions & 0 deletions examples/todo application (PostgreSQL)/sqlpage/sqlpage.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
{
"database_url": "sqlite://./sqlpage/sqlpage.db?mode=rwc"
}
20 changes: 20 additions & 0 deletions examples/todo application (PostgreSQL)/sqlpage/templates/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
# SQLPage component templates

SQLPage templates are handlebars[^1] files that are used to render the results of SQL queries.

[^1]: https://handlebarsjs.com/

## Default components

SQLPage comes with a set of default[^2] components that you can use without having to write any code.
These are documented on https://sql.ophir.dev/components.sql

## Custom components

You can [write your own component templates](https://sql.ophir.dev/custom_components.sql)
and place them in the `sqlpage/templates` directory.
To override a default component, create a file with the same name as the default component.
If you want to start from an existing component, you can copy it from the `sqlpage/templates` directory
in the SQLPage source code[^2].

[^2]: A simple component to start from: https://github.com/lovasoa/SQLpage/blob/main/sqlpage/templates/code.handlebars
25 changes: 25 additions & 0 deletions examples/todo application (PostgreSQL)/timeline.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
select
'dynamic' as component,
sqlpage.run_sql ('shell.sql') as properties;

select
'timeline' as component;

SELECT
title,
'todo_form.sql?todo_id=' || id AS link,
TO_CHAR (created_at, 'FMMonth DD, YYYY, HH12:MI AM TZ') AS date,
'calendar' AS icon,
'green' AS color,
CONCAT (
EXTRACT(
DAY
FROM
NOW () - created_at
),
' days ago'
) AS description
FROM
todos
ORDER BY
created_at DESC;
34 changes: 34 additions & 0 deletions examples/todo application (PostgreSQL)/todo_form.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@

-- When the form is submitted, we insert the todo item into the database
-- or update it if it already exists
-- and redirect the user to the home page.
-- When the form is initially loaded, :todo is null,
-- nothing is inserted, and the 'redirect' component is not returned.
insert into todos(id, title)
select COALESCE($todo_id::int, nextval('todos_id_seq')), :todo -- $todo_id will be null if the page is accessed via the 'Add new todo' button (without a ?todo_id= parameter)
where :todo is not null -- only insert if the form was submitted
on conflict(id) do update set title = excluded.title
returning
'redirect' as component,
'/' as link;

-- The header needs to come before the form, but after the potential redirect
select 'dynamic' as component, sqlpage.run_sql('shell.sql') as properties;

-- The form needs to come AFTER the insert statement
-- because the insert statement will redirect the user to the home page if the form was submitted
select
'form' as component,
'Todo' as title,
(
case when $todo_id is null then
'Add new todo'
else
'Edit todo'
end
) as validate;
select
'Todo item' as label,
'todo' as name,
'What do you have to do ?' as placeholder,
(select title from todos where id = $todo_id::int) as value;
89 changes: 46 additions & 43 deletions examples/todo application/README.md
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
# Todo app with SQLPage

This is a simple todo app implemented with SQLPage. It uses a SQLite database to store the todo items.
(See [the PostgreSQL version](<../todo%20application%20(PostgreSQL)/README.md>))

![Screenshot](screenshot.png)

Expand All @@ -15,23 +16,25 @@ It will be loaded when the user visits the root of the application
(`http://localhost:8080/` when running this example locally).

In order, it uses:
- the [`dynamic`](https://sql.ophir.dev/documentation.sql?component=dynamic#component) component to load the [`shell.sql`](#shellsql) file that will be used at the top of every page
in the application to create a consistent layout and top bar.
- the [`list`](https://sql.ophir.dev/documentation.sql?component=list#component) component to display the list of todo items.
- the [`button`](https://sql.ophir.dev/documentation.sql?component=button#component) component to create a button that will redirect the user to the [`todo_form.sql`](#todo_formsql) page to create a new todo item when clicked.

- the [`dynamic`](https://sql.ophir.dev/documentation.sql?component=dynamic#component) component to load the [`shell.sql`](#shellsql) file that will be used at the top of every page
in the application to create a consistent layout and top bar.
- the [`list`](https://sql.ophir.dev/documentation.sql?component=list#component) component to display the list of todo items.
- the [`button`](https://sql.ophir.dev/documentation.sql?component=button#component) component to create a button that will redirect the user to the [`todo_form.sql`](#todo_formsql) page to create a new todo item when clicked.

### [`todo_form.sql`](./todo_form.sql)

This file is used to create a new todo item or edit an existing one.

It uses:
1. the [`redirect`](https://sql.ophir.dev/documentation.sql?component=redirect#component) component to redirect the user back to the [`index.sql`](#indexsql) page after the form is submitted.
1. the [`dynamic`](https://sql.ophir.dev/documentation.sql?component=dynamic#component) component to load [`shell.sql`](#shellsql) to create a consistent layout and top bar.
1. the [`form`](https://sql.ophir.dev/documentation.sql?component=form#component) component to create a form with fields for the title and description of the todo item.

The order of the components is important, as the `redirect` component cannot be used after the page has been displayed. It is called first to ensure that the user is redirected immediately after submitting the form. It is guarded by a `WHERE :todo_id IS NOT NULL` clause to ensure that it only redirects when
the form was submitted, not when the page is
initially loaded by the user in their browser.
1. the [`redirect`](https://sql.ophir.dev/documentation.sql?component=redirect#component) component to redirect the user back to the [`index.sql`](#indexsql) page after the form is submitted.
1. the [`dynamic`](https://sql.ophir.dev/documentation.sql?component=dynamic#component) component to load [`shell.sql`](#shellsql) to create a consistent layout and top bar.
1. the [`form`](https://sql.ophir.dev/documentation.sql?component=form#component) component to create a form with fields for the title and description of the todo item.

The order of the components is important, as the `redirect` component cannot be used after the page has been displayed. It is called first to ensure that the user is redirected immediately after submitting the form. It is guarded by a `WHERE :todo_id IS NOT NULL` clause to ensure that it only redirects when
the form was submitted, not when the page is
initially loaded by the user in their browser.

![diagram explaining the structure of the application](./explanation_diagram.svg)

Expand All @@ -43,34 +46,34 @@ It contains a delete statement guarded by a
`WHERE $confirm = 'yes'` clause.
So, the delete is not executed when the page
is initially loaded, but only when the user
clicks the "Yes" button, which contains a link
clicks the "Yes" button, which contains a link
pointing to the same page with the `confirm=yes` query parameter.

The detailed step by step explanation of the delete process is as follows:
- From the `index.sql` page, the user clicks the 'Delete' button on a todo item
- It loads the page `/delete.sql?todo_id=7` (without the `confirm=yes` parameter)
- the delete statement **is** sent to the database and executed. SQLPage has bound the values to URL query parameters, so we have
- `$todo_id` bound to `'7'`, and
- `$confirm` bound to `NULL` (since there was no `confirm` parameter in the url)
- the database evaluates the `where id = $todo_id and $confirm = 'yes'` condition to FALSE
- so it deletes nothing, and returns nothing
- SQLPage receives no row back from the database, it continues processing normally
- it executes the `select 'dynamic' ...` query, which itself requires executing the `shell.sql` file. The result of this is a row that contains `component=dynamic` and `properties={"component": "shell", "title": "My Todo App", ... }`
- it renders the page header with the application header and the top bar following the results of the query
- it sends to the database the last query: `select 'alert' as component, ... from todos where id = $todo_id` it binds the parameters like before
- `$todo_id` bound to `'7'`
- the database returns a single row, containing `component=alert`, `description_md=Are you sure [...] [the title of the todo item with id 7]`, ...
- SQLPage returns the the `alert` component with its contents to the browser
- The user sees the confirmation alert and clicks the 'Delete' button
- The page is reloaded, this time with the URL `/delete.sql?todo_id=7&confirm=yes`
- the delete statement is sent to the database and executed like last time. But this time SQLPage has bound the values to the new URL query parameters,
- `$todo_id` bound to `'7'`, (like before)
- `$confirm` bound to `'yes'` (since there is now a `confirm` parameter in the url)
- the database evaluates the `where id = $todo_id and $confirm = 'yes'` condition to TRUE
- so it deletes the todo item with id 7 and, as instructed by the `returning` clause, returns a single row containing `component=redirect`, `link=/`
- SQLPage receives the row back from the database, and immediately returns sends a 302 redirect response to the browser, redirecting the user to the `/` page.
- The following queries are not executed, as the page is redirected before they are processed.

- From the `index.sql` page, the user clicks the 'Delete' button on a todo item
- It loads the page `/delete.sql?todo_id=7` (without the `confirm=yes` parameter)
- the delete statement **is** sent to the database and executed. SQLPage has bound the values to URL query parameters, so we have
- `$todo_id` bound to `'7'`, and
- `$confirm` bound to `NULL` (since there was no `confirm` parameter in the url)
- the database evaluates the `where id = $todo_id and $confirm = 'yes'` condition to FALSE
- so it deletes nothing, and returns nothing
- SQLPage receives no row back from the database, it continues processing normally
- it executes the `select 'dynamic' ...` query, which itself requires executing the `shell.sql` file. The result of this is a row that contains `component=dynamic` and `properties={"component": "shell", "title": "My Todo App", ... }`
- it renders the page header with the application header and the top bar following the results of the query
- it sends to the database the last query: `select 'alert' as component, ... from todos where id = $todo_id` it binds the parameters like before
- `$todo_id` bound to `'7'`
- the database returns a single row, containing `component=alert`, `description_md=Are you sure [...] [the title of the todo item with id 7]`, ...
- SQLPage returns the the `alert` component with its contents to the browser
- The user sees the confirmation alert and clicks the 'Delete' button
- The page is reloaded, this time with the URL `/delete.sql?todo_id=7&confirm=yes`
- the delete statement is sent to the database and executed like last time. But this time SQLPage has bound the values to the new URL query parameters,
- `$todo_id` bound to `'7'`, (like before)
- `$confirm` bound to `'yes'` (since there is now a `confirm` parameter in the url)
- the database evaluates the `where id = $todo_id and $confirm = 'yes'` condition to TRUE
- so it deletes the todo item with id 7 and, as instructed by the `returning` clause, returns a single row containing `component=redirect`, `link=/`
- SQLPage receives the row back from the database, and immediately returns sends a 302 redirect response to the browser, redirecting the user to the `/` page.
- The following queries are not executed, as the page is redirected before they are processed.

### [`shell.sql`](./shell.sql)

Expand All @@ -92,14 +95,14 @@ of the common features of SQLPage.

### Components

- [list](https://sql.ophir.dev/documentation.sql?component=list#component)
- [button](https://sql.ophir.dev/documentation.sql?component=button#component)
- [form](https://sql.ophir.dev/documentation.sql?component=form#component)
- [redirect](https://sql.ophir.dev/documentation.sql?component=redirect#component)
- [shell](https://sql.ophir.dev/documentation.sql?component=shell#component)
- [timeline](https://sql.ophir.dev/documentation.sql?component=timeline#component)
- [dynamic](https://sql.ophir.dev/documentation.sql?component=timeline#component)
- [list](https://sql.ophir.dev/documentation.sql?component=list#component)
- [button](https://sql.ophir.dev/documentation.sql?component=button#component)
- [form](https://sql.ophir.dev/documentation.sql?component=form#component)
- [redirect](https://sql.ophir.dev/documentation.sql?component=redirect#component)
- [shell](https://sql.ophir.dev/documentation.sql?component=shell#component)
- [timeline](https://sql.ophir.dev/documentation.sql?component=timeline#component)
- [dynamic](https://sql.ophir.dev/documentation.sql?component=timeline#component)

### Functions

- [sqlpage.run_sql](https://sql.ophir.dev/functions.sql?function=run_sql#function)
- [sqlpage.run_sql](https://sql.ophir.dev/functions.sql?function=run_sql#function)

0 comments on commit 164b79f

Please sign in to comment.