Skip to content

Commit 8ba15fd

Browse files
committed
form select
1 parent 69b3207 commit 8ba15fd

File tree

5 files changed

+90
-9
lines changed

5 files changed

+90
-9
lines changed

CHANGELOG.md

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,8 @@
1313
- Update ApexCharts to [v4.4.0](https://github.com/apexcharts/apexcharts.js/releases/tag/v4.4.0): fixes multiple small bugs in the chart component.
1414
- Add a new `auto_submit` parameter to the form component. When set to true, the form will be automatically submitted when the user changes any of its fields, and the page will be reloaded with the new value. The validation button is removed.
1515
- This is useful to quickly create filters at the top of a dashboard or report page, that will be automatically applied when the user changes them.
16+
- New `options_source` parameter in the form component. This allows to dynamically load options for dropdowns from a different SQL file.
17+
- This allows easily implementing autocomplete for form fields with a large number of possible options.
1618

1719
## 0.32.1 (2025-01-03)
1820

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
select 'json' as component;
2+
3+
select name as value, name as label
4+
from component
5+
where name like '%' || $search || '%';

examples/official-site/sqlpage/migrations/01_documentation.sql

Lines changed: 37 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -375,7 +375,7 @@ FROM fruits
375375
('form', '### Multi-select
376376
You can authorize the user to select multiple options by setting the `multiple` property to `true`.
377377
This creates a more compact (but arguably less user-friendly) alternative to a series of checkboxes.
378-
In this case, you should add square brackets to the name of the field.
378+
In this case, you should add square brackets to the name of the field (e.g. `''my_field[]'' as name`).
379379
The target page will then receive the value as a JSON array of strings, which you can iterate over using
380380
- the `json_each` function [in SQLite](https://www.sqlite.org/json1.html) and [Postgres](https://www.postgresql.org/docs/9.3/functions-json.html),
381381
- the [`OPENJSON`](https://learn.microsoft.com/fr-fr/sql/t-sql/functions/openjson-transact-sql?view=sql-server-ver16) function in Microsoft SQL Server.
@@ -388,14 +388,20 @@ The target page could then look like this:
388388
```sql
389389
insert into best_fruits(id) -- INSERT INTO ... SELECT ... runs the SELECT query and inserts the results into the table
390390
select CAST(value AS integer) as id -- all values are transmitted by the browser as strings
391-
from json_each($preferred_fruits); -- json_each returns a table with a "value" column for each element in the JSON array
391+
from json_each($my_field); -- in SQLite, json_each returns a table with a "value" column for each element in the JSON array
392392
```
393393
394394
### Example multiselect generated from a database table
395395
396-
As an example, if you have a table of all possible options (`my_options(id int, label text)`),
397-
and another table that contains the selected options per user (`my_user_options(user_id int, option_id int)`),
398-
you can use a query like this to generate the multi-select field:
396+
If you have a table of all possible options (`my_options(id int, label text)`),
397+
and want to generate a multi-select field from it, you have two options:
398+
- if the number of options is not too large, you can use the `options` parameter to return them all as a JSON array in the SQL query
399+
- if the number of options is large (e.g. more than 1000), you can use `options_source` to load options dynamically from a different SQL query as the user types
400+
401+
#### Embedding all options in the SQL query
402+
403+
Let''s say you have a table that contains the selected options per user (`my_user_options(user_id int, option_id int)`).
404+
You can use a query like this to generate the multi-select field:
399405
400406
```sql
401407
select ''select'' as type, true as multiple, json_group_array(json_object(
@@ -408,10 +414,33 @@ left join my_user_options
408414
on my_options.id = my_user_options.option_id
409415
and my_user_options.user_id = $user_id
410416
```
417+
418+
This will generate a json array of objects, each containing the label, value and selected status of each option.
419+
420+
#### Loading options dynamically from a different SQL query with `options_source`
421+
422+
If the `my_options` table has a large number of rows, you can use the `options_source` parameter to load options dynamically from a different SQL query as the user types.
423+
424+
We''ll write a second SQL file, `options_source.sql`, that will receive the user''s search string as a parameter named `$search`,
425+
and return a json array of objects, each containing the label and value of each option.
426+
427+
##### `options_source.sql`
428+
429+
```sql
430+
select ''json'' as component;
431+
432+
select id as value, label as label
433+
from my_options
434+
where label like $search || ''%'';
435+
```
436+
437+
##### `form`
438+
411439
', json('[{"component":"form", "action":"examples/show_variables.sql", "reset": "Reset"},
412-
{"label": "Fruits", "name": "fruits[]", "type": "select", "multiple": true, "create_new":true, "placeholder": "Good fruits...", "searchable": true, "description": "press ctrl to select multiple values", "options":
413-
"[{\"label\": \"Orange\", \"value\": 0, \"selected\": true}, {\"label\": \"Apple\", \"value\": 1}, {\"label\": \"Banana\", \"value\": 3, \"selected\": true}]"}
414-
]')),
440+
{"name": "component", "type": "select",
441+
"options_source": "examples/from_component_options_source.sql",
442+
"description": "Start typing the name of a component like ''map'' or ''form''..."
443+
}]')),
415444
('form', 'This example illustrates the use of the `radio` type.
416445
The `name` parameter is used to group the radio buttons together.
417446
The `value` parameter is used to set the value that will be submitted when the user selects the radio button.

sqlpage/templates/form.handlebars

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -69,10 +69,11 @@
6969
{{~#if autofocus}} autofocus {{/if~}}
7070
{{~#if disabled}}disabled {{/if~}}
7171
{{~#if multiple}} multiple {{/if~}}
72-
{{~#if (or dropdown searchable)}}
72+
{{~#if (or dropdown searchable options_source)}}
7373
data-pre-init="select-dropdown"
7474
data-sqlpage-js="{{static_path 'tomselect.js'}}"
7575
{{/if~}}
76+
{{~#if options_source}} data-options_source="{{options_source}}" {{/if~}}
7677
{{~#if placeholder}} placeholder="{{placeholder}}" {{/if~}}
7778
{{~#if create_new}} data-create_new={{create_new}} {{/if~}}
7879
>

sqlpage/tomselect.js

Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9,7 +9,12 @@ function sqlpage_select_dropdown() {
99
// By default, TomSelect will not retain the focus if s is already focused
1010
// This is a workaround to fix that
1111
const is_focused = s === document.activeElement;
12+
1213
const tom = new TomSelect(s, {
14+
load: sqlpage_load_options_source(s.dataset.options_source),
15+
valueField: "value",
16+
labelField: "label",
17+
searchField: "label",
1318
create: s.dataset.create_new,
1419
maxOptions: null,
1520
onItemAdd: function () {
@@ -32,4 +37,43 @@ function sqlpage_select_dropdown() {
3237
}
3338
}
3439

40+
function sqlpage_load_options_source(options_source) {
41+
if (!options_source) return;
42+
return async (query, callback) => {
43+
const err = (label) =>
44+
callback([{ label, value: "" }]);
45+
const resp = await fetch(
46+
`${options_source}?search=${encodeURIComponent(query)}`,
47+
);
48+
if (!resp.ok) {
49+
return err(
50+
`Error loading options from "${options_source}": ${resp.status} ${resp.statusText}`,
51+
);
52+
}
53+
const resp_type = resp.headers.get("content-type");
54+
if (resp_type !== "application/json") {
55+
return err(
56+
`Invalid response type: ${resp_type} from "${options_source}". Make sure to use the 'json' component in the SQL file that generates the options.`,
57+
);
58+
}
59+
const results = await resp.json();
60+
if (!Array.isArray(results)) {
61+
return err(
62+
`Invalid response from "${options_source}". The response must be an array of objects with a 'label' and a 'value' property.`,
63+
);
64+
}
65+
if (results.length === 1 && results[0].error) {
66+
return err(results[0].error);
67+
}
68+
if (results.length > 0) {
69+
const keys = Object.keys(results[0]);
70+
if (keys.length !== 2 || !keys.includes("label") || !keys.includes("value")) {
71+
return err(
72+
`Invalid response from "${options_source}". The response must be an array of objects with a 'label' and a 'value' property. Got: ${JSON.stringify(results[0])} in the first object instead.`,
73+
);
74+
}
75+
}
76+
callback(results);
77+
};
78+
}
3579
add_init_fn(sqlpage_select_dropdown);

0 commit comments

Comments
 (0)