Skip to content

Commit

Permalink
satellitedb: removed unused id on storagenode_storage_tallies table, …
Browse files Browse the repository at this point in the history
…add index on node_id

The goal of this change is to improve the storagenode_storage_tallies table by removing the unneeded id column that is not being used but only taking up space, and also to add an index on a different column that needs it. Removing and adding a column seems simple, but ended up being more complicated because of some cockroachdb limitations.

The cockroachdb limitation when trying to remove a column from a table and create a new primary key are:
1. only allows primary key creation at table creation time (docs: https://www.cockroachlabs.com/docs/stable/primary-key.html)
2. table drop or rename is performed async and cannot be done in a transaction (issue: cockroachdb/cockroach#12123, cockroachdb/cockroach#22868)

To address these differences between cockroachdb  and Postgres, this PR performs different migrations for the two database. The Postgres migration is straight forward and what you would expect, but the cockroach migration has two main changes:
1. To change a primary key, use the recommended process from the cockroachdb docs to create a new table with the new primary key you want and then migrate the data.
2. In order to do 1, we needed to do the new table renaming in a separate transaction from the data migration.

Ref: SM-65

Change-Id: Idc9aee3ab57aa4d5570e3d2980afea853cd966bf
  • Loading branch information
JessicaGreben authored and VinozzZ committed Mar 29, 2020
1 parent 5c1afd9 commit d06a3f2
Show file tree
Hide file tree
Showing 7 changed files with 667 additions and 260 deletions.
28 changes: 15 additions & 13 deletions satellite/satellitedb/dbx/satellitedb.dbx
Original file line number Diff line number Diff line change
Expand Up @@ -617,26 +617,28 @@ read all (
)

model storagenode_storage_tally (
key id
// this primary key will enforce uniqueness on interval_end_time,node_id
// and also creates an index on interval_end_time implicitly.
// the interval_end_time will be the same value for many rows so
// we put that first so we can use cockroachdb prefix compression.
// node_id is also used many times but interval_end_time is more
// repetative and will benefit greater.
key interval_end_time node_id

field id serial64
field node_id blob
index ( fields node_id )

field node_id blob
field interval_end_time timestamp
field data_total float64
field data_total float64
)

create storagenode_storage_tally ( noreturn )
delete storagenode_storage_tally ( where storagenode_storage_tally.id = ? )
read one (
select storagenode_storage_tally
where storagenode_storage_tally.id = ?
)
read all (
select storagenode_storage_tally
select storagenode_storage_tally
)

read all (
select storagenode_storage_tally
where storagenode_storage_tally.interval_end_time >= ?
select storagenode_storage_tally
where storagenode_storage_tally.interval_end_time >= ?
)

// --- storage node payment tables --- //
Expand Down
4 changes: 2 additions & 2 deletions satellite/satellitedb/dbx/satellitedb.dbx.cockroach.sql
Original file line number Diff line number Diff line change
Expand Up @@ -308,11 +308,10 @@ CREATE TABLE storagenode_paystubs (
PRIMARY KEY ( period, node_id )
);
CREATE TABLE storagenode_storage_tallies (
id bigserial NOT NULL,
node_id bytea NOT NULL,
interval_end_time timestamp with time zone NOT NULL,
data_total double precision NOT NULL,
PRIMARY KEY ( id )
PRIMARY KEY ( interval_end_time, node_id )
);
CREATE TABLE stripe_customers (
user_id bytea NOT NULL,
Expand Down Expand Up @@ -439,4 +438,5 @@ CREATE UNIQUE INDEX serial_number_index ON serial_numbers ( serial_number );
CREATE INDEX serial_numbers_expires_at_index ON serial_numbers ( expires_at );
CREATE INDEX storagenode_payments_node_id_period_index ON storagenode_payments ( node_id, period );
CREATE INDEX storagenode_paystubs_node_id_index ON storagenode_paystubs ( node_id );
CREATE INDEX storagenode_storage_tallies_node_id_index ON storagenode_storage_tallies ( node_id );
CREATE UNIQUE INDEX credits_earned_user_id_offer_id ON user_credits ( id, offer_id );
Loading

0 comments on commit d06a3f2

Please sign in to comment.