-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
scheme: create transaction_summary table and triggers
- Loading branch information
1 parent
a22fef9
commit 0828d60
Showing
7 changed files
with
131 additions
and
2 deletions.
There are no files selected for viewing
20 changes: 20 additions & 0 deletions
20
storage/sqlite/migrations/20240611140734_create_transaction_summary_table.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,20 @@ | ||
-- +goose Up | ||
-- +goose StatementBegin | ||
CREATE TABLE transaction_summary ( | ||
tx_id TEXT PRIMARY KEY, | ||
coinbase BOOLEAN, | ||
total_loss INTEGER, | ||
block_height INTEGER, | ||
block_hash TEXT | ||
); | ||
|
||
CREATE INDEX transaction_summary_block_height_index ON transaction_summary (block_height); | ||
CREATE INDEX transaction_summary_block_hash_index ON transaction_summary (block_hash); | ||
CREATE INDEX transaction_summary_coinbase_index ON transaction_summary (coinbase); | ||
CREATE INDEX transaction_summary_total_loss_index ON transaction_summary (total_loss); | ||
-- +goose StatementEnd | ||
|
||
-- +goose Down | ||
-- +goose StatementBegin | ||
DROP TABLE transaction_summary; | ||
-- +goose StatementEnd |
64 changes: 64 additions & 0 deletions
64
storage/sqlite/migrations/20240611140850_triggers_losses_to_tx_summary.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,64 @@ | ||
-- +goose Up | ||
-- +goose StatementBegin | ||
-- Trigger for INSERT operations | ||
CREATE TRIGGER update_transaction_summary_insert | ||
AFTER INSERT ON losses | ||
BEGIN | ||
INSERT INTO transaction_summary (tx_id, coinbase, total_loss, block_height, block_hash) | ||
SELECT | ||
new.tx_id, | ||
EXISTS (SELECT 1 FROM losses WHERE tx_id = new.tx_id AND vout = -1), | ||
COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = new.tx_id), 0), | ||
new.block_height, | ||
new.block_hash | ||
ON CONFLICT(tx_id) DO UPDATE SET | ||
coinbase = EXISTS (SELECT 1 FROM losses WHERE tx_id = new.tx_id AND vout = -1), | ||
total_loss = COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = new.tx_id), 0), | ||
block_height = new.block_height, | ||
block_hash = new.block_hash; | ||
END; | ||
|
||
-- Trigger for UPDATE operations | ||
CREATE TRIGGER update_transaction_summary_update | ||
AFTER UPDATE ON losses | ||
BEGIN | ||
INSERT INTO transaction_summary (tx_id, coinbase, total_loss, block_height, block_hash) | ||
SELECT | ||
new.tx_id, | ||
EXISTS (SELECT 1 FROM losses WHERE tx_id = new.tx_id AND vout = -1), | ||
COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = new.tx_id), 0), | ||
new.block_height, | ||
new.block_hash | ||
ON CONFLICT(tx_id) DO UPDATE SET | ||
coinbase = EXISTS (SELECT 1 FROM losses WHERE tx_id = new.tx_id AND vout = -1), | ||
total_loss = COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = new.tx_id), 0), | ||
block_height = new.block_height, | ||
block_hash = new.block_hash; | ||
END; | ||
|
||
|
||
-- Trigger for DELETE operations | ||
CREATE TRIGGER update_transaction_summary_delete | ||
AFTER DELETE ON losses | ||
BEGIN | ||
INSERT INTO transaction_summary (tx_id, coinbase, total_loss, block_height, block_hash) | ||
SELECT | ||
old.tx_id, | ||
EXISTS (SELECT 1 FROM losses WHERE tx_id = old.tx_id AND vout = -1), | ||
COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = old.tx_id), 0), | ||
old.block_height, | ||
old.block_hash | ||
ON CONFLICT(tx_id) DO UPDATE SET | ||
coinbase = EXISTS (SELECT 1 FROM losses WHERE tx_id = old.tx_id AND vout = -1), | ||
total_loss = COALESCE((SELECT sum(amount) FROM losses WHERE tx_id = old.tx_id), 0), | ||
block_height = old.block_height, | ||
block_hash = old.block_hash; | ||
END; | ||
-- +goose StatementEnd | ||
|
||
-- +goose Down | ||
-- +goose StatementBegin | ||
DROP TRIGGER update_transaction_summary_insert; | ||
DROP TRIGGER update_transaction_summary_update; | ||
DROP TRIGGER update_transaction_summary_delete; | ||
-- +goose StatementEnd |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,34 @@ | ||
package sqlite | ||
|
||
import ( | ||
"database/sql" | ||
|
||
"github.com/RaghavSood/btcsupply/types" | ||
) | ||
|
||
func (d *SqliteBackend) GetTransactionSummary(limit int) ([]types.TransactionSummary, error) { | ||
query := `SELECT tx_id, coinbase, total_loss, block_height, block_hash FROM transaction_summary ORDER BY block_height DESC LIMIT ?` | ||
|
||
rows, err := d.db.Query(query, limit) | ||
if err != nil { | ||
return nil, err | ||
} | ||
|
||
defer rows.Close() | ||
summaries, err := scanTransactionSummaries(rows) | ||
|
||
return summaries, err | ||
} | ||
|
||
func scanTransactionSummaries(rows *sql.Rows) ([]types.TransactionSummary, error) { | ||
var summaries []types.TransactionSummary | ||
for rows.Next() { | ||
var summary types.TransactionSummary | ||
err := rows.Scan(&summary.Txid, &summary.Coinbase, &summary.TotalLoss, &summary.BlockHeight, &summary.BlockHash) | ||
if err != nil { | ||
return nil, err | ||
} | ||
summaries = append(summaries, summary) | ||
} | ||
return summaries, nil | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
package types | ||
|
||
type TransactionSummary struct { | ||
Txid string `json:"tx_id"` | ||
Coinbase bool `json:"coinbase"` | ||
TotalLoss *BigInt `json:"total_loss"` | ||
BlockHeight int64 `json:"block_height"` | ||
BlockHash string `json:"block_hash"` | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters