use crate::structs::{ candle::Candle, coingecko::{PgCoinGecko24HighLow, PgCoinGecko24HourVolume}, openbook::PgOpenBookFill, resolution::Resolution, trader::PgTrader, }; use chrono::{DateTime, Utc}; use deadpool_postgres::{GenericClient, Pool}; pub async fn fetch_earliest_fill( pool: &Pool, market_address_string: &str, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT block_datetime as "time", bid as "bid", maker as "maker", price as "price", size as "size" from openbook.openbook_fill_events where market = $1 and maker = true ORDER BY time asc LIMIT 1"#; let row = client.query_opt(stmt, &[&market_address_string]).await?; match row { Some(r) => Ok(Some(PgOpenBookFill::from_row(r))), None => Ok(None), } } pub async fn fetch_fills_from( pool: &Pool, market_address_string: &str, start_time: DateTime, end_time: DateTime, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT block_datetime as "time", bid as "bid", maker as "maker", price as "price", size as "size" from openbook.openbook_fill_events where market = $1 and block_datetime >= $2::timestamptz and block_datetime < $3::timestamptz and maker = true ORDER BY time asc"#; let rows = client .query(stmt, &[&market_address_string, &start_time, &end_time]) .await?; Ok(rows.into_iter().map(PgOpenBookFill::from_row).collect()) } pub async fn fetch_latest_finished_candle( pool: &Pool, market_name: &str, resolution: Resolution, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT market_name as "market_name", start_time as "start_time", end_time as "end_time", resolution as "resolution", open as "open", close as "close", high as "high", low as "low", volume as "volume", complete as "complete" from openbook.candles where market_name = $1 and resolution = $2 and complete = true ORDER BY start_time desc LIMIT 1"#; let row = client .query_opt(stmt, &[&market_name, &resolution.to_string()]) .await?; match row { Some(r) => Ok(Some(Candle::from_row(r))), None => Ok(None), } } /// Fetches all of the candles for the given market and resoultion, starting from the earliest. /// Note that this function will fetch ALL candles. pub async fn fetch_earliest_candles( pool: &Pool, market_name: &str, resolution: Resolution, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT market_name as "market_name", start_time as "start_time", end_time as "end_time", resolution as "resolution!", open as "open", close as "close", high as "high", low as "low", volume as "volume", complete as "complete" from openbook.candles where market_name = $1 and resolution = $2 ORDER BY start_time asc"#; let rows = client .query(stmt, &[&market_name, &resolution.to_string()]) .await?; Ok(rows.into_iter().map(Candle::from_row).collect()) } pub async fn fetch_candles_from( pool: &Pool, market_name: &str, resolution: Resolution, start_time: DateTime, end_time: DateTime, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT market_name as "market_name", start_time as "start_time", end_time as "end_time", resolution as "resolution", open as "open", close as "close", high as "high", low as "low", volume as "volume", complete as "complete" from openbook.candles where market_name = $1 and resolution = $2 and start_time >= $3 and end_time <= $4 ORDER BY start_time asc"#; let rows = client .query( stmt, &[ &market_name, &resolution.to_string(), &start_time, &end_time, ], ) .await?; Ok(rows.into_iter().map(Candle::from_row).collect()) } pub async fn fetch_top_traders_by_base_volume_from( pool: &Pool, market_address_string: &str, start_time: DateTime, end_time: DateTime, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT open_orders_owner, sum( native_quantity_paid * CASE bid WHEN true THEN 0 WHEN false THEN 1 END ) as "raw_ask_size", sum( native_quantity_received * CASE bid WHEN true THEN 1 WHEN false THEN 0 END ) as "raw_bid_size" FROM openbook.openbook_fill_events WHERE market = $1 AND time >= $2 AND time < $3 GROUP BY open_orders_owner ORDER BY sum(native_quantity_paid * CASE bid WHEN true THEN 0 WHEN false THEN 1 END) + sum(native_quantity_received * CASE bid WHEN true THEN 1 WHEN false THEN 0 END) DESC LIMIT 10000"#; let rows = client .query(stmt, &[&market_address_string, &start_time, &end_time]) .await?; Ok(rows.into_iter().map(PgTrader::from_row).collect()) } pub async fn fetch_top_traders_by_quote_volume_from( pool: &Pool, market_address_string: &str, start_time: DateTime, end_time: DateTime, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT open_orders_owner, sum( native_quantity_received * CASE bid WHEN true THEN 0 WHEN false THEN 1 END ) as "raw_ask_size", sum( native_quantity_paid * CASE bid WHEN true THEN 1 WHEN false THEN 0 END ) as "raw_bid_size" FROM openbook.openbook_fill_events WHERE market = $1 AND time >= $2 AND time < $3 GROUP BY open_orders_owner ORDER BY sum(native_quantity_received * CASE bid WHEN true THEN 0 WHEN false THEN 1 END) + sum(native_quantity_paid * CASE bid WHEN true THEN 1 WHEN false THEN 0 END) DESC LIMIT 10000"#; let rows = client .query(stmt, &[&market_address_string, &start_time, &end_time]) .await?; Ok(rows.into_iter().map(PgTrader::from_row).collect()) } pub async fn fetch_coingecko_24h_volume( pool: &Pool, market_address_strings: &Vec<&str>, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"SELECT t1.market, COALESCE(t2.native_quantity_received, 0) as "raw_base_size", COALESCE(t2.native_quantity_paid, 0) as "raw_quote_size" FROM ( SELECT distinct on (market) * FROM openbook.openbook_fill_events f where bid = true and market = any($1) order by market, "time" desc ) t1 LEFT JOIN ( select market, sum(native_quantity_received) as "native_quantity_received", sum(native_quantity_paid) as "native_quantity_paid" from openbook.openbook_fill_events where "time" >= current_timestamp - interval '1 day' and bid = true group by market ) t2 ON t1.market = t2.market"#; let rows = client.query(stmt, &[&market_address_strings]).await?; Ok(rows .into_iter() .map(PgCoinGecko24HourVolume::from_row) .collect()) } pub async fn fetch_coingecko_24h_high_low( pool: &Pool, market_names: &Vec<&str>, ) -> anyhow::Result> { let client = pool.get().await?; let stmt = r#"select r.market_name as "market_name!", coalesce(c.high, r.high) as "high!", coalesce(c.low, r.low) as "low!", r."close" as "close!" from ( SELECT * from openbook.candles where (market_name, start_time, resolution) in ( select market_name, max(start_time), resolution from openbook.candles where "resolution" = '1M' and market_name = any($1) group by market_name, resolution ) ) as r left join ( SELECT market_name, max(start_time) as "start_time", max(high) as "high", min(low) as "low" from openbook.candles where "resolution" = '1M' and "start_time" >= current_timestamp - interval '1 day' group by market_name ) c on r.market_name = c.market_name"#; let rows = client.query(stmt, &[&market_names]).await?; Ok(rows .into_iter() .map(PgCoinGecko24HighLow::from_row) .collect()) }