Skip to content

Commit

Permalink
Calculate send slash function
Browse files Browse the repository at this point in the history
  • Loading branch information
youngkidwarrior committed Nov 15, 2024
1 parent c648f18 commit 4991e50
Show file tree
Hide file tree
Showing 2 changed files with 119 additions and 0 deletions.
13 changes: 13 additions & 0 deletions supabase/database-generated.types.ts
Original file line number Diff line number Diff line change
Expand Up @@ -295,6 +295,7 @@ export type Database = {
number: number
qualification_end: string
qualification_start: string
send_slash_divisor: number | null
snapshot_block_num: number | null
updated_at: string
}
Expand All @@ -313,6 +314,7 @@ export type Database = {
number: number
qualification_end: string
qualification_start: string
send_slash_divisor?: number | null
snapshot_block_num?: number | null
updated_at?: string
}
Expand All @@ -331,6 +333,7 @@ export type Database = {
number?: number
qualification_end?: string
qualification_start?: string
send_slash_divisor?: number | null
snapshot_block_num?: number | null
updated_at?: string
}
Expand Down Expand Up @@ -1228,6 +1231,16 @@ export type Database = {
Args: Record<PropertyKey, never>
Returns: string
}
get_send_slash_calculations: {
Args: {
distribution_number: number
}
Returns: {
user_id: string
capped_sum: number
slash_percentage: number
}[]
}
insert_challenge: {
Args: Record<PropertyKey, never>
Returns: {
Expand Down
106 changes: 106 additions & 0 deletions supabase/migrations/20241110000436_calculate_send_slash.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
ALTER TABLE "public"."distributions"
ADD COLUMN "send_slash_minimum_sends" smallint DEFAULT '1'::smallint;

ALTER TABLE "public"."distributions"
ADD COLUMN "send_slash_past_rewards_divisor" smallint DEFAULT '1'::smallint;

UPDATE
"public"."distributions"
SET
send_slash_minimum_sends = 50
WHERE
number = 9;

UPDATE
"public"."distributions"
SET
send_slash_past_rewards_divisor = 3
WHERE
number = 9;

CREATE OR REPLACE FUNCTION get_send_slash_calculations(distribution_number integer)
RETURNS TABLE(
user_id uuid,
capped_sum numeric,
slash_percentage numeric)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY WITH distribution_info AS(
SELECT
id,
qualification_start,
qualification_end,
send_slash_minimum_sends,
send_slash_past_rewards_divisor,
hodler_min_balance,
(
SELECT
SUM(ds.amount)
FROM
distribution_shares ds
WHERE
ds.distribution_id =(
SELECT
id
FROM
distributions
WHERE
number = distribution_number - 1)) AS prev_shares
FROM
distributions
WHERE
number = distribution_number
),
previous_shares AS(
SELECT
ds.user_id,
ds.amount AS user_prev_shares
FROM
distribution_shares ds
WHERE
ds.distribution_id =(
SELECT
id
FROM
distributions
WHERE
number = distribution_number - 1)
),
user_transfers AS(
SELECT
sa.user_id,
SUM(LEAST(stt.v,(ROUND(COALESCE(ps.user_prev_shares, di.hodler_min_balance) /(di.send_slash_minimum_sends * di.send_slash_past_rewards_divisor)))::numeric)) AS capped_sum
FROM
send_token_transfers stt
JOIN send_accounts sa ON sa.address = concat('0x', encode(stt.f, 'hex'))::citext
CROSS JOIN distribution_info di
LEFT JOIN previous_shares ps ON ps.user_id = sa.user_id
WHERE
stt.block_time >= extract(epoch FROM di.qualification_start)
AND stt.block_time < extract(epoch FROM di.qualification_end)
GROUP BY
sa.user_id
)
SELECT
ut.user_id,
ut.capped_sum,
ROUND(
CASE WHEN ut.capped_sum > 0 THEN
LEAST(1.0, ut.capped_sum / NULLIF(COALESCE((
SELECT
user_prev_shares
FROM previous_shares ps
WHERE
ps.user_id = ut.user_id), di.hodler_min_balance) / di.send_slash_past_rewards_divisor, 0))::numeric
ELSE
0
END, 8) AS slash_percentage
FROM
user_transfers ut
CROSS JOIN distribution_info di
WHERE
ut.capped_sum > 0;
END;
$$;

0 comments on commit 4991e50

Please sign in to comment.