-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathqueries.sql
315 lines (266 loc) · 10 KB
/
queries.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
/*
* Data exploration queries for NFT transactions
*/
/* Count queries */
SELECT count(*) FROM assets
SELECT count(*) FROM collections
SELECT count(*) FROM accounts
SELECT count(*), MIN(time) AS min_date, MAX(time) AS max_date FROM nft_sales
/* Payment symbols */
SELECT payment_symbol, count(*) FROM nft_sales
GROUP BY payment_symbol
ORDER BY count(*) DESC
/* Assets most often sold in the past 2 weeks*/
SELECT count(*) AS volume, a.name AS nft, a.url, c.name AS collection FROM nft_sales s
INNER JOIN assets a ON a.id = s.asset_id
INNER JOIN collections c ON c.id = s.collection_id
WHERE time > NOW() - INTERVAL '2 weeks'
GROUP BY s.asset_id , a.name, a.url, c.name
ORDER BY volume DESC
LIMIT 10
/* Time-series chart: total daily ETH volume of a given collection */
SELECT
time_bucket('1 day', time) AS bucket,
count(*) AS total_volume,
sum(total_price) total_volume_eth,
count(DISTINCT asset_id) AS count_nfts
FROM nft_sales s
INNER JOIN collections c ON c.id = s.collection_id
WHERE payment_symbol = 'ETH' AND c.name = 'CryptoKitties'
GROUP BY bucket
ORDER BY bucket DESC
/* Most often traded collections in the past month*/
SELECT c.name AS collection, count(*) AS sale_count, count(DISTINCT asset_id) AS nft_count
FROM nft_sales s
INNER JOIN collections c ON c.id = collection_id
WHERE time > NOW() - INTERVAL '1 month'
GROUP BY collection_id, c.name
ORDER BY sale_count DESC
LIMIT 5
/* Time-series chart: total daily ETH volume of the most traded collections */
WITH most_traded_collections AS (
SELECT collection_id
FROM nft_sales s
GROUP BY collection_id
ORDER BY count(*) DESC
LIMIT 5
)
SELECT
time_bucket('1 day', time) AS bucket,
c.name AS collection, c.url AS collection_url,
count(*) AS trade_count,
sum(total_price) total_volume_eth,
count(DISTINCT asset_id) AS count_nfts
FROM nft_sales s
INNER JOIN collections c ON c.id = s.collection_id
WHERE collection_id IN (SELECT * FROM most_traded_collections) AND time > NOW() - INTERVAL '1 month'
GROUP BY bucket, c.name, c.url
ORDER BY bucket DESC
/* Time-series: Average volume per 15min */
WITH buckets AS (
SELECT time_bucket('15 min', time) AS bucket, count(*) AS volume FROM nft_sales
WHERE time > NOW() - INTERVAL '1 month'
GROUP BY bucket
)
SELECT bucket, volume FROM buckets
ORDER BY bucket
/* Time-series: amount of sales weekly in the past 3 months */
SELECT time_bucket('1 week', time) AS bucket, count(*) AS volume FROM nft_sales
WHERE time > NOW() - INTERVAL '3 month'
GROUP BY bucket
ORDER BY bucket DESC
/* Most expensive asset sold per week in the last month */
SELECT time_bucket('1 week', time) AS bucket, MAX(total_price) AS price_paid,
LAST(a.id , total_price) AS asset_name, LAST(a.url, total_price) AS url
FROM nft_sales s
INNER JOIN assets a ON a.id = s.asset_id
WHERE time > NOW() - INTERVAL '1 month' AND payment_symbol = 'ETH'
GROUP BY bucket
ORDER BY bucket DESC
/*Time-series: daily price of the most traded asset in the past <time-period> */
WITH highest_volume_asset AS (
SELECT asset_id FROM nft_sales
WHERE time > NOW() - INTERVAL '1 month'
GROUP BY asset_id
ORDER BY count(*) DESC
LIMIT 1
)
SELECT a.name AS nft, a.url AS nft_url, time_bucket('1 day', time) AS bucket, LAST(total_price, time) price
FROM nft_sales s
INNER JOIN assets a ON a.id = s.asset_id
WHERE asset_id = (SELECT asset_id FROM highest_volume_asset) AND time > NOW() - INTERVAL '1 month' AND payment_symbol = 'ETH'
GROUP BY bucket, a.name, a.url
ORDER BY bucket DESC
/* Daily total volume of the 5 top buyers */
WITH top_five_buyers AS (
SELECT winner_account FROM nft_sales
GROUP BY winner_account
ORDER BY count(*) DESC
LIMIT 5
)
SELECT time_bucket('1 day', time) AS bucket, count(*) AS total_volume FROM nft_sales
WHERE winner_account IN (SELECT winner_account FROM top_five_buyers)
GROUP BY bucket
ORDER BY bucket DESC
/* Collection continuous aggregates */
CREATE MATERIALIZED VIEW collections_daily
WITH (timescaledb.continuous) AS
SELECT
collection_id,
time_bucket('1 day', time) AS bucket,
mean(percentile_agg(total_price)) AS mean_price,
approx_percentile(0.5, percentile_agg(total_price)) AS median_price,
COUNT(*) AS volume,
SUM(total_price) AS volume_eth,
LAST(asset_id, total_price) AS most_expensive_nft_id,
MAX(total_price) AS max_price
FROM nft_sales
GROUP BY bucket, collection_id;
SELECT add_continuous_aggregate_policy('collections_daily',
start_offset => INTERVAL '2 days',
end_offset => INTERVAL '1 day',
schedule_interval => INTERVAL '1 day');
/* Asset continuous aggregates */
CREATE MATERIALIZED VIEW assets_daily
WITH (timescaledb.continuous) AS
SELECT time_bucket('1 day', time) AS bucket,
asset_id,
collection_id,
mean(percentile_agg(total_price)) AS mean_price,
approx_percentile(0.5, percentile_agg(total_price)) AS median_price,
COUNT(*) AS volume,
SUM(total_price) AS volume_eth,
FIRST(total_price, time) AS open_price,
MAX(total_price) AS high_price,
MIN(total_price) AS low_price,
LAST(total_price, time) AS close_price
FROM nft_sales
WHERE payment_symbol = 'ETH'
GROUP BY bucket, asset_id, collection_id
HAVING COUNT(*) > 1
SELECT add_continuous_aggregate_policy('assets_daily',
start_offset => NULL,
end_offset => INTERVAL '1 day',
schedule_interval => INTERVAL '1 day');
/* Collections with the highest volume? */
SELECT
slug,
SUM(volume) total_volume,
SUM(volume_eth) total_volume_eth
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
GROUP BY cagg.collection_id, slug
ORDER BY total_volume DESC;
/* Daily number of “CryptoKitties” NFT transactions? */
SELECT bucket, slug, volume
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
WHERE slug = 'cryptokitties'
ORDER BY bucket DESC
/* Daily number of NFT transactions, "CryptoKitties" vs Ape Gang from past 3 months? */
SELECT bucket, slug, volume
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
WHERE slug IN ('cryptokitties', 'ape-gang') AND bucket > NOW() - INTERVAL '3 month'
ORDER BY bucket DESC, slug;
/* Daily ETH volume of CryptoKitties NFT transactions? */
SELECT bucket, slug, volume_eth
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
WHERE slug = 'cryptokitties'
ORDER BY bucket DESC
/* Daily ETH volume of NFT transactions: CryptoKitties vs Ape Gang? */
SELECT bucket, slug, volume_eth
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
WHERE slug IN ('cryptokitties', 'ape-gang') AND bucket > NOW() - INTERVAL '3 month'
ORDER BY bucket, slug DESC;
/* Mean vs median sale price of CryptoKitties? */
SELECT bucket, slug, mean_price, median_price
FROM collections_daily cagg
INNER JOIN collections c ON cagg.collection_id = c.id
WHERE slug = 'cryptokitties'
ORDER BY bucket DESC
/* Get the image URLs of the 5 most expensive NFTs sold in the past 3 months */
SELECT url, total_price, details->>'image_url' AS image_url FROM nft_sales
INNER JOIN assets a ON a.id = nft_sales.asset_id
WHERE payment_symbol = 'ETH' AND time > NOW() - INTERVAL '3 month'
ORDER BY total_price DESC
LIMIT 5
/* Calculating 15-min mean and median sale prices of highest trade count NFT on 2021-10-17 */
WITH one_day AS (
SELECT time, asset_id, total_price FROM nft_sales
WHERE time BETWEEN '2021-10-06 00:00:00' AND '2021-10-06 23:59:59' AND payment_symbol = 'ETH'
)
SELECT time_bucket('30 min', time) AS bucket,
assets.name AS nft,
mean(percentile_agg(total_price)) AS mean_price,
approx_percentile(0.5, percentile_agg(total_price)) AS median_price
FROM one_day
INNER JOIN assets ON assets.id = one_day.asset_id
WHERE asset_id = (SELECT asset_id FROM one_day GROUP BY asset_id ORDER BY count(*) DESC LIMIT 1)
GROUP BY bucket, nft
ORDER BY DESC
/* Weekly OHLCV per asset */
SELECT time_bucket('7 day', time) AS bucket, asset_id,
FIRST(total_price, time) AS open_price, LAST(total_price, time) AS close_price,
MIN(total_price) AS low_price, MAX(total_price) AS high_price,
count(*) AS volume
FROM nft_sales
WHERE payment_symbol = 'ETH'
GROUP BY bucket, asset_id
HAVING count(*) > 100
ORDER BY bucket
/* Daily OHLCV per asset */
SELECT time_bucket('1 day', time) AS bucket, asset_id,
FIRST(total_price, time) AS open_price, LAST(total_price, time) AS close_price,
MIN(total_price) AS low_price, MAX(total_price) AS high_price,
count(*) AS volume
FROM nft_sales
WHERE payment_symbol = 'ETH'
GROUP BY bucket, asset_id
HAVING count(*) > 100
ORDER BY bucket
/* Daily assets sorted by biggest intraday price change in the last 6 month*/
SELECT time_bucket('1 day', time) AS bucket, a.name AS nft, a.url,
FIRST(total_price, time) AS open_price, LAST(total_price, time) AS close_price,
MAX(total_price)-MIN(total_price) AS intraday_max_change
FROM nft_sales s
INNER JOIN assets a ON a.id = s.asset_id
WHERE payment_symbol = 'ETH' AND time > NOW() - INTERVAL '6 month'
GROUP BY bucket, asset_id, a.name, a.url
ORDER BY intraday_max_change DESC
LIMIT 5
SELECT bucket, nft, url,
open_price, close_price,
intraday_max_change
FROM top_assets ta
INNER JOIN LATERAL (
SELECT name AS nft, url FROM assets a
WHERE a.id = ta.asset_id
) assets ON TRUE;
/* Snoop Dogg's transactions in the past 3 months aggregated */
WITH snoop_dogg AS (
SELECT id FROM accounts
WHERE address = '0xce90a7949bb78892f159f428d0dc23a8e3584d75'
)
SELECT
COUNT(*) AS trade_count,
COUNT(DISTINCT asset_id) AS nft_count,
COUNT(DISTINCT collection_id) AS collection_count,
COUNT(*) FILTER (WHERE seller_account = (SELECT id FROM snoop_dogg)) AS sale_count,
COUNT(*) FILTER (WHERE winner_account = (SELECT id FROM snoop_dogg)) AS buy_count,
SUM(total_price) AS total_volume_eth,
AVG(total_price) AS avg_price,
MIN(total_price) AS min_price,
MAX(total_price) AS max_price
FROM nft_sales
WHERE payment_symbol = 'ETH' AND ( seller_account = (SELECT id FROM snoop_dogg) OR winner_account = (SELECT id FROM snoop_dogg) )
AND time > NOW()-INTERVAL '3 months'
/* Top 5 most expensive NFTs in the CryptoKitties collection */
SELECT a.name AS nft, total_price, time, a.url FROM nft_sales s
INNER JOIN collections c ON c.id = s.collection_id
INNER JOIN assets a ON a.id = s.asset_id
WHERE slug = 'cryptokitties' AND payment_symbol = 'ETH'
ORDER BY total_price DESC
LIMIT 5