├── ethereum ├── ether-supply-by-day.png ├── ether-supply-by-day.sql ├── shortest-path-via-traces.sql └── unique-addresses-by-day.sql ├── band ├── log-types-by-transaction.sql └── latest-prices.sql ├── bitcoin ├── top-bitcoin-balances.sql └── gini-index-by-day.sql ├── LICENSE ├── zilliqa └── shortest-path-via-traces-v2.sql └── README.md /ethereum/ether-supply-by-day.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/blockchain-etl/awesome-bigquery-views/HEAD/ethereum/ether-supply-by-day.png -------------------------------------------------------------------------------- /band/log-types-by-transaction.sql: -------------------------------------------------------------------------------- 1 | #standardSQL 2 | SELECT type, count(*) AS count 3 | FROM `public-data-finance.crypto_band.logs`, UNNEST(events) 4 | GROUP BY type 5 | ORDER BY count DESC 6 | -------------------------------------------------------------------------------- /ethereum/ether-supply-by-day.sql: -------------------------------------------------------------------------------- 1 | WITH ether_emitted_by_date AS ( 2 | SELECT date(block_timestamp) AS date, SUM(value) AS value 3 | FROM `bigquery-public-data.crypto_ethereum.traces` 4 | WHERE trace_type IN ('genesis', 'reward') 5 | GROUP BY DATE(block_timestamp) 6 | ) 7 | SELECT date, SUM(value) OVER (ORDER BY date) / POWER(10, 18) AS supply 8 | FROM ether_emitted_by_date 9 | -------------------------------------------------------------------------------- /bitcoin/top-bitcoin-balances.sql: -------------------------------------------------------------------------------- 1 | WITH double_entry_book AS ( 2 | -- debits 3 | SELECT array_to_string(inputs.addresses, ",") AS address, inputs.type, -inputs.value AS value 4 | FROM `bigquery-public-data.crypto_bitcoin.inputs` AS inputs 5 | UNION ALL 6 | -- credits 7 | SELECT array_to_string(outputs.addresses, ",") AS address, outputs.type, outputs.value AS value 8 | FROM `bigquery-public-data.crypto_bitcoin.outputs` AS outputs 9 | ) 10 | SELECT address, type, sum(value) AS balance 11 | FROM double_entry_book 12 | GROUP BY address, type 13 | ORDER BY balance DESC 14 | LIMIT 1000 15 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2019 Blockchain ETL 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /band/latest-prices.sql: -------------------------------------------------------------------------------- 1 | #standardSQL 2 | -- parse requests for Aggregator script (oracle_script_id = 3) 3 | WITH parsed_aggregator_oracle_requests AS ( 4 | SELECT ARRAY( 5 | SELECT JSON_EXTRACT_SCALAR(symbol_as_json, '$') 6 | FROM UNNEST(JSON_EXTRACT_ARRAY(decoded_result.calldata, "$.symbols")) AS symbol_as_json 7 | ) AS symbols, 8 | CAST(JSON_EXTRACT_SCALAR(decoded_result.calldata, "$.multiplier") AS FLOAT64) AS multiplier, 9 | ARRAY( 10 | SELECT CAST(JSON_EXTRACT_SCALAR(rate_as_json, '$') AS FLOAT64) 11 | FROM UNNEST(JSON_EXTRACT_ARRAY(decoded_result.result, "$.rates")) AS rate_as_json 12 | ) AS rates, 13 | block_timestamp, 14 | oracle_request_id, 15 | FROM `public-data-finance.crypto_band.oracle_requests` 16 | WHERE request.oracle_script_id = 3 17 | AND decoded_result.calldata IS NOT NULL 18 | AND decoded_result.result IS NOT NULL 19 | ), 20 | -- zip symbols and rates 21 | zipped_rates AS ( 22 | SELECT block_timestamp, 23 | oracle_request_id, 24 | struct(symbol, rates[OFFSET(off)] AS rate) AS zipped, 25 | multiplier, 26 | FROM parsed_aggregator_oracle_requests, 27 | UNNEST(symbols) AS symbol WITH OFFSET off 28 | WHERE ARRAY_LENGTH(symbols) = ARRAY_LENGTH(rates) 29 | ), 30 | -- adjust for multiplier 31 | adjusted_rates AS ( 32 | SELECT 33 | block_timestamp, 34 | oracle_request_id, 35 | struct(zipped.symbol, IEEE_DIVIDE(zipped.rate, multiplier) AS rate) AS zipped, 36 | FROM zipped_rates 37 | ) 38 | SELECT 39 | block_timestamp, 40 | oracle_request_id, 41 | zipped.symbol, 42 | zipped.rate, 43 | FROM adjusted_rates 44 | --WHERE zipped.symbol = 'ETH' 45 | ORDER BY block_timestamp DESC 46 | LIMIT 1000 47 | -------------------------------------------------------------------------------- /ethereum/shortest-path-via-traces.sql: -------------------------------------------------------------------------------- 1 | # This query will fail if there are too many traces. 2 | # There is a workaround here: 3 | # https://console.cloud.google.com/bigquery?sq=749871510730:082d50190dc04d79aaf7ee4d5c6f9d00 4 | 5 | DECLARE start_address STRING DEFAULT LOWER('0x47068105c5feff69e44520b251b9666d4b512a70'); 6 | DECLARE end_address STRING DEFAULT LOWER('0x2604afb5a64992e5abbf25865c9d3387ade92bad'); 7 | 8 | WITH traces_0 AS ( 9 | SELECT * 10 | FROM `bigquery-public-data.crypto_ethereum.traces` 11 | WHERE from_address = start_address 12 | ), 13 | traces_1_hop AS ( 14 | SELECT 15 | 1 AS hops, 16 | traces_1.from_address, 17 | traces_1.to_address, 18 | traces_1.trace_address, 19 | traces_1.block_timestamp, 20 | concat(traces_0.from_address, ' -> ', traces_0.to_address, ' -> ', traces_1.to_address) as path 21 | FROM `bigquery-public-data.crypto_ethereum.traces` AS traces_1 22 | INNER JOIN traces_0 23 | ON traces_0.to_address = traces_1.from_address 24 | AND traces_0.block_timestamp <= traces_1.block_timestamp 25 | ), 26 | traces_2_hops AS ( 27 | SELECT 28 | 2 AS hops, 29 | traces_2.from_address, 30 | traces_2.to_address, 31 | traces_2.trace_address, 32 | traces_2.block_timestamp, 33 | concat(path, ' -> ', traces_2.to_address) AS path 34 | FROM `bigquery-public-data.crypto_ethereum.traces` AS traces_2 35 | INNER JOIN traces_1_hop 36 | ON traces_1_hop.to_address = traces_2.from_address 37 | AND traces_1_hop.block_timestamp <= traces_2.block_timestamp 38 | ), 39 | traces_3_hops AS ( 40 | SELECT 41 | 3 AS hops, 42 | traces_3.from_address, 43 | traces_3.to_address, 44 | traces_3.trace_address, 45 | traces_2_hops.block_timestamp, 46 | concat(path, ' -> ', traces_3.to_address) AS path 47 | FROM `bigquery-public-data.crypto_ethereum.traces` AS traces_3 48 | INNER JOIN traces_2_hops 49 | ON traces_2_hops.to_address = traces_3.from_address 50 | AND traces_2_hops.block_timestamp <= traces_3.block_timestamp 51 | WHERE traces_3.to_address = end_address 52 | ), 53 | traces_all_hops AS ( 54 | SELECT * FROM traces_1_hop 55 | UNION ALL 56 | SELECT * FROM traces_2_hops 57 | UNION ALL 58 | SELECT * FROM traces_3_hops 59 | ) 60 | SELECT * 61 | FROM traces_all_hops 62 | WHERE hops = 3 63 | LIMIT 100 64 | -------------------------------------------------------------------------------- /bitcoin/gini-index-by-day.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | double_entry_book AS ( 3 | SELECT 4 | ARRAY_TO_STRING(outputs.addresses,',') AS address, 5 | value, block_timestamp 6 | FROM `bigquery-public-data.crypto_bitcoin.transactions` JOIN UNNEST(outputs) AS outputs 7 | UNION ALL 8 | SELECT 9 | ARRAY_TO_STRING(inputs.addresses,',') AS address, 10 | -value AS value, block_timestamp 11 | FROM `bigquery-public-data.crypto_bitcoin.transactions` JOIN UNNEST(inputs) AS inputs 12 | ), 13 | double_entry_book_by_date AS ( 14 | SELECT 15 | DATE(block_timestamp) AS date, 16 | address, 17 | SUM(value * 0.00000001) AS value 18 | FROM double_entry_book 19 | GROUP BY address, date 20 | ), 21 | daily_balances_with_gaps AS ( 22 | SELECT 23 | address, 24 | date, 25 | SUM(value) OVER (PARTITION BY address ORDER BY date) AS balance, 26 | LEAD(date, 1, CURRENT_DATE()) OVER (PARTITION BY address ORDER BY date) AS next_date 27 | FROM double_entry_book_by_date 28 | ), 29 | calendar as ( 30 | SELECT date FROM UNNEST(GENERATE_DATE_ARRAY('2009-01-03', CURRENT_DATE())) AS date 31 | ), 32 | daily_balances AS ( 33 | SELECT address, calendar.date, balance 34 | FROM daily_balances_with_gaps 35 | JOIN calendar ON daily_balances_with_gaps.date <= calendar.date AND calendar.date < daily_balances_with_gaps.next_date 36 | WHERE balance > 1 37 | ), 38 | address_counts AS ( 39 | SELECT 40 | date, 41 | count(*) AS address_count 42 | FROM 43 | daily_balances 44 | GROUP BY date 45 | ), 46 | daily_balances_sampled AS ( 47 | SELECT address, daily_balances.date, balance 48 | FROM daily_balances 49 | JOIN address_counts ON daily_balances.date = address_counts.date 50 | WHERE MOD(ABS(FARM_FINGERPRINT(address)), 100000000)/100000000 <= SAFE_DIVIDE(10000, address_count) 51 | ), 52 | ranked_daily_balances AS ( 53 | SELECT 54 | date, 55 | balance, 56 | ROW_NUMBER() OVER (PARTITION BY date ORDER BY balance DESC) AS rank 57 | FROM daily_balances_sampled 58 | ) 59 | SELECT 60 | date, 61 | -- (1 − 2B) https://en.wikipedia.org/wiki/Gini_coefficient 62 | 1 - 2 * SUM((balance * (rank - 1) + balance / 2)) / COUNT(*) / SUM(balance) AS gini 63 | FROM ranked_daily_balances 64 | GROUP BY date 65 | HAVING SUM(balance) > 0 66 | ORDER BY date ASC 67 | -------------------------------------------------------------------------------- /ethereum/unique-addresses-by-day.sql: -------------------------------------------------------------------------------- 1 | WITH double_entry_book AS ( 2 | -- debits 3 | SELECT to_address AS address, value AS value, block_timestamp 4 | FROM `bigquery-public-data.crypto_ethereum.traces` 5 | WHERE to_address IS NOT NULL 6 | AND status = 1 7 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 8 | UNION ALL 9 | -- credits 10 | SELECT FROM_address AS address, -value AS value, block_timestamp 11 | FROM `bigquery-public-data.crypto_ethereum.traces` 12 | WHERE FROM_address IS NOT NULL 13 | AND status = 1 14 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 15 | UNION ALL 16 | -- transaction fees debits 17 | SELECT 18 | miner AS address, 19 | SUM(CAST(receipt_gas_used AS numeric) * CAST((receipt_effective_gas_price - COALESCE(base_fee_per_gas, 0)) AS numeric)) AS value, 20 | block_timestamp 21 | FROM `bigquery-public-data.crypto_ethereum.transactions` AS transactions 22 | JOIN `bigquery-public-data.crypto_ethereum.blocks` AS blocks ON blocks.number = transactions.block_number 23 | GROUP BY blocks.miner, block_timestamp 24 | UNION ALL 25 | -- transaction fees credits 26 | SELECT 27 | FROM_address AS address, 28 | -(CAST(receipt_gas_used AS numeric) * CAST(receipt_effective_gas_price AS numeric)) AS value, 29 | block_timestamp 30 | FROM `bigquery-public-data.crypto_ethereum.transactions` 31 | ), 32 | double_entry_book_grouped_by_date AS ( 33 | SELECT address, SUM(value) AS balance_increment, DATE(block_timestamp) AS date 34 | FROM double_entry_book 35 | GROUP BY address, date 36 | ), 37 | daily_balances_WITH_gaps AS ( 38 | SELECT address, date, SUM(balance_increment) OVER (PARTITION BY address ORDER BY date) AS balance, 39 | LEAD(date, 1, CURRENT_DATE()) over (PARTITION BY address ORDER BY date) AS next_date 40 | FROM double_entry_book_grouped_by_date 41 | ), 42 | calendar AS ( 43 | SELECT date FROM UNNEST(GENERATE_DATE_ARRAY('2015-07-30', CURRENT_DATE())) AS date 44 | ), 45 | daily_balances AS ( 46 | SELECT address, calendar.date, balance 47 | FROM daily_balances_WITH_gaps 48 | JOIN calendar ON daily_balances_WITH_gaps.date <= calendar.date AND calendar.date < daily_balances_with_gaps.next_date 49 | ) 50 | SELECT date, COUNT(*) AS address_count 51 | FROM daily_balances 52 | WHERE balance > 0 53 | GROUP BY date 54 | -------------------------------------------------------------------------------- /zilliqa/shortest-path-via-traces-v2.sql: -------------------------------------------------------------------------------- 1 | #standardSQL 2 | DECLARE start_address STRING DEFAULT 'zil1jrpjd8pjuv50cfkfr7eu6yrm3rn5u8rulqhqpz'; 3 | DECLARE end_address STRING DEFAULT 'zil19nmxkh020jnequql9kvqkf3pkwm0j0spqtd26e'; 4 | -- Addresses with the number of outgoing transactions exceeding this parameter are excluded from shortest path calculation. 5 | -- For most types of analyses it's not an encumbering limitation as addresses with high fan out are usually exchanges. 6 | -- If the query takes too long too finish try reducing this parameter. 7 | DECLARE max_fan_out INT64 DEFAULT 50; 8 | 9 | WITH all_transactions AS ( 10 | SELECT id AS transaction_id, block_number, block_timestamp, sender AS from_address, to_addr AS to_address 11 | FROM `public-data-finance.crypto_zilliqa.transactions` 12 | UNION ALL 13 | SELECT transaction_id, block_number, block_timestamp, addr AS from_addr, recipient AS to_addr 14 | FROM `public-data-finance.crypto_zilliqa.transitions` 15 | ), 16 | addresses_with_high_fan_out AS ( 17 | SELECT from_address AS address 18 | FROM all_transactions 19 | GROUP BY from_address 20 | HAVING COUNT(*) > max_fan_out 21 | ), 22 | transactions_0_hops AS ( 23 | SELECT 24 | 0 AS hops, 25 | transactions.from_address, 26 | transactions.to_address, 27 | transactions.block_timestamp, 28 | CONCAT(transactions.from_address, ' --(tx ', SUBSTR(transactions.transaction_id, 0, 5), '..)--> ', transactions.to_address) AS path 29 | FROM all_transactions AS transactions 30 | WHERE transactions.from_address = start_address 31 | ), 32 | transactions_1_hops AS ( 33 | SELECT 34 | 1 AS hops, 35 | transactions.from_address, 36 | transactions.to_address, 37 | transactions.block_timestamp, 38 | CONCAT(path, ' --(tx ', SUBSTR(transactions.transaction_id, 0, 5), '..)--> ', transactions.to_address) AS path 39 | FROM all_transactions AS transactions 40 | INNER JOIN transactions_0_hops ON transactions_0_hops.to_address = transactions.from_address 41 | AND transactions_0_hops.block_timestamp <= transactions.block_timestamp 42 | LEFT JOIN addresses_with_high_fan_out 43 | ON addresses_with_high_fan_out.address = transactions.from_address 44 | WHERE addresses_with_high_fan_out.address IS NULL 45 | ), 46 | transactions_2_hops AS ( 47 | SELECT 48 | 2 AS hops, 49 | transactions.from_address, 50 | transactions.to_address, 51 | transactions.block_timestamp, 52 | CONCAT(path, ' --(tx ', SUBSTR(transactions.transaction_id, 0, 5), '..)--> ', transactions.to_address) AS path 53 | FROM all_transactions AS transactions 54 | INNER JOIN transactions_1_hops 55 | ON transactions_1_hops.to_address = transactions.from_address 56 | AND transactions_1_hops.block_timestamp <= transactions.block_timestamp 57 | LEFT JOIN addresses_with_high_fan_out ON addresses_with_high_fan_out.address = transactions.from_address 58 | WHERE addresses_with_high_fan_out.address IS NULL 59 | ), 60 | transactions_3_hops AS ( 61 | SELECT 62 | 3 AS hops, 63 | transactions.from_address, 64 | transactions.to_address, 65 | transactions.block_timestamp, 66 | CONCAT(path, ' --(tx ', SUBSTR(transactions.transaction_id, 0, 5), '..)--> ', transactions.to_address) AS path 67 | FROM all_transactions AS transactions 68 | INNER JOIN transactions_2_hops ON transactions_2_hops.to_address = transactions.from_address 69 | AND transactions_2_hops.block_timestamp <= transactions.block_timestamp 70 | LEFT JOIN addresses_with_high_fan_out 71 | ON addresses_with_high_fan_out.address = transactions.from_address 72 | WHERE addresses_with_high_fan_out.address IS NULL 73 | ), 74 | transactions_all_hops AS ( 75 | SELECT * FROM transactions_0_hops WHERE to_address = end_address 76 | UNION ALL 77 | SELECT * FROM transactions_1_hops WHERE to_address = end_address 78 | UNION ALL 79 | SELECT * FROM transactions_2_hops WHERE to_address = end_address 80 | UNION ALL 81 | SELECT * FROM transactions_3_hops WHERE to_address = end_address 82 | ) 83 | SELECT 84 | hops, 85 | path 86 | FROM transactions_all_hops 87 | ORDER BY hops ASC 88 | LIMIT 1000 89 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Awesome BigQuery Views 2 | 3 | Here are some examples of how to derive insights from on-chain crypto data. Not all networks have examples here - you can find the complete list of crypto datasets in [blockchain-etl/public-datasets](https://github.com/blockchain-etl/public-datasets) 4 | 5 | ## Top Ethereum Balances 6 | 7 | ```sql 8 | WITH double_entry_book AS ( 9 | -- debits 10 | SELECT to_address AS address, value AS value 11 | FROM `bigquery-public-data.crypto_ethereum.traces` 12 | WHERE to_address IS NOT NULL 13 | AND status = 1 14 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 15 | UNION ALL 16 | -- credits 17 | SELECT from_address AS address, -value AS value 18 | FROM `bigquery-public-data.crypto_ethereum.traces` 19 | WHERE from_address IS NOT NULL 20 | AND status = 1 21 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 22 | UNION ALL 23 | -- transaction fees debits 24 | SELECT 25 | miner AS address, 26 | SUM(CAST(receipt_gas_used AS numeric) * CAST((receipt_effective_gas_price - COALESCE(base_fee_per_gas, 0)) as numeric)) AS value 27 | FROM `bigquery-public-data.crypto_ethereum.transactions` AS transactions 28 | join `bigquery-public-data.crypto_ethereum.blocks` AS blocks ON blocks.number = transactions.block_number 29 | GROUP BY blocks.number, blocks.miner 30 | UNION ALL 31 | -- transaction fees credits 32 | SELECT 33 | from_address AS address, 34 | -(CAST(receipt_gas_used AS numeric) * CAST(receipt_effective_gas_price AS numeric)) AS value 35 | FROM `bigquery-public-data.crypto_ethereum.transactions` 36 | ) 37 | SELECT address, SUM(value) AS balance 38 | FROM double_entry_book 39 | GROUP BY address 40 | ORDER BY balance DESC 41 | LIMIT 1000 42 | ``` 43 | 44 | Alternatively query `bigquery-public-data.crypto_ethereum.balances` (updated daily), e.g.: 45 | 46 | ```sql 47 | SELECT * 48 | FROM `bigquery-public-data.crypto_ethereum.balances` 49 | WHERE SEARCH(address, '0x0cfb686e114d478b055ce8614621f8bb62f70360', analyzer=>'NO_OP_ANALYZER'); 50 | ``` 51 | 52 | ## Every Ethereum Balance on Every Day 53 | 54 | ```sql 55 | WITH double_entry_book AS ( 56 | -- debits 57 | SELECT to_address AS address, value AS value, block_timestamp 58 | FROM `bigquery-public-data.crypto_ethereum.traces` 59 | WHERE to_address IS NOT NULL 60 | AND status = 1 61 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 62 | UNION ALL 63 | -- credits 64 | SELECT from_address AS address, -value AS value, block_timestamp 65 | FROM `bigquery-public-data.crypto_ethereum.traces` 66 | WHERE from_address IS NOT NULL 67 | AND status = 1 68 | AND (call_type NOT IN ('delegatecall', 'callcode', 'staticcall') OR call_type IS NULL) 69 | UNION ALL 70 | -- transaction fees debits 71 | SELECT 72 | miner AS address, 73 | SUM(CAST(receipt_gas_used AS numeric) * CAST((receipt_effective_gas_price - COALESCE(base_fee_per_gas, 0)) AS numeric)) AS value, 74 | block_timestamp 75 | FROM `bigquery-public-data.crypto_ethereum.transactions` AS transactions 76 | JOIN `bigquery-public-data.crypto_ethereum.blocks` AS blocks ON blocks.number = transactions.block_number 77 | GROUP BY blocks.number, blocks.miner, block_timestamp 78 | UNION ALL 79 | -- transaction fees credits 80 | SELECT 81 | from_address AS address, 82 | -(CAST(receipt_gas_used AS numeric) * CAST(receipt_effective_gas_price AS numeric)) AS value, 83 | block_timestamp 84 | FROM `bigquery-public-data.crypto_ethereum.transactions` 85 | ), 86 | double_entry_book_grouped_by_date AS ( 87 | SELECT address, SUM(value) AS balance_increment, DATE(block_timestamp) AS date 88 | FROM double_entry_book 89 | GROUP BY address, date 90 | ), 91 | daily_balances_with_gaps AS ( 92 | SELECT address, date, SUM(balance_increment) OVER (PARTITION BY address ORDER BY date) AS balance, 93 | LEAD(date, 1, CURRENT_DATE()) OVER (PARTITION BY address ORDER BY date) AS next_date 94 | FROM double_entry_book_grouped_by_date 95 | ), 96 | calendar AS ( 97 | SELECT date FROM UNNEST(GENERATE_DATE_ARRAY('2015-07-30', CURRENT_DATE())) AS date 98 | ), 99 | daily_balances AS ( 100 | SELECT address, calendar.date, balance 101 | FROM daily_balances_with_gaps 102 | JOIN calendar ON daily_balances_with_gaps.date <= calendar.date AND calendar.date < daily_balances_with_gaps.next_date 103 | ) 104 | SELECT address, date, balance 105 | FROM daily_balances 106 | ``` 107 | 108 | Related article: https://medium.com/google-cloud/plotting-ethereum-address-growth-chart-55cc0e7207b2 109 | 110 | ## Transaction Throughput Comparison 111 | 112 | ```sql 113 | WITH bitcoin_throughput AS ( 114 | -- takes transactions count in every block and divides it by average block time on that day 115 | SELECT 'bitcoin' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 116 | FROM `bigquery-public-data.crypto_bitcoin.transactions` AS transactions 117 | GROUP BY transactions.block_number, transactions.block_timestamp 118 | ORDER BY throughput DESC 119 | LIMIT 1 120 | ), 121 | bitcoin_cash_throughput AS ( 122 | SELECT 'bitcoin_cash' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 123 | FROM `bigquery-public-data.crypto_bitcoin_cash.transactions` AS transactions 124 | GROUP BY transactions.block_number, transactions.block_timestamp 125 | ORDER BY throughput DESC 126 | LIMIT 1 127 | ), 128 | ethereum_throughput AS ( 129 | SELECT 'ethereum' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 130 | FROM `bigquery-public-data.crypto_ethereum.transactions` AS transactions 131 | GROUP BY transactions.block_number, transactions.block_timestamp 132 | ORDER BY throughput DESC 133 | LIMIT 1 134 | ), 135 | ethereum_classic_throughput AS ( 136 | SELECT 'ethereum_classic' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 137 | FROM `bigquery-public-data.crypto_ethereum_classic.transactions` AS transactions 138 | GROUP BY transactions.block_number, transactions.block_timestamp 139 | ORDER BY throughput DESC 140 | LIMIT 1 141 | ), 142 | dogecoin_throughput AS ( 143 | SELECT 'dogecoin' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 144 | FROM `bigquery-public-data.crypto_dogecoin.transactions` AS transactions 145 | GROUP BY transactions.block_number, transactions.block_timestamp 146 | ORDER BY throughput DESC 147 | LIMIT 1 148 | ), 149 | litecoin_throughput AS ( 150 | SELECT 'litecoin' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 151 | FROM `bigquery-public-data.crypto_litecoin.transactions` AS transactions 152 | GROUP BY transactions.block_number, transactions.block_timestamp 153 | ORDER BY throughput DESC 154 | LIMIT 1 155 | ), 156 | dash_throughput AS ( 157 | SELECT 'dash' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 158 | FROM `bigquery-public-data.crypto_dash.transactions` AS transactions 159 | GROUP BY transactions.block_number, transactions.block_timestamp 160 | ORDER BY throughput DESC 161 | LIMIT 1 162 | ), 163 | zcash_throughput AS ( 164 | SELECT 'zcash' AS chain, count(*) / (24 * 60 * 60 / count(*) OVER (PARTITION BY DATE(block_timestamp))) AS throughput, block_timestamp AS time 165 | FROM `bigquery-public-data.crypto_zcash.transactions` AS transactions 166 | GROUP BY transactions.block_number, transactions.block_timestamp 167 | ORDER BY throughput DESC 168 | LIMIT 1 169 | ) 170 | SELECT * FROM bitcoin_throughput 171 | UNION ALL 172 | SELECT * FROM bitcoin_cash_throughput 173 | UNION ALL 174 | SELECT * FROM ethereum_throughput 175 | UNION ALL 176 | SELECT * FROM ethereum_classic_throughput 177 | UNION ALL 178 | SELECT * FROM dogecoin_throughput 179 | UNION ALL 180 | SELECT * FROM litecoin_throughput 181 | UNION ALL 182 | SELECT * FROM dash_throughput 183 | UNION ALL 184 | SELECT * FROM zcash_throughput 185 | ORDER BY throughput DESC 186 | ``` 187 | 188 | Related article: 189 | https://medium.com/@medvedev1088/comparing-transaction-throughputs-for-8-blockchains-in-google-bigquery-with-google-data-studio-edbabb75b7f1 190 | 191 | ## More Queries 192 | 193 | | Network | Description | Query | Screenshot | BigQuery | DataStudio | Notes 194 | | --- | --- | --- | --- | --- | --- | --- 195 | | Band | Latest oracle prices | [📝](band/latest-prices.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:9d41f5f621fe4deea11ed3be32ed0a5d) | | | 196 | | Band | Log types by transaction | [📝](band/log-types-by-transaction.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:4643d2cc218d497aa2bf4173c39cbce8) 197 | | Bitcoin | Top 1K addresses, by balance | [📝](bitcoin/top-bitcoin-balances.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:9bd85ce4d6174e909cfc89c09cb1cc55) | [📊](https://datastudio.google.com/u/1/reporting/c61d1ee3-0e67-4f19-a322-4aed82a21e1b/page/p_a72nk0pzzc) | | 198 | | Bitcoin | Bitcoin Gini index, by day | [📝](bitcoin/gini-index-by-day.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:531f2d1edf614723b2120a839e5df04b) | [📊](https://datastudio.google.com/u/1/reporting/c61d1ee3-0e67-4f19-a322-4aed82a21e1b/page/p_a72nk0pzzc) | [[1](https://cloud.google.com/blog/products/data-analytics/introducing-six-new-cryptocurrencies-in-bigquery-public-datasets-and-how-to-analyze-them)] 199 | | Ethereum | Every account balance on every day | [📝](ethereum/every-balance-every-day.sql)| | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:c5323064f9fb45529ebdd65fb4091374) | [📊](https://datastudio.google.com/u/1/reporting/c61d1ee3-0e67-4f19-a322-4aed82a21e1b/page/9tC6C) | [[1](https://medium.com/google-cloud/plotting-ethereum-address-growth-chart-55cc0e7207b2)] 200 | | Ethereum | Ether supply by day | [📝](ethereum/ether-supply-by-day.sql)| [🖼️](ethereum/ether-supply-by-day.png) | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:7bd873dec1cd417b89552495cad09e56) | [📊](https://datastudio.google.com/u/1/reporting/c61d1ee3-0e67-4f19-a322-4aed82a21e1b/page/9tC6C) | [[1](https://medium.com/google-cloud/how-to-query-ether-supply-in-bigquery-90f8ae795a8)] 201 | | Ethereum | Shortest path between addresses | [📝](ethereum/shortest-path-via-traces.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:2d202e496bf343a0aa1060f4ef35ffff) | ❌ 202 | | Zilliqa | Shortest path between addresses v2 | [📝](zilliqa/shortest-path-via-traces-v2.sql) | | [🔍](https://console.cloud.google.com/bigquery?sq=896878822558:c4c9b9294acb42b183233b158cc67074) | ❌ 203 | 204 | Check out this awesome repository: https://github.com/RokoMijic/awesome-bigquery-views 205 | --------------------------------------------------------------------------------