Skip to content

Commit

Permalink
improve docs for mysql
Browse files Browse the repository at this point in the history
  • Loading branch information
lovasoa committed Oct 21, 2023
1 parent ec65bc9 commit bac3ccc
Showing 1 changed file with 29 additions and 16 deletions.
45 changes: 29 additions & 16 deletions examples/official-site/sqlpage/migrations/20_variables_function.sql
Original file line number Diff line number Diff line change
Expand Up @@ -48,31 +48,44 @@ SELECT key AS question_id, value AS answer
FROM json_each_text(sqlpage.variables(''post'')::json);
```
#### In MySQL
MySQL has [`JSON_TABLE`](https://dev.mysql.com/doc/refman/8.0/en/json-table-functions.html), which is less straightforward to use :
#### In Microsoft SQL Server
```sql
INSERT INTO survey_answers (question_id, answer)
INSERT INTO survey_answers (question_id, answer)
SELECT
var_name as question_id,
JSON_UNQUOTE(JSON_EXTRACT(sqlpage.variables(''post''), CONCAT(''$."'', var_name, ''"''))) as value -- Extract the value from the key name
FROM JSON_TABLE( -- iterate on keys in the json array
JSON_KEYS(sqlpage.variables(''post'')), -- Get the keys as an arrey
''$[*]'' COLUMNS (var_name text PATH ''$'' ERROR ON ERROR) -- form a table with a single var_name column
) AS vars;
INSERT INTO survey_answers
SELECT [key] AS question_id, [value] AS answer
FROM OPENJSON(''{"x":"y"}'');
```
> Unfortunately, this MySQL-specific syntax is [not supported in sqlpage at the moment](https://github.com/sqlparser-rs/sqlparser-rs/issues/1019)
#### In MySQL
#### In Microsoft SQL Server
MySQL has [`JSON_TABLE`](https://dev.mysql.com/doc/refman/8.0/en/json-table-functions.html), which is less straightforward to use.
Outside of sqlpage, one can define a procedure :
```sql
INSERT INTO survey_answers
SELECT [key] AS question_id, [value] AS answer
FROM OPENJSON(''{"x":"y"}'');
DELIMITER //
CREATE PROCEDURE process_survey_answer(jsonData JSON)
BEGIN
insert into survey_answers (question_id, answer)
SELECT
var_name as "key",
JSON_UNQUOTE(JSON_EXTRACT(jsonData, CONCAT(''$."'', var_name, ''"''))) as "value"
FROM JSON_TABLE(
JSON_KEYS(jsonData),
''$[*]'' COLUMNS (var_name text PATH ''$'' ERROR ON ERROR)
) AS vars;
END//
DELIMITER ;
```
then in `handle_survey_answer.sql` :
```sql
CALL process_survey_answer(sqlpage.variables(''post''));
```
'
);

Expand Down

0 comments on commit bac3ccc

Please sign in to comment.