Skip to content

Commit

Permalink
T 13866 looksrare transactions on v2 (#1241)
Browse files Browse the repository at this point in the history
Brief comments on the purpose of your changes:

This PR adds the LooksRare platform (Ethereum) on Dune v2.
It includes LooksRare transactions, mints, burns, and fees tables
Using the merge into strategy, I made rows are unique. I also added a test against Dune v1 nft.trades_v2_beta table
I made sure the new tables have the appropriate metadata and can be exposed on the Dune App + are integrated to get included in nft.transactions/trades/mints/burns.

*For Dune Engine V2*
I've checked that:

* [x] I tested the query on dune.com after compiling the model with dbt compile (compiled queries are written to the target directory)
* [x] I used "refs" to reference other models in this repo and "sources" to reference raw or decoded tables 
* [x] if adding a new model, I added a test
* [x] the filename is unique and ends with .sql
* [x] each sql file is a select statement and has only one view, table or function defined  
* [x] column names are `lowercase_snake_cased`

When you are ready for a review, tag duneanalytics/data-experience. We will re-open your forked pull request as an internal pull request. Then your spells will run in dbt and the logs will be avaiable in Github Actions DBT Slim CI. This job will only run the models and tests changed by your PR compared to the production project.
  • Loading branch information
soispoke authored Jul 15, 2022
1 parent b573cb4 commit 47e711f
Show file tree
Hide file tree
Showing 17 changed files with 1,695 additions and 11 deletions.
6 changes: 6 additions & 0 deletions spellbook/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,12 @@ models:
solana:
+schema: opensea_solana
+materialized: view
looksrare:
+schema: looksrare
+materialized: view
ethereum:
+schema: looksrare_ethereum
+materialized: view
magiceden:
+schema: magiceden
+materialized: view
Expand Down
50 changes: 50 additions & 0 deletions spellbook/macros/alter_table_properties.sql
Original file line number Diff line number Diff line change
Expand Up @@ -127,6 +127,51 @@ ALTER VIEW opensea.fees SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}

{% set looksrare_ethereum_events %}
ALTER TABLE looksrare_ethereum.events SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.blockchains'='["ethereum"]',
'dune.data_explorer.category'='abstraction',
'dune.data_explorer.abstraction.type'='project',
'dune.data_explorer.abstraction.name'='looksrare',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}

{% set looksrare_ethereum_trades %}
ALTER VIEW looksrare_ethereum.trades SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.blockchains'='["ethereum"]',
'dune.data_explorer.category'='abstraction',
'dune.data_explorer.abstraction.type'='project',
'dune.data_explorer.abstraction.name'='looksrare',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}

{% set looksrare_ethereum_mints %}
ALTER VIEW looksrare_ethereum.mints SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.blockchains'='["ethereum"]',
'dune.data_explorer.category'='abstraction',
'dune.data_explorer.abstraction.type'='project',
'dune.data_explorer.abstraction.name'='looksrare',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}

{% set looksrare_ethereum_burns %}
ALTER VIEW looksrare_ethereum.burns SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.blockchains'='["ethereum"]',
'dune.data_explorer.category'='abstraction',
'dune.data_explorer.abstraction.type'='project',
'dune.data_explorer.abstraction.name'='looksrare',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}

{% set looksrare_ethereum_fees %}
ALTER VIEW looksrare_ethereum.fees SET TBLPROPERTIES('dune.public'='true',
'dune.data_explorer.blockchains'='["ethereum"]',
'dune.data_explorer.category'='abstraction',
'dune.data_explorer.abstraction.type'='project',
'dune.data_explorer.abstraction.name'='looksrare',
'dune.data_explorer.contributors'='["soispoke"]');
{% endset %}


{% set magiceden_events %}
ALTER TABLE magiceden.events SET TBLPROPERTIES('dune.public'='true',
Expand Down Expand Up @@ -304,6 +349,11 @@ ALTER VIEW ens.view_renewals SET TBLPROPERTIES('dune.public'='true',
{% do run_query(opensea_mints) %}
{% do run_query(opensea_burns) %}
{% do run_query(opensea_fees) %}
{% do run_query(looksrare_ethereum_events) %}
{% do run_query(looksrare_ethereum_trades) %}
{% do run_query(looksrare_ethereum_mints) %}
{% do run_query(looksrare_ethereum_burns) %}
{% do run_query(looksrare_ethereum_fees) %}
{% do run_query(magiceden_events) %}
{% do run_query(magiceden_trades) %}
{% do run_query(magiceden_mints) %}
Expand Down
33 changes: 33 additions & 0 deletions spellbook/models/looksrare/ethereum/looksrare_ethereum_burns.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
{{
config(
alias='burns')
}}

SELECT blockchain,
project,
version,
block_time,
token_id,
collection,
amount_usd,
token_standard,
trade_type,
number_of_items,
trade_category,
evt_type,
seller,
buyer,
amount_original,
amount_raw,
currency_symbol,
currency_contract,
nft_contract_address,
project_contract_address,
aggregator_name,
aggregator_address,
tx_hash,
tx_from,
tx_to,
unique_trade_id
FROM ({{ ref('looksrare_ethereum_events') }})
WHERE evt_type = 'Burn'
170 changes: 170 additions & 0 deletions spellbook/models/looksrare/ethereum/looksrare_ethereum_events.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,170 @@
{{ config(
alias ='events',
materialized ='incremental',
file_format ='delta',
incremental_strategy='merge',
unique_key='unique_trade_id'
)
}}

WITH looks_rare AS (
SELECT
ask.evt_block_time AS block_time,
ask.tokenId::string AS token_id,
ask.amount AS number_of_items,
taker AS seller,
maker AS buyer,
price AS price,
roy.amount AS royalty_fee,
roy.royaltyRecipient AS royalty_fee_receive_address,
roy.currency AS royalty_fee_currency_symbol,
CASE -- REPLACE `ETH` WITH `WETH` for ERC20 lookup later
WHEN ask.currency = '0x0000000000000000000000000000000000000000' THEN '0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'
ELSE ask.currency
END AS currency_contract,
ask.currency AS currency_contract_original,
ask.collection AS nft_contract_address,
ask.contract_address AS contract_address,
ask.evt_tx_hash AS tx_hash,
ask.evt_block_number AS block_number,
ask.evt_index AS evt_index,
roy.evt_index as roy_event_index,
CASE -- CATEGORIZE Collection Wide Offers Accepted
WHEN strategy = '0x86f909f70813cdb1bc733f4d97dc6b03b8e7e8f3' THEN 'Collection Offer Accepted'
ELSE 'Offer Accepted'
END AS category
FROM {{ source('looksrare_ethereum','looksrareexchange_evt_takerask') }} ask
LEFT JOIN {{ source('looksrare_ethereum','looksrareexchange_evt_royaltypayment') }} roy ON roy.evt_tx_hash = ask.evt_tx_hash
AND ask.evt_index - 2 = roy.evt_index
{% if is_incremental() %} -- this filter will only be applied on an incremental run
WHERE ask.evt_block_time >= (select max(block_time) from {{ this }})
{% endif %}
UNION
SELECT
bid.evt_block_time AS block_time,
bid.tokenId::string AS token_id,
bid.amount AS number_of_items,
maker AS seller,
taker AS buyer,
price AS price,
roy.amount AS royalty_fee,
roy.royaltyRecipient AS royalty_fee_receive_address,
roy.currency AS royalty_fee_currency_symbol,
CASE -- REPLACE `ETH` WITH `WETH` for ERC20 lookup later
WHEN bid.currency = '0x0000000000000000000000000000000000000000' THEN '0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'
ELSE bid.currency
END AS currency_contract,
bid.currency AS currency_contract_original,
bid.collection AS nft_contract_address,
bid.contract_address AS contract_address,
bid.evt_tx_hash AS tx_hash,
bid.evt_block_number AS block_number,
bid.evt_index AS evt_index,
roy.evt_index as roy_event_index,
'Buy' as category
FROM {{ source('looksrare_ethereum','looksrareexchange_evt_takerbid') }} bid
LEFT JOIN {{ source('looksrare_ethereum','looksrareexchange_evt_royaltypayment') }} roy ON roy.evt_tx_hash = bid.evt_tx_hash
AND roy.evt_index = bid.evt_index - 4
{% if is_incremental() %} -- this filter will only be applied on an incremental run
WHERE bid.evt_block_time >= (select max(block_time) from {{ this }})
{% endif %}
),

-- Get ERC721 AND ERC1155 transfer data for every trade TRANSACTION
erc_transfers as
(SELECT evt_tx_hash,
contract_address,
id::string as token_id_erc,
cardinality(collect_list(value)) as count_erc,
value as value_unique,
CASE WHEN erc1155.from = '0x0000000000000000000000000000000000000000' THEN 'Mint'
WHEN erc1155.to = '0x0000000000000000000000000000000000000000'
OR erc1155.to = '0x000000000000000000000000000000000000dead' THEN 'Burn'
ELSE 'Trade' END AS evt_type,
evt_index
FROM {{ source('erc1155_ethereum','evt_transfersingle') }} erc1155
WHERE erc1155.evt_block_time > '2022-01-01'
GROUP BY evt_tx_hash,value,id,evt_index, erc1155.from, erc1155.to, erc1155.contract_address
UNION
SELECT evt_tx_hash,
contract_address,
tokenId::string as token_id_erc,
COUNT(tokenId) as count_erc,
NULL as value_unique,
CASE WHEN erc721.from = '0x0000000000000000000000000000000000000000' THEN 'Mint'
WHEN erc721.to = '0x0000000000000000000000000000000000000000'
OR erc721.to = '0x000000000000000000000000000000000000dead' THEN 'Burn'
ELSE 'Trade' END AS evt_type,
evt_index
FROM {{ source('erc721_ethereum','evt_transfer') }} erc721
WHERE erc721.evt_block_time > '2022-01-01'
GROUP BY evt_tx_hash,tokenId,evt_index, erc721.from, erc721.to, erc721.contract_address)

SELECT DISTINCT
'ethereum' as blockchain,
'looksrare' as project,
'v1' as version,
looks_rare.block_time,
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 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'
ELSE 'Single Item Trade' END AS trade_type,
-- Count number of items traded for different trade types and erc standards
CASE WHEN agg.name is NULL AND erc.value_unique > 1 THEN erc.value_unique
WHEN agg.name is NULL AND erc.value_unique is NULL AND erc.count_erc > 1 THEN erc.count_erc
WHEN tokens.standard = 'erc1155' THEN erc.value_unique
WHEN tokens.standard = 'erc721' THEN erc.count_erc
ELSE (SELECT
count(1)::bigint cnt
FROM {{ source('erc721_ethereum','evt_transfer') }} erc721
WHERE erc721.evt_tx_hash = tx_hash
) +
(SELECT
count(1)::bigint cnt
FROM {{ source('erc1155_ethereum','evt_transfersingle') }} erc1155
WHERE erc1155.evt_tx_hash = tx_hash
) END AS number_of_items,
looks_rare.category as trade_category,
evt_type,
seller,
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,
currency_contract,
COALESCE(erc.contract_address, nft_contract_address) AS nft_contract_address,
looks_rare.contract_address AS project_contract_address,
agg.name AS aggregator_name,
agg.contract_address AS aggregator_address,
tx_hash,
tx.from AS tx_from,
tx.to AS tx_to,
ROUND((2*(looks_rare.price)/100),7) as platform_fee_amount_raw,
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,
royalty_fee_receive_address,
royalty_fee_currency_symbol,
tx_hash || '-' || token_id || '-' || seller || '-' || looks_rare.evt_index::string || '-' || evt_type as unique_trade_id
FROM looks_rare
INNER JOIN {{ source('ethereum','transactions') }} tx ON tx_hash = tx.hash
AND tx.block_time > '2022-01-01'
LEFT JOIN erc_transfers erc ON erc.evt_tx_hash = tx_hash AND erc.token_id_erc = token_id
LEFT JOIN {{ ref('tokens_ethereum_nft') }} tokens ON tokens.contract_address = nft_contract_address
LEFT JOIN {{ ref('nft_ethereum_aggregators') }} agg ON agg.contract_address = tx.to
LEFT JOIN {{ source('prices', 'usd') }} p ON p.minute = date_trunc('minute', looks_rare.block_time)
AND p.contract_address = currency_contract
AND p.blockchain ='ethereum'
LEFT JOIN {{ ref('tokens_ethereum_erc20') }} erc20 ON erc20.contract_address = currency_contract
{% if is_incremental() %}
-- this filter will only be applied on an incremental run
WHERE looks_rare.block_time >= (select max(block_time) from {{ this }})
{% endif %}
37 changes: 37 additions & 0 deletions spellbook/models/looksrare/ethereum/looksrare_ethereum_fees.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
{{
config(
alias='fees')
}}

SELECT blockchain,
project,
version,
block_time,
token_id,
collection,
platform_fee_amount_raw,
platform_fee_amount,
platform_fee_amount_usd,
platform_fee_percentage,
royalty_fee_amount_raw,
royalty_fee_amount,
royalty_fee_amount_usd,
royalty_fee_percentage,
royalty_fee_receive_address,
royalty_fee_currency_symbol,
token_standard,
trade_type,
number_of_items,
trade_category,
evt_type,
seller,
buyer,
nft_contract_address,
project_contract_address,
aggregator_name,
aggregator_address,
tx_hash,
tx_from,
tx_to,
unique_trade_id
FROM ({{ ref('looksrare_ethereum_events') }})
33 changes: 33 additions & 0 deletions spellbook/models/looksrare/ethereum/looksrare_ethereum_mints.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
{{
config(
alias='mints')
}}

SELECT blockchain,
project,
version,
block_time,
token_id,
collection,
amount_usd,
token_standard,
trade_type,
number_of_items,
trade_category,
evt_type,
seller,
buyer,
amount_original,
amount_raw,
currency_symbol,
currency_contract,
nft_contract_address,
project_contract_address,
aggregator_name,
aggregator_address,
tx_hash,
tx_from,
tx_to,
unique_trade_id
FROM ({{ ref('looksrare_ethereum_events') }})
WHERE evt_type = 'Mint'
Loading

0 comments on commit 47e711f

Please sign in to comment.