Skip to content

Commit

Permalink
Add rowid to tables with inefficient clustered indices (#5394)
Browse files Browse the repository at this point in the history
## Motivation
`WITHOUT ROWID` doesn't work well for table rows over about 1/20th the size of a database page (50 bytes for 1KiB pages). This causes slower database access and increased disk usage.

## Changes
Remove WITHOUT ROWID from problematic tables, add integer `n` column (also serving as rowid) for forthcoming syncv2 changes

## Test Plan
**TODO**: verify that mainnet nodes function correctly after migration

## TODO
- [x] Explain motivation or link existing issue(s)
- [x] Test changes and document test plan
- [x] Update [changelog](../CHANGELOG.md) as needed
  • Loading branch information
ivan4th committed Jan 15, 2024
1 parent 2f94423 commit e3cfe55
Show file tree
Hide file tree
Showing 6 changed files with 106 additions and 4 deletions.
3 changes: 3 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -78,6 +78,9 @@ configuration is as follows:

### Improvements

* [#5394] Fix inefficient SQLite clustered indices
The database size is reduced and query performance is improved

## Release v1.3.2

### Improvements
Expand Down
2 changes: 1 addition & 1 deletion config/mainnet.go
Original file line number Diff line number Diff line change
Expand Up @@ -69,7 +69,7 @@ func MainnetConfig() Config {
MetricsPort: 1010,
DatabaseConnections: 16,
DatabasePruneInterval: 30 * time.Minute,
DatabaseVacuumState: 8,
DatabaseVacuumState: 9,
PruneActivesetsFrom: 12, // starting from epoch 13 activesets below 12 will be pruned
NetworkHRP: "sm",

Expand Down
2 changes: 1 addition & 1 deletion sql/database.go
Original file line number Diff line number Diff line change
Expand Up @@ -331,7 +331,7 @@ func exec(conn *sqlite.Conn, query string, encoder Encoder, decoder Decoder) (in
row, err := stmt.Step()
if err != nil {
code := sqlite.ErrCode(err)
if code == sqlite.SQLITE_CONSTRAINT_PRIMARYKEY {
if code == sqlite.SQLITE_CONSTRAINT_PRIMARYKEY || code == sqlite.SQLITE_CONSTRAINT_UNIQUE {
return 0, ErrObjectExists
}
return 0, fmt.Errorf("step %d: %w", rows, err)
Expand Down
2 changes: 1 addition & 1 deletion sql/database_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -135,7 +135,7 @@ func TestDatabaseVacuumState(t *testing.T) {

db, err = Open("file:"+dbFile,
WithMigrations([]Migration{}),
WithVacuumState(9),
WithVacuumState(10),
)
require.NoError(t, err)
require.NoError(t, db.Close())
Expand Down
99 changes: 99 additions & 0 deletions sql/migrations/state/0010_rowid.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,99 @@
DROP INDEX atxs_by_pubkey_by_epoch_desc;
DROP INDEX atxs_by_epoch_by_pubkey;
ALTER TABLE atxs RENAME TO atxs_old;
CREATE TABLE atxs
(
id CHAR(32) PRIMARY KEY,
epoch INT NOT NULL,
effective_num_units INT NOT NULL,
commitment_atx CHAR(32),
nonce UNSIGNED LONG INT,
base_tick_height UNSIGNED LONG INT,
tick_count UNSIGNED LONG INT,
sequence UNSIGNED LONG INT,
pubkey CHAR(32),
coinbase CHAR(24),
atx BLOB,
received INT NOT NULL
);
INSERT INTO atxs (id, epoch, effective_num_units, commitment_atx, nonce, base_tick_height, tick_count, sequence, pubkey, coinbase, atx, received)
SELECT id, epoch, effective_num_units, commitment_atx, nonce, base_tick_height, tick_count, sequence, pubkey, coinbase, atx, received
FROM atxs_old;
CREATE INDEX atxs_by_pubkey_by_epoch_desc ON atxs (pubkey, epoch desc);
CREATE INDEX atxs_by_epoch_by_pubkey ON atxs (epoch, pubkey);
DROP TABLE atxs_old;

DROP INDEX ballots_by_layer_by_pubkey;
DROP INDEX ballots_by_atx_by_layer;
ALTER TABLE ballots RENAME TO ballots_old;
CREATE TABLE ballots
(
id CHAR(20) PRIMARY KEY,
atx CHAR(32) NOT NULL,
layer INT NOT NULL,
pubkey VARCHAR,
ballot BLOB
);
INSERT INTO ballots (id, atx, layer, pubkey, ballot)
SELECT id, atx, layer, pubkey, ballot from ballots_old;
CREATE INDEX ballots_by_layer_by_pubkey ON ballots (layer asc, pubkey);
CREATE INDEX ballots_by_atx_by_layer ON ballots (atx, layer asc);
DROP TABLE ballots_old;

DROP INDEX blocks_by_layer;
ALTER TABLE blocks RENAME TO blocks_old;
CREATE TABLE blocks
(
id CHAR(20) PRIMARY KEY,
layer INT NOT NULL,
validity SMALL INT,
block BLOB
);
INSERT INTO blocks (id, layer, validity, block)
SELECT id, layer, validity, block FROM blocks_old;
CREATE INDEX blocks_by_layer ON blocks (layer, id asc);
DROP TABLE blocks_old;

DROP INDEX poets_by_service_id_by_round_id;
ALTER TABLE poets RENAME TO poets_old;
CREATE TABLE poets
(
ref VARCHAR PRIMARY KEY,
poet BLOB,
service_id VARCHAR,
round_id VARCHAR
);
INSERT INTO poets (ref, poet, service_id, round_id)
SELECT ref, poet, service_id, round_id FROM poets_old;
CREATE INDEX poets_by_service_id_by_round_id ON poets (service_id, round_id);
DROP TABLE poets_old;

ALTER TABLE certificates RENAME TO certificates_old;
CREATE TABLE certificates
(
layer INT NOT NULL,
block VARCHAR NOT NULL,
cert BLOB,
valid bool NOT NULL,
PRIMARY KEY (layer, block)
);
INSERT INTO certificates (layer, block, cert, valid)
SELECT layer, block, cert, valid FROM certificates_old;
DROP TABLE certificates_old;

DROP INDEX proposals_by_layer;
ALTER TABLE proposals RENAME TO proposals_old;
CREATE TABLE proposals
(
id CHAR(20) PRIMARY KEY,
ballot_id CHAR(20),
layer INT NOT NULL,
tx_ids BLOB,
mesh_hash CHAR(32),
signature VARCHAR,
proposal BLOB
);
INSERT INTO proposals (id, ballot_id, layer, tx_ids, mesh_hash, signature, proposal)
SELECT id, ballot_id, layer, tx_ids, mesh_hash, signature, proposal FROM proposals_old;
CREATE INDEX proposals_by_layer ON proposals (layer);
DROP TABLE proposals_old;
2 changes: 1 addition & 1 deletion sql/migrations_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -15,5 +15,5 @@ func TestMigrationsAppliedOnce(t *testing.T) {
return true
})
require.NoError(t, err)
require.Equal(t, version, 9)
require.Equal(t, version, 10)
}

0 comments on commit e3cfe55

Please sign in to comment.