Skip to content

Commit 18e6c24

Browse files
committed
new example: many-to-many
See #29
1 parent 634c47a commit 18e6c24

File tree

14 files changed

+394
-0
lines changed

14 files changed

+394
-0
lines changed
Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
# A simple blog with topics and posts
2+
3+
Users can create topics and posts. A topic can have many posts and a post can have many topics.
4+
5+
See
6+
- [`write.sql`](./write.sql) for the form definition,
7+
- [`write_submit.sql`](./write_submit.sql) for the database insertion code.
8+
9+
![](./screenshots/home.png)
10+
![](./screenshots/topics.png)
11+
![](./screenshots/topic.png)
12+
![](./screenshots/post.png)
13+
![](./screenshots/write.png)
Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
1+
SELECT * FROM sqlpage_shell LIMIT 1;
2+
3+
SELECT 'list' as component,
4+
COALESCE(
5+
(SELECT name FROM topic WHERE id = $topic),
6+
'Recent blog posts'
7+
) as title;
8+
9+
SELECT post.title as title,
10+
'post.sql?id=' || post.id as link,
11+
'Published on ' || created_at as description,
12+
CASE
13+
WHEN created_at > date('now', '-2 days') THEN 'red'
14+
ELSE NULL
15+
END as color,
16+
topic.icon as icon,
17+
created_at > date('now', '-2 days') as active
18+
FROM post
19+
LEFT JOIN topic ON topic.id = post.main_topic_id
20+
WHERE $topic IS NULL
21+
OR topic.id = $topic
22+
OR EXISTS (
23+
SELECT 1
24+
FROM topic_post
25+
WHERE topic_post.topic_id = $topic
26+
AND topic_post.post_id = post.id
27+
)
28+
ORDER BY created_at DESC;
29+
30+
SELECT 'text' AS component;
31+
SELECT 'No blog post yet. ' AS contents WHERE NOT EXISTS (SELECT 1 FROM post);
32+
SELECT 'Write a post !' AS contents, 'write.sql' AS link;
Lines changed: 21 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
SELECT *
2+
FROM sqlpage_shell
3+
LIMIT 1;
4+
5+
SELECT 'text' AS component;
6+
7+
SELECT content || '
8+
9+
---
10+
11+
Published on: _' || created_at || '_ in category [' || topic.name || '](/?topic=' || topic.id || ')' || '.
12+
13+
Other associated categories: ' || (
14+
SELECT group_concat('[' || name || '](/?topic=' || topic_id || ')', ', ')
15+
FROM topic_post
16+
INNER JOIN topic ON topic.id = topic_post.topic_id
17+
WHERE post_id = $id
18+
) || '.' AS contents_md
19+
FROM post
20+
INNER JOIN topic ON topic.id = post.main_topic_id
21+
WHERE post.id = $id;
120 KB
Loading
219 KB
Loading
64.1 KB
Loading
192 KB
Loading
90.2 KB
Loading
Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,37 @@
1+
-- A simple blog with topics and posts
2+
-- Users can create topics and posts. A topic can have many posts and a post can have many topics.
3+
4+
-- The first step is to create the tables in the database. We will use the following SQL queries:
5+
CREATE TABLE topic (
6+
id INTEGER PRIMARY KEY,
7+
name TEXT NOT NULL,
8+
icon TEXT NOT NULL,
9+
UNIQUE (name)
10+
);
11+
12+
CREATE TABLE post (
13+
id INTEGER PRIMARY KEY,
14+
title TEXT NOT NULL,
15+
content TEXT NOT NULL, -- The contents will be stored in markdown
16+
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
17+
main_topic_id INTEGER REFERENCES topic(id)
18+
);
19+
20+
CREATE TABLE topic_post (
21+
topic_id INTEGER NOT NULL REFERENCES topic(id),
22+
post_id INTEGER NOT NULL REFERENCES post(id),
23+
PRIMARY KEY (topic_id, post_id)
24+
) WITHOUT ROWID;
25+
26+
-- A view of the topics with the number of posts and most recent post
27+
CREATE VIEW topic_with_stats AS
28+
SELECT topic.id,
29+
topic.name,
30+
topic.icon,
31+
COALESCE(count(topic_post.post_id), 0) as nb_posts,
32+
max(post.created_at) as last_post
33+
FROM topic
34+
LEFT JOIN topic_post ON topic_post.topic_id = topic.id
35+
LEFT JOIN post ON post.id = topic_post.post_id
36+
GROUP BY topic.id
37+
ORDER BY nb_posts DESC;

examples/modeling a many to many relationship with a form/sqlpage/migrations/01_sample_data.sql

Lines changed: 233 additions & 0 deletions
Large diffs are not rendered by default.

0 commit comments

Comments
 (0)