Skip to content

Commit

Permalink
add an example to illustrate json handling in mysql
Browse files Browse the repository at this point in the history
  • Loading branch information
lovasoa committed Dec 4, 2023
1 parent 51f5840 commit 2fed231
Show file tree
Hide file tree
Showing 6 changed files with 84 additions and 1 deletion.
6 changes: 6 additions & 0 deletions examples/mysql json handling/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
# Handling json data in MySQL

This demonstrates both how to produce json data from a SQL query in MySQL
and how to consume json data from SQLPage.

![](./screenshots/app.png)
19 changes: 19 additions & 0 deletions examples/mysql json handling/docker-compose.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
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: mysql://root:secret@db/sqlpage
db: # The DB environment variable can be set to "mariadb" or "postgres" to test the code with different databases
ports:
- "3306:3306"
image: mariadb:10.6 # support for json_table was added in mariadb 10.6
environment:
MYSQL_ROOT_PASSWORD: secret
MYSQL_DATABASE: sqlpage
41 changes: 41 additions & 0 deletions examples/mysql json handling/index.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
select 'form' as component, 'Create a new Group' as title, 'Create' as validate;
select 'Name' as name;

insert into groups(name) select :Name where :Name is not null;

select 'list' as component, 'Groups' as title, 'No group yet' as empty_title;
select name as title from groups;

select 'form' as component, 'Add an user' as title, 'Add' as validate;
select 'UserName' as name, 'Name' as label;
select
'Memberships[]' as name,
'Group memberships' as label,
'select' as type,
TRUE as multiple,
'press ctrl to select multiple values' as description,
json_arrayagg(json_object("label", name, "value", id)) as options
from groups;

insert into users(name) select :UserName where :UserName is not null;
insert into group_members(group_id, user_id)
select CAST(json_unquote(json_elems.json_value) AS INT), last_insert_id()
from (
with recursive json_elems(n, json_value) as (
select 0, json_extract(:Memberships, '$[0]')
union all
select n + 1, json_extract(:Memberships, concat('$[', n + 1, ']'))
from json_elems
where json_value is not null
) select * from json_elems where json_value is not null
) as json_elems
where :Memberships is not null;

select 'list' as component, 'Users' as title, 'No user yet' as empty_title;
select
users.name as title,
group_concat(groups.name) as description
from users
left join group_members on users.id = group_members.user_id
left join groups on groups.id = group_members.group_id
group by users.id, users.name;
Binary file added examples/mysql json handling/screenshots/app.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
create table users (
id int primary key auto_increment,
name varchar(255) not null
);

create table groups (
id int primary key auto_increment,
name varchar(255) not null
);

create table group_members (
group_id int not null,
user_id int not null,
primary key (group_id, user_id),
foreign key (group_id) references groups (id),
foreign key (user_id) references users (id)
);
Original file line number Diff line number Diff line change
Expand Up @@ -324,8 +324,8 @@ This creates a more compact (but arguably less user-friendly) alternative to a s
In this case, you should add square brackets to the name of the field.
The target page will then receive the value as a JSON array of strings, which you can iterate over using
- the `json_each` function [in SQLite](https://www.sqlite.org/json1.html) and [Postgres](https://www.postgresql.org/docs/9.3/functions-json.html),
- the [`JSON_TABLE`](https://dev.mysql.com/doc/refman/8.0/en/json-table-functions.html) function in MySQL (which you''ll need to wrap in a function, because SQLPage cannot parse the non-standard syntax of this function)
- the [`OPENJSON`](https://learn.microsoft.com/fr-fr/sql/t-sql/functions/openjson-transact-sql?view=sql-server-ver16) function in Microsoft SQL Server.
- in MySQL, json manipulation is less straightforward: see [the SQLPage MySQL json example](https://github.com/lovasoa/SQLpage/tree/main/examples/mysql%20json%20handling)
The target page could then look like this:
Expand Down

0 comments on commit 2fed231

Please sign in to comment.