diff --git a/packages/snaplet/.snaplet/dataModel.json b/packages/snaplet/.snaplet/dataModel.json index 3684a54d6..233206629 100644 --- a/packages/snaplet/.snaplet/dataModel.json +++ b/packages/snaplet/.snaplet/dataModel.json @@ -287,20 +287,6 @@ "schemaName": "public", "tableName": "affiliate_stats", "fields": [ - { - "id": "public.affiliate_stats.paymaster_tx_count", - "name": "paymaster_tx_count", - "columnName": "paymaster_tx_count", - "type": "int8", - "isRequired": true, - "kind": "scalar", - "isList": false, - "isGenerated": false, - "sequence": false, - "hasDefaultValue": true, - "isId": false, - "maxLength": null - }, { "id": "public.affiliate_stats.user_id", "name": "user_id", @@ -357,6 +343,20 @@ "isId": false, "maxLength": null }, + { + "id": "public.affiliate_stats.send_plus_minus", + "name": "send_plus_minus", + "columnName": "send_plus_minus", + "type": "int8", + "isRequired": true, + "kind": "scalar", + "isList": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": true, + "isId": false, + "maxLength": null + }, { "name": "profiles", "type": "profiles", @@ -978,6 +978,20 @@ "isId": true, "maxLength": null }, + { + "id": "public.distribution_shares.amount_after_slash", + "name": "amount_after_slash", + "columnName": "amount_after_slash", + "type": "numeric", + "isRequired": true, + "kind": "scalar", + "isList": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": false, + "isId": false, + "maxLength": null + }, { "name": "users", "type": "users", @@ -1631,6 +1645,20 @@ "isGenerated": false, "sequence": false, "hasDefaultValue": false + }, + { + "name": "send_slash", + "type": "send_slash", + "isRequired": false, + "kind": "object", + "relationName": "send_slashTodistributions", + "relationFromFields": [], + "relationToFields": [], + "isList": true, + "isId": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": false } ], "uniqueConstraints": [ @@ -6513,6 +6541,82 @@ } ] }, + "send_slash": { + "id": "public.send_slash", + "schemaName": "public", + "tableName": "send_slash", + "fields": [ + { + "id": "public.send_slash.distribution_number", + "name": "distribution_number", + "columnName": "distribution_number", + "type": "int4", + "isRequired": true, + "kind": "scalar", + "isList": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": false, + "isId": true, + "maxLength": null + }, + { + "id": "public.send_slash.minimum_sends", + "name": "minimum_sends", + "columnName": "minimum_sends", + "type": "int2", + "isRequired": true, + "kind": "scalar", + "isList": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": true, + "isId": false, + "maxLength": null + }, + { + "id": "public.send_slash.scaling_divisor", + "name": "scaling_divisor", + "columnName": "scaling_divisor", + "type": "int2", + "isRequired": true, + "kind": "scalar", + "isList": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": true, + "isId": false, + "maxLength": null + }, + { + "name": "distributions", + "type": "distributions", + "isRequired": true, + "kind": "object", + "relationName": "send_slashTodistributions", + "relationFromFields": [ + "distribution_number" + ], + "relationToFields": [ + "number" + ], + "isList": false, + "isId": false, + "isGenerated": false, + "sequence": false, + "hasDefaultValue": false + } + ], + "uniqueConstraints": [ + { + "name": "send_slash_pkey", + "fields": [ + "distribution_number" + ], + "nullNotDistinct": false + } + ] + }, "send_token_transfers": { "id": "public.send_token_transfers", "schemaName": "public", @@ -9165,6 +9269,9 @@ { "name": "create_passkey" }, + { + "name": "send_ceiling" + }, { "name": "send_one_hundred" }, diff --git a/supabase/database-generated.types.ts b/supabase/database-generated.types.ts index 42beb3f1a..9d9fb5b4b 100644 --- a/supabase/database-generated.types.ts +++ b/supabase/database-generated.types.ts @@ -137,6 +137,7 @@ export type Database = { Row: { address: string amount: number + amount_after_slash: number bonus_pool_amount: number created_at: string distribution_id: number @@ -150,6 +151,7 @@ export type Database = { Insert: { address: string amount: number + amount_after_slash: number bonus_pool_amount: number created_at?: string distribution_id: number @@ -163,6 +165,7 @@ export type Database = { Update: { address?: string amount?: number + amount_after_slash?: number bonus_pool_amount?: number created_at?: string distribution_id?: number @@ -856,6 +859,32 @@ export type Database = { } Relationships: [] } + send_slash: { + Row: { + distribution_number: number + minimum_sends: number + scaling_divisor: number + } + Insert: { + distribution_number: number + minimum_sends?: number + scaling_divisor?: number + } + Update: { + distribution_number?: number + minimum_sends?: number + scaling_divisor?: number + } + Relationships: [ + { + foreignKeyName: "send_slash_distribution_number_fkey" + columns: ["distribution_number"] + isOneToOne: true + referencedRelation: "distributions" + referencedColumns: ["number"] + }, + ] + } send_token_transfers: { Row: { abi_idx: number @@ -1138,6 +1167,12 @@ export type Database = { } } Functions: { + calculate_and_insert_send_ceiling_verification: { + Args: { + distribution_number: number + } + Returns: undefined + } citext: | { Args: { @@ -1244,10 +1279,7 @@ export type Database = { id: string created_at: string user_id: string - send_plus_minus: number referral_count: number - network_plus_minus: number - affiliate_send_score: number }[] } insert_challenge: { @@ -1307,6 +1339,17 @@ export type Database = { user_id: string } } + sum_qualification_sends: { + Args: { + distribution_number: number + send_ceiling: number + } + Returns: { + user_id: string + amount: number + sent_to: string[] + }[] + } tag_search: { Args: { query: string @@ -1343,6 +1386,7 @@ export type Database = { | "send_one_hundred" | "total_tag_referrals" | "send_streak" + | "send_ceiling" verification_value_mode: "individual" | "aggregate" } CompositeTypes: { diff --git a/supabase/migrations/20241123134636_create_send_slash_table_and_update_distribution_nine.sql.sql b/supabase/migrations/20241123134636_create_send_slash_table_and_update_distribution_nine.sql.sql new file mode 100644 index 000000000..5e3dc5120 --- /dev/null +++ b/supabase/migrations/20241123134636_create_send_slash_table_and_update_distribution_nine.sql.sql @@ -0,0 +1,119 @@ +-- Change the amount of the distribution to 300,000,000 SEND +UPDATE + public.distributions +SET + amount = 300000000 -- 300,000,000 SEND +WHERE + id = 9; + +CREATE INDEX idx_transfers_composite ON send_token_transfers(block_time, f, t, v); + +-- Add send_ceiling verification type +ALTER TYPE public.verification_type + ADD VALUE IF NOT EXISTS 'send_ceiling'; + +-- Create new table for send slash settings +CREATE TABLE "public"."send_slash"( + "distribution_number" integer PRIMARY KEY, + "minimum_sends" smallint DEFAULT '1' ::smallint NOT NULL, + "scaling_divisor" smallint DEFAULT '1' ::smallint NOT NULL, + CONSTRAINT "send_slash_distribution_number_fkey" FOREIGN KEY ("distribution_number") REFERENCES "public"."distributions"("number") ON DELETE CASCADE +); + +ALTER TABLE send_slash ENABLE ROW LEVEL SECURITY; + +-- Add amount_after_slash column to distribution_shares +ALTER TABLE public.distribution_shares + ADD COLUMN amount_after_slash numeric NOT NULL DEFAULT 0; + +UPDATE + public.distribution_shares +SET + amount_after_slash = amount; + +-- After update, we could remove the default if desired +ALTER TABLE public.distribution_shares + ALTER COLUMN amount_after_slash DROP DEFAULT; + +INSERT INTO public.send_slash( + distribution_number, + minimum_sends, + scaling_divisor) +VALUES ( + 9, + 50, + 3); + +CREATE OR REPLACE FUNCTION public.update_distribution_shares(distribution_id integer, shares distribution_shares[]) + RETURNS void + LANGUAGE plpgsql + SECURITY DEFINER + SET search_path TO 'public' + AS $function$ +BEGIN + -- validate shares are greater than 0 + IF( + SELECT + count(*) + FROM + unnest(shares) shares + WHERE + shares.amount_after_slash <= 0) > 0 THEN + RAISE EXCEPTION 'Shares must be greater than 0.'; + END IF; + -- get the distribution + IF( + SELECT + 1 + FROM + distributions d + WHERE + d.id = $1 + LIMIT 1) IS NULL THEN + RAISE EXCEPTION 'Distribution not found.'; + END IF; + -- validate shares are for the correct distribution + IF( + SELECT + count(DISTINCT id) + FROM + distributions + WHERE + id IN( + SELECT + shares.distribution_id + FROM + unnest(shares) shares)) <> 1 THEN + RAISE EXCEPTION 'Shares are for the wrong distribution.'; + END IF; + -- delete existing shares + DELETE FROM distribution_shares + WHERE distribution_shares.distribution_id = $1; + -- insert new shares + INSERT INTO distribution_shares( + distribution_id, + user_id, + address, + amount, + amount_after_slash, + hodler_pool_amount, + bonus_pool_amount, + fixed_pool_amount, + "index") + SELECT + update_distribution_shares.distribution_id, + shares.user_id, + shares.address, + shares.amount, + shares.amount_after_slash, + shares.hodler_pool_amount, + shares.bonus_pool_amount, + shares.fixed_pool_amount, + row_number() OVER(PARTITION BY update_distribution_shares.distribution_id ORDER BY shares.address) - 1 AS "index" + FROM + unnest(shares) shares +ORDER BY + shares.address; +END; +$function$; + diff --git a/supabase/migrations/20241124071815_insert_send_ceiling_verification.sql b/supabase/migrations/20241124071815_insert_send_ceiling_verification.sql new file mode 100644 index 000000000..47e17b525 --- /dev/null +++ b/supabase/migrations/20241124071815_insert_send_ceiling_verification.sql @@ -0,0 +1,294 @@ +INSERT INTO public.distribution_verification_values( + type, + fixed_value, + bips_value, + distribution_id) +VALUES ( + 'send_ceiling' ::public.verification_type, + 0, + 0, +( + SELECT + id + FROM + distributions + WHERE + number = 9)); + +CREATE OR REPLACE FUNCTION sum_qualification_sends(distribution_number integer, send_ceiling numeric) + RETURNS TABLE( + user_id uuid, + amount numeric, + sent_to citext[]) + LANGUAGE plpgsql + AS $$ +BEGIN + -- Create temporary table to store qualification period + CREATE TEMPORARY TABLE IF NOT EXISTS qual_period AS + SELECT + extract(epoch FROM qualification_start) AS start_time, + extract(epoch FROM qualification_end) AS end_time + FROM + distributions + WHERE + number = distribution_number; + -- Create temporary table for first sends to each address + CREATE TEMPORARY TABLE first_sends AS SELECT DISTINCT ON(sa.user_id, concat('0x', encode(stt.t, 'hex') +)::citext) sa.user_id, + concat('0x', encode(stt.t, 'hex'))::citext AS recipient, + LEAST(stt.v, send_ceiling) AS capped_amount, + stt.block_time +FROM + send_token_transfers stt + JOIN send_accounts sa ON sa.address = concat('0x', encode(stt.f, 'hex'))::citext + CROSS JOIN qual_period qp +WHERE + stt.block_time >= qp.start_time + AND stt.block_time < qp.end_time + ORDER BY + sa.user_id, + concat('0x', encode(stt.t, 'hex'))::citext, + stt.block_time; + -- Create index for performance + CREATE INDEX ON first_sends(user_id); + -- Return aggregated results + RETURN QUERY + SELECT + fs.user_id, + SUM(fs.capped_amount) AS amount, + array_agg(fs.recipient) AS sent_to + FROM + first_sends fs + GROUP BY + fs.user_id; + -- Cleanup + DROP TABLE IF EXISTS qual_period; + DROP TABLE IF EXISTS first_sends; +END; +$$; + +-- Update the initial insert to include sent_to array +CREATE OR REPLACE FUNCTION calculate_and_insert_send_ceiling_verification(distribution_number integer) + RETURNS void + LANGUAGE plpgsql + AS $$ +BEGIN + WITH send_settings AS( + SELECT + minimum_sends * scaling_divisor AS divider + FROM + send_slash ss + WHERE + ss.distribution_number = $1 +), +previous_distribution AS( + SELECT + ds.user_id, + ds.amount AS user_prev_shares + FROM + distribution_shares ds + WHERE + ds.distribution_id =( + SELECT + id + FROM + distributions d + WHERE + d.number = $1 - 1) +), +send_ceiling_settings AS( + SELECT + pd.user_id, + ROUND(COALESCE(pd.user_prev_shares, d.hodler_min_balance) / ss.divider)::numeric AS send_ceiling + FROM + distributions d + JOIN previous_distribution pd ON TRUE + CROSS JOIN send_settings ss + WHERE + d.number = $1 +), +qualifying_sends AS( + SELECT + qs.user_id, + qs.amount, + qs.sent_to + FROM + send_ceiling_settings scs + LEFT JOIN LATERAL sum_qualification_sends($1, scs.send_ceiling) qs ON qs.user_id = scs.user_id) + INSERT INTO distribution_verifications( + distribution_id, + user_id, + type, + weight, + metadata) + SELECT +( + SELECT + id + FROM + distributions d + WHERE + d.number = $1), qs.user_id, 'send_ceiling'::public.verification_type, qs.amount, jsonb_build_object('value', scs.send_ceiling, 'sent_to', qs.sent_to) + FROM + qualifying_sends qs + JOIN send_ceiling_settings scs ON scs.user_id = qs.user_id + WHERE + qs.amount > 0; +END; +$$; + +SELECT + calculate_and_insert_send_ceiling_verification(9); + +CREATE OR REPLACE FUNCTION insert_verification_send_ceiling() + RETURNS TRIGGER + LANGUAGE plpgsql + AS $$ +DECLARE + _user_id uuid; + _recipient_address citext; + _distribution_id integer; + _distribution_number integer; + _send_ceiling numeric; + _verification_exists boolean; +BEGIN + -- Get the sender's user_id + SELECT + user_id INTO _user_id + FROM + send_accounts + WHERE + address = concat('0x', encode(NEW.f, 'hex'))::citext; + -- Get recipient address + _recipient_address := concat('0x', encode(NEW.t, 'hex'))::citext; + -- Get the active distribution id and number + SELECT + d.id, + d.number INTO _distribution_id, + _distribution_number + FROM + distributions d + WHERE + extract(epoch FROM d.qualification_start) <= NEW.block_time + AND extract(epoch FROM d.qualification_end) > NEW.block_time + AND d.number = 9; + -- If we found matching distribution and user + IF _user_id IS NOT NULL AND _distribution_id IS NOT NULL THEN + -- Check if verification exists + SELECT + EXISTS ( + SELECT + 1 + FROM + distribution_verifications + WHERE + user_id = _user_id + AND distribution_id = _distribution_id + AND type = 'send_ceiling') INTO _verification_exists; + IF NOT _verification_exists THEN + -- Get send ceiling from send_ceiling_settings calculation + WITH send_settings AS ( + SELECT + minimum_sends * scaling_divisor AS divider + FROM + send_slash + WHERE + distribution_number = _distribution_number +), -- Added comma here +previous_distribution AS ( + SELECT + ds.amount AS user_prev_shares + FROM + distribution_shares ds + WHERE + ds.distribution_id =( + SELECT + id + FROM + distributions + WHERE + number = _distribution_number - 1) + AND ds.user_id = _user_id +), -- Added comma here +distribution_info AS ( + SELECT + hodler_min_balance + FROM + distributions + WHERE + id = _distribution_id) -- Removed semicolon here + SELECT + ROUND(COALESCE(pd.user_prev_shares, di.hodler_min_balance) / ss.divider)::numeric INTO _send_ceiling + FROM + distribution_info di + CROSS JOIN send_settings ss + LEFT JOIN previous_distribution pd ON TRUE; + -- Create new verification + INSERT INTO distribution_verifications( + distribution_id, + user_id, + type, + weight, + metadata) + VALUES ( + _distribution_id, + _user_id, + 'send_ceiling', + LEAST( + NEW.v, _send_ceiling), + jsonb_build_object( + 'value', _send_ceiling, 'sent_to', ARRAY[_recipient_address])); +ELSE + -- Get the send ceiling for existing verification + SELECT + (metadata ->> 'value')::numeric INTO _send_ceiling + FROM + distribution_verifications + WHERE + user_id = _user_id + AND distribution_id = _distribution_id + AND type = 'send_ceiling'; + -- Update existing verification + UPDATE + distribution_verifications + SET + metadata = jsonb_set(metadata, '{sent_to}', to_jsonb(array_append(COALESCE(metadata -> 'sent_to'::citext[], ARRAY[]::citext[]), _recipient_address))), + weight = weight + LEAST(NEW.v, _send_ceiling) + WHERE + user_id = _user_id + AND distribution_id = _distribution_id + AND type = 'send_ceiling' + AND NOT (_recipient_address = ANY (metadata -> 'sent_to'::citext[])); +END IF; +END IF; + RETURN NEW; +END; +$$; + +-- Add trigger +CREATE TRIGGER insert_verification_send_ceiling_trigger + AFTER INSERT ON send_token_transfers + FOR EACH ROW + EXECUTE FUNCTION insert_verification_send_ceiling(); + +-- Revoke execute from all roles for sum_qualification_sends +REVOKE EXECUTE ON FUNCTION "public"."sum_qualification_sends"(integer, numeric) FROM PUBLIC; + +REVOKE EXECUTE ON FUNCTION "public"."sum_qualification_sends"(integer, numeric) FROM anon; + +REVOKE EXECUTE ON FUNCTION "public"."sum_qualification_sends"(integer, numeric) FROM authenticated; + +-- Revoke execute from all roles for calculate_and_insert_send_ceiling_verification +REVOKE EXECUTE ON FUNCTION "public"."calculate_and_insert_send_ceiling_verification"(integer) FROM PUBLIC; + +REVOKE EXECUTE ON FUNCTION "public"."calculate_and_insert_send_ceiling_verification"(integer) FROM anon; + +REVOKE EXECUTE ON FUNCTION "public"."calculate_and_insert_send_ceiling_verification"(integer) FROM authenticated; + +-- Revoke execute from all roles for update_send_ceiling_verification +REVOKE EXECUTE ON FUNCTION "public"."insert_verification_send_ceiling"() FROM PUBLIC; + +REVOKE EXECUTE ON FUNCTION "public"."insert_verification_send_ceiling"() FROM anon; + +REVOKE EXECUTE ON FUNCTION "public"."insert_verification_send_ceiling"() FROM authenticated; +