Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Some fixes for OpenSea, Seaport, LooksRare and X2Y2 #1536

Merged
merged 14 commits into from
Oct 24, 2022
38 changes: 32 additions & 6 deletions models/looksrare/ethereum/looksrare_ethereum_events.sql
Original file line number Diff line number Diff line change
Expand Up @@ -124,7 +124,7 @@ SELECT DISTINCT
token_id,
tokens.name AS collection,
looks_rare.price / power(10,erc20.decimals) * p.price AS amount_usd,
tokens.standard AS token_standard,
CASE WHEN erct4.evt_block_time IS NOT NULL THEN 'erc721' ELSE 'erc1155' END AS token_standard,
CASE
WHEN agg.name is NULL AND erc.value_unique = 1 OR erc.count_erc = 1 THEN 'Single Item Trade'
WHEN agg.name is NULL AND erc.value_unique > 1 OR erc.count_erc > 1 THEN 'Bundle Trade'
Expand All @@ -147,7 +147,9 @@ SELECT DISTINCT
looks_rare.category as trade_category,
CASE WHEN evt_type is NULL THEN 'Other' ELSE evt_type END as evt_type,
seller,
buyer,
CASE WHEN looks_rare.buyer=agg.contract_address AND erct2.to IS NOT NULL THEN erct2.to
WHEN looks_rare.buyer=agg.contract_address AND erct3.to IS NOT NULL THEN erct3.to
ELSE looks_rare.buyer END AS buyer,
looks_rare.price / power(10,erc20.decimals) AS amount_original,
looks_rare.price AS amount_raw,
CASE WHEN looks_rare.currency_contract_original = '0x0000000000000000000000000000000000000000' THEN 'ETH' ELSE erc20.symbol END AS currency_symbol,
Expand All @@ -164,10 +166,10 @@ SELECT DISTINCT
ROUND((2*(looks_rare.price / power(10,erc20.decimals))/100),7) platform_fee_amount,
ROUND((2*(looks_rare.price / power(10,erc20.decimals) * p.price)/100),7) as platform_fee_amount_usd,
'2' as platform_fee_percentage,
royalty_fee as royalty_fee_amount_raw,
royalty_fee / power(10,erc20.decimals) as royalty_fee_amount,
royalty_fee * p.price/ power(10,erc20.decimals) as royalty_fee_amount_usd,
royalty_fee / looks_rare.price * 100 as royalty_fee_percentage,
COALESCE(royalty_fee, 0) as royalty_fee_amount_raw,
COALESCE(royalty_fee / power(10,erc20.decimals), 0) as royalty_fee_amount,
COALESCE(royalty_fee * p.price/ power(10,erc20.decimals), 0) as royalty_fee_amount_usd,
COALESCE(royalty_fee / looks_rare.price * 100, 0) as royalty_fee_percentage,
royalty_fee_receive_address,
royalty_fee_currency_symbol,
'looksrare' || '-' || COALESCE(looks_rare.tx_hash, '-1') || '-' || COALESCE(token_id::string, '-1') || '-' || COALESCE(seller::string, '-1') || '-' || COALESCE(erc.contract_address, nft_contract_address) || '-' || COALESCE(looks_rare.evt_index::string, '-1') || '-' || COALESCE(evt_type::string, 'Other') || '-' || COALESCE(erc.evt_index, '-1') || '-' || COALESCE(case when erc.value_unique::string is null then '0' ELSE '1' end, '1') as unique_trade_id
Expand All @@ -189,6 +191,30 @@ LEFT JOIN {{ source('prices', 'usd') }} p ON p.minute = date_trunc('minute', loo
AND p.minute >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ ref('tokens_erc20') }} erc20 ON erc20.contract_address = currency_contract AND erc20.blockchain = 'ethereum'
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=looks_rare.block_time
AND looks_rare.nft_contract_address=erct2.contract_address
AND erct2.evt_tx_hash=looks_rare.tx_hash
AND erct2.tokenId=looks_rare.token_id
AND erct2.from=looks_rare.buyer
{% if is_incremental() %}
AND erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=looks_rare.block_time
AND looks_rare.nft_contract_address=erct3.contract_address
AND erct3.evt_tx_hash=looks_rare.tx_hash
AND erct3.id=looks_rare.token_id
AND erct3.from=looks_rare.buyer
{% if is_incremental() %}
AND erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct4 ON erct4.evt_block_time=looks_rare.block_time
AND looks_rare.nft_contract_address=erct4.contract_address
AND erct4.evt_tx_hash=looks_rare.tx_hash
AND erct4.tokenId=looks_rare.token_id
AND erct4.from=looks_rare.seller
{% if is_incremental() %}
AND erct4.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('ethereum','traces') }} ett
ON looks_rare.block_time = ett.block_time AND looks_rare.tx_hash = ett.tx_hash AND right(ett.input, 8)='72db8c0b'
{% if is_incremental() %}
Expand Down
10 changes: 5 additions & 5 deletions models/looksrare/ethereum/looksrare_ethereum_schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@ models:
meta:
blockchain: ethereum
project: looksrare
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','looksrare','v1','events']
description: >
Expand Down Expand Up @@ -129,7 +129,7 @@ models:
meta:
blockchain: ethereum
project: looksrare
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','looksrare','trades']
description: >
Expand Down Expand Up @@ -167,7 +167,7 @@ models:
meta:
blockchain: ethereum
project: looksrare
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','looksrare','mints']
description: >
Expand Down Expand Up @@ -205,7 +205,7 @@ models:
meta:
blockchain: ethereum
project: looksrare
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','looksrare','burns']
description: >
Expand Down Expand Up @@ -243,7 +243,7 @@ models:
meta:
blockchain: ethereum
project: looksrare
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','looksrare','fees']
description: >
Expand Down
8 changes: 4 additions & 4 deletions models/opensea/ethereum/opensea_ethereum_schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,7 @@ models:
meta:
blockchain: ethereum
project: opensea
contributors: soispoke, umer_h_adil
contributors: soispoke, umer_h_adil, hildobby
config:
tags: ['ethereum','opensea','v1','events']
description: >
Expand Down Expand Up @@ -162,7 +162,7 @@ models:
meta:
blockchain: ethereum
project: opensea
contributors: soispoke, sohwak
contributors: [soispoke, sohwak, hildobby]
config:
tags: ['ethereum','opensea','v3','events']
description: >
Expand Down Expand Up @@ -212,7 +212,7 @@ models:
meta:
blockchain: ethereum
project: opensea
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','opensea','events']
description: >
Expand Down Expand Up @@ -258,7 +258,7 @@ models:
meta:
blockchain: ethereum
project: opensea
contributors: soispoke
contributors: [soispoke, hildobby]
config:
tags: ['ethereum','opensea','trades']
description: >
Expand Down
23 changes: 21 additions & 2 deletions models/opensea/ethereum/opensea_v1_ethereum_events.sql
Original file line number Diff line number Diff line change
Expand Up @@ -161,7 +161,9 @@ SELECT DISTINCT
) END AS number_of_items,
'Buy' AS trade_category,
wa.seller AS seller,
wa.buyer AS buyer,
CASE WHEN buyer=agg.contract_address AND erct2.to IS NOT NULL THEN erct2.to
WHEN buyer=agg.contract_address AND erct3.to IS NOT NULL THEN erct3.to
ELSE buyer END AS buyer,
CASE WHEN shared_storefront_address = '0x495f947276749ce646f68ac8c248420045cb7b5e' THEN 'Mint'
WHEN evt_type is not NULL THEN evt_type ELSE 'Trade' END as evt_type,
wa.amount_original / power(10,erc20.decimals) AS amount_original,
Expand All @@ -186,7 +188,7 @@ SELECT DISTINCT
(wa.fees / wa.amount_original * 100)::string AS royalty_fee_percentage,
wa.fee_receive_address as royalty_fee_receive_address,
wa.fee_currency_symbol as royalty_fee_currency_symbol,
'opensea' || '-' || wa.call_tx_hash || '-' || coalesce(token_id_erc_uncapped, wa.token_id, '') || '-' || wa.seller || '-' || coalesce(evt_index::string, '') || '-' || coalesce(wa.call_trace_address::string,'') as unique_trade_id
'opensea' || '-' || wa.call_tx_hash || '-' || coalesce(token_id_erc_uncapped, wa.token_id, '') || '-' || wa.seller || '-' || coalesce(erc_transfers.evt_index::string, '') || '-' || coalesce(wa.call_trace_address::string,'') as unique_trade_id
FROM wyvern_all wa
INNER JOIN {{ source('ethereum','transactions') }} tx ON wa.call_tx_hash = tx.hash
{% if is_incremental() %}
Expand All @@ -196,6 +198,22 @@ LEFT JOIN erc_transfers ON erc_transfers.evt_tx_hash = wa.call_tx_hash AND (wa.t
OR wa.token_id = null)
LEFT JOIN {{ ref('tokens_nft') }} tokens_nft ON tokens_nft.contract_address = wa.nft_contract_address and tokens_nft.blockchain = 'ethereum'
LEFT JOIN {{ ref('nft_aggregators') }} agg ON agg.contract_address = tx.to AND agg.blockchain = 'ethereum'
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=tx.block_time
AND wa.nft_contract_address=erct2.contract_address
AND erct2.evt_tx_hash=wa.call_tx_hash
AND erct2.tokenId=coalesce(token_id_erc, wa.token_id)
AND erct2.from=buyer
{% if is_incremental() %}
and erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=tx.block_time
AND wa.nft_contract_address=erct3.contract_address
AND erct3.evt_tx_hash=wa.call_tx_hash
AND erct3.id=coalesce(token_id_erc, wa.token_id)
AND erct3.from=buyer
{% if is_incremental() %}
and erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('prices', 'usd') }} p ON p.minute = date_trunc('minute', tx.block_time)
AND p.contract_address = wa.currency_contract
AND p.blockchain ='ethereum'
Expand All @@ -208,3 +226,4 @@ LEFT JOIN {{ ref('tokens_erc20') }} erc20 ON erc20.contract_address = wa.currenc
*
FROM
{{ ref('opensea_v1_ethereum_excluded_txns') }})
;
100 changes: 96 additions & 4 deletions models/seaport/ethereum/seaport_ethereum_transfers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -179,7 +179,8 @@ with p1_call as (
,a.purchase_method as trade_category
,'Trade' as evt_type
,concat('0x',substr(seller,3,40)) as seller
,concat('0x',substr(buyer,3,40)) as buyer
, CASE WHEN concat('0x',substr(buyer,3,40))=agg.contract_address THEN COALESCE(erct2.to, erct3.to)
ELSE concat('0x',substr(buyer,3,40)) END AS buyer
,a.original_amount / power(10,t1.decimals) as amount_original
,a.original_amount as amount_raw
,case when a.original_currency_contract = '0x0000000000000000000000000000000000000000' then 'ETH'
Expand Down Expand Up @@ -231,6 +232,28 @@ with p1_call as (
ON agg.contract_address = tx.to AND agg.blockchain = 'ethereum'
left join {{ ref('tokens_nft') }} n
on n.contract_address = nft_contract_address and n.blockchain = 'ethereum'
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=a.block_time
AND nft_contract_address=erct2.contract_address
AND erct2.evt_tx_hash=a.tx_hash
AND erct2.tokenId=a.nft_token_id
AND erct2.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct2.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=a.block_time
AND nft_contract_address=erct3.contract_address
AND erct3.evt_tx_hash=a.tx_hash
AND erct3.id=a.nft_token_id
AND erct3.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct3.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
left join {{ ref('tokens_erc20') }} t1
on t1.contract_address =
case when a.original_currency_contract = '0x0000000000000000000000000000000000000000'
Expand Down Expand Up @@ -388,7 +411,8 @@ with p1_call as (
,a.purchase_method as trade_category
,'Trade' as evt_type
,concat('0x',substr(seller,3,40)) as seller
,concat('0x',substr(buyer,3,40)) as buyer
, CASE WHEN concat('0x',substr(buyer,3,40))=agg.contract_address THEN COALESCE(erct2.to, erct3.to)
ELSE concat('0x',substr(buyer,3,40)) END AS buyer
,a.attempt_amount / power(10,t1.decimals) as amount_original
,a.attempt_amount as amount_raw
,case when concat('0x',substr(a.price_token,3,40)) =
Expand Down Expand Up @@ -433,6 +457,28 @@ with p1_call as (
{% if is_incremental() %}
and tx.block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=a.block_time
AND concat('0x',substr(a.nft_address,3,40))=erct2.contract_address
AND erct2.evt_tx_hash=a.tx_hash
AND erct2.tokenId=a.nft_token_id
AND erct2.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct2.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=a.block_time
AND concat('0x',substr(a.nft_address,3,40))=erct3.contract_address
AND erct3.evt_tx_hash=a.tx_hash
AND erct3.id=a.nft_token_id
AND erct3.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct3.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
left join {{ source('ethereum','traces') }} ett
ON a.block_time = ett.block_time AND a.tx_hash = ett.tx_hash AND right(ett.input, 8)='72db8c0b'
{% if is_incremental() %}
Expand Down Expand Up @@ -626,7 +672,8 @@ with p1_call as (
,a.purchase_method as trade_category
,'Trade' as evt_type
,concat('0x',substr(seller,3,40)) as seller
,concat('0x',substr(buyer,3,40)) as buyer
, CASE WHEN concat('0x',substr(buyer,3,40))=agg.contract_address THEN COALESCE(erct2.to, erct3.to)
ELSE concat('0x',substr(buyer,3,40)) END AS buyer
,a.attempt_amount / power(10,t1.decimals) as amount_original
,a.attempt_amount as amount_raw
,case when a.original_currency_contract = '0x0000000000000000000000000000000000000000' then 'ETH'
Expand Down Expand Up @@ -679,6 +726,28 @@ with p1_call as (
{% endif %}
left join {{ ref('tokens_nft') }} n
on n.contract_address = nft_contract_address and n.blockchain = 'ethereum'
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=a.block_time
AND nft_contract_address=erct2.contract_address
AND erct2.evt_tx_hash=a.tx_hash
AND erct2.tokenId=a.nft_token_id
AND erct2.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct2.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=a.block_time
AND nft_contract_address=erct3.contract_address
AND erct3.evt_tx_hash=a.tx_hash
AND erct3.id=a.nft_token_id
AND erct3.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct3.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
left join {{ ref('tokens_erc20') }} t1
on t1.contract_address =
case when a.original_currency_contract = '0x0000000000000000000000000000000000000000'
Expand Down Expand Up @@ -837,7 +906,8 @@ with p1_call as (
,a.purchase_method as trade_category
,'Trade' as evt_type
,concat('0x',substr(seller,3,40)) as seller
,concat('0x',substr(buyer,3,40)) as buyer
, CASE WHEN concat('0x',substr(buyer,3,40))=agg.contract_address THEN COALESCE(erct2.to, erct3.to)
ELSE concat('0x',substr(buyer,3,40)) END AS buyer
,a.attempt_amount / power(10,t1.decimals) as amount_original
,a.attempt_amount as amount_raw
,case when concat('0x',substr(a.price_token,3,40)) =
Expand Down Expand Up @@ -881,6 +951,28 @@ with p1_call as (
{% if is_incremental() %}
and tx.block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=a.block_time
AND concat('0x',substr(a.nft_address,3,40))=erct2.contract_address
AND erct2.evt_tx_hash=a.tx_hash
AND erct2.tokenId=a.nft_token_id
AND erct2.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct2.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=a.block_time
AND concat('0x',substr(a.nft_address,3,40))=erct3.contract_address
AND erct3.evt_tx_hash=a.tx_hash
AND erct3.id=a.nft_token_id
AND erct3.from=concat('0x',substr(buyer,3,40))
{% if not is_incremental() %}
and erct3.evt_block_number > 14801608
{% endif %}
{% if is_incremental() %}
and erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
left join {{ source('ethereum','traces') }} ett
ON a.block_time = ett.block_time AND a.tx_hash = ett.tx_hash AND right(ett.input, 8)='72db8c0b'
{% if is_incremental() %}
Expand Down
28 changes: 26 additions & 2 deletions models/x2y2/ethereum/x2y2_ethereum_events.sql
Original file line number Diff line number Diff line change
Expand Up @@ -164,15 +164,20 @@ SELECT 'ethereum' AS blockchain
END AS trade_category
, 'Trade' AS evt_type
, txs.seller
, txs.buyer
, CASE WHEN txs.buyer=txs.aggregator_address AND erct2.to IS NOT NULL THEN erct2.to
WHEN txs.buyer=txs.aggregator_address AND erct3.to IS NOT NULL THEN erct3.to
ELSE txs.buyer END AS buyer
, CASE WHEN currency_contract='0x0000000000000000000000000000000000000000' THEN txs.amount_raw/POWER(10, 18)
ELSE txs.amount_raw/POWER(10, pu.decimals)
END AS amount_original
, txs.amount_raw
, CASE WHEN currency_contract='0x0000000000000000000000000000000000000000' THEN 'ETH'
ELSE pu.symbol
END AS currency_symbol
, txs.currency_contract
, CASE WHEN txs.currency_contract='0x0000000000000000000000000000000000000000' THEN
'0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'
ELSE txs.currency_contract
END AS currency_contract
, txs.project_contract_address
, txs.nft_contract_address
, aggregator_name
Expand Down Expand Up @@ -219,3 +224,22 @@ LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct ON erct.evt_block_
AND erct.evt_tx_hash=txs.tx_hash
AND erct.tokenId=txs.token_id
AND erct.from=txs.seller
{% if is_incremental() %}
AND erct.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc721_ethereum','evt_transfer') }} erct2 ON erct2.evt_block_time=txs.block_time
AND txs.nft_contract_address=erct2.contract_address
AND erct2.evt_tx_hash=txs.tx_hash
AND erct2.tokenId=txs.token_id
AND erct2.from=txs.buyer
{% if is_incremental() %}
AND erct2.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}
LEFT JOIN {{ source('erc1155_ethereum','evt_transfersingle') }} erct3 ON erct3.evt_block_time=txs.block_time
AND txs.nft_contract_address=erct3.contract_address
AND erct3.evt_tx_hash=txs.tx_hash
AND erct3.id=txs.token_id
AND erct3.from=txs.buyer
{% if is_incremental() %}
AND erct3.evt_block_time >= date_trunc("day", now() - interval '1 week')
{% endif %}