Implement stored procedure for the first time

This commit is contained in:
Dita Aji Pratama 2025-09-03 14:21:45 +07:00
parent 9b414339ca
commit 356d88f73a
2 changed files with 36 additions and 13 deletions

View File

@ -36,6 +36,7 @@ class auth:
self.cursor.execute(f"SELECT `id` FROM `auth_roles` WHERE `name` = %s ;", (roles,) )
result_roles = self.cursor.fetchone()
loggorilla.prcss(APIADDR, "Process parameters")
ls_roles = [ result_roles["id"] ]
hashed = bcrypt.hashpw(password.encode(), bcrypt.gensalt()).decode()
token = saltedkey.token(username, hashed)
if globalvar.production == True:
@ -51,11 +52,7 @@ class auth:
result_validation = procedure_validation.validation().register(APIADDR, captcha, score, roles, username, password, email)
if result_validation['status'] == "valid":
loggorilla.prcss(APIADDR, "Inserting")
self.cursor.execute("INSERT INTO `auth` VALUES (%s, %s);", (token, hashed) )
self.cursor.execute("INSERT INTO `auth_profile` VALUES (DEFAULT, %s, %s, %s, NULL);", (token, username, email) )
auth_profile_lastrowid = self.cursor.lastrowid
self.cursor.execute("INSERT INTO `auth_profile_verification` VALUES (DEFAULT, %s, 'email', 0);", (auth_profile_lastrowid,) )
self.cursor.execute("INSERT INTO `auth_profile_roles` VALUES (DEFAULT, %s, %s);", (auth_profile_lastrowid, result_roles['id']) )
self.cursor.execute("CALL sp_auth_add(%s, %s, %s, %s, %s, %s);", (token, hashed, username, email, 0, str(ls_roles)) )
loggorilla.prcss(APIADDR, "Set expired datetime")
expired = globalvar.verification_link_expiration
expired_isoformat = expired.isoformat()
@ -378,12 +375,7 @@ class auth:
hashed = bcrypt.hashpw(password.encode(), bcrypt.gensalt()).decode()
token = saltedkey.token(username, hashed)
loggorilla.prcss(APIADDR, "Inserting")
self.cursor.execute("INSERT INTO `auth` VALUES (%s, %s);", (token, hashed) )
self.cursor.execute("INSERT INTO `auth_profile` VALUES (DEFAULT, %s, %s, %s, NULL);", (token, username, email) )
auth_profile_lastrowid = self.cursor.lastrowid
self.cursor.execute("INSERT INTO `auth_profile_verification` VALUES (DEFAULT, %s, 'email', 1);", (auth_profile_lastrowid,) )
for role in roles:
self.cursor.execute("INSERT INTO `auth_profile_roles` VALUES (DEFAULT, %s, %s);", (auth_profile_lastrowid, role) )
self.cursor.execute("CALL sp_auth_add(%s, %s, %s, %s, %s, %s);", (token, hashed, username, email, 1, str(roles)) )
loggorilla.prcss(APIADDR, "Sending email")
webmail_data = {
"username" : username,

View File

@ -1,8 +1,11 @@
-- README
-- idx_ = index
-- fk_ = foreign
-- Prefix idx_ = index
-- Prefix fk_ = foreign
-- Create an index for fast lookups
-- Defining constraints separately for better readability & maintainability
-- Prefix sp_ = Stored Procedure
-- Prefix p_ = Parameter(s)
-- Prefix v_ = Variable(s)
-- NOTE
-- Next verification variation should be based from identity and contact
@ -75,3 +78,31 @@ INSERT INTO `auth_roles` VALUES
(3, 'member' ),
(4, 'tester' );
DELIMITER //
CREATE PROCEDURE sp_auth_add(
IN p_token binary(40),
IN p_hashed binary(60),
IN p_username varchar(36),
IN p_email LONGTEXT,
IN p_verified int(1), -- register:0, accept:1
IN p_roles JSON -- example: [1,2,4]. Roles duplication was checked on Back-End side.
)
BEGIN
DECLARE i INT DEFAULT 0;
DECLARE n INT;
DECLARE v_auth_profile_lastrowid INT(11);
INSERT INTO `auth` VALUES (p_token, p_hashed);
INSERT INTO `auth_profile` VALUES (DEFAULT, p_token, p_username, p_email, NULL);
SET v_auth_profile_lastrowid = LAST_INSERT_ID();
INSERT INTO `auth_profile_verification` VALUES (DEFAULT, v_auth_profile_lastrowid, 'email', p_verified);
SET n = JSON_LENGTH(p_roles);
WHILE i < n DO
INSERT INTO `auth_profile_roles` VALUES (
DEFAULT,
v_auth_profile_lastrowid,
JSON_UNQUOTE(JSON_EXTRACT(p_roles, CONCAT('$[', i, ']')))
);
SET i = i + 1;
END WHILE;
END //
DELIMITER ;