Skip to content

Commit

Permalink
Casted u64 index (#124)
Browse files Browse the repository at this point in the history
* Use TEXT instead of VARCHAR

See "Tip" here https://www.postgresql.org/docs/current/datatype-character.html

* Add casted index for u64 values used to sort results

* Cast as numeric so the index is actually used

* Update changelog
  • Loading branch information
cafca committed May 17, 2022
1 parent 4144d24 commit 0d82cfb
Show file tree
Hide file tree
Showing 4 changed files with 25 additions and 18 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,7 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0
- Move to `tokio` async runtime [#75](https://github.com/p2panda/aquadoggo/pull/75)
- Implement SQL storage using `p2panda_rs` storage provider traits [#80](https://github.com/p2panda/aquadoggo/pull/80)
- Improve `Signal` efficiency in `ServiceManager` [#95](https://github.com/p2panda/aquadoggo/pull/95)
- Improvements for log and entry table layout [#124](https://github.com/p2panda/aquadoggo/issues/122)

## [0.2.0]

Expand Down
19 changes: 11 additions & 8 deletions aquadoggo/migrations/20201229215646_create-entries.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,17 @@
-- SPDX-License-Identifier: AGPL-3.0-or-later

CREATE TABLE IF NOT EXISTS entries (
author VARCHAR(64) NOT NULL,
entry_bytes TEXT NOT NULL,
entry_hash VARCHAR(68) NOT NULL UNIQUE,
-- Store u64 integer as 20 character string
log_id VARCHAR(20) NOT NULL,
author TEXT NOT NULL,
entry_bytes TEXT NOT NULL,
entry_hash TEXT NOT NULL UNIQUE,
-- Store u64 integer as character string
log_id TEXT NOT NULL,
payload_bytes TEXT,
payload_hash VARCHAR(68) NOT NULL,
-- Store u64 integer as 20 character string
seq_num VARCHAR(20) NOT NULL,
payload_hash TEXT NOT NULL,
-- Store u64 integer as character string
seq_num TEXT NOT NULL,
PRIMARY KEY (author, log_id, seq_num)
);

-- Create an index for sorting by sequence number
CREATE INDEX idx_entries_by_seq_num ON entries (CAST(seq_num AS NUMERIC));
13 changes: 8 additions & 5 deletions aquadoggo/migrations/20201230002752_create-logs.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,17 @@
-- SPDX-License-Identifier: AGPL-3.0-or-later

CREATE TABLE IF NOT EXISTS logs (
author VARCHAR(64) NOT NULL,
document VARCHAR(68) NOT NULL,
-- Store u64 integer as 20 character string
log_id VARCHAR(20) NOT NULL,
schema VARCHAR(68) NOT NULL,
author TEXT NOT NULL,
document TEXT NOT NULL,
-- Store u64 integer as text
log_id TEXT NOT NULL,
schema TEXT NOT NULL,
PRIMARY KEY (author, document, log_id),
UNIQUE(author, log_id)
);

-- Create an index for querying by schema
CREATE INDEX idx_logs_schema ON logs (author, log_id, schema);

-- Create an index for sorting by log id
CREATE INDEX idx_logs_by_id ON logs (CAST(log_id AS NUMERIC));
10 changes: 5 additions & 5 deletions aquadoggo/src/db/stores/entry.rs
Original file line number Diff line number Diff line change
Expand Up @@ -257,7 +257,7 @@ impl EntryStore<StorageEntry> for SqlStorage {
author = $1
AND log_id = $2
ORDER BY
CAST(seq_num AS INTEGER) DESC
CAST(seq_num AS NUMERIC) DESC
LIMIT
1
",
Expand Down Expand Up @@ -335,9 +335,9 @@ impl EntryStore<StorageEntry> for SqlStorage {
WHERE
author = $1
AND log_id = $2
AND CAST(seq_num AS INTEGER) BETWEEN $3 and $4
AND CAST(seq_num AS NUMERIC) BETWEEN $3 and $4
ORDER BY
CAST(seq_num AS INTEGER)
CAST(seq_num AS NUMERIC)
",
)
.bind(author.as_str())
Expand Down Expand Up @@ -388,9 +388,9 @@ impl EntryStore<StorageEntry> for SqlStorage {
WHERE
author = $1
AND log_id = $2
AND CAST(seq_num AS INTEGER) IN ({})
AND CAST(seq_num AS NUMERIC) IN ({})
ORDER BY
CAST(seq_num AS INTEGER) DESC
CAST(seq_num AS NUMERIC) DESC
",
cert_pool_seq_nums
);
Expand Down

0 comments on commit 0d82cfb

Please sign in to comment.