Newer
Older
SET vMaxRate = CalculateMaxRateForExtra(vDisciplineID, pStudentID);
END IF;
# 1) check rights
IF NOT InternalIsStudentAttached(pStudentID, vDisciplineID) OR
NOT InternalIsTeacherBound(pTeacherID, vDisciplineID) THEN
RETURN 1;
END IF;
# 2) check, you can't rate regular and bonus after milestone
IF (vIsOver AND (vModuleType = 1 OR vModuleType = 3)) THEN # 1 - regular, 3 - bonus
RETURN 2;
END IF;
IF pRate > vMaxRate THEN
RETURN 3;
END IF;
# add rate, or update old
SET @isUpdated = FALSE;
INSERT INTO rating_table (StudentID, TeacherID, SubmoduleID, Rate, Date)
VALUES ( pStudentID, pTeacherID, pSubmoduleID, pRate, CURDATE() )
ON DUPLICATE KEY UPDATE
rating_table.TeacherID = (@isUpdated := pTeacherID),
rating_table.Rate = pRate,
rating_table.Date = CURDATE();
# log rate
INSERT INTO logs_rating (StudentID, SubmoduleID, TeacherID, Rate, Action )
VALUES (pStudentID, pSubmoduleID, pTeacherID, pRate, IF(@isUpdated, 'change', 'add') );
# lock discipline for structure editing
IF NOT vIsLocked THEN
UPDATE disciplines
SET disciplines.IsLocked = TRUE
WHERE disciplines.ID = vDisciplineID
LIMIT 1;
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
END IF;
# add submodule to max rate counting (see triggers)
IF NOT vIsUsed THEN
UPDATE submodules
SET submodules.IsUsed = TRUE
WHERE submodules.ID = pSubmoduleID
LIMIT 1;
END IF;
RETURN 0;
END //
# -------------------------------------------------------------------------------------------
# Label: requests
# -------------------------------------------------------------------------------------------
DROP FUNCTION IF EXISTS SetRequestStatus//
CREATE FUNCTION SetRequestStatus (
pRequestID INT,
pStatus enum('opened','processed','closed')
) RETURNS int(11)
NO SQL
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
UPDATE requests
SET requests.Status = pStatus
WHERE requests.ID = pRequestID
LIMIT 1;
RETURN ROW_COUNT()-1;
END//
-- todo: does it work? HasImage field not found
DROP FUNCTION IF EXISTS CreateRequest//
CREATE FUNCTION CreateRequest (
pAccountID INT,
pTitle VARCHAR(50) CHARSET utf8,
pDescription TEXT CHARSET utf8,
pImage BOOLEAN
) RETURNS int(11)
NO SQL
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
INSERT INTO requests (AccountID, Title, Description, Status, HasImage)
VALUES (pAccountID, pTitle, pDescription, 'opened', pImage);
RETURN LAST_INSERT_ID();
END//
DROP FUNCTION IF EXISTS UpdateRequest//
CREATE FUNCTION UpdateRequest (
pRequestID INT,
pTitle VARCHAR(50) CHARSET utf8,
pDescription TEXT CHARSET utf8
) RETURNS int(11)
NO SQL
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -1;
UPDATE requests
SET requests.Description = pDescription,
requests.Title = pTitle,
requests.Date = NOW()
WHERE requests.ID = pRequestID AND
requests.Description IS NULL AND
requests.Title IS NULL
LIMIT 1;
RETURN ROW_COUNT()-1;
END//
# return StudentID or TeacherID depending on UserRoleID
DROP FUNCTION IF EXISTS GetUserStudentOrTeacherID//
CREATE FUNCTION GetUserStudentOrTeacherID (
pAccountID INT(11),
pUserRoleID INT(11)
) RETURNS INT(11)
READS SQL DATA
BEGIN
DECLARE vID INT DEFAULT -1;
IF pUserRoleID = GetUserRole('student') THEN
SELECT students.ID
INTO vID
FROM students
WHERE students.AccountID = pAccountID
LIMIT 1;
ELSE
SELECT teachers.ID
INTO vID
FROM teachers
WHERE teachers.AccountID = pAccountID
LIMIT 1;
END IF;
RETURN vID;
END//
# -------------------------------------------------------------------------------------------
# Label: recovery
# -------------------------------------------------------------------------------------------
DROP FUNCTION IF EXISTS CreateRecoveryToken//
CREATE FUNCTION CreateRecoveryToken (
pAccountOrEMail VARCHAR(255) CHARSET utf8,
pToken VARCHAR(100) CHARSET utf8
) RETURNS VARCHAR(255) charset utf8
NO SQL
BEGIN
DECLARE vAccountID INT DEFAULT -1;
DECLARE vUserFullName TEXT charset utf8;
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -2;
# get account ID
SELECT accounts.ID INTO vAccountID
FROM accounts
WHERE accounts.EMail = pAccountOrEMail OR
accounts.Login = pAccountOrEMail
LIMIT 1;
IF vAccountID <= 0 THEN
RETURN '';
END IF;
SET vUserFullName = GetUserFullNameByAccountID(vAccountID);
IF vUserFullName IS NULL OR vUserFullName = '' THEN
RETURN '';
END IF;
# transform all unused recovery tokens into used
UPDATE recovery_tokens
SET recovery_tokens.isUsed = 1
WHERE recovery_tokens.isUsed = 0 AND
recovery_tokens.AccountID = vAccountID;
# handle catch constraints violations
INSERT INTO recovery_tokens
( AccountID, Token )
VALUES (vAccountID, pToken);
RETURN vUserFullName;
END//
DROP FUNCTION IF EXISTS GetUserFullNameByAccountID//
CREATE FUNCTION GetUserFullNameByAccountID (
pAccountID INT(11)
) RETURNS VARCHAR(255) charset utf8
READS SQL DATA
BEGIN
DECLARE vUserFullName VARCHAR(255) charset utf8;
Artem Konenko
committed
SELECT CONCAT(accounts.LastName,' ',accounts.FirstName,' ',accounts.SecondName)
INTO vUserFullName
FROM accounts
WHERE ID = pAccountID
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
LIMIT 1;
RETURN vUserFullName;
END//
DROP FUNCTION IF EXISTS UseRecoveryToken//
CREATE FUNCTION UseRecoveryToken (
pToken VARCHAR(100) CHARSET utf8
) RETURNS int(11)
NO SQL
BEGIN
DECLARE vChecker INT DEFAULT -1;
# set token used
UPDATE recovery_tokens
SET recovery_tokens.IsUsed = 1
WHERE recovery_tokens.Token = pToken
LIMIT 1;
RETURN ROW_COUNT()-1;
END//
PavelBegunkov
committed
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
# -------------------------------------------------------------------------------------------
# Label: authorization
# -------------------------------------------------------------------------------------------
DROP FUNCTION IF EXISTS SignIn//
CREATE FUNCTION SignIn (
pLoginOrMail VARCHAR(255) CHARSET utf8,
pPassword VARCHAR(64) CHARSET utf8
) RETURNS int(11) # account id
NO SQL
BEGIN
DECLARE vAccountID INT DEFAULT -1;
#check account existence
SELECT accounts.ID INTO vAccountID FROM accounts
WHERE accounts.Password = SHA1(pPassword) AND
(accounts.Login = pLoginOrMail OR accounts.EMail = pLoginOrMail)
LIMIT 1;
IF vAccountID <= 0 THEN
RETURN -1;
END IF;
INSERT INTO logs_signin (AccountID) VALUES (vAccountID);
RETURN vAccountID;
END //
DROP FUNCTION IF EXISTS SignInByOpenID//
CREATE FUNCTION SignInByOpenID (
pGlobalKey VARCHAR(255) CHARSET utf8
) RETURNS int(11) # account id
NO SQL
#check account existence
SELECT accounts.ID INTO vAccountID FROM accounts
WHERE concat('st-', accounts.ExternalID) = pGlobalKey
OR concat('ss-', accounts.INILA) = pGlobalKey
LIMIT 1;
IF vAccountID <= 0 THEN
RETURN -1;
END IF;
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
INSERT INTO logs_signin (AccountID) VALUES (vAccountID);
RETURN vAccountID;
END //
DROP FUNCTION IF EXISTS SignInTeacherByOpenID//
CREATE FUNCTION SignInTeacherByOpenID (
pGlobalKey VARCHAR(255) CHARSET utf8
) RETURNS int(11) # account id
NO SQL
BEGIN
DECLARE vAccountID INT DEFAULT -1;
#check account existence
SELECT accounts.ID INTO vAccountID
FROM accounts
JOIN teachers ON accounts.ID = teachers.AccountID
WHERE teachers.INILA = pGlobalKey
LIMIT 1;
IF vAccountID <= 0 THEN
RETURN -1;
END IF;
INSERT INTO logs_signin (AccountID) VALUES (vAccountID);
RETURN vAccountID;
END //
PavelBegunkov
committed
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
-- returns:
-- -1 : invalid token
-- >0 : accountID
DROP FUNCTION IF EXISTS SignInByToken//
CREATE FUNCTION SignInByToken (pToken char(40) charset ascii) RETURNS int(11) # account id
NO SQL
BEGIN
DECLARE vAccountID INT DEFAULT -1;
SELECT auth_tokens.AccountID INTO vAccountID
FROM auth_tokens
WHERE auth_tokens.Token = pToken
LIMIT 1;
IF vAccountID = -1 THEN
RETURN -1; -- token not found
END IF;
UPDATE auth_tokens
SET Accessed = CURRENT_TIMESTAMP
WHERE auth_tokens.Token = pToken
LIMIT 1;
INSERT INTO logs_signin(AccountID) VALUES (vAccountID);
RETURN vAccountID;
END //
DROP FUNCTION IF EXISTS DeleteAuthToken//
CREATE FUNCTION DeleteAuthToken(pToken char(40) CHARSET ascii) RETURNS int(11)
NO SQL
BEGIN
DELETE FROM auth_tokens
WHERE auth_tokens.Token = pToken;
RETURN ROW_COUNT()-1;
END//
-- returns NULL if failed, token otherwise
PavelBegunkov
committed
DROP FUNCTION IF EXISTS CreateAuthToken//
CREATE FUNCTION CreateAuthToken(
pAccountID int(11),
pDescription varchar(60) CHARACTER SET utf8,
PavelBegunkov
committed
pRightMask int(11)
) RETURNS char(40) charset ascii
NO SQL
BEGIN
DECLARE vTries int(11) DEFAULT 13; -- number of tries to generate unique token
PavelBegunkov
committed
DECLARE vCreated boolean DEFAULT FALSE;
DECLARE vSeed int(11) DEFAULT FLOOR(4294967296 * RAND(CURRENT_TIMESTAMP ^ LAST_INSERT_ID() ^ (pAccountID << 10)));
DECLARE vToken char(40) charset ascii DEFAULT SHA1(vSeed);
WHILE NOT vCreated AND vTries > 0 DO BEGIN
PavelBegunkov
committed
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION SET vCreated = FALSE;
SET vToken = SHA1(RAND());
PavelBegunkov
committed
SET vCreated = TRUE;
INSERT INTO auth_tokens(Token, AccountID, Description, Mask) VALUES (vToken, pAccountID, pDescription, pRightMask);
PavelBegunkov
committed
END; END WHILE;
RETURN IF(vCreated, vToken, NULL);
PavelBegunkov
committed
END//
Юрий Федоров
committed
# -------------------------------------------------------------------------------------------
# Label: roles
# -------------------------------------------------------------------------------------------
DROP FUNCTION IF EXISTS SetRole//
CREATE FUNCTION `SetRole` (
`pID` INT,
`pRole` INT
) RETURNS tinyint(1)
NO SQL
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN 0;
UPDATE `accounts`
SET accounts.UserRoleID = pRole
WHERE accounts.ID = pID;
RETURN 1;
END //
# -------------------------------------------------------------------------------------------
# Label: text marks
# -------------------------------------------------------------------------------------------
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
CREATE FUNCTION `GetTextMark`(isAfterExam char(1), examType varchar(20), rate INT) RETURNS varchar(100) CHARSET utf8
NO SQL
BEGIN
declare markTextId int;
declare markText varchar(100) charset utf8;
if examType = 'credit' then
if rate < 60 then
set markTextId = 6;#незачет
else
set markTextId = 7;#зачет
end if;
elseif examType = 'gradingcredit' then
if rate >= 85 then
set markTextId = 5;#неуд.
elseif rate >= 70 then
set markTextId = 4;#хорошо
elseif rate >= 60 then
set markTextId = 3;#удовл.
else
set markTextId = 2;#неуд.
end if;
elseif isAfterExam = '0' then
if rate < 38 then
set markTextId = 1;#недопуск
else
return "";
end if;
else
if rate >= 85 then
set markTextId = 5;#неуд.
elseif rate >= 70 then
set markTextId = 4;#хорошо
elseif rate >= 60 then
set markTextId = 3;#удовл.
else
set markTextId = 2;#неуд.
end if;
end if;
select name from text_mark where id = markTextId into markText;
return markText;
END//
Artem Konenko
committed
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
-- Вспомогательные строковые функции
DROP FUNCTION IF EXISTS levenshtein//
CREATE FUNCTION levenshtein( s1 VARCHAR(255), s2 VARCHAR(255) )
RETURNS INT
DETERMINISTIC
BEGIN
DECLARE s1_len, s2_len, i, j, c, c_temp, cost INT;
DECLARE s1_char CHAR;
-- max strlen=255
DECLARE cv0, cv1 VARBINARY(256);
SET s1_len = CHAR_LENGTH(s1), s2_len = CHAR_LENGTH(s2), cv1 = 0x00, j = 1, i = 1, c = 0;
IF s1 = s2 THEN
RETURN 0;
ELSEIF s1_len = 0 THEN
RETURN s2_len;
ELSEIF s2_len = 0 THEN
RETURN s1_len;
ELSE
WHILE j <= s2_len DO
SET cv1 = CONCAT(cv1, UNHEX(HEX(j))), j = j + 1;
END WHILE;
WHILE i <= s1_len DO
SET s1_char = SUBSTRING(s1, i, 1), c = i, cv0 = UNHEX(HEX(i)), j = 1;
WHILE j <= s2_len DO
SET c = c + 1;
IF s1_char = SUBSTRING(s2, j, 1) THEN
SET cost = 0; ELSE SET cost = 1;
END IF;
SET c_temp = CONV(HEX(SUBSTRING(cv1, j, 1)), 16, 10) + cost;
IF c > c_temp THEN SET c = c_temp; END IF;
SET c_temp = CONV(HEX(SUBSTRING(cv1, j+1, 1)), 16, 10) + 1;
IF c > c_temp THEN
SET c = c_temp;
END IF;
SET cv0 = CONCAT(cv0, UNHEX(HEX(c))), j = j + 1;
END WHILE;
SET cv1 = cv0, i = i + 1;
END WHILE;
END IF;
RETURN c;
END//
DROP FUNCTION IF EXISTS levenshtein_ratio//
CREATE FUNCTION levenshtein_ratio( s1 VARCHAR(255), s2 VARCHAR(255) )
RETURNS INT
DETERMINISTIC
BEGIN
DECLARE s1_len, s2_len, max_len INT;
SET s1_len = LENGTH(s1), s2_len = LENGTH(s2);
IF s1_len > s2_len THEN
SET max_len = s1_len;
ELSE
SET max_len = s2_len;
END IF;
RETURN ROUND((1 - LEVENSHTEIN(s1, s2) / max_len) * 100);
END//