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

Add query nft trades labels #1513

Merged
merged 6 commits into from
Sep 8, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 4 additions & 0 deletions dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -119,6 +119,10 @@ models:
+schema: labels
+materialized: view

labels:
+schema: labels
+materialized: view

tokens:
+schema: tokens
+materialized: view
Expand Down
3 changes: 3 additions & 0 deletions models/labels/labels_all.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,5 +4,8 @@
file_format = 'delta')
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We need to also add an alter table statement for this. Could you try adding it to post_hook here, would be interesting to see if it works. Because then we can keep those things in the files and not forget.

Copy link
Contributor Author

@soispoke soispoke Sep 7, 2022

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes, I initially didn't want to expose the labels yet, until we have added a couple more queries/static labels. I also don't really want to add alter table statements as post hook as I've done this before and it ended up being extremely long and messy in the dbt_project.yml file. I think the most promising avenue is to alter table properties in the models directly (databricks/dbt-databricks#33), but we have to wait until the databricks adapter is supported by dbt cloud.

In any case, maybe we could open another PR/discussion around this ?

}}

-- Query Labels
SELECT * FROM {{ ref('labels_nft') }}
UNION
-- Static Labels
SELECT * FROM {{ ref('labels_cex') }}
6 changes: 3 additions & 3 deletions models/labels/labels_all_schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -5,10 +5,10 @@ models:
meta:
blockchain: ethereum, solana
sector: labels
category: cex
category: nft, cex
contibutors: hildobby, soispoke
config:
tags: ['labels', 'ethereum', 'cex']
tags: ['labels', 'ethereum', 'solana', 'nft', 'cex']
description: "All labels across chains and categories"
columns:
- name: blockchain
Expand All @@ -26,4 +26,4 @@ models:
- name: created_at
description: "When were labels created"
- name: updated_at
description: "When were labels updated for the last time ?"
description: "When were labels updated for the last time"
7 changes: 7 additions & 0 deletions models/labels/nft/labels_nft.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
{{config(alias='nft')}}

SELECT * FROM {{ ref('labels_nft_traders_transactions') }}
UNION
SELECT * FROM {{ ref('labels_nft_traders_volume_usd') }}
UNION
SELECT * FROM {{ ref('labels_nft_users_platforms') }}
113 changes: 113 additions & 0 deletions models/labels/nft/labels_nft_schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,113 @@
version: 2

models:
- name: labels_nft
meta:
blockchain: ethereum, solana
sector: labels
category: nft
project: ['opensea', 'looksrare', 'x2y2', 'magiceden']
contibutors: soispoke
config:
tags: ['labels', 'nft', 'ethereum', 'solana', 'opensea', 'looksrare', 'x2y2', 'magiceden']
description: "NFT query labels"
columns:
- name: blockchain
description: "Blockchain on which NFT trades have been made"
- name: address
description: "Address of NFT traders"
- name: name
description: "Label name NFT trader (Top 1, 5, 10% or simply NFT Trader when an address has traded NFTs but is not in top top 10 or above)"
- name: category
description: "Label category (NFT here)"
- name: contributor
description: "Wizard(s) contributing to labels"
- name: source
description: "How were labels generated (could be static or query)"
- name: created_at
description: "When were labels created"
- name: updated_at
description: "When were labels updated for the last time"

- name: labels_nft_users_platforms
meta:
blockchain: ethereum, solana
sector: labels
category: nft
project: ['labels','opensea', 'looksrare', 'x2y2', 'magiceden']
contibutors: soispoke
config:
tags: ['labels', 'nft_traders', 'ethereum', 'solana', 'opensea', 'looksrare', 'x2y2', 'magiceden']
description: "NFT Platforms users across chains"
columns:
- name: blockchain
description: "Blockchain"
- name: address
description: "Address of NFT platforms users"
- name: name
description: "Label name (NFT Platform User)"
- name: category
description: "Label category (NFT here)"
- name: contributor
description: "Wizard(s) contributing to labels"
- name: source
description: "How were labels generated (could be static or query)"
- name: created_at
description: "When were labels created"
- name: updated_at
description: "When were labels updated for the last time"

- name: labels_nft_traders_transactions
meta:
blockchain: ethereum, solana
sector: labels
category: nft
project: ['labels','opensea', 'looksrare', 'x2y2', 'magiceden']
contibutors: soispoke
config:
tags: ['labels', 'nft_traders', 'ethereum', 'solana', 'opensea', 'looksrare', 'x2y2', 'magiceden']
description: "Top NFT traders based on the number of transactions across chains"
columns:
- name: blockchain
description: "Blockchain on which NFT trades have been made"
- name: address
description: "Address of NFT traders"
- name: name
description: "Label name NFT trader (Top 1, 5, 10% or simply NFT Trader when an address has traded NFTs but is not in top top 10 or above)"
- name: category
description: "Label category (NFT here)"
- name: contributor
description: "Wizard(s) contributing to labels"
- name: source
description: "How were labels generated (could be static or query)"
- name: created_at
description: "When were labels created"
- name: updated_at
description: "When were labels updated for the last time"

- name: labels_nft_traders_volume_usd
meta:
blockchain: ethereum, solana
sector: labels
project: ['labels','opensea', 'looksrare', 'x2y2', 'magiceden']
contibutors: soispoke
config:
tags: ['labels', 'nft_traders', 'ethereum', 'solana', 'opensea', 'looksrare', 'x2y2', 'magiceden']
description: "Top NFT traders based on volume in USD across chains"
columns:
- name: blockchain
description: "Blockchain on which NFT trades have been made"
- name: address
description: "Address of NFT traders"
- name: name
description: "Label name NFT trader (Top 1, 5, 10% or simply NFT Trader when an address has traded NFTs but is not in top top 10 or above)"
- name: category
description: "Label category (NFT here)"
- name: contributor
description: "Wizard(s) contributing to labels"
- name: source
description: "How were labels generated (could be static or query)"
- name: created_at
description: "When were labels created"
- name: updated_at
description: "When were labels updated for the last time"
45 changes: 45 additions & 0 deletions models/labels/nft/labels_nft_traders_transactions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@

{{config(alias='nft_traders_transactions')}}

WITH nft_trades AS (
SELECT
blockchain,
tx_hash,
buyer AS address
FROM {{ ref('nft_trades') }}
UNION
SELECT
blockchain,
tx_hash,
seller AS address
FROM {{ ref('nft_trades') }}
),

total as (
SELECT
address,
COUNT(tx_hash) AS total_count
FROM nft_trades
GROUP BY 1
)

SELECT
collect_set(nft_trades.blockchain) as blockchain,
nft_trades.address,
CASE WHEN ((ROW_NUMBER() OVER(ORDER BY COUNT(tx_hash) DESC)) / total_count * 100) <= 10
AND ((ROW_NUMBER() OVER(ORDER BY COUNT(tx_hash) DESC)) / total_count * 100) > 5
THEN 'Top 10% NFT Trader (Transaction)'
WHEN ((ROW_NUMBER() OVER(ORDER BY COUNT(tx_hash) DESC)) / total_count * 100) <= 5
AND ((ROW_NUMBER() OVER(ORDER BY COUNT(tx_hash) DESC)) / total_count * 100) > 1
THEN 'Top 5% NFT Trader (Transactions)'
WHEN ((ROW_NUMBER() OVER(ORDER BY COUNT(tx_hash) DESC)) / total_count * 100) <= 1
THEN 'Top 1% NFT Trader (Transactions)' END AS name,
'nft' AS category,
'soispoke' AS contributor,
'query' AS source,
timestamp('2022-08-24') as created_at,
now() as updated_at
FROM nft_trades
JOIN total on total.address = nft_trades.address
WHERE nft_trades.address is not null
GROUP BY nft_trades.address, total_count
44 changes: 44 additions & 0 deletions models/labels/nft/labels_nft_traders_volume_usd.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
{{config(alias='nft_traders_volume_usd')}}

WITH nft_trades AS (
SELECT
blockchain,
amount_usd,
buyer AS address
FROM {{ ref('nft_trades') }}
UNION
SELECT
blockchain,
amount_usd,
seller AS address
FROM {{ ref('nft_trades') }}
),

total as (
SELECT
address,
SUM(amount_usd) AS total_count
FROM nft_trades
GROUP BY 1
)

SELECT
collect_set(nft_trades.blockchain) as blockchain,
nft_trades.address,
CASE WHEN ((ROW_NUMBER() OVER(ORDER BY SUM(amount_usd) DESC)) / total_count * 100) <= 10
AND ((ROW_NUMBER() OVER(ORDER BY SUM(amount_usd) DESC)) / total_count * 100) > 5
THEN 'Top 10% NFT Trader (Volume in $USD)'
WHEN ((ROW_NUMBER() OVER(ORDER BY SUM(amount_usd) DESC)) / total_count * 100) <= 5
AND ((ROW_NUMBER() OVER(ORDER BY SUM(amount_usd) DESC)) / total_count * 100) > 1
THEN 'Top 5% NFT Trader (Volume in $USD)'
WHEN ((ROW_NUMBER() OVER(ORDER BY SUM(amount_usd) DESC)) / total_count * 100) <= 1
THEN 'Top 1% NFT Trader (Volume in $USD)' END AS name,
'nft' AS category,
'soispoke' AS contributor,
'query' AS source,
timestamp('2022-08-24') as created_at,
now() as updated_at
FROM nft_trades
JOIN total on total.address = nft_trades.address
WHERE nft_trades.address is not null and amount_usd is not null
GROUP BY nft_trades.address, total_count
28 changes: 28 additions & 0 deletions models/labels/nft/labels_nft_users_platforms.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
{{config(alias='nft_users_platforms')}}

WITH nft_trades AS (
SELECT
blockchain,
project,
buyer AS address
FROM {{ ref('nft_trades') }}
UNION
SELECT
blockchain,
project,
seller AS address
FROM {{ ref('nft_trades') }}
)

SELECT
collect_set(blockchain) as blockchain,
address,
array_join(collect_set(concat(upper(substring(project,1,1)),substring(project,2))), ', ') ||' User' as name,
'nft' AS category,
'soispoke' AS contributor,
'query' AS source,
timestamp('2022-09-03') as created_at,
now() as updated_at
FROM nft_trades
WHERE address is not null
GROUP BY address