diff --git a/sql_extensions/migrations/00006_user_rank.sql b/sql_extensions/migrations/00006_user_rank.sql index 028c55e..0b575c3 100644 --- a/sql_extensions/migrations/00006_user_rank.sql +++ b/sql_extensions/migrations/00006_user_rank.sql @@ -1,16 +1,34 @@ CREATE TABLE inbox_user_balance ( - user_address TEXT NOT NULL PRIMARY KEY, - balance_as_fraction_of_circulating_supply NUMERIC + user_address TEXT NOT NULL, + market_id NUMERIC, + balance_as_fraction_of_circulating_supply NUMERIC, + PRIMARY KEY (user_address, market_id) ); +INSERT INTO inbox_user_balance +SELECT DISTINCT ON (data ->> 'user', data -> 'market_metadata' ->> 'market_id') + data ->> 'user', + (data -> 'market_metadata' ->> 'market_id')::NUMERIC, + (data ->> 'balance_as_fraction_of_circulating_supply_q64')::NUMERIC / POW(2::NUMERIC, 64::NUMERIC) +FROM + inbox_events +WHERE + event_name = 'emojicoin_dot_fun::Chat' +ORDER BY + data ->> 'user', + data -> 'market_metadata' ->> 'market_id', + transaction_version DESC, + event_index DESC; + CREATE OR REPLACE FUNCTION UPDATE_USER_BALANCE() RETURNS TRIGGER AS $$ BEGIN INSERT INTO inbox_user_balance SELECT NEW.data ->> 'user', + (NEW.data -> 'market_metadata' ->> 'market_id')::NUMERIC, (NEW.data ->> 'balance_as_fraction_of_circulating_supply_q64')::NUMERIC / POW(2::NUMERIC, 64::NUMERIC) - ON CONFLICT (user_address) DO UPDATE SET + ON CONFLICT (user_address, market_id) DO UPDATE SET balance_as_fraction_of_circulating_supply = (NEW.data ->> 'balance_as_fraction_of_circulating_supply_q64')::NUMERIC / POW(2::NUMERIC, 64::NUMERIC); RETURN NEW; END; @@ -22,7 +40,7 @@ FOR EACH ROW WHEN (new.event_name = 'emojicoin_dot_fun::Chat') EXECUTE PROCEDURE UPDATE_USER_BALANCE(); -CREATE VIEW inbox_swaps AS +CREATE OR REPLACE VIEW inbox_swaps AS SELECT swaps.sequence_number, swaps.creation_number, @@ -35,7 +53,8 @@ SELECT swaps.event_index, swaps.indexed_type, swaps.event_name, + (swaps."data"->>'market_id')::NUMERIC AS market_id, inbox_user_balance.balance_as_fraction_of_circulating_supply FROM inbox_events AS swaps -LEFT JOIN inbox_user_balance ON swaps.data ->> 'swapper' = inbox_user_balance.user_address +LEFT JOIN inbox_user_balance ON swaps.data ->> 'swapper' = inbox_user_balance.user_address AND (swaps."data" ->> 'market_id')::NUMERIC = inbox_user_balance.market_id WHERE swaps.event_name = 'emojicoin_dot_fun::Swap';