Skip to content

Commit

Permalink
Merge branch 'main' into alpha
Browse files Browse the repository at this point in the history
  • Loading branch information
Anton-Mushnin authored Mar 22, 2024
2 parents a475400 + b94bd7a commit ae5ba9b
Show file tree
Hide file tree
Showing 25 changed files with 1,163 additions and 289 deletions.
55 changes: 55 additions & 0 deletions api/queries/sepolia/home_run_leaderboard.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM arbitrum_sepolia_labels
WHERE label='moonworm-alpha'
AND address='0x3a1Ad54d12b1f39805Ea77aFe7DeeFf2F32C97f5'
AND log_index IS NOT NULL
), AtBats as (
SELECT
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='AtBatProgress' AND label_data->'args'->>'outcome'!='0'
), batter_stats as (
SELECT
SUM(CASE
WHEN outcome = '1' THEN 1 ELSE 0
END) as strikeouts,
SUM(CASE
WHEN outcome = '2' THEN 1 ELSE 0
END) as walks,
SUM(CASE
WHEN outcome = '3' THEN 1 ELSE 0
END) as singles,
SUM(CASE
WHEN outcome = '4' THEN 1 ELSE 0
END) as doubles,
SUM(CASE
WHEN outcome = '5' THEN 1 ELSE 0
END) as triples,
SUM(CASE
WHEN outcome = '6' THEN 1 ELSE 0
END) as home_runs,
SUM(CASE
WHEN outcome = '7' THEN 1 ELSE 0
END) as in_play_outs,
count(*) as total_batter_events,
batter_address as batter_address,
batter_token_id as batter_token_id
FROM AtBats
GROUP BY batter_address, batter_token_id
ORDER BY home_runs DESC
)
select
batter_address || '_' || batter_token_id as address,
home_runs as score,
json_build_object(
'home_runs', home_runs
) as points_data
from batter_stats
50 changes: 50 additions & 0 deletions api/queries/sepolia/pitch_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM arbitrum_sepolia_labels
WHERE label='moonworm-alpha'
AND address='0x3a1Ad54d12b1f39805Ea77aFe7DeeFf2F32C97f5'
AND log_index IS NOT NULL
), SessionResolved as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='SessionResolved'
), PitchRevealed as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->'pitch'-> 1 as pitch_speed,
label_data->'args'->'pitch'-> 2 as pitch_vertical,
label_data->'args'->'pitch'-> 3 as pitch_horizontal,
log_index
FROM dedup_events
WHERE label_data->>'name'='PitchRevealed'
), PitchDistribution as (
SELECT
pitcher_address || '_' || pitcher_token_id as address,
pitch_speed,
pitch_vertical,
pitch_horizontal,
count(*) as pitch_count
FROM SessionResolved LEFT JOIN PitchRevealed ON (SessionResolved.contract_address=PitchRevealed.contract_address AND SessionResolved.session_id = PitchRevealed.session_id)
GROUP BY pitcher_address, pitcher_token_id, pitch_speed, pitch_vertical, pitch_horizontal
ORDER BY pitch_speed, pitch_vertical, pitch_horizontal
)
SELECT
address,
json_agg(json_build_object(
'pitch_speed', pitch_speed,
'pitch_vertical', pitch_vertical,
'pitch_horizontal', pitch_horizontal,
'count', pitch_count
)) as pitch_distribution
FROM PitchDistribution
GROUP BY address
122 changes: 122 additions & 0 deletions api/queries/sepolia/player_stats_atbat.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,122 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM arbitrum_sepolia_labels
WHERE label='moonworm-alpha'
AND address='0x3a1Ad54d12b1f39805Ea77aFe7DeeFf2F32C97f5'
AND log_index IS NOT NULL
), AtBats as (
SELECT
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='AtBatProgress' AND label_data->'args'->>'outcome'!='0'
), batter_stats as (
SELECT
SUM(CASE
WHEN outcome = '1' THEN 1 ELSE 0
END) as strikeouts,
SUM(CASE
WHEN outcome = '2' THEN 1 ELSE 0
END) as walks,
SUM(CASE
WHEN outcome = '3' THEN 1 ELSE 0
END) as singles,
SUM(CASE
WHEN outcome = '4' THEN 1 ELSE 0
END) as doubles,
SUM(CASE
WHEN outcome = '5' THEN 1 ELSE 0
END) as triples,
SUM(CASE
WHEN outcome = '6' THEN 1 ELSE 0
END) as home_runs,
SUM(CASE
WHEN outcome = '7' THEN 1 ELSE 0
END) as in_play_outs,
count(*) as total_batter_events,
batter_address as batter_address,
batter_token_id as batter_token_id
FROM AtBats
GROUP BY batter_address, batter_token_id
), pitcher_stats as (
SELECT
SUM(CASE
WHEN outcome = '1' THEN 1 ELSE 0
END) as strikeouts,
SUM(CASE
WHEN outcome = '2' THEN 1 ELSE 0
END) as walks,
SUM(CASE
WHEN outcome = '3' THEN 1 ELSE 0
END) as singles,
SUM(CASE
WHEN outcome = '4' THEN 1 ELSE 0
END) as doubles,
SUM(CASE
WHEN outcome = '5' THEN 1 ELSE 0
END) as triples,
SUM(CASE
WHEN outcome = '6' THEN 1 ELSE 0
END) as home_runs,
SUM(CASE
WHEN outcome = '7' THEN 1 ELSE 0
END) as in_play_outs,
count(*) as total_pitcher_events,
pitcher_address,
pitcher_token_id
FROM AtBats
GROUP BY pitcher_address, pitcher_token_id
), pitcher_data as (
select
pitcher_address || '_' || pitcher_token_id as address,
json_build_object(
'strikeouts', strikeouts,
'walks', walks,
'singles', singles,
'doubles', doubles,
'triples', triples,
'home_runs', home_runs,
'in_play_outs', in_play_outs,
'innings', (strikeouts + in_play_outs) / 3.0,
'earned_runs', 1.5 * singles + 2.5 * doubles + 3 * triples + 4 * home_runs,
'earned_run_average', 9.0 * (1.5 * singles + 2.5 * doubles + 3 * triples + 4 * home_runs) / NULLIF((strikeouts + in_play_outs) / 3.0, 0),
'whip', (walks + singles + doubles + triples + home_runs) / NULLIF((strikeouts + in_play_outs) / 3.0, 0),
'batting_average_against', 1.0 * (singles + doubles + triples + home_runs) / NULLIF(total_pitcher_events - walks, 0)
) as points_data
from pitcher_stats
), batter_data as (
select
batter_address || '_' || batter_token_id as address,
json_build_object(
'strikeouts', strikeouts,
'walks', walks,
'singles', singles,
'doubles', doubles,
'triples', triples,
'home_runs', home_runs,
'in_play_outs', in_play_outs,
'at_bats', total_batter_events - walks,
'hits', singles + doubles + triples + home_runs,
'runs_batted_in', walks + 1.5 * singles + 2.5 * doubles + 3 * triples + 4 * home_runs,
'batting_average', 1.0 * (singles + doubles + triples + home_runs) / NULLIF(total_batter_events - walks, 0),
'on-base', 1.0 * (walks + singles + doubles + triples + home_runs) / NULLIF(total_batter_events, 0),
'slugging', (1.0 * singles + 2.0 * doubles + 3.0 * triples + 4.0 * home_runs) / NULLIF(total_batter_events - walks, 0),
'ops', COALESCE(1.0 * (walks + singles + doubles + triples + home_runs) / NULLIF(total_batter_events, 0), 0) +
COALESCE((1.0 * singles + 2.0 * doubles + 3.0 * triples + 4.0 * home_runs) / NULLIF(total_batter_events - walks, 0), 0)
) as points_data
from batter_stats
)
select
COALESCE(batter_data.address, pitcher_data.address) as address,
0 as score,
json_build_object(
'batting_data', batter_data.points_data,
'pitching_data', pitcher_data.points_data
) as points_data
from batter_data full outer join pitcher_data on batter_data.address = pitcher_data.address
55 changes: 55 additions & 0 deletions api/queries/sepolia/strikeout_leaderboard.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM arbitrum_sepolia_labels
WHERE label='moonworm-alpha'
AND address='0x3a1Ad54d12b1f39805Ea77aFe7DeeFf2F32C97f5'
AND log_index IS NOT NULL
), AtBats as (
SELECT
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='AtBatProgress' AND label_data->'args'->>'outcome'!='0'
), pitcher_stats as (
SELECT
SUM(CASE
WHEN outcome = '1' THEN 1 ELSE 0
END) as strikeouts,
SUM(CASE
WHEN outcome = '2' THEN 1 ELSE 0
END) as walks,
SUM(CASE
WHEN outcome = '3' THEN 1 ELSE 0
END) as singles,
SUM(CASE
WHEN outcome = '4' THEN 1 ELSE 0
END) as doubles,
SUM(CASE
WHEN outcome = '5' THEN 1 ELSE 0
END) as triples,
SUM(CASE
WHEN outcome = '6' THEN 1 ELSE 0
END) as home_runs,
SUM(CASE
WHEN outcome = '7' THEN 1 ELSE 0
END) as in_play_outs,
count(*) as total_pitcher_events,
pitcher_address,
pitcher_token_id
FROM AtBats
GROUP BY pitcher_address, pitcher_token_id
ORDER BY strikeouts DESC
)
select
pitcher_address || '_' || pitcher_token_id as address,
strikeouts as score,
json_build_object(
'strikeouts', strikeouts
) as points_data
from pitcher_stats
50 changes: 50 additions & 0 deletions api/queries/sepolia/swing_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM arbitrum_sepolia_labels
WHERE label='moonworm-alpha'
AND address='0x3a1Ad54d12b1f39805Ea77aFe7DeeFf2F32C97f5'
AND log_index IS NOT NULL
), SessionResolved as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='SessionResolved'
), SwingRevealed as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->'swing'-> 1 as swing_type,
label_data->'args'->'swing'-> 2 as swing_vertical,
label_data->'args'->'swing'-> 3 as swing_horizontal,
log_index
FROM dedup_events
WHERE label_data->>'name'='SwingRevealed'
), SwingDistribution as (
SELECT
batter_address || '_' || batter_token_id as address,
swing_type,
swing_vertical,
swing_horizontal,
count(*) as swing_count
FROM SessionResolved LEFT JOIN SwingRevealed ON (SessionResolved.contract_address=SwingRevealed.contract_address AND SessionResolved.session_id = SwingRevealed.session_id)
GROUP BY batter_address, batter_token_id, swing_type, swing_vertical, swing_horizontal
ORDER BY swing_type, swing_vertical, swing_horizontal
)
SELECT
address,
json_agg(json_build_object(
'swing_type', swing_type,
'swing_vertical', swing_vertical,
'swing_horizontal', swing_horizontal,
'count', swing_count
)) as swing_distribution
FROM SwingDistribution
GROUP BY address
File renamed without changes.
52 changes: 52 additions & 0 deletions api/queries/wyrm/pitch_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
with dedup_events as (
SELECT
DISTINCT ON(transaction_hash, log_index) *
FROM wyrm_labels
WHERE label='moonworm-alpha'
AND (address='0xde191e8c352BA59F95cf19f0931cCbBcc7B60934'
OR address='0x9270df8d907A99E5024dc3532657a5cF9C7A4889'
OR address='0xC90F37D09f2f8fB2e9D1Aa9a9d5142f5aE100d84')
AND log_index IS NOT NULL
), SessionResolved as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->>'outcome' as outcome,
label_data->'args'->>'batterAddress' as batter_address,
label_data->'args'->>'batterTokenID' as batter_token_id,
label_data->'args'->>'pitcherAddress' as pitcher_address,
label_data->'args'->>'pitcherTokenID' as pitcher_token_id,
log_index
FROM dedup_events
WHERE label_data->>'name'='SessionResolved'
), PitchRevealed as (
SELECT
address as contract_address,
label_data->'args'->>'sessionID' as session_id,
label_data->'args'->'pitch'-> 1 as pitch_speed,
label_data->'args'->'pitch'-> 2 as pitch_vertical,
label_data->'args'->'pitch'-> 3 as pitch_horizontal,
log_index
FROM dedup_events
WHERE label_data->>'name'='PitchRevealed'
), PitchDistribution as (
SELECT
pitcher_address || '_' || pitcher_token_id as address,
pitch_speed,
pitch_vertical,
pitch_horizontal,
count(*) as pitch_count
FROM SessionResolved LEFT JOIN PitchRevealed ON (SessionResolved.contract_address=PitchRevealed.contract_address AND SessionResolved.session_id = PitchRevealed.session_id)
GROUP BY pitcher_address, pitcher_token_id, pitch_speed, pitch_vertical, pitch_horizontal
ORDER BY pitch_speed, pitch_vertical, pitch_horizontal
)
SELECT
address,
json_agg(json_build_object(
'pitch_speed', pitch_speed,
'pitch_vertical', pitch_vertical,
'pitch_horizontal', pitch_horizontal,
'count', pitch_count
)) as pitch_distribution
FROM PitchDistribution
GROUP BY address
File renamed without changes.
File renamed without changes.
File renamed without changes.
Loading

0 comments on commit ae5ba9b

Please sign in to comment.