1
+ set check_function_bodies = off;
2
+
3
+ CREATE OR REPLACE FUNCTION public .insert_send_streak_verification()
4
+ RETURNS trigger
5
+ LANGUAGE plpgsql
6
+ SECURITY DEFINER
7
+ SET search_path TO ' public'
8
+ AS $function$
9
+ DECLARE
10
+ curr_distribution_id bigint ;
11
+ from_user_id uuid;
12
+ to_user_id uuid;
13
+ unique_recipient_count integer ;
14
+ current_streak integer ;
15
+ existing_record_id bigint ;
16
+ ignored_addresses bytea [] := ARRAY[' \x 592e1224d203be4214b15e205f6081fbbacfcd2d' ::bytea , ' \x 36f43082d01df4801af2d95aeed1a0200c5510ae' ::bytea ];
17
+ BEGIN
18
+ -- Get the current distribution id
19
+ SELECT id INTO curr_distribution_id
20
+ FROM distributions
21
+ WHERE qualification_start <= CURRENT_TIMESTAMP AT TIME ZONE ' UTC'
22
+ AND qualification_end >= CURRENT_TIMESTAMP AT TIME ZONE ' UTC'
23
+ ORDER BY qualification_start DESC
24
+ LIMIT 1 ;
25
+
26
+ -- Get user_ids from send_accounts
27
+ SELECT user_id INTO from_user_id
28
+ FROM send_accounts
29
+ WHERE address = concat(' 0x' , encode(NEW .f , ' hex' ))::citext;
30
+
31
+ SELECT user_id INTO to_user_id
32
+ FROM send_accounts
33
+ WHERE address = concat(' 0x' , encode(NEW .t , ' hex' ))::citext;
34
+
35
+ IF curr_distribution_id IS NOT NULL AND from_user_id IS NOT NULL AND to_user_id IS NOT NULL THEN
36
+ -- Calculate streak with simplified unique recipients per day logic
37
+ WITH daily_unique_transfers AS (
38
+ SELECT
39
+ DATE (to_timestamp(block_time) at time zone ' UTC' ) AS transfer_date
40
+ FROM send_token_transfers stt
41
+ WHERE f = NEW .f
42
+ AND NOT (t = ANY (ignored_addresses))
43
+ AND block_time >= (
44
+ SELECT extract(epoch FROM qualification_start)
45
+ FROM distributions
46
+ WHERE id = curr_distribution_id
47
+ )
48
+ GROUP BY DATE (to_timestamp(block_time) at time zone ' UTC' )
49
+ HAVING COUNT (DISTINCT t) > 0
50
+ ),
51
+ streaks AS (
52
+ SELECT
53
+ transfer_date,
54
+ transfer_date - (ROW_NUMBER() OVER (ORDER BY transfer_date))::integer AS streak_group
55
+ FROM daily_unique_transfers
56
+ )
57
+ SELECT COUNT (* ) INTO current_streak
58
+ FROM streaks
59
+ WHERE streak_group = (
60
+ SELECT streak_group
61
+ FROM streaks
62
+ WHERE transfer_date = DATE (to_timestamp(NEW .block_time ) at time zone ' UTC' )
63
+ );
64
+
65
+ -- Handle send_streak verification
66
+ SELECT id INTO existing_record_id
67
+ FROM public .distribution_verifications
68
+ WHERE distribution_id = curr_distribution_id
69
+ AND user_id = from_user_id
70
+ AND type = ' send_streak' ::public .verification_type ;
71
+
72
+ IF existing_record_id IS NOT NULL THEN
73
+ UPDATE public .distribution_verifications
74
+ SET weight = GREATEST(current_streak, weight),
75
+ created_at = to_timestamp(NEW .block_time ) at time zone ' UTC'
76
+ WHERE id = existing_record_id;
77
+ ELSE
78
+ INSERT INTO public .distribution_verifications (
79
+ distribution_id,
80
+ user_id,
81
+ type,
82
+ created_at,
83
+ weight
84
+ )
85
+ VALUES (
86
+ curr_distribution_id,
87
+ from_user_id,
88
+ ' send_streak' ::public .verification_type ,
89
+ to_timestamp(NEW .block_time ) at time zone ' UTC' ,
90
+ current_streak
91
+ );
92
+ END IF;
93
+ END IF;
94
+
95
+ RETURN NEW;
96
+ END;
97
+ $function$
98
+ ;
99
+
100
+ select * from insert_send_streak_verifications(16 );
101
+
102
+ -- Add security settings to existing views
103
+ ALTER MATERIALIZED VIEW " private" ." send_scores_history" OWNER TO postgres;
104
+ ALTER VIEW " public" ." send_scores_current_unique" OWNER TO postgres;
105
+ ALTER VIEW " public" ." send_scores_current" OWNER TO postgres;
106
+ ALTER VIEW " public" ." send_scores" OWNER TO postgres;
107
+
108
+ -- Permissions
109
+ REVOKE ALL ON " private" ." send_scores_history" FROM PUBLIC;
110
+ REVOKE ALL ON " private" ." send_scores_history" FROM authenticated;
111
+ GRANT ALL ON " private" ." send_scores_history" TO service_role;
112
+
113
+ GRANT ALL ON " public" ." send_scores_current_unique" TO PUBLIC;
114
+ GRANT ALL ON " public" ." send_scores_current_unique" TO service_role;
115
+ GRANT ALL ON " public" ." send_scores_current_unique" TO authenticated;
116
+
117
+ REVOKE ALL ON " public" ." send_scores_current" FROM PUBLIC;
118
+ REVOKE ALL ON " public" ." send_scores_current" FROM anon;
119
+ GRANT ALL ON " public" ." send_scores_current" TO service_role;
120
+ GRANT ALL ON " public" ." send_scores_current" TO authenticated;
121
+
122
+ GRANT ALL ON " public" ." send_scores" TO PUBLIC;
123
+ GRANT ALL ON " public" ." send_scores" TO service_role;
124
+ GRANT ALL ON " public" ." send_scores" TO authenticated;
0 commit comments