This commit is contained in:
Angela Minster 2022-09-30 15:56:24 -04:00
parent 2087bdfa04
commit 1db6d66f1f
9 changed files with 158 additions and 0 deletions

BIN
.DS_Store vendored Normal file

Binary file not shown.

4
.gitignore vendored Normal file
View File

@ -0,0 +1,4 @@
.Rproj.user
.Rhistory
.RData
.Ruserdata

BIN
sql/.DS_Store vendored Normal file

Binary file not shown.

BIN
sql/bags/.DS_Store vendored Normal file

Binary file not shown.

View File

@ -0,0 +1,52 @@
WITH dep_addys AS (
SELECT
sender
FROM FLOW.CORE.EZ_TOKEN_TRANSFERS
WHERE recipient IN (SELECT address FROM FLIPSIDE_PROD_DB.CROSSCHAIN.ADDRESS_LABELS WHERE blockchain = 'flow' AND label_type = 'cex' AND label_subtype = 'hot_wallet')
GROUP BY sender
),
deps AS (
SELECT
sender AS user_address,
token_contract AS token_contract,
count(tx_id) AS n_deposits,
sum(amount) AS token_deposit_volume
FROM
flow.core.ez_token_transfers
WHERE
block_timestamp > current_date - 90
AND
tx_succeeded = 'TRUE'
AND
recipient IN (SELECT sender FROM dep_addys)
GROUP BY
user_address, token_contract
),
wdraws AS (
SELECT
recipient AS user_address,
token_contract AS token_contract,
count(tx_id) AS n_withdrawals,
sum(amount) AS token_withdrawal_volume
FROM
flow.core.ez_token_transfers
WHERE
block_timestamp > current_date - 90
AND
tx_succeeded = 'TRUE'
AND
sender IN (SELECT address FROM FLIPSIDE_PROD_DB.CROSSCHAIN.ADDRESS_LABELS WHERE blockchain = 'flow' AND label_type = 'cex' AND label_subtype = 'hot_wallet')
GROUP BY
user_address, token_contract
)
SELECT
COALESCE(ds.user_address, ws.user_address) AS user_address,
COALESCE(ds.token_contract, ws.token_contract) AS token_contract,
COALESCE(n_deposits, 0) AS n_deposits,
COALESCE(token_deposit_volume, 0) AS token_deposit_volume,
COALESCE(n_withdrawals, 0) AS n_withdrawals,
COALESCE(token_withdrawal_volume, 0) AS token_withdrawal_volume
FROM deps ds
FULL OUTER JOIN wdraws ws ON ds.user_address = ws.user_address
AND ds.token_contract = ws.token_contract

View File

@ -0,0 +1,43 @@
-- n sells / amount / protocol / token
WITH sells AS (
SELECT
trader AS user_address,
swap_contract,
token_out_contract AS token_contract,
count(tx_id) AS n_sells,
sum(token_out_amount) AS token_sell_volume
FROM
flow.core.ez_dex_swaps
WHERE
block_timestamp > current_date - 90
GROUP BY
trader, swap_contract, token_out_contract
),
buys AS (
SELECT
trader AS user_address,
swap_contract,
token_in_contract AS token_contract,
count(tx_id) AS n_buys,
sum(token_in_amount) AS token_buy_volume
FROM
flow.core.ez_dex_swaps
WHERE
block_timestamp > current_date - 90
GROUP BY
trader, swap_contract, token_in_contract
)
SELECT
COALESCE(sells.user_address, buys.user_address) AS user_address,
COALESCE(sells.swap_contract, buys.swap_contract) AS swap_contract,
COALESCE(sells.token_contract, buys.token_contract) AS token_contract,
COALESCE(n_buys, 0) AS n_buys,
COALESCE(token_buy_volume, 0) AS token_buy_volume,
COALESCE(n_sells, 0) AS n_sells,
COALESCE(token_sell_volume, 0) AS token_sell_volume
FROM sells
FULL OUTER JOIN buys ON sells.user_address = buys.user_address
AND sells.swap_contract = buys.swap_contract
AND sells.token_contract = buys.token_contract

BIN
sql/nfts/.DS_Store vendored Normal file

Binary file not shown.

View File

@ -0,0 +1,46 @@
WITH sells AS (
SELECT
seller AS user_address,
marketplace,
nft_collection AS nf_token_contract,
count(tx_id) AS n_sells,
sum(price) AS token_sell_volume,
currency
FROM
flow.core.ez_nft_sales
WHERE
block_timestamp > current_date - 90
GROUP BY
seller, marketplace, nf_token_contract, currency
),
buys AS (
SELECT
buyer AS user_address,
marketplace,
nft_collection AS nf_token_contract,
count(tx_id) AS n_buys,
sum(price) AS token_buy_volume,
currency
FROM
flow.core.ez_nft_sales
WHERE
block_timestamp > current_date - 90
GROUP BY
buyer, marketplace, nf_token_contract, currency
)
SELECT
COALESCE(sells.user_address, buys.user_address) AS user_address,
COALESCE(sells.marketplace, buys.marketplace) AS marketplace,
COALESCE(sells.nf_token_contract, buys.nf_token_contract) AS nf_token_contract,
COALESCE(sells.currency, buys.currency) AS currency,
COALESCE(n_buys, 0) AS n_buys,
COALESCE(token_buy_volume, 0) AS token_buy_volume,
COALESCE(n_sells, 0) AS n_sells,
COALESCE(token_sell_volume, 0) AS token_sell_volume
FROM sells
FULL OUTER JOIN buys ON sells.user_address = buys.user_address
AND sells.marketplace = buys.marketplace
AND sells.nf_token_contract = buys.nf_token_contract
AND sells.currency = buys.currency

13
user_metrics.Rproj Normal file
View File

@ -0,0 +1,13 @@
Version: 1.0
RestoreWorkspace: Default
SaveWorkspace: Default
AlwaysSaveHistory: Default
EnableCodeIndexing: Yes
UseSpacesForTab: Yes
NumSpacesForTab: 2
Encoding: UTF-8
RnwWeave: Sweave
LaTeX: pdfLaTeX