Skip to content

Commit 97c2e4a

Browse files
lovasoacursoragentkryskool
authored
wip: perf guide (#1077)
* wip: perf guide * update guide * Add materialized views section to performance guide - Introduced a new section on materialized views, explaining their purpose and benefits for optimizing analytical queries. - Added an example SQL statement for creating a materialized view to compute total sales per store. - Provided guidance on refreshing materialized views manually or via external scripts. * Document nginx streaming and compression for sqlpage (#1080) * Docs: Add Nginx streaming and compression configuration Co-authored-by: contact <[email protected]> * Add NGINX streaming and compression configuration Co-authored-by: contact <[email protected]> * Refactor NGINX proxy settings documentation for clarity Co-authored-by: contact <[email protected]> * Refine NGINX proxy buffering recommendations for streaming Co-authored-by: contact <[email protected]> * Update NGINX proxy buffering settings for improved streaming performance Revised the documentation to clarify the impact of enabling and disabling proxy buffering in NGINX for SQLPage. Added concise recommendations for handling slow SQL queries and emphasized the importance of adjusting `compress_responses` in `sqlpage.json` when using a reverse proxy. Co-authored-by: contact <[email protected]> --------- Co-authored-by: Cursor Agent <[email protected]> * Update dependencies and version for sqlpage to 0.39.1 - Bump versions of several dependencies including `aho-corasick`, `cc`, `clap`, `icu_collections`, and others to their latest releases. - Update `Cargo.toml` to reflect the new version of sqlpage. - Ensure compatibility with updated dependencies and improve overall project stability. * fix handling of one-element arrays in doc code generator see #1079 * In the table component, allow simple objects in custom_actions instead of requiring arrays of objects. fix #1079 * Implement faster icon loading by inlining icons from the Tabler sprite. The previous method required downloading and parsing a large file, causing delays in icon rendering. Now, icons are generated and cached, improving page load times. Update the icon helper to utilize the new inline method. * Update tabler icons to version 3.35 and refactor icon extraction logic for improved performance * icon image helper: logging and error handling - Changed debug logs to warning logs for invalid icon names and missing icons in the IconImgHelper. - Updated the way icons are retrieved from the ICON_MAP for better clarity and performance. * IconImgHelper: use raw string literals for SVG output * Refactor icon extraction logic in build.rs to improve performance and memory usage. The download_tabler_icons function now directly processes sprite content in memory, eliminating the need for temporary file storage. Updated extract_icons_from_sprite to handle byte slices instead of strings, enhancing efficiency. * build.rs: raise on missing icon id * Simlplify icon generation in build.rs * simplify icon _img helper * update input field docs fixes #1081 * better form documentation * fix ipv6 notation (#1084) On Mac OS, when localhost:8080 is defined and sqlpage config file, the SocketAddr is resolved with ipv6 address if ip V6 is available on the internal network. ```json { "listen_on": "localhost:8080" } ``` On the terminal we can Ctrl + Click, but the URL is incorrect (ipV6 notation use bracket) Actually we have ```shell View your website at: 🔗 http://::1:8080 ``` Instead of ``` View your website at: 🔗 http://[::1]:8080 ``` Regards, * Update dependencies in Cargo.lock to latest versions * Fix github pr ci cache warnings (#1086) * feat: Add shared-key to cargo cache action Co-authored-by: contact <[email protected]> * Refactor: Use matrix-specific cache key in CI Co-authored-by: contact <[email protected]> * feat: Cache Rust build artifacts only on main branch Co-authored-by: contact <[email protected]> --------- Co-authored-by: Cursor Agent <[email protected]> * Enhance SQL performance guidance in migration script - Added detailed recommendations for using primary and foreign keys, including examples for product and sales tables. - Introduced best practices for indexing, query performance debugging, and database maintenance commands. - Included advice on lazy loading and reducing the number of queries to optimize SQLPage applications. --------- Co-authored-by: Cursor Agent <[email protected]> Co-authored-by: Christophe CHAUVET <[email protected]>
1 parent 2e2c5e9 commit 97c2e4a

File tree

2 files changed

+296
-12
lines changed

2 files changed

+296
-12
lines changed

examples/official-site/performance.sql

Lines changed: 12 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -22,20 +22,21 @@ as opposed to writing imperative code in a backend programming language like Jav
2222
This declarative approach allows SQLPage to offer **optimizations** out of the box that are difficult or time-consuming
2323
to achieve in traditional web development stacks.
2424
25-
## Server-side rendering
25+
## Progressive server-side rendering
2626
2727
SQLPage applications are [server-side rendered](https://web.dev/articles/rendering-on-the-web),
28-
which means that the SQL queries are executed on the server, and the results are sent to the user''s browser
29-
as HTML, which allows it to start rendering the page as soon as the first byte is received.
28+
which means that the SQL queries are executed on the server, and the results are sent to the user''s browser as HTML.
3029
In contrast, many other web frameworks render the page on the client side, which means that the browser has to download
3130
some HTML, then download some JavaScript, then execute the JavaScript, then make more requests,
31+
wait for the database to produce a full result set,
3232
then process the responses before it can start rendering the actual data the user is interested in.
3333
This can lead to loading times that are several times longer than a SQLPage application.
3434
3535
### Streaming
3636
3737
SQLPage applications will often feel faster than even equivalent applications written even in alternative server-side rendering
3838
frameworks, because SQLPage streams the results of the SQL queries to the browser as soon as they are available.
39+
The user sees the start of the page even before the database has finished producing the last query results.
3940
4041
Most server-side rendering frameworks will first wait for all the SQL queries to finish, then render the page in memory
4142
on the server, and only then send the HTML webpage to the browser. If a page contains a long list of items, the user
@@ -51,7 +52,7 @@ an execution plan every time an user requests a page.
5152
5253
When an user loads a page, all SQLPage has to do is tell the database: "Hey, do you remember that query we talked about
5354
earlier? Can you give me the results for these specific parameters?". This is much faster than sending the whole SQL query
54-
string to the database every time.
55+
string to the database every time, especially for large complex queries that require heavy planning on the database side.
5556
5657
## Compiled templates
5758
@@ -87,16 +88,15 @@ interaction.
8788
8889
## Key Takeaways
8990
90-
SQLPage offers a radically different approach to web development,
91-
resolving the classical tension between performance and ease of use.
92-
93-
By leveraging a declarative approach, server-side rendering, and advanced optimization techniques, SQLPage enables:
94-
95-
* **Faster page loads**: Long loading times make your website feel sluggish and unresponsive, causing users to leave.
96-
* **Easier development**: Focus on writing SQL queries; all the heavy lifting is done for you.
97-
* **Cost effective**: SQLPage''s low CPU and memory usage means you can host your website extremely cheaply, even if it gets significant traffic.
91+
Performance is a key feature of SQLPage.
92+
Its architecture allows you to build fast websites without having to implement advanced optimizations yourself.
9893
9994
## Ready to get started?
10095
10196
[Build your fast, secure, and beautiful website](/your-first-sql-website) with SQLPage today!
97+
98+
## Already a SQLPage developer ?
99+
100+
Have a look at our [performance guide](/blog?post=Performance+Guide) to learn the best practices to leverage
101+
all the features that will make your site faster.
102102
' as contents_md;
Lines changed: 284 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,284 @@
1+
2+
INSERT INTO blog_posts (title, description, icon, created_at, content)
3+
VALUES
4+
(
5+
'Performance Guide',
6+
'Concrete advice on how to make your SQLPage webapp fast',
7+
'bolt',
8+
'2025-10-31',
9+
'
10+
# Performance Guide
11+
12+
SQLPage is [optimized](/performance)
13+
to allow you to create web pages that feel snappy.
14+
This guide contains advice on how to ensure your users never wait
15+
behind a blank screen waiting for your pages to load.
16+
17+
A lot of the advice here is not specific to SQLPage, but applies
18+
to making SQL queries fast in general.
19+
If you are already comfortable with SQL performance optimization, feel free to jump right to
20+
the second part of the quide: *SQLPage-specific advice*.
21+
22+
## Make your queries fast
23+
24+
The best way to ensure your SQLPage webapp is fast is to ensure your
25+
database is well managed and your SQL queries are well written.
26+
We''ll go over the most common database performance pitfalls so that you know how to avoid them.
27+
28+
### Choose the right database schema
29+
30+
#### Normalize (but not too much)
31+
32+
Your database schema should be [normalized](https://en.wikipedia.org/wiki/Database_normalization):
33+
one piece of information should be stored in only one place in the database.
34+
This is a good practice that will not only make your queries faster,
35+
but also make it impossible to store incoherent data.
36+
You should use meaningful natural [primary keys](https://en.wikipedia.org/wiki/Primary_key) for your tables
37+
and resort to surrogate keys (such as auto-incremented integer ids) only when the data is not naturally keyed.
38+
Relationships between tables should be explicitly represented by [foreign keys](https://en.wikipedia.org/wiki/Foreign_key).
39+
40+
```sql
41+
-- Products table, naturally keyed by catalog_number
42+
CREATE TABLE product (
43+
catalog_number VARCHAR(20) PRIMARY KEY,
44+
name TEXT NOT NULL,
45+
price DECIMAL(10,2) NOT NULL
46+
);
47+
48+
-- Sales table: natural key = (sale_date, store_id, transaction_number)
49+
-- composite primary key used since no single natural attribute alone uniquely identifies a sale
50+
CREATE TABLE sale (
51+
sale_date DATE NOT NULL,
52+
store_id VARCHAR(10) NOT NULL,
53+
transaction_number INT NOT NULL,
54+
product_catalog_number VARCHAR(20) NOT NULL,
55+
quantity INT NOT NULL CHECK (quantity > 0),
56+
PRIMARY KEY (sale_date, store_id, transaction_number),
57+
FOREIGN KEY (product_catalog_number) REFERENCES product(catalog_number),
58+
FOREIGN KEY (store_id) REFERENCES store(store_id)
59+
);
60+
```
61+
62+
Always use foreign keys instead of trying to store redundant data such as store names in the sales table.
63+
64+
This way, when you need to display the list of stores in your application, you don''t have to
65+
run a slow `select distinct store from sales`, that would have to go through your millions of sales
66+
(*even if you have an index on the store column*), you just query the tiny `stores` table directly.
67+
68+
You also need to use the right [data types](https://en.wikipedia.org/wiki/Data_type) for your columns,
69+
otherwise you will waste a lot of space and time converting data at query time.
70+
See [postgreSQL data types](https://www.postgresql.org/docs/current/datatype.html),
71+
[MySQL data types](https://dev.mysql.com/doc/refman/8.0/en/data-types.html),
72+
[Microsoft SQL Server data types](https://learn.microsoft.com/en-us/sql/t-sql/data-types/data-types-transact-sql?view=sql-server-ver16),
73+
[SQLite data types](https://www.sqlite.org/datatype3.html).
74+
75+
[Denormalization](https://en.wikipedia.org/wiki/Denormalization) can be introduced
76+
only after you have already normalized your data, and is often not required at all.
77+
78+
### Use views
79+
80+
Querying normalized views can be cumbersome.
81+
`select store_name, sum(paid_eur) from sale group by store_name`
82+
is more readable than
83+
84+
```sql
85+
select store.name, sum(sale.paid_eur)
86+
from sales
87+
inner join stores on sale.store_id = store.store_id
88+
group by store_name
89+
```
90+
91+
To work around that, you can create views that contain
92+
useful table joins so that you do not have to duplicate them in all your queries:
93+
94+
```sql
95+
create view enriched_sales as
96+
select sales.sales_eur, sales.client_id, store.store_name
97+
from sales
98+
inner join store
99+
```
100+
101+
#### Materialized views
102+
103+
Some analytical queries just have to compute aggregated statistics over large quantities of data.
104+
For instance, you might want to compute the total sales per store, or the total sales per product.
105+
These queries are slow to compute when there are many rows, and you might not want to run them on every request.
106+
You can use [materialized views](https://en.wikipedia.org/wiki/Materialized_view) to cache the results of these queries.
107+
Materialized views are views that are stored as regular tables in the database.
108+
109+
Depending on the database, you might have to refresh the materialized view manually.
110+
You can either refresh the view manually from inside your sql pages when you detect they are outdated,
111+
or write an external script to refresh the view periodically.
112+
113+
```sql
114+
create materialized view total_sales_per_store as
115+
select store_name, sum(sales_eur) as total_sales
116+
from sales
117+
group by store_name;
118+
```
119+
120+
### Use database indices
121+
122+
When a query on a large table uses non-primary column in a `WHERE`, `GROUP BY`, `ORDER BY`, or `JOIN`,
123+
you should create an [index](https://en.wikipedia.org/wiki/Database_index) on that column.
124+
When multiple columns are used in the query, you should create a composite index on those columns.
125+
When creating a composite index, the order of the columns is important.
126+
The most frequently used columns should be first.
127+
128+
```sql
129+
create index idx_sales_store_date on sale (store_id, sale_date); -- useful for queries that filter by "store" or by "store and date"
130+
create index idx_sales_product_date on sale (product_id, sale_date);
131+
create index idx_sales_store_product_date on sale (store_id, product_id, sale_date);
132+
```
133+
134+
Indexes are updated automatically when the table is modified.
135+
They slow down the insertion and deletion of rows in the table,
136+
but speed up the retrieval of rows in queries that use the indexed columns.
137+
138+
### Query performance debugging
139+
140+
When a query is slow, you can use the `EXPLAIN` keyword to see how the database will execute the query.
141+
Just add `EXPLAIN` before the query you want to analyze.
142+
143+
On PostgreSQL, you can use a tool like [explain.dalibo.com](https://explain.dalibo.com/) to visualize the query plan.
144+
145+
What to look for:
146+
- Are indexes used? You should see references to the indices you created.
147+
- Are full table scans used? Large tables should never be scanned.
148+
- Are expensive operations used? Such as sorting, hashing, bitmap index scans, etc.
149+
- Are operations happening in the order you expected them to? Filtering large tables should come first.
150+
151+
### Vacuum your database regularly
152+
153+
On PostgreSQL, you can use the [`VACUUM`](https://www.postgresql.org/docs/current/sql-vacuum.html) command to garbage-collect and analyze a database.
154+
155+
On MySQL, you can use the [`OPTIMIZE TABLE`](https://dev.mysql.com/doc/refman/8.0/en/optimize-table.html) command to reorganize it on disk and make it faster.
156+
On Microsoft SQL Server, you can use the [`DBCC DBREINDEX`](https://learn.microsoft.com/en-us/sql/t-sql/database-console-commands/dbcc-dbreindex-transact-sql?view=sql-server-ver17) command to rebuild the indexes.
157+
On SQLite, you can use the [`VACUUM`](https://www.sqlite.org/lang_vacuum.html) command to garbage-collect and analyze the database.
158+
159+
### Use the right database engine
160+
161+
If the amount of data you are working with is very large, does not change frequently, and you need to run complex queries on it,
162+
you could use a specialized analytical database such as [ClickHouse](https://clickhouse.com/) or [DuckDB](https://duckdb.org/).
163+
Such databases can be used with SQLPage by using their [ODBC](https://en.wikipedia.org/wiki/Open_Database_Connectivity) drivers.
164+
165+
### Database-specific performance recommendations
166+
167+
- [PostgreSQL "Performance Tips"](https://www.postgresql.org/docs/current/performance-tips.html)
168+
- [MySQL optimization guide](https://dev.mysql.com/doc/refman/8.0/en/optimization.html)
169+
- [Microsoft SQL Server "Monitor and Tune for Performance"](https://learn.microsoft.com/en-us/sql/relational-databases/performance/monitor-and-tune-for-performance?view=sql-server-ver17)
170+
- [SQLite query optimizer overview](https://www.sqlite.org/optoverview.html)
171+
172+
## SQLPage-specific advice
173+
174+
The best way to make your SQLPage webapp fast is to make your queries fast.
175+
Sometimes, you just don''t have control over the database, and have to run slow queries.
176+
This section will help you minimize the impact to your users.
177+
178+
### Order matters
179+
180+
SQLPage executes the queries in your `.sql` files in order.
181+
It does not start executing a query before the previous one has returned all its results.
182+
So, if you have to execute a slow query, put it as far down in the page as possible.
183+
184+
#### No heavy computation before the shell
185+
186+
Every user-facing page in a SQLPage site has a [shell](/components?component=shell).
187+
188+
The first queries in any sql file (all the ones that come before the [shell](/components?component=shell))
189+
are executed before any data has been sent to the user''s browser.
190+
During that time, the user will see a blank screen.
191+
So, ensure your shell comes as early as possible, and does not require any heavy computation.
192+
If you can make your shell entirely static (independent of the database), do so,
193+
and it will be rendered before SQLPage even finishes acquiring a database connection.
194+
195+
#### Set variables just above their first usage
196+
197+
For the reasons explained above, you should avoid defining all variables at the top of your sql file.
198+
Instead, define them just above their first usage.
199+
200+
### Avoid recomputing the same data multiple times
201+
202+
Often, a single page will require the same pieces of data in multiple places.
203+
In this case, avoid recomputing it on every use inside the page.
204+
205+
#### Reusing a single database record
206+
207+
When that data is small, store it in a sqlpage variable as JSON and then
208+
extract the data you need using [json operations](/blog.sql?post=JSON%20in%20SQL%3A%20A%20Comprehensive%20Guide).
209+
210+
```sql
211+
set product = (
212+
select json_object(''name'', name, ''price'', price) -- in postgres, you can simply use row_to_json(product)
213+
from products where id = $product_id
214+
);
215+
216+
select ''alert'' as component, ''Product'' as title, $product->>''name'' as description;
217+
```
218+
219+
#### Reusing a large query result set
220+
221+
You may have a page that lets the user filter a large dataset by many different criteria,
222+
and then displays multiple charts and tables based on the filtered data.
223+
224+
In this case, store the filtered data in a temporary table and then reuse it in multiple places.
225+
226+
```sql
227+
drop table if exists filtered_products;
228+
create temporary table filtered_products as
229+
select * from products where
230+
($category is null or category = $category) and
231+
($manufacturer is null or manufacturer = $manufacturer);
232+
233+
select ''alert'' as component, count(*) || '' products'' as title
234+
from filtered_products;
235+
236+
select ''list'' as component;
237+
select name as title from filtered_products;
238+
```
239+
240+
### Reduce the number of queries
241+
242+
Each query you execute has an overhead of at least the time it takes to send a packet back and forth
243+
between SQLPage and the database.
244+
When it''s possible, combine multiple queries into a single one, possibly using
245+
[`UNION ALL`](https://en.wikipedia.org/wiki/Set_operations_(SQL)#UNION_operator).
246+
247+
```sql
248+
select ''big_number'' as component;
249+
250+
with stats as (
251+
select count(*) as total, avg(price) as average_price from filtered_products
252+
)
253+
select ''count'' as title, stats.total as value from stats
254+
union all
255+
select ''average price'' as title, stats.average_price as value from stats;
256+
```
257+
258+
### Lazy loading
259+
260+
Use the [card](/component?component=card) and [modal](/component?component=modal) components
261+
with the `embed` attribute to load data lazily.
262+
Lazy loaded content is not sent to the user''s browser when the page initially loads,
263+
so it does not block the initial rendering of the page and provides a better experience for
264+
data that might be slow to load.
265+
266+
### Database connections
267+
268+
SQLPage uses connection pooling: it keeps multiple database connections opened,
269+
and reuses them for consecutive requests. When it does not receive requests for a long time,
270+
it closes idle connection. When it receives many requests, it opens new connection,
271+
but never more than the value specified by `max_database_pool_connections` in its
272+
[configuration](https://github.com/sqlpage/SQLPage/blob/main/configuration.md).
273+
You can increase the value of that parameter if your website has many concurrent users and your
274+
database is configured to allow opening many simultaneous connections.
275+
276+
### SQLPage performance debugging
277+
278+
When `environment` is set to `development` in its [configuration](https://github.com/sqlpage/SQLPage/blob/main/configuration.md),
279+
SQLPage will include precise measurement of the time it spends in each of the steps it has to go through before starting to send data
280+
back to the user''s browser. You can visualize that performance data in your browser''s network inspector.
281+
282+
You can set the `RUST_LOG` environment variable to `sqlpage=debug` to make SQLPage
283+
print detailed messages associated with precise timing for everything it does.
284+
');

0 commit comments

Comments
 (0)