-
Notifications
You must be signed in to change notification settings - Fork 1
WIP: Support DAMM v2 #470
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
WIP: Support DAMM v2 #470
Changes from 1 commit
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,55 @@ | ||
BEGIN; | ||
DROP FUNCTION IF EXISTS calculate_artist_coin_fees(TEXT); | ||
CREATE OR REPLACE FUNCTION calculate_artist_coin_fees(artist_coin_mint TEXT) | ||
RETURNS TABLE ( | ||
unclaimed_dbc_fees NUMERIC, | ||
total_dbc_fees NUMERIC, | ||
unclaimed_damm_v2_fees NUMERIC, | ||
total_damm_v2_fees NUMERIC, | ||
unclaimed_fees NUMERIC, | ||
total_fees NUMERIC | ||
) LANGUAGE sql AS $function$ | ||
WITH | ||
damm_fees AS ( | ||
SELECT | ||
pool.token_a_mint AS mint, | ||
( | ||
pool.fee_b_per_liquidity | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. confirming that |
||
* ( | ||
position.unlocked_liquidity + position.vested_liquidity + position.permanent_locked_liquidity | ||
) | ||
/ POWER (2, 128) | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. what's this? There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. So the liquidity is represented as an enormous integer but is actually shifted 128 bits - AI says its a method for doing precise math w/ large fixed fractional components (In this case, 128bits for the whole component, and 128bits for the fractional component?) pretty interesting.. wish they had better explainers |
||
+ position.fee_b_pending | ||
) AS total_damm_v2_fees, | ||
( | ||
(pool.fee_b_per_liquidity - position.fee_b_per_token_checkpoint) | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. what is fee_b_per_token_checkpoint? There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. This is updated as you claim and marks the amount you've already claimed basically |
||
* ( | ||
position.unlocked_liquidity + position.vested_liquidity + position.permanent_locked_liquidity | ||
) | ||
/ POWER (2, 128) | ||
+ position.fee_b_pending | ||
) AS unclaimed_damm_v2_fees | ||
FROM sol_meteora_damm_v2_pools pool | ||
JOIN sol_meteora_dbc_migrations migration ON migration.base_mint = pool.token_a_mint | ||
JOIN sol_meteora_damm_v2_positions position ON position.address = migration.first_position | ||
WHERE pool.token_a_mint = artist_coin_mint | ||
), | ||
dbc_fees AS ( | ||
SELECT | ||
base_mint AS mint, | ||
total_trading_quote_fee / 2 AS total_dbc_fees, | ||
creator_quote_fee / 2 AS unclaimed_dbc_fees | ||
FROM artist_coin_pools | ||
WHERE base_mint = artist_coin_mint | ||
) | ||
SELECT | ||
FLOOR(COALESCE(dbc_fees.unclaimed_dbc_fees, 0)) AS unclaimed_dbc_fees, | ||
FLOOR(COALESCE(dbc_fees.total_dbc_fees, 0)) AS total_dbc_fees, | ||
FLOOR(COALESCE(damm_fees.unclaimed_damm_v2_fees, 0)) AS unclaimed_damm_v2_fees, | ||
FLOOR(COALESCE(damm_fees.total_damm_v2_fees, 0)) AS total_damm_v2_fees, | ||
FLOOR(COALESCE(dbc_fees.unclaimed_dbc_fees, 0) + COALESCE(damm_fees.unclaimed_damm_v2_fees, 0)) AS unclaimed_fees, | ||
FLOOR(COALESCE(dbc_fees.total_dbc_fees, 0) + COALESCE(damm_fees.total_damm_v2_fees, 0)) AS total_fees | ||
FROM dbc_fees | ||
FULL OUTER JOIN damm_fees USING (mint); | ||
$function$; | ||
COMMIT; |
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,21 @@ | ||
CREATE OR REPLACE FUNCTION handle_meteora_dbc_migrations() | ||
RETURNS trigger AS $$ | ||
BEGIN | ||
PERFORM pg_notify('meteora_dbc_migration', json_build_object('operation', TG_OP)::text); | ||
RETURN NEW; | ||
EXCEPTION | ||
WHEN OTHERS THEN | ||
RAISE WARNING 'An error occurred in %: %', TG_NAME, SQLERRM; | ||
RETURN NULL; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
|
||
DO $$ | ||
BEGIN | ||
CREATE TRIGGER on_meteora_dbc_migrations | ||
AFTER INSERT OR DELETE ON sol_meteora_dbc_migrations | ||
FOR EACH ROW EXECUTE FUNCTION handle_meteora_dbc_migrations(); | ||
EXCEPTION | ||
WHEN others THEN NULL; -- Ignore if trigger already exists | ||
END $$; | ||
COMMENT ON TRIGGER on_meteora_dbc_migrations ON sol_meteora_dbc_migrations IS 'Notifies when a DBC pool migrates to a DAMM V2 pool.' |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
note: kinda yucky but because I'm doing ROW_TO_JSON here, the struct deserializes using the JSON struct tag names. Thus the JSON struct tags need to be underscores. To my knowledge, it's not possible to have one JSON struct tag for serializing and another for deserializing.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
instead could we just select the fields off of the resulting row from calculate_artist_coin_fees?
i think this is also okay though
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
yeah and use JSON_BUILD_OBJECT? we could do that. I could also make that function return camelCased columns...