Skip to content

Commit 9e58075

Browse files
committed
Easier json handling in databases without a native json type. SQLPage now detects when you use a json function in SQLite or MariaDB to generate a column, and automatically converts the resulting string to a json object. This allows easily using components that take json parameters (like the new columns component) in MariaDB and SQLite.
fixes #633
1 parent cf9812c commit 9e58075

File tree

6 files changed

+148
-5
lines changed

6 files changed

+148
-5
lines changed

CHANGELOG.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44

55
- **Fix**: the search feature in the shell component was not working when no menu item was defined.
66
- Add support for encrypted Microsoft SQL Server connections. This finally allows connecting to databases that refuse clear-text connections, such as those hosted on Azure.
7+
- Easier json handling in databases without a native json type. SQLPage now detects when you use a json function in SQLite or MariaDB to generate a column, and automatically converts the resulting string to a json object. This allows easily using components that take json parameters (like the new columns component) in MariaDB and SQLite.
78

89
## 0.29.0 (2024-09-25)
910
- New columns component: `columns`. Useful to display a comparison between items, or large key figures to an user.

docker-compose.yml

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,7 @@ services:
3131
environment:
3232
MYSQL_ROOT_PASSWORD: Password123!
3333
MYSQL_DATABASE: sqlpage
34+
3435
mssql:
3536
profiles: ["mssql"]
3637
ports: ["1433:1433"]
@@ -41,6 +42,7 @@ services:
4142
timeout: 3s
4243
retries: 10
4344
start_period: 10s
45+
4446
mariadb:
4547
profiles: ["mariadb"]
4648
ports: ["3306:3306"]

src/webserver/database/execute_queries.rs

Lines changed: 31 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@ use futures_util::StreamExt;
44
use std::borrow::Cow;
55
use std::collections::HashMap;
66
use std::pin::Pin;
7+
use serde_json::Value;
78

89
use super::csv_import::run_csv_import;
910
use super::sql::{
@@ -59,6 +60,7 @@ pub fn stream_query_results_with_conn<'a>(
5960
let is_err = elem.is_err();
6061
let mut query_result = parse_single_sql_result(&stmt.query, elem);
6162
apply_delayed_functions(request, &stmt.delayed_functions, &mut query_result).await?;
63+
apply_json_columns(&mut query_result, &stmt.json_columns);
6264
for i in parse_dynamic_rows(query_result) {
6365
yield i;
6466
}
@@ -333,6 +335,34 @@ fn json_to_fn_param(json: serde_json::Value) -> Option<Cow<'static, str>> {
333335
}
334336
}
335337

338+
fn apply_json_columns(item: &mut DbItem, json_columns: &[String]) {
339+
if let DbItem::Row(Value::Object(ref mut row)) = item {
340+
for column in json_columns {
341+
if let Some(value) = row.get_mut(column) {
342+
if let Value::String(json_str) = value {
343+
if let Ok(parsed_json) = serde_json::from_str(json_str) {
344+
log::trace!("Parsed JSON column {column}: {parsed_json}");
345+
*value = parsed_json;
346+
} else {
347+
log::warn!("The column {column} contains invalid JSON: {json_str}");
348+
}
349+
} else if let Value::Array(array) = value {
350+
for item in array {
351+
if let Value::String(json_str) = item {
352+
if let Ok(parsed_json) = serde_json::from_str(json_str) {
353+
log::trace!("Parsed JSON array item: {parsed_json}");
354+
*item = parsed_json;
355+
}
356+
}
357+
}
358+
}
359+
} else {
360+
log::warn!("The column {column} is missing from the result set, so it cannot be converted to JSON.");
361+
}
362+
}
363+
}
364+
}
365+
336366
pub struct StatementWithParams<'a> {
337367
sql: &'a str,
338368
arguments: AnyArguments<'a>,
@@ -355,4 +385,4 @@ impl<'q> sqlx::Execute<'q, Any> for StatementWithParams<'q> {
355385
// Let sqlx create a prepared statement the first time it is executed, and then reuse it.
356386
true
357387
}
358-
}
388+
}

src/webserver/database/sql.rs

Lines changed: 104 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -9,7 +9,7 @@ use async_trait::async_trait;
99
use sqlparser::ast::{
1010
BinaryOperator, CastKind, CharacterLength, DataType, Expr, Function, FunctionArg,
1111
FunctionArgExpr, FunctionArgumentList, FunctionArguments, Ident, ObjectName,
12-
OneOrManyWithParens, SelectItem, Statement, Value, VisitMut, VisitorMut,
12+
OneOrManyWithParens, SelectItem, SetExpr, Statement, Value, VisitMut, VisitorMut,
1313
};
1414
use sqlparser::dialect::{Dialect, MsSqlDialect, MySqlDialect, PostgreSqlDialect, SQLiteDialect};
1515
use sqlparser::parser::{Parser, ParserError};
@@ -64,6 +64,9 @@ pub(super) struct StmtWithParams {
6464
/// Functions that are called on the result set after the query has been executed,
6565
/// and which can be passed the result of the query as an argument.
6666
pub delayed_functions: Vec<DelayedFunctionCall>,
67+
/// Columns that are JSON columns, and which should be converted to JSON objects after the query is executed.
68+
/// Only relevant for databases that do not have a native JSON type, and which return JSON values as text.
69+
pub json_columns: Vec<String>,
6770
}
6871

6972
#[derive(Debug)]
@@ -136,6 +139,7 @@ fn parse_single_statement(
136139
query,
137140
params,
138141
delayed_functions: Vec::new(),
142+
json_columns: Vec::new(),
139143
},
140144
});
141145
}
@@ -148,6 +152,7 @@ fn parse_single_statement(
148152
}
149153
let delayed_functions = extract_toplevel_functions(&mut stmt);
150154
remove_invalid_function_calls(&mut stmt, &mut params);
155+
let json_columns = extract_json_columns(&stmt, db_kind);
151156
let query = format!(
152157
"{stmt}{semicolon}",
153158
semicolon = if semicolon { ";" } else { "" }
@@ -157,6 +162,7 @@ fn parse_single_statement(
157162
query,
158163
params,
159164
delayed_functions,
165+
json_columns,
160166
}))
161167
}
162168

@@ -771,6 +777,64 @@ fn sqlpage_func_name(func_name_parts: &[Ident]) -> &str {
771777
}
772778
}
773779

780+
fn extract_json_columns(stmt: &Statement, db_kind: AnyKind) -> Vec<String> {
781+
// Only extract JSON columns for databases without native JSON support
782+
if matches!(db_kind, AnyKind::Postgres | AnyKind::Mssql) {
783+
return Vec::new();
784+
}
785+
786+
let mut json_columns = Vec::new();
787+
788+
if let Statement::Query(query) = stmt {
789+
if let SetExpr::Select(select) = query.body.as_ref() {
790+
for item in &select.projection {
791+
if let SelectItem::ExprWithAlias { expr, alias } = item {
792+
if is_json_function(expr) {
793+
json_columns.push(alias.value.clone());
794+
log::trace!("Found JSON column: {alias}");
795+
}
796+
}
797+
}
798+
}
799+
}
800+
801+
json_columns
802+
}
803+
804+
fn is_json_function(expr: &Expr) -> bool {
805+
match expr {
806+
Expr::Function(function) => {
807+
if let [Ident { value, .. }] = function.name.0.as_slice() {
808+
[
809+
"json_object",
810+
"json_array",
811+
"json_build_object",
812+
"json_build_array",
813+
"to_json",
814+
"to_jsonb",
815+
"json_agg",
816+
"jsonb_agg",
817+
"json_arrayagg",
818+
"json_objectagg",
819+
"json_group_array",
820+
"json_group_object",
821+
]
822+
.iter()
823+
.any(|&func| value.eq_ignore_ascii_case(func))
824+
} else {
825+
false
826+
}
827+
}
828+
Expr::Cast { data_type, .. } => {
829+
matches!(data_type, DataType::JSON | DataType::JSONB)
830+
|| (matches!(data_type, DataType::Custom(ObjectName(parts), _) if
831+
(parts.len() == 1)
832+
&& (parts[0].value.eq_ignore_ascii_case("json"))))
833+
}
834+
_ => false,
835+
}
836+
}
837+
774838
#[cfg(test)]
775839
mod test {
776840
use super::super::sqlpage_functions::functions::SqlPageFunctionName;
@@ -1131,4 +1195,43 @@ mod test {
11311195
None
11321196
);
11331197
}
1198+
1199+
#[test]
1200+
fn test_extract_json_columns() {
1201+
let sql = r#"
1202+
WITH json_cte AS (
1203+
SELECT json_build_object('a', x, 'b', y) AS cte_json
1204+
FROM generate_series(1, 3) x
1205+
JOIN generate_series(4, 6) y ON true
1206+
)
1207+
SELECT
1208+
json_object('key', 'value') AS json_col1,
1209+
json_array(1, 2, 3) AS json_col2,
1210+
(SELECT json_build_object('nested', subq.val)
1211+
FROM (SELECT AVG(x) AS val FROM generate_series(1, 5) x) subq
1212+
) AS json_col3, -- not supported because of the subquery
1213+
CASE
1214+
WHEN EXISTS (SELECT 1 FROM json_cte WHERE cte_json->>'a' = '2')
1215+
THEN to_json(ARRAY(SELECT cte_json FROM json_cte))
1216+
ELSE json_build_array()
1217+
END AS json_col4, -- not supported because of the CASE
1218+
json_unknown_fn(regular_column) AS non_json_col,
1219+
CAST(json_col1 AS json) AS json_col6
1220+
FROM some_table
1221+
CROSS JOIN json_cte
1222+
WHERE json_typeof(json_col1) = 'object'
1223+
"#;
1224+
1225+
let stmt = parse_postgres_stmt(sql);
1226+
let json_columns = extract_json_columns(&stmt, AnyKind::Sqlite);
1227+
1228+
assert_eq!(
1229+
json_columns,
1230+
vec![
1231+
"json_col1".to_string(),
1232+
"json_col2".to_string(),
1233+
"json_col6".to_string()
1234+
]
1235+
);
1236+
}
11341237
}
Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
select 'columns' as component;
2+
3+
select
4+
JSON_OBJECT('description', 'It works !') as item,
5+
JSON_OBJECT('description', 'It works !') as item
6+
;

tests/upload_csv_test.sql

Lines changed: 4 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
1-
create table people(name text, age text);
2-
copy people(name, age) from 'people_file' with (format csv, header true);
1+
drop table if exists sqlpage_people_test_table;
2+
create table sqlpage_people_test_table(name text, age text);
3+
copy sqlpage_people_test_table(name, age) from 'people_file' with (format csv, header true);
34
select 'text' as component,
45
name || ' is ' || age || ' years old. ' as contents
5-
from people;
6+
from sqlpage_people_test_table;

0 commit comments

Comments
 (0)