Skip to content

Commit

Permalink
scheme: create transaction_summary table and triggers
Browse files Browse the repository at this point in the history
  • Loading branch information
RaghavSood committed Jun 11, 2024
1 parent a22fef9 commit 0828d60
Show file tree
Hide file tree
Showing 7 changed files with 131 additions and 2 deletions.
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
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
34 changes: 34 additions & 0 deletions storage/sqlite/transaction_summary.go
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
}
2 changes: 2 additions & 0 deletions storage/storage.go
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,8 @@ type Storage interface {
GetTransactionLossSummaryForScript(script string) ([]types.TransactionLossSummary, error)
GetTransactionLossSummaryForTxid(txid string) (types.TransactionLossSummary, error)

GetTransactionSummary(limit int) ([]types.TransactionSummary, error)

GetLossyBlocks(limit int) ([]types.BlockLossSummary, error)
GetBlockLossSummary(identifier string) (types.BlockLossSummary, error)
GetBlock(identifier string) (types.Block, error)
Expand Down
2 changes: 1 addition & 1 deletion templates/index.tmpl
Original file line number Diff line number Diff line change
Expand Up @@ -62,7 +62,7 @@
<tr>
<td class="px-4 py-2 border-b border-slate-700">
<a class="text-sky-400/70 break-all hover:underline hover:decoration-dotted hover:text-slate-200" href="/transaction/{{ .Txid }}">{{ .Txid }}</a>
{{ if eq .Vout -1 }}
{{ if eq .Coinbase true }}
⛏️
{{ end }}
</td>
Expand Down
9 changes: 9 additions & 0 deletions types/transaction_summary.go
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"`
}
2 changes: 1 addition & 1 deletion webui/webui.go
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,7 @@ func (w *WebUI) Serve() {
}

func (w *WebUI) Index(c *gin.Context) {
losses, err := w.db.GetTransactionLossSummary(50)
losses, err := w.db.GetTransactionSummary(50)
if err != nil {
log.Error().Err(err).Msg("Failed to get recent losses")
c.AbortWithError(http.StatusInternalServerError, err)
Expand Down

0 comments on commit 0828d60

Please sign in to comment.