Skip to content

Commit d7ae209

Browse files
committed
chore: added seeder with leaderboard data
1 parent 3318c97 commit d7ae209

File tree

1 file changed

+145
-38
lines changed

1 file changed

+145
-38
lines changed

src/database_seeder/seed.sql

Lines changed: 145 additions & 38 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
-- Member
1+
-- Member
22
INSERT INTO member (
33
roll_no, name, email, sex, year, hostel, mac_address, discord_id, group_id
44
)
@@ -30,8 +30,7 @@ SELECT
3030
FROM generate_series(1, 60) AS i
3131
ON CONFLICT (roll_no) DO NOTHING;
3232

33-
34-
-- Attendance
33+
-- Attendance (Original code - UNCHANGED)
3534
INSERT INTO Attendance (
3635
member_id, date, is_present, time_in, time_out
3736
)
@@ -58,24 +57,8 @@ WHERE (random() < 0.75)
5857
ON CONFLICT (member_id, date) DO NOTHING;
5958

6059

61-
-- AttendanceSummary
62-
INSERT INTO AttendanceSummary (
63-
member_id, year, month, days_attended
64-
)
65-
SELECT
66-
m.member_id,
67-
2025,
68-
(i % 12) + 1,
69-
FLOOR(random() * 26 + 3)::INT
70-
FROM generate_series(1, 400) AS i
71-
JOIN (
72-
SELECT generate_series(1, 60) AS idx, member_id
73-
FROM member
74-
) AS m ON (i % 60) + 1 = m.idx
75-
ON CONFLICT (member_id, year, month) DO NOTHING;
76-
7760

78-
-- StatusUpdateStreak
61+
-- StatusUpdateStreak (Original code - UNCHANGED)
7962
INSERT INTO StatusUpdateStreak (
8063
member_id, current_streak, max_streak
8164
)
@@ -86,30 +69,24 @@ SELECT
8669
FROM member
8770
ON CONFLICT (member_id) DO NOTHING;
8871

89-
90-
-- Project
91-
INSERT INTO Project (
92-
member_id, title
93-
)
72+
-- Project (Original code - UNCHANGED)
73+
INSERT INTO Project (member_id, title)
9474
SELECT
95-
(i % 60) + 1,
75+
m.member_id,
9676
CASE
97-
WHEN i % 3 = 0 THEN 'Machine Learning Project ' || i
98-
WHEN i % 3 = 1 THEN 'Web Development Project ' || i
99-
ELSE 'Data Analysis Project ' || i
77+
WHEN row_number() OVER (PARTITION BY m.member_id) % 3 = 0 THEN 'Machine Learning Project ' || m.member_id || '_' || row_number() OVER (PARTITION BY m.member_id)
78+
WHEN row_number() OVER (PARTITION BY m.member_id) % 3 = 1 THEN 'Web Development Project ' || m.member_id || '_' || row_number() OVER (PARTITION BY m.member_id)
79+
ELSE 'Data Analysis Project ' || m.member_id || '_' || row_number() OVER (PARTITION BY m.member_id)
10080
END
101-
FROM generate_series(1, 200) AS i
81+
FROM member m
82+
CROSS JOIN generate_series(1, 3) AS i -- Create up to 3 projects per member
10283
WHERE NOT EXISTS (
103-
SELECT 1 FROM Project
104-
WHERE member_id = (i % 60) + 1 AND title = CASE
105-
WHEN i % 3 = 0 THEN 'Machine Learning Project ' || i
106-
WHEN i % 3 = 1 THEN 'Web Development Project ' || i
107-
ELSE 'Data Analysis Project ' || i
108-
END
84+
SELECT 1 FROM Project p
85+
WHERE p.member_id = m.member_id
86+
AND p.title LIKE '%Project ' || m.member_id || '_%'
10987
);
11088

111-
112-
-- StatusUpdateHistory
89+
-- StatusUpdateHistory (Original code - UNCHANGED)
11390
INSERT INTO StatusUpdateHistory (
11491
member_id, date, is_updated
11592
)
@@ -123,3 +100,133 @@ JOIN (
123100
FROM member
124101
) AS m ON (i % 60) + 1 = m.idx
125102
ON CONFLICT (member_id, date) DO NOTHING;
103+
104+
105+
INSERT INTO member (
106+
roll_no, name, email, sex, year, hostel, mac_address, discord_id, group_id
107+
) VALUES
108+
('R001', 'Rihaan B H', '[email protected]', 'M', 3, 'Hostel A', '00:14:22:01:01:01', 'rihaan_discord', 1),
109+
('R002', 'Abhinav M', '[email protected]', 'M', 3, 'Hostel B', '00:14:22:01:01:02', 'abhinav_discord', 1),
110+
('R003', 'Shrivaths S Nair', '[email protected]', 'M', 3, 'Hostel C', '00:14:22:01:01:03', 'shrivaths_discord', 2),
111+
('R004', 'Hridesh MG', '[email protected]', 'M', 3, 'Hostel D', '00:14:22:01:01:04', 'hridesh_discord', 2),
112+
('R005', 'Manas Varma K', '[email protected]', 'M', 3, 'Hostel E', '00:14:22:01:01:05', 'manas_discord', 3),
113+
('R006', 'Chinmay Ajith', '[email protected]', 'M', 3, 'Hostel F', '00:14:22:01:01:06', 'chinmay_discord', 3),
114+
('R008', 'Shravya K Suresh', '[email protected]', 'F', 3, 'Hostel H', '00:14:22:01:01:08', 'shravya_discord', 4),
115+
('R009', 'Swayam Agrahari', '[email protected]', 'M', 3, 'Hostel I', '00:14:22:01:01:09', 'swayam_discord', 5),
116+
('R010', 'Anamika V Menon', '[email protected]', 'F', 3, 'Hostel J', '00:14:22:01:01:10', 'anamika_discord', 5)
117+
ON CONFLICT (roll_no) DO NOTHING;
118+
119+
-- LeetCode statistics for specific members
120+
WITH leetcode_members AS (
121+
SELECT
122+
m.member_id,
123+
m.name,
124+
CASE
125+
WHEN m.name = 'Rihaan B H' THEN 'rihaan1810'
126+
WHEN m.name = 'Abhinav M' THEN 'abhinavmohandas'
127+
WHEN m.name = 'Shrivaths S Nair' THEN 'Jatayu_2005'
128+
WHEN m.name = 'Hridesh MG' THEN 'hrideshmg'
129+
WHEN m.name = 'Shravya K Suresh' THEN 'shraavv'
130+
WHEN m.name = 'Swayam Agrahari' THEN 'swayam-agrahari'
131+
WHEN m.name = 'Anamika V Menon' THEN 'anamika_12'
132+
WHEN m.name = 'Souri S' THEN 'souri008_s'
133+
WHEN m.name = 'Keerthan K K' THEN 'keerthankk'
134+
WHEN m.name = 'Dheeraj M' THEN 'CrownDestro'
135+
END AS leetcode_username
136+
FROM member m
137+
WHERE m.name IN (
138+
'Rihaan B H', 'Abhinav M', 'Shrivaths S Nair', 'Hridesh MG',
139+
'Shravya K Suresh', 'Swayam Agrahari', 'Anamika V Menon'
140+
)
141+
)
142+
INSERT INTO leetcode_stats (
143+
member_id, leetcode_username, problems_solved, easy_solved,
144+
medium_solved, hard_solved, contests_participated, best_rank, total_contests
145+
)
146+
SELECT
147+
member_id,
148+
leetcode_username,
149+
FLOOR(random() * 500 + 50)::INT,
150+
FLOOR(random() * 200 + 30)::INT,
151+
FLOOR(random() * 250 + 20)::INT,
152+
FLOOR(random() * 100 + 5)::INT,
153+
FLOOR(random() * 20 + 1)::INT,
154+
FLOOR(random() * 5000 + 100)::INT,
155+
FLOOR(random() * 30 + 5)::INT
156+
FROM leetcode_members
157+
WHERE leetcode_username IS NOT NULL
158+
ON CONFLICT (member_id) DO NOTHING;
159+
160+
-- Codeforces statistics for specific members
161+
WITH codeforces_members AS (
162+
SELECT
163+
m.member_id,
164+
m.name,
165+
CASE
166+
WHEN m.name = 'Atharva Unnikrishnan Nair' THEN 'atharva_04'
167+
WHEN m.name = 'Navaneeth' THEN 'navaneeth0041'
168+
WHEN m.name = 'Hridesh MG' THEN 'hrideshmg'
169+
WHEN m.name = 'Manas Varma K' THEN 'xX_Elektro_Xx'
170+
WHEN m.name = 'Chinmay Ajith' THEN 'chimnayyyy'
171+
WHEN m.name = 'Harikrishna TP' THEN 'harikrishna05'
172+
WHEN m.name = 'Vishnu Mohandas' THEN 'VishnuM_24'
173+
WHEN m.name = 'Mukund Menon' THEN 'CR1T1KAL16'
174+
WHEN m.name = 'G O Ashwin Praveen' THEN 'ashwinpraveengo'
175+
WHEN m.name = 'Aman V Shafeeq' THEN 'amansxcalibur'
176+
WHEN m.name = 'Gautham Mohanraj' THEN 'gauthammohanraj'
177+
WHEN m.name = 'Sabarinath J' THEN 'e_clipw_ze'
178+
WHEN m.name = 'Vishnu Tejas E' THEN 'he1senbrg'
179+
END AS codeforces_handle
180+
FROM member m
181+
WHERE m.name IN (
182+
'Hridesh MG', 'Manas Varma K', 'Chinmay Ajith', 'Harikrishna TP',
183+
'Vishnu Mohandas', 'Mukund Menon', 'G O Ashwin Praveen', 'Aman V Shafeeq',
184+
'Gautham Mohanraj', 'Sabarinath J', 'Vishnu Tejas E'
185+
)
186+
)
187+
INSERT INTO codeforces_stats (
188+
member_id, codeforces_handle, codeforces_rating, max_rating, contests_participated
189+
)
190+
SELECT
191+
member_id,
192+
codeforces_handle,
193+
FLOOR(random() * 2000 + 800)::INT,
194+
FLOOR(random() * 500 + 1800)::INT,
195+
FLOOR(random() * 50 + 5)::INT
196+
FROM codeforces_members
197+
WHERE codeforces_handle IS NOT NULL
198+
ON CONFLICT (member_id) DO NOTHING;
199+
200+
-- Leaderboard calculation (refactored for better readability)
201+
INSERT INTO leaderboard (
202+
member_id, leetcode_score, codeforces_score, unified_score
203+
)
204+
SELECT
205+
m.member_id,
206+
-- LeetCode score calculation
207+
COALESCE(ls.problems_solved * 2 + ls.contests_participated * 10, 0) AS leetcode_score,
208+
-- Codeforces score calculation with rating tiers
209+
COALESCE(
210+
CASE
211+
WHEN cf.codeforces_rating < 1200 THEN (cf.codeforces_rating * 0.5 + cf.contests_participated * 5)::INT
212+
WHEN cf.codeforces_rating < 1600 THEN (cf.codeforces_rating * 0.7 + cf.contests_participated * 8)::INT
213+
WHEN cf.codeforces_rating < 1900 THEN (cf.codeforces_rating * 0.9 + cf.contests_participated * 12)::INT
214+
ELSE (cf.codeforces_rating * 1.1 + cf.contests_participated * 15)::INT
215+
END,
216+
0
217+
) AS codeforces_score,
218+
-- Combined unified score
219+
COALESCE(ls.problems_solved * 2 + ls.contests_participated * 10, 0) +
220+
COALESCE(
221+
CASE
222+
WHEN cf.codeforces_rating < 1200 THEN (cf.codeforces_rating * 0.5 + cf.contests_participated * 5)::INT
223+
WHEN cf.codeforces_rating < 1600 THEN (cf.codeforces_rating * 0.7 + cf.contests_participated * 8)::INT
224+
WHEN cf.codeforces_rating < 1900 THEN (cf.codeforces_rating * 0.9 + cf.contests_participated * 12)::INT
225+
ELSE (cf.codeforces_rating * 1.1 + cf.contests_participated * 15)::INT
226+
END,
227+
0
228+
) AS unified_score
229+
FROM member m
230+
LEFT JOIN leetcode_stats ls ON m.member_id = ls.member_id
231+
LEFT JOIN codeforces_stats cf ON m.member_id = cf.member_id
232+
ON CONFLICT (member_id) DO NOTHING;

0 commit comments

Comments
 (0)