Skip to content

Commit 23f834d

Browse files
authored
null variables (#136)
* update dependencies * Add support for resetting variables to a `NULL` value using `SET`. Previously, storing `NULL` in a variable would store the string `'null'` instead of the `NULL` value.
1 parent 563bc87 commit 23f834d

File tree

9 files changed

+51
-44
lines changed

9 files changed

+51
-44
lines changed

CHANGELOG.md

+25-4
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,33 @@
11
# CHANGELOG.md
22

3-
## unreleased
3+
## 0.16.0 (2023-11-19)
44

55
- Add special handling of hidden inputs in [forms](https://sql.ophir.dev/documentation.sql?component=form#component). Hidden inputs are now completely invisible to the end user, facilitating the implementation of multi-step forms, csrf protaction, and other complex forms.
6-
- 18 new icons available (see https://github.com/tabler/tabler-icons/releases/tag/v2.40.0)
6+
- 36 new icons available
7+
- https://github.com/tabler/tabler-icons/releases/tag/v2.40.0
8+
- https://github.com/tabler/tabler-icons/releases/tag/v2.41.0
79
- Support multiple statements in [`on_connect.sql`](./configuration.md) in MySQL.
8-
- Randomize postgres prepared statement names to avoid name collisions. This should fix a bug where SQLPage would report errors like `prepared statement "sqlx_s_3" already exists` when using a connection pooler in front of a PostgreSQL database.
9-
- Delegate statement preparation to sqlx. The logic of preparing statements and caching them for later reuse is now entirely delegated to the sql driver library (sqlx). This simplifies the code and logic inside sqlpage itself. More importantly, statements are now prepared in a streaming fashion when a file is first loaded, instead of all at once, which allows referencing a temporary table created at the start of a file in a later statement in the same file.
10+
- Randomize postgres prepared statement names to avoid name collisions. This should fix a bug where SQLPage would report errors like `prepared statement "sqlx_s_1" already exists` when using a connection pooler in front of a PostgreSQL database. It is still not recommended to use SQLPage with an external connection pooler (such as pgbouncer), because SQLPage already implements its own connection pool. If you really want to use a connection pooler, you should set the [`max_connections`](./configuration.md) configuration parameter to `1` to disable the connection pooling logic in SQLPage.
11+
- SQL statements are now prepared lazily right before their first execution, instead of all at once when a file is first loaded, which allows **referencing a temporary table created at the start of a file in a later statement** in the same file. This works by delegating statement preparation to the database interface library we use (sqlx). The logic of preparing statements and caching them for later reuse is now entirely delegated to sqlx. This also nicely simplifies the code and logic inside sqlpage itself, and should slightly improve performance and memory usage.
12+
- Creating temporary tables at the start of a file is a nice way to keep state between multiple statements in a single file, without having to use variables, which can contain only a single string value:
13+
```sql
14+
DROP VIEW IF EXISTS current_user;
15+
16+
CREATE TEMPORARY VIEW current_user AS
17+
SELECT * FROM users
18+
INNER JOIN sessions ON sessions.user_id = users.id
19+
WHERE sessions.session_id = sqlpage.cookie('session_id');
20+
21+
SELECT 'card' as component,
22+
'Welcome, ' || username as title
23+
FROM current_user;
24+
```
25+
- Add support for resetting variables to a `NULL` value using `SET`. Previously, storing `NULL` in a variable would store the string `'null'` instead of the `NULL` value. This is now fixed.
26+
```sql
27+
SET myvar = NULL;
28+
SELECT 'card' as component;
29+
SELECT $myvar IS NULL as title; -- this used to display false, it now displays true
30+
```
1031

1132
## 0.15.2 (2023-11-12)
1233

Cargo.lock

+3-3
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

Cargo.toml

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
[package]
22
name = "sqlpage"
3-
version = "0.15.2"
3+
version = "0.16.0"
44
edition = "2021"
55
description = "A SQL-only web application framework. Takes .sql files and formats the query result using pre-made configurable professional-looking components."
66
keywords = ["web", "sql", "framework"]
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,12 @@
1+
SET username = (SELECT username FROM login_session WHERE id = sqlpage.cookie('session'));
2+
13
SELECT 'redirect' AS component,
24
'signin.sql?error' AS link
3-
WHERE logged_in_user(sqlpage.cookie('session')) IS NULL;
4-
-- logged_in_user is a custom postgres function defined in the first migration of this example
5-
-- that avoids having to repeat `(SELECT username FROM login_session WHERE id = session_id)` everywhere.
5+
WHERE $username IS NULL;
66

77
SELECT 'shell' AS component, 'Protected page' AS title, 'lock' AS icon, '/' AS link, 'logout' AS menu_item;
88

99
SELECT 'text' AS component,
10-
'Welcome, ' || logged_in_user(sqlpage.cookie('session')) || ' !' AS title,
10+
'Welcome, ' || $username || ' !' AS title,
1111
'This content is [top secret](https://youtu.be/dQw4w9WgXcQ).
1212
You cannot view it if you are not connected.' AS contents_md;

examples/user-authentication/sqlpage/migrations/0000_init.sql

-7
Original file line numberDiff line numberDiff line change
@@ -8,10 +8,3 @@ CREATE TABLE login_session (
88
username TEXT NOT NULL REFERENCES user_info(username),
99
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
1010
);
11-
12-
-- A small pure utility function to get the current user from a session cookie.
13-
-- In a database that does not support functions, you could inline this query
14-
-- or use a view if you need more information from the user table
15-
CREATE FUNCTION logged_in_user(session_id TEXT) RETURNS TEXT AS $$
16-
SELECT username FROM login_session WHERE id = session_id;
17-
$$ LANGUAGE SQL STABLE;

sqlpage/apexcharts.js

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
/* !include https://cdn.jsdelivr.net/npm/apexcharts@3.43.2-0/dist/apexcharts.min.js */
1+
/* !include https://cdn.jsdelivr.net/npm/apexcharts@3.44.0/dist/apexcharts.min.js */
22

33

44
function sqlpage_chart() {

sqlpage/tabler-icons.svg

+1-1
Loading

src/webserver/database/execute_queries.rs

+7-23
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,6 @@
11
use anyhow::anyhow;
22
use futures_util::stream::Stream;
33
use futures_util::StreamExt;
4-
use serde_json::Value;
54
use std::borrow::Cow;
65
use std::collections::HashMap;
76

@@ -14,7 +13,6 @@ use sqlx::pool::PoolConnection;
1413
use sqlx::{Any, AnyConnection, Arguments, Either, Executor, Row, Statement};
1514

1615
use super::sql_pseudofunctions::StmtParam;
17-
use super::sql_to_json::sql_to_json;
1816
use super::{highlight_sql_error, Database, DbItem};
1917

2018
impl Database {
@@ -55,11 +53,15 @@ pub fn stream_query_results<'a>(
5553
ParsedStatement::SetVariable { variable, value} => {
5654
let query = bind_parameters(value, request).await?;
5755
let connection = take_connection(db, &mut connection_opt).await?;
58-
let row = connection.fetch_optional(query).await?;
56+
log::debug!("Executing query to set the {variable:?} variable: {:?}", query.sql);
57+
let value: Option<String> = connection.fetch_optional(query).await?
58+
.and_then(|row| row.try_get::<Option<String>, _>(0).ok().flatten());
5959
let (vars, name) = vars_and_name(request, variable)?;
60-
if let Some(row) = row {
61-
vars.insert(name.clone(), row_to_varvalue(&row));
60+
if let Some(value) = value {
61+
log::debug!("Setting variable {name} to {value:?}");
62+
vars.insert(name.clone(), SingleOrVec::Single(value));
6263
} else {
64+
log::debug!("Removing variable {name}");
6365
vars.remove(&name);
6466
}
6567
},
@@ -92,24 +94,6 @@ fn vars_and_name<'a>(
9294
}
9395
}
9496

95-
fn row_to_varvalue(row: &AnyRow) -> SingleOrVec {
96-
let Some(col) = row.columns().first() else {
97-
return SingleOrVec::Single(String::new());
98-
};
99-
match sql_to_json(row, col) {
100-
Value::String(s) => SingleOrVec::Single(s),
101-
Value::Array(vals) => SingleOrVec::Vec(
102-
vals.into_iter()
103-
.map(|v| match v {
104-
Value::String(s) => s,
105-
other => other.to_string(),
106-
})
107-
.collect(),
108-
),
109-
other => SingleOrVec::Single(other.to_string()),
110-
}
111-
}
112-
11397
async fn take_connection<'a, 'b>(
11498
db: &'a Database,
11599
conn: &'b mut Option<PoolConnection<sqlx::Any>>,
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,9 @@
1+
set i_am_null = NULL;
2+
select 'text' as component,
3+
CASE
4+
WHEN $i_am_null IS NULL
5+
THEN
6+
'It works !'
7+
ELSE
8+
'error: expected null, got: ' || $i_am_null
9+
END as contents;

0 commit comments

Comments
 (0)