You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

85 lines
3.2 KiB

  1. /*
  2. This file defines the database schema for the PostgresQL ("psql") event sink
  3. implementation in Tendermint. The operator must create a database and install
  4. this schema before using the database to index events.
  5. */
  6. -- The blocks table records metadata about each block.
  7. -- The block record does not include its events or transactions (see tx_results).
  8. CREATE TABLE blocks (
  9. rowid BIGSERIAL PRIMARY KEY,
  10. height BIGINT NOT NULL,
  11. chain_id VARCHAR NOT NULL,
  12. -- When this block header was logged into the sink, in UTC.
  13. created_at TIMESTAMPTZ NOT NULL,
  14. UNIQUE (height, chain_id)
  15. );
  16. -- Index blocks by height and chain, since we need to resolve block IDs when
  17. -- indexing transaction records and transaction events.
  18. CREATE INDEX idx_blocks_height_chain ON blocks(height, chain_id);
  19. -- The tx_results table records metadata about transaction results. Note that
  20. -- the events from a transaction are stored separately.
  21. CREATE TABLE tx_results (
  22. rowid BIGSERIAL PRIMARY KEY,
  23. -- The block to which this transaction belongs.
  24. block_id BIGINT NOT NULL REFERENCES blocks(rowid),
  25. -- The sequential index of the transaction within the block.
  26. index INTEGER NOT NULL,
  27. -- When this result record was logged into the sink, in UTC.
  28. created_at TIMESTAMPTZ NOT NULL,
  29. -- The hex-encoded hash of the transaction.
  30. tx_hash VARCHAR NOT NULL,
  31. -- The protobuf wire encoding of the TxResult message.
  32. tx_result BYTEA NOT NULL,
  33. UNIQUE (block_id, index)
  34. );
  35. -- The events table records events. All events (both block and transaction) are
  36. -- associated with a block ID; transaction events also have a transaction ID.
  37. CREATE TABLE events (
  38. rowid BIGSERIAL PRIMARY KEY,
  39. -- The block and transaction this event belongs to.
  40. -- If tx_id is NULL, this is a block event.
  41. block_id BIGINT NOT NULL REFERENCES blocks(rowid),
  42. tx_id BIGINT NULL REFERENCES tx_results(rowid),
  43. -- The application-defined type label for the event.
  44. type VARCHAR NOT NULL
  45. );
  46. -- The attributes table records event attributes.
  47. CREATE TABLE attributes (
  48. event_id BIGINT NOT NULL REFERENCES events(rowid),
  49. key VARCHAR NOT NULL, -- bare key
  50. composite_key VARCHAR NOT NULL, -- composed type.key
  51. value VARCHAR NULL,
  52. UNIQUE (event_id, key)
  53. );
  54. -- A joined view of events and their attributes. Events that do not have any
  55. -- attributes are represented as a single row with empty key and value fields.
  56. CREATE VIEW event_attributes AS
  57. SELECT block_id, tx_id, type, key, composite_key, value
  58. FROM events LEFT JOIN attributes ON (events.rowid = attributes.event_id);
  59. -- A joined view of all block events (those having tx_id NULL).
  60. CREATE VIEW block_events AS
  61. SELECT blocks.rowid as block_id, height, chain_id, type, key, composite_key, value
  62. FROM blocks JOIN event_attributes ON (blocks.rowid = event_attributes.block_id)
  63. WHERE event_attributes.tx_id IS NULL;
  64. -- A joined view of all transaction events.
  65. CREATE VIEW tx_events AS
  66. SELECT height, index, chain_id, type, key, composite_key, value, tx_results.created_at
  67. FROM blocks JOIN tx_results ON (blocks.rowid = tx_results.block_id)
  68. JOIN event_attributes ON (tx_results.rowid = event_attributes.tx_id)
  69. WHERE event_attributes.tx_id IS NOT NULL;