storagenode/storagenodedb: backfill reputation.joined_at
it was being used in ways that implied it should be NOT NULL
even though it was possibly null. we used to get this data
from the satellite db's added_at column as seen in 30369b02
,
so backfill it using that data where joined_at is NULL, and
then alter the table to constrain the column to be NOT NULL.
Fixes #3866.
Change-Id: If2d856189209740d985f71dada7b93525e625ef3
This commit is contained in:
parent
6c4d3f133f
commit
4ad01e8170
@ -9,6 +9,7 @@ import (
|
||||
"context"
|
||||
"os"
|
||||
"path/filepath"
|
||||
"time"
|
||||
|
||||
"github.com/google/go-cmp/cmp"
|
||||
_ "github.com/mattn/go-sqlite3" // used indirectly.
|
||||
@ -1202,6 +1203,103 @@ func (db *DB) Migration(ctx context.Context) *migrate.Migration {
|
||||
`DROP TABLE payments;`,
|
||||
},
|
||||
},
|
||||
{
|
||||
DB: db.reputationDB,
|
||||
Description: "Backfill joined_at column",
|
||||
Version: 38,
|
||||
Action: migrate.Func(func(ctx context.Context, _ *zap.Logger, rdb tagsql.DB, rtx tagsql.Tx) (err error) {
|
||||
stx, err := db.satellitesDB.Begin(ctx)
|
||||
if err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
defer func() {
|
||||
if err != nil {
|
||||
err = errs.Combine(err, stx.Rollback())
|
||||
} else {
|
||||
err = errs.Wrap(stx.Commit())
|
||||
}
|
||||
}()
|
||||
|
||||
rows, err := rtx.Query(ctx, `SELECT satellite_id FROM reputation WHERE joined_at ISNULL`)
|
||||
if err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
defer func() { err = errs.Combine(err, errs.Wrap(rows.Close())) }()
|
||||
|
||||
var satelliteID []byte
|
||||
var addedAt time.Time
|
||||
|
||||
for rows.Next() {
|
||||
if err := rows.Scan(&satelliteID); err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
|
||||
err = stx.QueryRow(ctx, `SELECT added_at FROM satellites WHERE node_id = ?`,
|
||||
satelliteID).Scan(&addedAt)
|
||||
if err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
|
||||
_, err = rtx.Exec(ctx, `UPDATE reputation SET joined_at = ? WHERE satellite_id = ?`,
|
||||
addedAt.UTC(), satelliteID)
|
||||
if err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
}
|
||||
if err := rows.Err(); err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
|
||||
// in order to add the not null constraint, we have to do a
|
||||
// generalized ALTER TABLE prodedure.
|
||||
// see https://www.sqlite.org/lang_altertable.html
|
||||
|
||||
_, err = rtx.Exec(ctx, `
|
||||
CREATE TABLE reputation_new (
|
||||
satellite_id BLOB NOT NULL,
|
||||
uptime_success_count INTEGER NOT NULL,
|
||||
uptime_total_count INTEGER NOT NULL,
|
||||
uptime_reputation_alpha REAL NOT NULL,
|
||||
uptime_reputation_beta REAL NOT NULL,
|
||||
uptime_reputation_score REAL NOT NULL,
|
||||
audit_success_count INTEGER NOT NULL,
|
||||
audit_total_count INTEGER NOT NULL,
|
||||
audit_reputation_alpha REAL NOT NULL,
|
||||
audit_reputation_beta REAL NOT NULL,
|
||||
audit_reputation_score REAL NOT NULL,
|
||||
disqualified TIMESTAMP,
|
||||
updated_at TIMESTAMP NOT NULL,
|
||||
suspended TIMESTAMP,
|
||||
joined_at TIMESTAMP NOT NULL,
|
||||
PRIMARY KEY (satellite_id)
|
||||
);
|
||||
INSERT INTO reputation_new SELECT
|
||||
satellite_id,
|
||||
uptime_success_count,
|
||||
uptime_total_count,
|
||||
uptime_reputation_alpha,
|
||||
uptime_reputation_beta,
|
||||
uptime_reputation_score,
|
||||
audit_success_count,
|
||||
audit_total_count,
|
||||
audit_reputation_alpha,
|
||||
audit_reputation_beta,
|
||||
audit_reputation_score,
|
||||
disqualified,
|
||||
updated_at,
|
||||
suspended,
|
||||
joined_at
|
||||
FROM reputation;
|
||||
DROP TABLE reputation;
|
||||
ALTER TABLE reputation_new RENAME TO reputation;
|
||||
`)
|
||||
if err != nil {
|
||||
return errs.Wrap(err)
|
||||
}
|
||||
|
||||
return nil
|
||||
}),
|
||||
},
|
||||
},
|
||||
}
|
||||
}
|
||||
|
@ -513,7 +513,7 @@ func Schema() map[string]*dbschema.Schema {
|
||||
&dbschema.Column{
|
||||
Name: "joined_at",
|
||||
Type: "TIMESTAMP",
|
||||
IsNullable: true,
|
||||
IsNullable: false,
|
||||
},
|
||||
&dbschema.Column{
|
||||
Name: "satellite_id",
|
||||
@ -675,3 +675,4 @@ func Schema() map[string]*dbschema.Schema {
|
||||
},
|
||||
}
|
||||
}
|
||||
|
||||
|
@ -52,6 +52,7 @@ var States = MultiDBStates{
|
||||
&v35,
|
||||
&v36,
|
||||
&v37,
|
||||
&v38,
|
||||
},
|
||||
}
|
||||
|
||||
|
46
storagenode/storagenodedb/testdata/v27.go
vendored
46
storagenode/storagenodedb/testdata/v27.go
vendored
@ -16,30 +16,30 @@ var v27 = MultiDBState{
|
||||
storagenodedb.PieceExpirationDBName: v26.DBStates[storagenodedb.PieceExpirationDBName],
|
||||
storagenodedb.OrdersDBName: &DBState{
|
||||
SQL: `
|
||||
-- table for storing all unsent orders
|
||||
CREATE TABLE unsent_order (
|
||||
satellite_id BLOB NOT NULL,
|
||||
serial_number BLOB NOT NULL,
|
||||
order_limit_serialized BLOB NOT NULL,
|
||||
order_serialized BLOB NOT NULL,
|
||||
order_limit_expiration TIMESTAMP NOT NULL,
|
||||
uplink_cert_id INTEGER NOT NULL,
|
||||
FOREIGN KEY(uplink_cert_id) REFERENCES certificate(cert_id)
|
||||
);
|
||||
CREATE UNIQUE INDEX idx_orders ON unsent_order(satellite_id, serial_number);
|
||||
-- table for storing all sent orders
|
||||
CREATE TABLE order_archive_ (
|
||||
satellite_id BLOB NOT NULL,
|
||||
serial_number BLOB NOT NULL,
|
||||
order_limit_serialized BLOB NOT NULL,
|
||||
order_serialized BLOB NOT NULL,
|
||||
uplink_cert_id INTEGER NOT NULL,
|
||||
status INTEGER NOT NULL,
|
||||
archived_at TIMESTAMP NOT NULL,
|
||||
FOREIGN KEY(uplink_cert_id) REFERENCES certificate(cert_id)
|
||||
);
|
||||
-- table for storing all unsent orders
|
||||
CREATE TABLE unsent_order (
|
||||
satellite_id BLOB NOT NULL,
|
||||
serial_number BLOB NOT NULL,
|
||||
order_limit_serialized BLOB NOT NULL,
|
||||
order_serialized BLOB NOT NULL,
|
||||
order_limit_expiration TIMESTAMP NOT NULL,
|
||||
uplink_cert_id INTEGER NOT NULL,
|
||||
FOREIGN KEY(uplink_cert_id) REFERENCES certificate(cert_id)
|
||||
);
|
||||
CREATE UNIQUE INDEX idx_orders ON unsent_order(satellite_id, serial_number);
|
||||
-- table for storing all sent orders
|
||||
CREATE TABLE order_archive_ (
|
||||
satellite_id BLOB NOT NULL,
|
||||
serial_number BLOB NOT NULL,
|
||||
order_limit_serialized BLOB NOT NULL,
|
||||
order_serialized BLOB NOT NULL,
|
||||
uplink_cert_id INTEGER NOT NULL,
|
||||
status INTEGER NOT NULL,
|
||||
archived_at TIMESTAMP NOT NULL,
|
||||
FOREIGN KEY(uplink_cert_id) REFERENCES certificate(cert_id)
|
||||
);
|
||||
CREATE INDEX idx_order_archived_at ON order_archive_(archived_at);
|
||||
INSERT INTO unsent_order VALUES(X'2b3a5863a41f25408a8f5348839d7a1361dbd886d75786bb139a8ca0bdf41000',X'1eddef484b4c03f01332279032796972',X'0a101eddef484b4c03f0133227903279697212202b3a5863a41f25408a8f5348839d7a1361dbd886d75786bb139a8ca0bdf410001a201968996e7ef170a402fdfd88b6753df792c063c07c555905ffac9cd3cbd1c00022200ed28abb2813e184a1e98b0f6605c4911ea468c7e8433eb583e0fca7ceac30002a20d00cf14f3c68b56321ace04902dec0484eb6f9098b22b31c6b3f82db249f191630643802420c08dfeb88e50510a8c1a5b9034a0c08dfeb88e50510a8c1a5b9035246304402204df59dc6f5d1bb7217105efbc9b3604d19189af37a81efbf16258e5d7db5549e02203bb4ead16e6e7f10f658558c22b59c3339911841e8dbaae6e2dea821f7326894',X'0a101eddef484b4c03f0133227903279697210321a47304502206d4c106ddec88140414bac5979c95bdea7de2e0ecc5be766e08f7d5ea36641a7022100e932ff858f15885ffa52d07e260c2c25d3861810ea6157956c1793ad0c906284','2019-04-01 16:01:35.9254586+00:00',1);
|
||||
INSERT INTO unsent_order VALUES(X'2b3a5863a41f25408a8f5348839d7a1361dbd886d75786bb139a8ca0bdf41000',X'1eddef484b4c03f01332279032796972',X'0a101eddef484b4c03f0133227903279697212202b3a5863a41f25408a8f5348839d7a1361dbd886d75786bb139a8ca0bdf410001a201968996e7ef170a402fdfd88b6753df792c063c07c555905ffac9cd3cbd1c00022200ed28abb2813e184a1e98b0f6605c4911ea468c7e8433eb583e0fca7ceac30002a20d00cf14f3c68b56321ace04902dec0484eb6f9098b22b31c6b3f82db249f191630643802420c08dfeb88e50510a8c1a5b9034a0c08dfeb88e50510a8c1a5b9035246304402204df59dc6f5d1bb7217105efbc9b3604d19189af37a81efbf16258e5d7db5549e02203bb4ead16e6e7f10f658558c22b59c3339911841e8dbaae6e2dea821f7326894',X'0a101eddef484b4c03f0133227903279697210321a47304502206d4c106ddec88140414bac5979c95bdea7de2e0ecc5be766e08f7d5ea36641a7022100e932ff858f15885ffa52d07e260c2c25d3861810ea6157956c1793ad0c906284','2019-04-01 16:01:35.9254586+00:00',1);
|
||||
`,
|
||||
},
|
||||
storagenodedb.BandwidthDBName: v26.DBStates[storagenodedb.BandwidthDBName],
|
||||
|
48
storagenode/storagenodedb/testdata/v38.go
vendored
Normal file
48
storagenode/storagenodedb/testdata/v38.go
vendored
Normal file
@ -0,0 +1,48 @@
|
||||
// Copyright (C) 2020 Storj Labs, Inc.
|
||||
// See LICENSE for copying information.
|
||||
|
||||
package testdata
|
||||
|
||||
import "storj.io/storj/storagenode/storagenodedb"
|
||||
|
||||
var v38 = MultiDBState{
|
||||
Version: 38,
|
||||
DBStates: DBStates{
|
||||
storagenodedb.UsedSerialsDBName: v28.DBStates[storagenodedb.UsedSerialsDBName],
|
||||
storagenodedb.StorageUsageDBName: v28.DBStates[storagenodedb.StorageUsageDBName],
|
||||
storagenodedb.ReputationDBName: &DBState{
|
||||
SQL: `
|
||||
-- tables to store nodestats cache
|
||||
CREATE TABLE reputation (
|
||||
satellite_id BLOB NOT NULL,
|
||||
uptime_success_count INTEGER NOT NULL,
|
||||
uptime_total_count INTEGER NOT NULL,
|
||||
uptime_reputation_alpha REAL NOT NULL,
|
||||
uptime_reputation_beta REAL NOT NULL,
|
||||
uptime_reputation_score REAL NOT NULL,
|
||||
audit_success_count INTEGER NOT NULL,
|
||||
audit_total_count INTEGER NOT NULL,
|
||||
audit_reputation_alpha REAL NOT NULL,
|
||||
audit_reputation_beta REAL NOT NULL,
|
||||
audit_reputation_score REAL NOT NULL,
|
||||
disqualified TIMESTAMP,
|
||||
suspended TIMESTAMP,
|
||||
updated_at TIMESTAMP NOT NULL,
|
||||
joined_at TIMESTAMP NOT NULL,
|
||||
PRIMARY KEY (satellite_id)
|
||||
);
|
||||
INSERT INTO reputation VALUES(X'0ed28abb2813e184a1e98b0f6605c4911ea468c7e8433eb583e0fca7ceac3000',1,1,1.0,1.0,1.0,1,1,1.0,1.0,1.0,'2019-07-19 20:00:00+00:00',NULL,'2019-08-23 20:00:00+00:00','2019-09-10 20:00:00+00:00');
|
||||
`,
|
||||
},
|
||||
storagenodedb.PieceSpaceUsedDBName: v31.DBStates[storagenodedb.PieceSpaceUsedDBName],
|
||||
storagenodedb.PieceInfoDBName: v28.DBStates[storagenodedb.PieceInfoDBName],
|
||||
storagenodedb.PieceExpirationDBName: v28.DBStates[storagenodedb.PieceExpirationDBName],
|
||||
storagenodedb.OrdersDBName: v28.DBStates[storagenodedb.OrdersDBName],
|
||||
storagenodedb.BandwidthDBName: v28.DBStates[storagenodedb.BandwidthDBName],
|
||||
storagenodedb.SatellitesDBName: v28.DBStates[storagenodedb.SatellitesDBName],
|
||||
storagenodedb.DeprecatedInfoDBName: v28.DBStates[storagenodedb.DeprecatedInfoDBName],
|
||||
storagenodedb.NotificationsDBName: v28.DBStates[storagenodedb.NotificationsDBName],
|
||||
storagenodedb.HeldAmountDBName: v37.DBStates[storagenodedb.HeldAmountDBName],
|
||||
storagenodedb.PricingDBName: v35.DBStates[storagenodedb.PricingDBName],
|
||||
},
|
||||
}
|
Loading…
Reference in New Issue
Block a user