added support for multiple affiliates

This commit is contained in:
Mike Stepanovic 2025-01-07 17:40:08 -07:00
parent d94cb70f2c
commit 85dded22d8
3 changed files with 66 additions and 15 deletions

View File

@ -20,6 +20,8 @@ WITH base AS (
to_pool_address,
affiliate_address,
affiliate_fee_basis_points,
affiliate_addresses_array,
affiliate_fee_basis_points_array,
from_asset,
to_asset,
from_amount,
@ -60,6 +62,8 @@ SELECT
to_pool_address,
affiliate_address,
affiliate_fee_basis_points,
affiliate_addresses_array,
affiliate_fee_basis_points_array,
from_asset,
to_asset,
from_amount,

View File

@ -0,0 +1,43 @@
{{ config(
materialized = 'view'
) }}
WITH base AS (
SELECT
tx_id,
blockchain,
block_timestamp,
pool_name,
affiliate_addresses_array,
affiliate_fee_basis_points_array,
_inserted_timestamp
FROM {{ ref('silver__swaps') }}
WHERE array_size(affiliate_addresses_array) > 0
),
exploded AS (
SELECT
tx_id,
blockchain,
block_timestamp,
pool_name,
f.value::string as affiliate_address,
b.value::integer as affiliate_fee_basis_points,
_inserted_timestamp,
f.index as affiliate_index,
concat_ws('-', tx_id, f.value::string) as _unique_key
FROM base,
LATERAL FLATTEN(input => affiliate_addresses_array) f,
LATERAL FLATTEN(input => affiliate_fee_basis_points_array) b
WHERE f.index = b.index
)
SELECT
tx_id,
blockchain,
block_timestamp,
pool_name,
affiliate_address,
affiliate_fee_basis_points,
_inserted_timestamp,
affiliate_index,
_unique_key
FROM exploded

View File

@ -83,21 +83,23 @@ SELECT
END AS native_to_address,
to_address AS to_pool_address,
CASE
WHEN COALESCE(SPLIT(memo, ':') [4], '') = '' THEN NULL
ELSE SPLIT(
memo,
':'
) [4] :: STRING
WHEN COALESCE(SPLIT(memo, ':')[4], '') = '' THEN NULL
WHEN CONTAINS(SPLIT(memo, ':')[4], '/') THEN
SPLIT(SPLIT(memo, ':')[4], '/')[0]
ELSE SPLIT(memo, ':')[4]::STRING
END AS affiliate_address,
TRY_CAST(
CASE
WHEN COALESCE(SPLIT(memo, ':') [5], '') = '' THEN NULL
ELSE SPLIT(
memo,
':'
) [5]
END :: STRING AS INT
WHEN COALESCE(SPLIT(memo, ':')[5], '') = '' THEN NULL
WHEN CONTAINS(SPLIT(memo, ':')[5], '/') THEN
SPLIT(SPLIT(memo, ':')[5], '/')[0]
ELSE SPLIT(memo, ':')[5]
END::STRING AS INT
) AS affiliate_fee_basis_points,
SPLIT(COALESCE(SPLIT(SPLIT(memo, '|')[0], ':')[4], ''), '/') AS affiliate_addresses_array,
ARRAY_AGG(
TRY_CAST(TRIM(f.value) AS INTEGER)
) WITHIN GROUP (ORDER BY f.index) AS affiliate_fee_basis_points_array,
from_asset,
to_asset,
COALESCE(from_e8 / pow(10, 8), 0) AS from_amount,
@ -152,7 +154,9 @@ SELECT
_INSERTED_TIMESTAMP
FROM
swaps se
LEFT JOIN {{ ref('silver__prices') }}
p
ON se.block_id = p.block_id
AND se.pool_name = p.pool_name
LEFT JOIN {{ ref('silver__prices') }} p
ON se.block_id = p.block_id
AND se.pool_name = p.pool_name,
LATERAL FLATTEN(input => SPLIT(COALESCE(SPLIT(memo, ':')[5], ''), '/')) f
GROUP BY
ALL