mirror of
https://github.com/FlipsideCrypto/osmosis-models.git
synced 2026-02-06 11:26:55 +00:00
adds in memo field to votes table (#103)
* adds in memo field to votes table * efficiency --------- Co-authored-by: Eric Laurello <eric.laurello@flipsidecrypto.com>
This commit is contained in:
parent
ea3bee5869
commit
2978408e00
@ -17,5 +17,6 @@ SELECT
|
||||
voter,
|
||||
proposal_id,
|
||||
vote_option,
|
||||
vote_weight
|
||||
vote_weight,
|
||||
memo
|
||||
FROM {{ ref('silver__governance_votes') }}
|
||||
@ -29,5 +29,9 @@ models:
|
||||
- dbt_expectations.expect_column_to_exist
|
||||
- name: VOTE_OPTION
|
||||
description: "{{ doc('vote_option') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_to_exist
|
||||
- name: MEMO
|
||||
description: "{{ doc('memo') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_to_exist
|
||||
5
models/descriptions/memo.md
Normal file
5
models/descriptions/memo.md
Normal file
@ -0,0 +1,5 @@
|
||||
{% docs memo %}
|
||||
|
||||
The memo the user input into the transaction body
|
||||
|
||||
{% enddocs %}
|
||||
@ -5,126 +5,143 @@
|
||||
cluster_by = ['block_timestamp::DATE'],
|
||||
) }}
|
||||
|
||||
WITH
|
||||
|
||||
{% if is_incremental() %}
|
||||
max_date AS (
|
||||
WITH base_tx AS (
|
||||
|
||||
SELECT
|
||||
MAX(
|
||||
_inserted_timestamp
|
||||
) _inserted_timestamp
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
tx_body :memo :: STRING AS memo,
|
||||
tx_body :messages AS messages,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
{{ this }}
|
||||
),
|
||||
{% endif %}
|
||||
{{ ref('silver__transactions') }}
|
||||
|
||||
{% if is_incremental() %}
|
||||
WHERE
|
||||
_inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(
|
||||
_inserted_timestamp
|
||||
)
|
||||
FROM
|
||||
{{ this }}
|
||||
)
|
||||
{% endif %}
|
||||
),
|
||||
memo_text AS (
|
||||
SELECT
|
||||
tx_id,
|
||||
memo
|
||||
FROM
|
||||
base_tx
|
||||
WHERE
|
||||
memo IS NOT NULL
|
||||
),
|
||||
weighted_votes AS (
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
tx_body,
|
||||
messages,
|
||||
path :: STRING AS _path,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
{{ ref('silver__transactions') }},
|
||||
base_tx,
|
||||
LATERAL FLATTEN (
|
||||
input => tx_body :messages,
|
||||
input => messages,
|
||||
recursive => TRUE
|
||||
) b
|
||||
WHERE
|
||||
key = '@type'
|
||||
AND VALUE :: STRING = '/cosmos.gov.v1beta1.MsgVoteWeighted'
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _inserted_timestamp >= (
|
||||
),
|
||||
pre_final AS (
|
||||
SELECT
|
||||
MAX(
|
||||
_inserted_timestamp
|
||||
)
|
||||
FROM
|
||||
max_date
|
||||
)
|
||||
{% endif %}
|
||||
)
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
path :: STRING AS _path,
|
||||
this :proposal_id :: STRING AS proposal_id,
|
||||
this :voter :: STRING AS voter,
|
||||
CASE
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_YES' THEN 1
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_ABSTAIN' THEN 2
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_NO' THEN 3
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_NO_WITH_VETO' THEN 4
|
||||
ELSE this :option
|
||||
END AS vote_option,
|
||||
1.000 AS vote_weight,
|
||||
_inserted_timestamp,
|
||||
concat_ws(
|
||||
'-',
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
proposal_id,
|
||||
voter,
|
||||
vote_option,
|
||||
_path
|
||||
) AS _unique_key
|
||||
FROM
|
||||
{{ ref('silver__transactions') }},
|
||||
LATERAL FLATTEN (
|
||||
input => tx_body :messages,
|
||||
recursive => TRUE
|
||||
) b
|
||||
WHERE
|
||||
key = '@type'
|
||||
AND VALUE :: STRING = '/cosmos.gov.v1beta1.MsgVote'
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND _inserted_timestamp >= (
|
||||
SELECT
|
||||
MAX(
|
||||
_inserted_timestamp
|
||||
)
|
||||
tx_succeeded,
|
||||
path :: STRING AS _path,
|
||||
this :proposal_id :: STRING AS proposal_id,
|
||||
this :voter :: STRING AS voter,
|
||||
CASE
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_YES' THEN 1
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_ABSTAIN' THEN 2
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_NO' THEN 3
|
||||
WHEN this :option :: STRING = 'VOTE_OPTION_NO_WITH_VETO' THEN 4
|
||||
ELSE this :option
|
||||
END AS vote_option,
|
||||
1.000 AS vote_weight,
|
||||
_inserted_timestamp,
|
||||
concat_ws(
|
||||
'-',
|
||||
tx_id,
|
||||
proposal_id,
|
||||
voter,
|
||||
vote_option,
|
||||
_path
|
||||
) AS _unique_key
|
||||
FROM
|
||||
max_date
|
||||
base_tx,
|
||||
LATERAL FLATTEN (
|
||||
input => messages,
|
||||
recursive => TRUE
|
||||
) b
|
||||
WHERE
|
||||
key = '@type'
|
||||
AND VALUE :: STRING = '/cosmos.gov.v1beta1.MsgVote'
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
tx_succeeded,
|
||||
_path,
|
||||
b.value :proposal_id :: NUMBER AS proposal_id,
|
||||
b.value :voter :: STRING AS voter,
|
||||
CASE
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_YES' THEN 1
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_ABSTAIN' THEN 2
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_NO' THEN 3
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_NO_WITH_VETO' THEN 4
|
||||
ELSE o.value :option
|
||||
END AS vote_option,
|
||||
o.value :weight :: FLOAT AS vote_weight,
|
||||
_inserted_timestamp,
|
||||
concat_ws(
|
||||
'-',
|
||||
tx_id,
|
||||
proposal_id,
|
||||
voter,
|
||||
vote_option,
|
||||
_path
|
||||
) AS _unique_key
|
||||
FROM
|
||||
weighted_votes,
|
||||
LATERAL FLATTEN (
|
||||
input => messages
|
||||
) b,
|
||||
LATERAL FLATTEN (
|
||||
input => b.value :options
|
||||
) o
|
||||
)
|
||||
{% endif %}
|
||||
UNION ALL
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
m.tx_id,
|
||||
tx_succeeded,
|
||||
_path,
|
||||
b.value :proposal_id :: NUMBER AS proposal_id,
|
||||
b.value :voter :: STRING AS voter,
|
||||
CASE
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_YES' THEN 1
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_ABSTAIN' THEN 2
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_NO' THEN 3
|
||||
WHEN o.value :option :: STRING = 'VOTE_OPTION_NO_WITH_VETO' THEN 4
|
||||
ELSE o.value :option
|
||||
END AS vote_option,
|
||||
o.value :weight :: FLOAT AS vote_weight,
|
||||
proposal_id,
|
||||
voter,
|
||||
vote_option,
|
||||
vote_weight,
|
||||
memo,
|
||||
_inserted_timestamp,
|
||||
concat_ws(
|
||||
'-',
|
||||
tx_id,
|
||||
proposal_id,
|
||||
voter,
|
||||
vote_option,
|
||||
_path
|
||||
) AS _unique_key
|
||||
_unique_key
|
||||
FROM
|
||||
weighted_votes,
|
||||
LATERAL FLATTEN (
|
||||
input => tx_body :messages
|
||||
) b,
|
||||
LATERAL FLATTEN (
|
||||
input => b.value :options
|
||||
) o
|
||||
pre_final p
|
||||
LEFT OUTER JOIN memo_text m
|
||||
ON p.tx_id = m.tx_id
|
||||
|
||||
@ -80,4 +80,11 @@ models:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- NUMBER
|
||||
- FLOAT
|
||||
- FLOAT
|
||||
- name: MEMO
|
||||
description: "{{ doc('memo') }}"
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_in_type_list:
|
||||
column_type_list:
|
||||
- STRING
|
||||
- VARCHAR
|
||||
Loading…
Reference in New Issue
Block a user