Skip to content

Commit

Permalink
Add transparent pagination to query tabs, also limit result size.
Browse files Browse the repository at this point in the history
Previously a query with 1M result rows would evaluate all 1M rows and
only afterwards trim to the number displayed per page (1000 by default).
This fixes the performance issue by applying a LIMIT to a wrapped
version of the query, and perhaps redundantly, also using the fetchmany()
API instead of fetchall().

Since we were in there, we added transparent pagination as well, and a
new configuration option to set the results-per-page on the query tabs.

Fixes #153
  • Loading branch information
coleifer committed May 5, 2024
1 parent cef7ed3 commit d084de5
Show file tree
Hide file tree
Showing 5 changed files with 81 additions and 10 deletions.
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -92,6 +92,7 @@ The following options are available:
password, but will use the value from the environment.
* `-r`, `--read-only`: open database in read-only mode.
* `-R`, `--rows-per-page`: set pagination on content page, default 50 rows.
* `-Q`, `--query-rows-per-page`: set pagination on query page, default 1000 rows.
* `-e`, `--extension`: path or name of loadable extension(s). To load
multiple extensions, specify ``-e [path]`` for each extension.
* `-f`, `--foreign-keys`: enable foreign-key constraint pragma.
Expand Down
57 changes: 51 additions & 6 deletions sqlite_web/sqlite_web.py
Original file line number Diff line number Diff line change
Expand Up @@ -87,8 +87,8 @@ def syntax_highlight(data):

CUR_DIR = os.path.realpath(os.path.dirname(__file__))
DEBUG = False
MAX_RESULT_SIZE = 1000
ROWS_PER_PAGE = 50
QUERY_ROWS_PER_PAGE = 1000
SECRET_KEY = 'sqlite-database-browser-0.1.0'

app = Flask(
Expand Down Expand Up @@ -304,18 +304,48 @@ def _query_view(template, table=None):
default_sql = ''
model_class = dataset._base_model

page = page_next = page_prev = page_start = page_end = total_pages = 1
total = -1 # Number of rows in query result.
if qsql:
if export_format:
query = model_class.raw(qsql).dicts()
return export(query, export_format, table)

try:
total, = dataset.query('SELECT COUNT(*) FROM (%s) as _' %
qsql.rstrip('; ')).fetchone()
except Exception as exc:
total = -1

# Apply pagination.
rpp = app.config['QUERY_ROWS_PER_PAGE']
page = request.values.get('page')
if page and page.isdigit():
page = max(int(page), 1)
else:
page = 1
offset = (page - 1) * rpp
page_prev, page_next = max(page - 1, 1), page + 1

# Figure out highest page.
if total > 0:
total_pages = max(1, int(math.ceil(total / float(rpp))))
page = max(min(page, total_pages), 1)
page_next = min(page + 1, total_pages)
page_start = offset + 1
page_end = min(total, page_start + rpp - 1)

if page > 1:
qsql = ('SELECT * FROM (%s) AS _ LIMIT %d OFFSET %d' %
(qsql.rstrip(' ;'), rpp, offset))

try:
cursor = dataset.query(qsql)
except Exception as exc:
error = str(exc)
app.logger.exception('Error in user-submitted query.')
else:
data = cursor.fetchall()[:app.config['MAX_RESULT_SIZE']]
data = cursor.fetchmany(rpp)
data_description = cursor.description
row_count = cursor.rowcount

Expand All @@ -326,11 +356,18 @@ def _query_view(template, table=None):
default_sql=default_sql,
error=error,
ordering=ordering,
page=page,
page_end=page_end,
page_next=page_next,
page_prev=page_prev,
page_start=page_start,
query_images=get_query_images(),
row_count=row_count,
sql=sql,
table=table,
table_sql=dataset.get_table_sql(table))
table_sql=dataset.get_table_sql(table),
total=total,
total_pages=total_pages)

@app.route('/query/', methods=['GET', 'POST'])
def generic_query():
Expand Down Expand Up @@ -601,8 +638,7 @@ def table_content(table):
rows_per_page = app.config['ROWS_PER_PAGE']
total_pages = max(1, int(math.ceil(total_rows / float(rows_per_page))))
# Restrict bounds.
page_number = min(page_number, total_pages)
page_number = max(page_number, 1)
page_number = max(min(page_number, total_pages), 1)

previous_page = page_number - 1 if page_number > 1 else None
next_page = page_number + 1 if page_number < total_pages else None
Expand Down Expand Up @@ -1188,7 +1224,14 @@ def get_option_parser():
'--rows-per-page',
default=50,
dest='rows_per_page',
help='Number of rows to display per page (default=50)',
help='Number of rows to display per page in content tab (default=50)',
type='int')
parser.add_option(
'-Q',
'--query-rows-per-page',
default=1000,
dest='query_rows_per_page',
help='Number of rows to display per page in query tab (default=1000)',
type='int')
parser.add_option(
'-u',
Expand Down Expand Up @@ -1330,6 +1373,8 @@ def main():

if options.rows_per_page:
app.config['ROWS_PER_PAGE'] = options.rows_per_page
if options.query_rows_per_page:
app.config['QUERY_ROWS_PER_PAGE'] = options.query_rows_per_page

# Initialize the dataset instance and (optionally) authentication handler.
initialize_app(args[0], options.read_only, password, options.url_prefix,
Expand Down
23 changes: 23 additions & 0 deletions sqlite_web/templates/pagination.html
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
<nav>
<form action="." method="post">
<input name="ordering" type="hidden" value="{% if ordering %}{{ ordering }}{% endif %}" />
<input name="sql" type="hidden" value="{{ sql|default('') }}" />
<ul class="pagination">
<li class="{% if page < 2 %}disabled {% endif %}page-item">
<button class="page-link" name="page" type="submit" value="1">&laquo;</a>
</li>
<li class="{% if page < 2 %}disabled {% endif %}page-item">
<button class="page-link" name="page" type="submit" value="{{ page_prev }}">&lsaquo;</a>
</li>
<li class="page-item disabled">
<span class="page-link">Page {{ page }} of {{ total_pages }}</span>
</li>
<li class="{% if page >= total_pages %}disabled {% endif %}page-item">
<button class="page-link" name="page" type="submit" value="{{ page_next }}">&rsaquo;</a>
</li>
<li class="{% if page >= total_pages %}disabled {% endif %}page-item">
<button class="page-link" name="page" type="submit" value="{{ total_pages }}">&raquo;</a>
</li>
</ul>
</form>
</nav>
5 changes: 3 additions & 2 deletions sqlite_web/templates/query.html
Original file line number Diff line number Diff line change
Expand Up @@ -66,9 +66,9 @@
{% if not data %}
<p>Empty result set.</p>
{% else %}
<a class="float-right" href="{{ url_for('generic_query', sql=sql) }}{% if ordering %}&ordering={{ ordering }}{% endif %}">Permalink</a>
<a class="float-right" href="{{ url_for('generic_query', sql=sql) }}{% if ordering %}&ordering={{ ordering }}{% endif %}{% if page > 1 %}&page={{ page }}{% endif %}">Permalink</a>
<h3>
Results ({{ data|length }})
Results ({% if total >= 0 %}{% if total_pages > 1 %}{{ page_start }}&ndash;{{ page_end }} of {% endif %}{{ total }}{% else %}unable to determine{% endif %})
</h3>
<table class="table table-striped small cell-content">
<thead>
Expand All @@ -92,6 +92,7 @@ <h3>
{% endfor %}
</tbody>
</table>
{% include "pagination.html" %}
{% endif %}
{% endif %}
<div class="modal fade" id="sql-image-modal" role="dialog">
Expand Down
5 changes: 3 additions & 2 deletions sqlite_web/templates/table_query.html
Original file line number Diff line number Diff line change
Expand Up @@ -75,9 +75,9 @@ <h3>
{% if not data %}
<p>Empty result set.</p>
{% else %}
<a class="float-right" href="{{ url_for('table_query', table=table, sql=sql) }}{% if ordering %}&ordering={{ ordering }}{% endif %}">Permalink</a>
<a class="float-right" href="{{ url_for('table_query', table=table, sql=sql) }}{% if ordering %}&ordering={{ ordering }}{% endif %}{% if page > 1 %}&page={{ page }}{% endif %}">Permalink</a>
<h3>
Results ({{ data|length }})
Results ({% if total >= 0 %}{% if total_pages > 1 %}{{ page_start }}&ndash;{{ page_end }} of {% endif %}{{ total }}{% else %}unable to determine{% endif %})
</h3>
<table class="table table-striped small cell-content">
<thead>
Expand All @@ -101,6 +101,7 @@ <h3>
{% endfor %}
</tbody>
</table>
{% include "pagination.html" %}
{% endif %}
{% endif %}
<div class="modal fade" id="sql-image-modal" role="dialog">
Expand Down

0 comments on commit d084de5

Please sign in to comment.