Skip to content

Commit 99be22d

Browse files
committed
New example: splitwise
1 parent 2d70e68 commit 99be22d

File tree

7 files changed

+126
-0
lines changed

7 files changed

+126
-0
lines changed

Diff for: README.md

+7
Original file line numberDiff line numberDiff line change
@@ -110,6 +110,13 @@ to the user's browser.
110110
- Create a file called index.sql with the contents from [this example](./index.sql)
111111
- Open https://localhost:8080 in your browser
112112

113+
114+
## Examples
115+
116+
- [Tiny splitwise clone](./examples/splitwise): a shared expense tracker app
117+
- [Corporate Conundrum](./examples/corporate-conundrum/): a board game implemented in SQL
118+
- [SQLPage's own official website and documentation](./examples/official-site/): the website you are currently reading
119+
113120
## Configuration
114121

115122
SQLPage can be configured through either a configuration file placed in `sqlpage/sqlpage.json`

Diff for: docs/example-splitwise.png

169 KB
Loading

Diff for: examples/splitwise/README.md

+6
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
# SQL-only expense tracker app
2+
3+
This is a small web application that allows you to track shared expenses with your friends.
4+
It is built entirely in SQL using SQLPage.
5+
6+
![screenshot](../../docs/example-splitwise.png)

Diff for: examples/splitwise/group.sql

+48
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,48 @@
1+
-- Write the name of the group in the title of the page
2+
SELECT 'title' as component, name as contents FROM expense_group WHERE id = $id;
3+
4+
5+
-- Handle the form to add a member to the group (we do it at the top of the page to see it right away)
6+
INSERT INTO group_member(group_id, name)
7+
SELECT $id, :new_member_name WHERE :new_member_name IS NOT NULL;
8+
9+
-- List of members of the group
10+
SELECT 'list' as component, 'Membres' as title;
11+
SELECT name AS title FROM group_member WHERE group_id = $id;
12+
13+
-- Form to add a new member to the group
14+
SELECT 'form' as component, 'Ajouter un membre au groupe' as validate;
15+
SELECT 'Nom du membre' AS 'label', 'new_member_name' AS name;
16+
17+
SELECT 'title' as component, 'Dépenses' as contents
18+
19+
-- Form to add an expense
20+
SELECT 'form' as component, 'Ajouter une dépense' as title, 'Ajouter' as validate;
21+
SELECT 'Description' AS name;
22+
SELECT 'Montant' AS name, 'number' AS type;
23+
SELECT 'Dépensé par' AS name, 'select' as type,
24+
json_group_array(json_object("label", name, "value", id)) as options
25+
FROM group_member WHERE group_id = $id;
26+
27+
-- Insert the expense posted by the form into the database
28+
INSERT INTO expense(spent_by, name, amount)
29+
SELECT :"Dépensé par", :Description, :Montant WHERE :Montant IS NOT NULL;
30+
31+
-- List of expenses of the group
32+
SELECT 'card' as component, 'Dépenses' as title;
33+
SELECT expense.name as title,
34+
'Par ' || group_member.name || ', le ' || expense.date as description,
35+
expense.amount || '' as footer,
36+
CASE
37+
WHEN expense.amount > 100 THEN 'red'
38+
WHEN expense.amount > 50 THEN 'orange'
39+
ELSE 'blue'
40+
END AS color
41+
FROM expense
42+
INNER JOIN group_member on expense.spent_by = group_member.id
43+
WHERE group_member.group_id = $id;
44+
45+
-- Show the positive and negative debts of each member
46+
SELECT 'chart' AS component, 'Dette par personne' AS title, 'bar' AS type, TRUE AS horizontal;
47+
SELECT member_name AS label, is_owed AS value FROM individual_debts
48+
WHERE group_id = $id ORDER BY is_owed DESC;

Diff for: examples/splitwise/index.sql

+19
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
2+
-- Simple form to create a shared expense account
3+
SELECT 'form' as component,
4+
'Nouveau compte partagé' as title,
5+
'Créer le compte de dépenses partagé !' as validate;
6+
SELECT 'Nom du compte' AS label,
7+
'shared_expense_name' AS name;
8+
9+
-- Insert the shared expense account posted by the form into the database
10+
INSERT INTO expense_group(name)
11+
SELECT :shared_expense_name
12+
WHERE :shared_expense_name IS NOT NULL;
13+
14+
-- List of shared expense accounts
15+
-- (we put it after the insertion because we want to see new accounts right away when they are created)
16+
SELECT 'list' as component;
17+
SELECT name AS title,
18+
'group.sql?id=' || id AS link
19+
FROM expense_group;
+19
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
CREATE TABLE expense_group(
2+
id INTEGER PRIMARY KEY AUTOINCREMENT,
3+
name TEXT
4+
);
5+
CREATE TABLE group_member(
6+
id INTEGER PRIMARY KEY AUTOINCREMENT,
7+
group_id INTEGER REFERENCES expense_group(id),
8+
name TEXT
9+
);
10+
CREATE TABLE expense(
11+
id INTEGER PRIMARY KEY AUTOINCREMENT,
12+
spent_by INTEGER REFERENCES group_member(id),
13+
-- identifiant du membre qui a fait la dépense
14+
date TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
15+
-- date et heure de la dépense
16+
name TEXT,
17+
-- intitulé
18+
amount DECIMAL -- montant en euros
19+
);

Diff for: examples/splitwise/sqlpage/migrations/0001_views.sql

+27
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,27 @@
1+
-- A view that shows all the expenses of a group, with at least one line per member
2+
DROP VIEW IF EXISTS members_with_expenses;
3+
CREATE VIEW members_with_expenses AS
4+
SELECT group_member.group_id AS group_id,
5+
group_member.id AS spent_by_id,
6+
COALESCE(expense.amount, 0) AS amount,
7+
group_member.name AS spent_by_name
8+
FROM group_member
9+
LEFT JOIN expense on expense.spent_by = group_member.id;
10+
-- A view that shows the total amount of expense per person of a group
11+
DROP VIEW IF EXISTS average_debt_per_person;
12+
CREATE VIEW average_debt_per_person AS
13+
SELECT group_id,
14+
sum(amount) / count(distinct spent_by_id) AS debt
15+
FROM members_with_expenses
16+
GROUP BY group_id;
17+
-- A view that shows the total amount a person is owed in a group
18+
DROP VIEW IF EXISTS individual_debts;
19+
CREATE VIEW individual_debts AS
20+
SELECT members_with_expenses.group_id AS group_id,
21+
spent_by_id AS member_id,
22+
spent_by_name AS member_name,
23+
sum(members_with_expenses.amount) - average_debt_per_person.debt AS is_owed
24+
FROM members_with_expenses
25+
INNER JOIN average_debt_per_person ON average_debt_per_person.group_id = members_with_expenses.group_id
26+
GROUP BY spent_by_id
27+
ORDER BY is_owed DESC;

0 commit comments

Comments
 (0)