From 462f94d84a47d9089c86c83d939cb75f9143c1dd Mon Sep 17 00:00:00 2001 From: Rob Mulholand Date: Tue, 1 May 2018 11:35:01 -0500 Subject: [PATCH] Associate receipts with blocks instead of transactions - Allows us to fetch receipts by block and persist even when associated transaction is unknown. (The associated transaction can still be derived from the tx_hash column at query time, but is an expensive operation to require for inserts). --- ...81_associate_receipts_with_blocks.down.sql | 23 ++++++++++++++++ ...2581_associate_receipts_with_blocks.up.sql | 23 ++++++++++++++++ db/schema.sql | 27 +++++++------------ .../postgres/repositories/block_repository.go | 14 +++++----- 4 files changed, 62 insertions(+), 25 deletions(-) create mode 100644 db/migrations/1525122581_associate_receipts_with_blocks.down.sql create mode 100644 db/migrations/1525122581_associate_receipts_with_blocks.up.sql diff --git a/db/migrations/1525122581_associate_receipts_with_blocks.down.sql b/db/migrations/1525122581_associate_receipts_with_blocks.down.sql new file mode 100644 index 00000000..0a32c92e --- /dev/null +++ b/db/migrations/1525122581_associate_receipts_with_blocks.down.sql @@ -0,0 +1,23 @@ +BEGIN; + +ALTER TABLE receipts + ADD COLUMN transaction_id INT; + +UPDATE receipts + SET transaction_id = ( + SELECT id FROM transactions WHERE transactions.hash = receipts.tx_hash + ); + +ALTER TABLE receipts + ALTER COLUMN transaction_id SET NOT NULL; + +ALTER TABLE receipts + ADD CONSTRAINT transaction_fk +FOREIGN KEY (transaction_id) +REFERENCES transactions (id) +ON DELETE CASCADE; + +ALTER TABLE receipts + DROP COLUMN block_id; + +COMMIT; \ No newline at end of file diff --git a/db/migrations/1525122581_associate_receipts_with_blocks.up.sql b/db/migrations/1525122581_associate_receipts_with_blocks.up.sql new file mode 100644 index 00000000..51d22747 --- /dev/null +++ b/db/migrations/1525122581_associate_receipts_with_blocks.up.sql @@ -0,0 +1,23 @@ +BEGIN; + +ALTER TABLE receipts + ADD COLUMN block_id INT; + +UPDATE receipts + SET block_id = ( + SELECT block_id FROM transactions WHERE transactions.id = receipts.transaction_id + ); + +ALTER TABLE receipts + ALTER COLUMN block_id SET NOT NULL; + +ALTER TABLE receipts + ADD CONSTRAINT blocks_fk +FOREIGN KEY (block_id) +REFERENCES blocks (id) +ON DELETE CASCADE; + +ALTER TABLE receipts + DROP COLUMN transaction_id; + +COMMIT; diff --git a/db/schema.sql b/db/schema.sql index be932862..0a8e84ed 100644 --- a/db/schema.sql +++ b/db/schema.sql @@ -206,13 +206,13 @@ ALTER SEQUENCE public.nodes_id_seq OWNED BY public.eth_nodes.id; CREATE TABLE public.receipts ( id integer NOT NULL, - transaction_id integer NOT NULL, contract_address character varying(42), cumulative_gas_used numeric, gas_used numeric, state_root character varying(66), status integer, - tx_hash character varying(66) + tx_hash character varying(66), + block_id integer NOT NULL ); @@ -496,13 +496,6 @@ CREATE INDEX block_number_index ON public.blocks USING btree (number); CREATE INDEX node_id_index ON public.blocks USING btree (eth_node_id); --- --- Name: transaction_id_index; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX transaction_id_index ON public.receipts USING btree (transaction_id); - - -- -- Name: tx_from_index; Type: INDEX; Schema: public; Owner: - -- @@ -525,6 +518,14 @@ ALTER TABLE ONLY public.transactions ADD CONSTRAINT blocks_fk FOREIGN KEY (block_id) REFERENCES public.blocks(id) ON DELETE CASCADE; +-- +-- Name: receipts blocks_fk; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public.receipts + ADD CONSTRAINT blocks_fk FOREIGN KEY (block_id) REFERENCES public.blocks(id) ON DELETE CASCADE; + + -- -- Name: blocks node_fk; Type: FK CONSTRAINT; Schema: public; Owner: - -- @@ -541,14 +542,6 @@ ALTER TABLE ONLY public.logs ADD CONSTRAINT receipts_fk FOREIGN KEY (receipt_id) REFERENCES public.receipts(id) ON DELETE CASCADE; --- --- Name: receipts transaction_fk; Type: FK CONSTRAINT; Schema: public; Owner: - --- - -ALTER TABLE ONLY public.receipts - ADD CONSTRAINT transaction_fk FOREIGN KEY (transaction_id) REFERENCES public.transactions(id) ON DELETE CASCADE; - - -- -- PostgreSQL database dump complete -- diff --git a/pkg/datastore/postgres/repositories/block_repository.go b/pkg/datastore/postgres/repositories/block_repository.go index 4de07f46..118bdfd2 100644 --- a/pkg/datastore/postgres/repositories/block_repository.go +++ b/pkg/datastore/postgres/repositories/block_repository.go @@ -136,19 +136,17 @@ func nullStringToZero(s string) string { } func (blockRepository BlockRepository) createTransaction(tx *sql.Tx, blockId int64, transaction core.Transaction) error { - var transactionId int - err := tx.QueryRow( + _, err := tx.Exec( `INSERT INTO transactions (block_id, hash, nonce, tx_to, tx_from, gaslimit, gasprice, value, input_data) VALUES ($1, $2, $3, $4, $5, $6, $7, $8::NUMERIC, $9) RETURNING id`, - blockId, transaction.Hash, transaction.Nonce, transaction.To, transaction.From, transaction.GasLimit, transaction.GasPrice, nullStringToZero(transaction.Value), transaction.Data). - Scan(&transactionId) + blockId, transaction.Hash, transaction.Nonce, transaction.To, transaction.From, transaction.GasLimit, transaction.GasPrice, nullStringToZero(transaction.Value), transaction.Data) if err != nil { return err } if hasReceipt(transaction) { - receiptId, err := blockRepository.createReceipt(tx, transactionId, transaction.Receipt) + receiptId, err := blockRepository.createReceipt(tx, blockId, transaction.Receipt) if err != nil { return err } @@ -170,15 +168,15 @@ func hasReceipt(transaction core.Transaction) bool { return transaction.Receipt.TxHash != "" } -func (blockRepository BlockRepository) createReceipt(tx *sql.Tx, transactionId int, receipt core.Receipt) (int, error) { +func (blockRepository BlockRepository) createReceipt(tx *sql.Tx, blockId int64, receipt core.Receipt) (int, error) { //Not currently persisting log bloom filters var receiptId int err := tx.QueryRow( `INSERT INTO receipts - (contract_address, tx_hash, cumulative_gas_used, gas_used, state_root, status, transaction_id) + (contract_address, tx_hash, cumulative_gas_used, gas_used, state_root, status, block_id) VALUES ($1, $2, $3, $4, $5, $6, $7) RETURNING id`, - receipt.ContractAddress, receipt.TxHash, receipt.CumulativeGasUsed, receipt.GasUsed, receipt.StateRoot, receipt.Status, transactionId).Scan(&receiptId) + receipt.ContractAddress, receipt.TxHash, receipt.CumulativeGasUsed, receipt.GasUsed, receipt.StateRoot, receipt.Status, blockId).Scan(&receiptId) if err != nil { return receiptId, err }