diff --git a/examples/mysql json handling/README.md b/examples/mysql json handling/README.md new file mode 100644 index 00000000..de7504fd --- /dev/null +++ b/examples/mysql json handling/README.md @@ -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) \ No newline at end of file diff --git a/examples/mysql json handling/docker-compose.yml b/examples/mysql json handling/docker-compose.yml new file mode 100644 index 00000000..0656b34e --- /dev/null +++ b/examples/mysql json handling/docker-compose.yml @@ -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 \ No newline at end of file diff --git a/examples/mysql json handling/index.sql b/examples/mysql json handling/index.sql new file mode 100644 index 00000000..5b2664ae --- /dev/null +++ b/examples/mysql json handling/index.sql @@ -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; \ No newline at end of file diff --git a/examples/mysql json handling/screenshots/app.png b/examples/mysql json handling/screenshots/app.png new file mode 100644 index 00000000..66077456 Binary files /dev/null and b/examples/mysql json handling/screenshots/app.png differ diff --git a/examples/mysql json handling/sqlpage/migrations/0001_users_and_groups.sql b/examples/mysql json handling/sqlpage/migrations/0001_users_and_groups.sql new file mode 100644 index 00000000..954872c0 --- /dev/null +++ b/examples/mysql json handling/sqlpage/migrations/0001_users_and_groups.sql @@ -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) +); \ No newline at end of file diff --git a/examples/official-site/sqlpage/migrations/01_documentation.sql b/examples/official-site/sqlpage/migrations/01_documentation.sql index 7cfb1f78..83bb29d3 100644 --- a/examples/official-site/sqlpage/migrations/01_documentation.sql +++ b/examples/official-site/sqlpage/migrations/01_documentation.sql @@ -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: