Skip to content

Commit

Permalink
remove support for set $variable (use set variable instead).
Browse files Browse the repository at this point in the history
  • Loading branch information
lovasoa committed Sep 13, 2024
1 parent 28d7fc7 commit c94b35a
Show file tree
Hide file tree
Showing 22 changed files with 91 additions and 90 deletions.
9 changes: 5 additions & 4 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@
- New `navbar_title` property in the [shell](https://sql.datapage.app/documentation.sql?component=shell#component) component to set the title of the top navigation bar. This allows to display a different title in the top menu than the one that appears in the tab of the browser. This can also be set to the empty string to hide the title in the top menu, in case you want to display only a logo for instance.
- Fixed: The `font` property in the [shell](https://sql.datapage.app/documentation.sql?component=shell#component) component was mistakingly not applied since v0.28.0. It works again.
- Updated SQL parser to [v0.51.0](https://github.com/sqlparser-rs/sqlparser-rs/blob/main/CHANGELOG.md#0510-2024-09-11). Improved `INTERVAL` parsing.
- **Important note**: this version removes support for the `SET $variable = ...` syntax in SQLite. This worked only with some databases. You should replace all occurrences of this syntax with `SET variable = ...` (without the `$` prefix).

## 0.28.0 (2024-08-31)
- Chart component: fix the labels of pie charts displaying too many decimal places.
Expand Down Expand Up @@ -192,7 +193,7 @@ select
- reuse the existing opened database connection for the current query in `sqlpage.run_sql` instead of opening a new one. This makes it possible to create a temporary table in a file, and reuse it in an included script, create a SQL transaction that spans over multiple run_sql calls, and should generally make run_sql more performant.
- Fixed a bug in the cookie component where removing a cookie from a subdirectory would not work.
- [Updated SQL parser](https://github.com/sqlparser-rs/sqlparser-rs/blob/main/CHANGELOG.md#0470-2024-06-01). Fixes support for `AT TIME ZONE` in postgres. Fixes `GROUP_CONCAT()` in MySQL.
- Add a new warning message in the logs when trying to use `SET $x = ` when there is already a form field named `x`.
- Add a new warning message in the logs when trying to use `set x = ` when there is already a form field named `x`.
- **Empty Uploaded files**: when a form contains an optional file upload field, and the user does not upload a file, the field used to still be accessible to SQLPage file-related functions such as `sqlpage.uploaded_file_path` and `sqlpage.uploaded_file_mime_type`. This is now fixed, and these functions will return `NULL` when the user does not upload a file. `sqlpage.persist_uploaded_file` will not create an empty file in the target directory when the user does not upload a file, instead it will do nothing and return `NULL`.
- In the [map](https://sql.datapage.app/documentation.sql?component=map#component) component, when top-level latitude and longitude properties are omitted, the map will now center on its markers. This makes it easier to create zoomed maps with a single marker.
- In the [button](https://sql.datapage.app/documentation.sql?component=button#component) component, add a `download` property to make the button download a file when clicked, a `target` property to open the link in a new tab, and a `rel` property to prevent search engines from following the link.
Expand All @@ -202,9 +203,9 @@ select
## 0.22.0 (2024-05-29)
- **Important Security Fix:** The behavior of `SET $x` has been modified to match `SELECT $x`.
- **Security Risk:** Previously, `SET $x` could be overwritten by a POST parameter named `x`.
- **Solution:** Upgrade to SQLPage v0.22. If not possible, then update your application to use `SET :x` instead of `SET $x`.
- **Important Security Fix:** The behavior of `set x` has been modified to match `SELECT $x`.
- **Security Risk:** Previously, `set x` could be overwritten by a POST parameter named `x`.
- **Solution:** Upgrade to SQLPage v0.22. If not possible, then update your application to use `SET :x` instead of `set x`.
- For more information, see [GitHub Issue #342](https://github.com/lovasoa/SQLpage/issues/342).
- **Deprecation Notice:** Reading POST variables using `$x`.
- **New Standard:** Use `:x` for POST variables and `$x` for GET variables.
Expand Down
28 changes: 14 additions & 14 deletions examples/CRUD - Authentication/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -10,14 +10,14 @@ Three files (login.sql, logout.sql, and create_session.sql) implement authentica
2. Session checking code snippet at the top of the protected page checks if a valid session token (cookie) is set. In this example, the SET statement sets a local variable, `$_username`, for later use:
```sql
-- Checks if a valid session token cookie is available
SET $_username = (
set _username = (
SELECT username
FROM sessions
WHERE sqlpage.cookie('session_token') = id
AND created_at > datetime('now', '-1 day')
);
```
3. Redirect to login page (login.sql) if no session is available (`$_username IS NULL`) and the starting page requires authentication (by setting `SET $_session_required = 1;` before executing the session checking code; see, e.g., the top of currencies_item_form.sql and currencies_list.sql):
3. Redirect to login page (login.sql) if no session is available (`$_username IS NULL`) and the starting page requires authentication (by setting `set _session_required = 1;` before executing the session checking code; see, e.g., the top of currencies_item_form.sql and currencies_list.sql):
```sql
SELECT
'redirect' AS component,
Expand All @@ -34,8 +34,8 @@ WHERE $_username IS NULL AND $_session_required;
Because the same code is used for session token check for all protected pages, it makes sense to place it in a separate module (header_shell_session.sql) and execute it via run_sql() at the top of protected files:

```sql
SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand Down Expand Up @@ -104,9 +104,9 @@ The `$_shell_enabled` variable controls the execution of the custom shell compon
The header modules expects that the calling module sets several variables. The SET statement makes it possible to check if the variables are set appropriately in one place at the beginning of the module, rather then placing guards every time theses variables are used. Hence, the top section of the header file includes

```sql
SET $_curpath = ifnull($_curpath, '/');
SET $_session_required = ifnull($_session_required, 1);
SET $_shell_enabled = ifnull($_shell_enabled, 1);
set _curpath = ifnull($_curpath, '/');
set _session_required = ifnull($_session_required, 1);
set _shell_enabled = ifnull($_shell_enabled, 1);
```
In this case, if any required variable is not set, a suitable default value is defined, so that the following code would not have to check for NULL values. Alternatively, a redirect to an error page may be used, to inform the programmer about the potential issue.

Expand Down Expand Up @@ -142,8 +142,8 @@ All three module load the footer module discussed above that produces a conditio
All three modules provide access to the database and are treated as protected: they are only accessible to authenticated users. Hence, they start with (mostly) the same code block:

```sql
SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand Down Expand Up @@ -178,7 +178,7 @@ SELECT
$_curpath AS link
WHERE $id = '' OR CAST($id AS INT) = 0;

SET $error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');
set error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');
SELECT
'redirect' AS component,
$_curpath || '?error=' || $error_msg AS link
Expand All @@ -190,7 +190,7 @@ The blank string and zero are considered the equivalents of NULL, so redirect to
Another accepted GET URL parameter is $values, which may be set to a JSON representation of the record. This parameter is returned from the currencies_item_dml.sql script if the database operation fails. Then the detail view will display an error message, but the form will remain populated with the user-submitted data. If $values is set, it takes precedence. This check throws an error if $values is set, but does not represent a valid JSON.

```sql
SET $_err_msg =
set _err_msg =
sqlpage.url_encode('Values is set to bad JSON: __ ') || $values || ' __';

SELECT
Expand All @@ -201,7 +201,7 @@ WHERE NOT json_valid($values);
The detail view maybe called with zero, one, or two (\$id/\$values) parameters. Invalid values are filtered out at this point, so the next step is to check provided parameters and determine the dataset that should go into the form.

```sql
SET $_values = (
set _values = (
WITH
fields AS (
SELECT id, name, to_rub
Expand Down Expand Up @@ -253,7 +253,7 @@ WHERE NOT ifnull($action = 'DELETE', FALSE);
The following section defines the main form with record fields. First the $\_valid_ids variable is constructed as the source for the drop-down id field. The code also adds the NULL value used for defining a new record. Note that, when this form is opened from the table view via the "New Record" button, the $action variable is set to "INSERT" and the id field is set to the empty array in the first assignment via the alternative UINION and to the single NULL in the second assignment. The two queries can also be combined relatively straightforwardly using CTEs.

```sql
SET $_valid_ids = (
set _valid_ids = (
SELECT json_group_array(
json_object('label', CAST(id AS TEXT), 'value', id) ORDER BY id
)
Expand All @@ -263,7 +263,7 @@ SET $_valid_ids = (
SELECT '[]'
WHERE $action = 'INSERT'
);
SET $_valid_ids = (
set _valid_ids = (
json_insert($_valid_ids, '$[#]',
json_object('label', 'NULL', 'value', json('null'))
)
Expand Down
28 changes: 14 additions & 14 deletions examples/CRUD - Authentication/www/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -10,14 +10,14 @@ Three files (login.sql, logout.sql, and create_session.sql) implement authentica
2. Session checking code snippet at the top of the protected page checks if a valid session token (cookie) is set. In this example, the SET statement sets a local variable, `$_username`, for later use:
```sql
-- Checks if a valid session token cookie is available
SET $_username = (
set _username = (
SELECT username
FROM sessions
WHERE sqlpage.cookie('session_token') = id
AND created_at > datetime('now', '-1 day')
);
```
3. Redirect to login page (login.sql) if no session is available (`$_username IS NULL`) and the starting page requires authentication (by setting `SET $_session_required = 1;` before executing the session checking code; see, e.g., the top of currencies_item_form.sql and currencies_list.sql):
3. Redirect to login page (login.sql) if no session is available (`$_username IS NULL`) and the starting page requires authentication (by setting `set _session_required = 1;` before executing the session checking code; see, e.g., the top of currencies_item_form.sql and currencies_list.sql):
```sql
SELECT
'redirect' AS component,
Expand All @@ -34,8 +34,8 @@ WHERE $_username IS NULL AND $_session_required;
Because the same code is used for session token check for all protected pages, it makes sense to place it in a separate module (header_shell_session.sql) and execute it via run_sql() at the top of protected files:

```sql
SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand Down Expand Up @@ -104,9 +104,9 @@ The `$_shell_enabled` variable controls the execution of the custom shell compon
The header modules expects that the calling module sets several variables. The SET statement makes it possible to check if the variables are set appropriately in one place at the beginning of the module, rather then placing guards every time theses variables are used. Hence, the top section of the header file includes

```sql
SET $_curpath = ifnull($_curpath, '/');
SET $_session_required = ifnull($_session_required, 1);
SET $_shell_enabled = ifnull($_shell_enabled, 1);
set _curpath = ifnull($_curpath, '/');
set _session_required = ifnull($_session_required, 1);
set _shell_enabled = ifnull($_shell_enabled, 1);
```
In this case, if any required variable is not set, a suitable default value is defined, so that the following code would not have to check for NULL values. Alternatively, a redirect to an error page may be used, to inform the programmer about the potential issue.

Expand Down Expand Up @@ -142,8 +142,8 @@ All three module load the footer module discussed above that produces a conditio
All three modules provide access to the database and are treated as protected: they are only accessible to authenticated users. Hence, they start with (mostly) the same code block:

```sql
SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand Down Expand Up @@ -178,7 +178,7 @@ SELECT
$_curpath AS link
WHERE $id = '' OR CAST($id AS INT) = 0;

SET $error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');
set error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');
SELECT
'redirect' AS component,
$_curpath || '?error=' || $error_msg AS link
Expand All @@ -190,7 +190,7 @@ The blank string and zero are considered the equivalents of NULL, so redirect to
Another accepted GET URL parameter is $values, which may be set to a JSON representation of the record. This parameter is returned from the currencies_item_dml.sql script if the database operation fails. Then the detail view will display an error message, but the form will remain populated with the user-submitted data. If $values is set, it takes precedence. This check throws an error if $values is set, but does not represent a valid JSON.

```sql
SET $_err_msg =
set _err_msg =
sqlpage.url_encode('Values is set to bad JSON: __ ') || $values || ' __';

SELECT
Expand All @@ -201,7 +201,7 @@ WHERE NOT json_valid($values);
The detail view maybe called with zero, one, or two (\$id/\$values) parameters. Invalid values are filtered out at this point, so the next step is to check provided parameters and determine the dataset that should go into the form.

```sql
SET $_values = (
set _values = (
WITH
fields AS (
SELECT id, name, to_rub
Expand Down Expand Up @@ -253,7 +253,7 @@ WHERE NOT ifnull($action = 'DELETE', FALSE);
The following section defines the main form with record fields. First the $\_valid_ids variable is constructed as the source for the drop-down id field. The code also adds the NULL value used for defining a new record. Note that, when this form is opened from the table view via the "New Record" button, the $action variable is set to "INSERT" and the id field is set to the empty array in the first assignment via the alternative UINION and to the single NULL in the second assignment. The two queries can also be combined relatively straightforwardly using CTEs.

```sql
SET $_valid_ids = (
set _valid_ids = (
SELECT json_group_array(
json_object('label', CAST(id AS TEXT), 'value', id) ORDER BY id
)
Expand All @@ -263,7 +263,7 @@ SET $_valid_ids = (
SELECT '[]'
WHERE $action = 'INSERT'
);
SET $_valid_ids = (
set _valid_ids = (
json_insert($_valid_ids, '$[#]',
json_object('label', 'NULL', 'value', json('null'))
)
Expand Down
16 changes: 8 additions & 8 deletions examples/CRUD - Authentication/www/currencies_item_dml.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,8 +7,8 @@

-- $_curpath and $_session_required are required for header_shell_session.sql.

SET $_session_required = 1;
SET $_shell_enabled = 0;
set _session_required = 1;
set _shell_enabled = 0;

SELECT
'dynamic' AS component,
Expand All @@ -18,7 +18,7 @@ SELECT
-- Redirect target must be passed as $path
-- =============================================================================

SET $_err_msg = '&path URL GET parameter (redirect target) is not set!';
set _err_msg = '&path URL GET parameter (redirect target) is not set!';

SELECT
'alert' AS component,
Expand Down Expand Up @@ -46,18 +46,18 @@ WHERE
-- For new records, the id (INTEGER PRIMARY KEY AUTOINCREMENT) should be set to NULL.
-- The id field is set as hidden in the record edit form and passed as the :id POST
-- variable. NULL, however, cannot be passed as such and is converted to blank string.
-- Check :id for '' and SET $id (:id will return the same value).
-- Check :id for '' and set id (:id will return the same value).

SET $_id = iif(typeof(:id) = 'text' AND :id = '', NULL, :id);
set _id = iif(typeof(:id) = 'text' AND :id = '', NULL, :id);

SET $_values = json_object(
set _values = json_object(
'id', CAST($_id AS INT),
'name', :name,
'to_rub', CAST(:to_rub AS NUMERIC)
);

SET $_op = iif($_id IS NULL, 'INSERT', 'UPDATE');
SET $_err_msg = sqlpage.url_encode('New currency already in the database');
set _op = iif($_id IS NULL, 'INSERT', 'UPDATE');
set _err_msg = sqlpage.url_encode('New currency already in the database');

SELECT
'redirect' AS component,
Expand Down
22 changes: 11 additions & 11 deletions examples/CRUD - Authentication/www/currencies_item_form.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,8 +8,8 @@

-- $_curpath and $_session_required are required for header_shell_session.sql.

SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand All @@ -19,9 +19,9 @@ SELECT
-- =============================== Module vars =================================
-- =============================================================================

SET $_getpath = '?path=' || ifnull($path, $_curpath);
SET $_action_target = 'currencies_item_dml.sql' || $_getpath;
SET $_table_list = 'currencies_list.sql';
set _getpath = '?path=' || ifnull($path, $_curpath);
set _action_target = 'currencies_item_dml.sql' || $_getpath;
set _table_list = 'currencies_list.sql';

-- =============================================================================
-- ========================== Filter invalid $id ===============================
Expand All @@ -36,7 +36,7 @@ WHERE $id = '' OR CAST($id AS INT) = 0;

-- If $id is set, it must be a valid PKEY value.

SET $error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');
set error_msg = sqlpage.url_encode('Bad {id = ' || $id || '} provided');

SELECT
'redirect' AS component,
Expand All @@ -52,7 +52,7 @@ WHERE $id NOT IN (SELECT currencies.id FROM currencies);
--
-- If $values is provided, it must contain a valid JSON.

SET $_err_msg =
set _err_msg =
sqlpage.url_encode('Values is set to bad JSON: __ ') || $values || ' __';

SELECT
Expand All @@ -70,9 +70,9 @@ WHERE NOT json_valid($values);
-- Field values may be provided via the $values GET variable formatted as JSON
-- object. If $values contains a valid JSON, use it to populate the form.
-- Otherwise, if $id is set to a valid value, retrieve the record from the
-- database and set $values. If not, set $values to all NULLs.
-- database and set values. If not, set values to all NULLs.

SET $_values = (
set _values = (
WITH
fields AS (
-- If valid "id" is supplied as a GET variable, retrieve the record and
Expand Down Expand Up @@ -136,7 +136,7 @@ WHERE NOT ifnull($action = 'DELETE', FALSE);
-- passed back as POST variables, and the code above sets the $_values variable
-- for proper initialization of the reloaded form.

SET $_valid_ids = (
set _valid_ids = (
SELECT json_group_array(
json_object('label', CAST(id AS TEXT), 'value', id) ORDER BY id
)
Expand All @@ -146,7 +146,7 @@ SET $_valid_ids = (
SELECT '[]'
WHERE $action = 'INSERT'
);
SET $_valid_ids = (
set _valid_ids = (
json_insert($_valid_ids, '$[#]',
json_object('label', 'NULL', 'value', json('null'))
)
Expand Down
8 changes: 4 additions & 4 deletions examples/CRUD - Authentication/www/currencies_list.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,8 +5,8 @@

-- $_curpath and $_session_required are required for header_shell_session.sql.

SET $_curpath = sqlpage.path();
SET $_session_required = 1;
set _curpath = sqlpage.path();
set _session_required = 1;

SELECT
'dynamic' AS component,
Expand All @@ -16,8 +16,8 @@ SELECT
-- =============================== Module vars =================================
-- =============================================================================

SET $_getpath = '&path=' || $_curpath;
SET $_item_form = 'currencies_item_form.sql';
set _getpath = '&path=' || $_curpath;
set _item_form = 'currencies_item_form.sql';

-- =============================================================================
-- ======================== Display confirmation ===============================
Expand Down
Loading

0 comments on commit c94b35a

Please sign in to comment.