mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 19:27:49 +00:00
Update OTP, add support for telegram
This commit is contained in:
@@ -83,7 +83,7 @@ AS $recover_fn$
|
|||||||
DECLARE
|
DECLARE
|
||||||
_email CITEXT := email;
|
_email CITEXT := email;
|
||||||
_user_id TEXT := NULL;
|
_user_id TEXT := NULL;
|
||||||
otp_pass VARCHAR(10) := NULL;
|
otp_pass TEXT := NULL;
|
||||||
_reset_qs TEXT := NULL;
|
_reset_qs TEXT := NULL;
|
||||||
user_settings jsonb := NULL;
|
user_settings jsonb := NULL;
|
||||||
BEGIN
|
BEGIN
|
||||||
@@ -96,9 +96,8 @@ AS $recover_fn$
|
|||||||
RAISE EXCEPTION 'Invalid input'
|
RAISE EXCEPTION 'Invalid input'
|
||||||
USING HINT = 'Check your parameter';
|
USING HINT = 'Check your parameter';
|
||||||
END IF;
|
END IF;
|
||||||
-- OTP Code
|
-- Generate OTP
|
||||||
SELECT generate_uid_fn(6) INTO otp_pass;
|
otp_pass := api.generate_otp_fn(email);
|
||||||
INSERT INTO auth.otp (user_email, otp_pass) VALUES (_email, otp_pass);
|
|
||||||
SELECT CONCAT('uuid=', _user_id, '&token=', otp_pass) INTO _reset_qs;
|
SELECT CONCAT('uuid=', _user_id, '&token=', otp_pass) INTO _reset_qs;
|
||||||
-- Send email/notifications
|
-- Send email/notifications
|
||||||
user_settings := '{"email": "' || _email || '", "reset_qs": "' || _reset_qs || '"}';
|
user_settings := '{"email": "' || _email || '", "reset_qs": "' || _reset_qs || '"}';
|
||||||
@@ -276,7 +275,7 @@ AS $pushover_subscribe_link$
|
|||||||
name = 'app.pushover_app_url';
|
name = 'app.pushover_app_url';
|
||||||
-- Generate OTP
|
-- Generate OTP
|
||||||
otp_code := api.generate_otp_fn(email);
|
otp_code := api.generate_otp_fn(email);
|
||||||
-- On sucess redirect to API endpoint
|
-- On success redirect to API endpoint
|
||||||
SELECT CONCAT(
|
SELECT CONCAT(
|
||||||
'?success=',
|
'?success=',
|
||||||
public.urlescape_py_fn(CONCAT(app_url,'/pushover?token=')),
|
public.urlescape_py_fn(CONCAT(app_url,'/pushover?token=')),
|
||||||
@@ -322,7 +321,7 @@ AS $pushover$
|
|||||||
DELETE FROM auth.otp
|
DELETE FROM auth.otp
|
||||||
WHERE user_email = _email;
|
WHERE user_email = _email;
|
||||||
-- Disable Notification because
|
-- Disable Notification because
|
||||||
-- Pushover send a notificataion when sucesssfull with the description of the app
|
-- Pushover send a notification when sucesssfull with the description of the app
|
||||||
--
|
--
|
||||||
-- Send Notification async
|
-- Send Notification async
|
||||||
--INSERT INTO process_queue (channel, payload, stored)
|
--INSERT INTO process_queue (channel, payload, stored)
|
||||||
@@ -335,7 +334,7 @@ $pushover$ language plpgsql security definer;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
api.pushover_fn
|
api.pushover_fn
|
||||||
IS 'Confirm Pushover Subscription and store pushover_user_key into user preferences if valid token/otp';
|
IS 'Confirm Pushover Subscription and store pushover_user_key into user preferences if provide a valid OTP token';
|
||||||
|
|
||||||
-- Telegram OTP Validation
|
-- Telegram OTP Validation
|
||||||
-- Expose as an API endpoint
|
-- Expose as an API endpoint
|
||||||
@@ -344,7 +343,6 @@ CREATE OR REPLACE FUNCTION api.telegram_fn(IN token TEXT, IN telegram_obj TEXT)
|
|||||||
AS $telegram$
|
AS $telegram$
|
||||||
DECLARE
|
DECLARE
|
||||||
_email TEXT := NULL;
|
_email TEXT := NULL;
|
||||||
_updated BOOLEAN := False;
|
|
||||||
user_settings jsonb;
|
user_settings jsonb;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Check parameters
|
-- Check parameters
|
||||||
@@ -357,14 +355,14 @@ AS $telegram$
|
|||||||
-- Set user email into env to allow RLS update
|
-- Set user email into env to allow RLS update
|
||||||
PERFORM set_config('user.email', _email, false);
|
PERFORM set_config('user.email', _email, false);
|
||||||
-- Add telegram obj into user preferences
|
-- Add telegram obj into user preferences
|
||||||
SELECT api.update_user_preferences_fn('{telegram}'::TEXT, telegram_obj::TEXT) INTO _updated;
|
PERFORM api.update_user_preferences_fn('{telegram}'::TEXT, telegram_obj::TEXT);
|
||||||
-- Delete token when validated
|
-- Delete token when validated
|
||||||
DELETE FROM auth.otp
|
DELETE FROM auth.otp
|
||||||
WHERE user_email = _email;
|
WHERE user_email = _email;
|
||||||
-- Send Notification async
|
-- Send Notification async
|
||||||
INSERT INTO process_queue (channel, payload, stored)
|
INSERT INTO process_queue (channel, payload, stored)
|
||||||
VALUES ('telegram_valid', _email, now());
|
VALUES ('telegram_valid', _email, now());
|
||||||
RETURN _updated;
|
RETURN True;
|
||||||
END IF;
|
END IF;
|
||||||
RETURN False;
|
RETURN False;
|
||||||
END;
|
END;
|
||||||
@@ -372,7 +370,7 @@ $telegram$ language plpgsql security definer;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
api.telegram_fn
|
api.telegram_fn
|
||||||
IS 'Confirm telegram user and store telegram chat details into user preferences if valid token/otp';
|
IS 'Confirm telegram user and store telegram chat details into user preferences if provide a valid OTP token';
|
||||||
|
|
||||||
-- Telegram user validation
|
-- Telegram user validation
|
||||||
DROP FUNCTION IF EXISTS auth.telegram_user_exists_fn;
|
DROP FUNCTION IF EXISTS auth.telegram_user_exists_fn;
|
||||||
@@ -399,11 +397,11 @@ $telegram_user_exists$ language plpgsql security definer;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
auth.telegram_user_exists_fn
|
auth.telegram_user_exists_fn
|
||||||
IS 'Check if user exist based on email and telegram obj preferences';
|
IS 'Check if user exist based on email and user_id';
|
||||||
|
|
||||||
-- Telegram otp validation
|
-- Telegram otp validation
|
||||||
DROP FUNCTION IF EXISTS auth.telegram_otp_fn;
|
DROP FUNCTION IF EXISTS api.telegram_otp_fn;
|
||||||
CREATE OR REPLACE FUNCTION auth.telegram_otp_fn(IN email TEXT, OUT otp_code TEXT) RETURNS TEXT
|
CREATE OR REPLACE FUNCTION api.telegram_otp_fn(IN email TEXT, OUT otp_code TEXT) RETURNS TEXT
|
||||||
AS $telegram_otp$
|
AS $telegram_otp$
|
||||||
DECLARE
|
DECLARE
|
||||||
_email CITEXT := email;
|
_email CITEXT := email;
|
||||||
@@ -425,30 +423,38 @@ AS $telegram_otp$
|
|||||||
$telegram_otp$ language plpgsql security definer;
|
$telegram_otp$ language plpgsql security definer;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
auth.telegram_otp_fn
|
api.telegram_otp_fn
|
||||||
IS 'TODO';
|
IS 'Telegram otp generation';
|
||||||
|
|
||||||
-- Telegram bot JWT auth
|
-- Telegram JWT auth
|
||||||
-- Expose as an API endpoint
|
-- Expose as an API endpoint
|
||||||
-- Avoid sending a password so use email and chat_id as key pair
|
-- Avoid sending a password so use email and chat_id as key pair
|
||||||
DROP FUNCTION IF EXISTS api.bot(text,BIGINT);
|
DROP FUNCTION IF EXISTS api.telegram;
|
||||||
CREATE OR REPLACE FUNCTION api.bot(IN email TEXT, IN user_id BIGINT) RETURNS auth.jwt_token
|
CREATE OR REPLACE FUNCTION api.telegram(IN user_id BIGINT, IN email TEXT DEFAULT NULL) RETURNS auth.jwt_token
|
||||||
AS $telegram_bot$
|
AS $telegram_jwt$
|
||||||
DECLARE
|
DECLARE
|
||||||
_email TEXT := email;
|
_email TEXT := email;
|
||||||
_user_id BIGINT := user_id;
|
_user_id BIGINT := user_id;
|
||||||
|
_uid TEXT := NULL;
|
||||||
_exist BOOLEAN := False;
|
_exist BOOLEAN := False;
|
||||||
result auth.jwt_token;
|
result auth.jwt_token;
|
||||||
app_jwt_secret text;
|
app_jwt_secret text;
|
||||||
BEGIN
|
BEGIN
|
||||||
IF _email IS NULL OR _chat_id IS NULL THEN
|
IF _user_id IS NULL THEN
|
||||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||||
END IF;
|
END IF;
|
||||||
-- check email and _chat_id
|
|
||||||
select auth.telegram_user_exists_fn(_email, _user_id) into _exist;
|
-- Check _user_id
|
||||||
if _exist is null or _exist <> True then
|
SELECT auth.telegram_session_exists_fn(_user_id) into _exist;
|
||||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
IF _exist IS NULL OR _exist <> True THEN
|
||||||
end if;
|
--RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||||
|
RETURN NULL;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Get email and user_id
|
||||||
|
SELECT a.email,a.user_id INTO _email,_uid
|
||||||
|
FROM auth.accounts a
|
||||||
|
WHERE cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
||||||
|
|
||||||
-- Get app_jwt_secret
|
-- Get app_jwt_secret
|
||||||
SELECT value INTO app_jwt_secret
|
SELECT value INTO app_jwt_secret
|
||||||
@@ -462,26 +468,28 @@ AS $telegram_bot$
|
|||||||
from (
|
from (
|
||||||
select 'user_role' as role,
|
select 'user_role' as role,
|
||||||
(select lower(_email)) as email,
|
(select lower(_email)) as email,
|
||||||
|
_uid as uid,
|
||||||
extract(epoch from now())::integer + 60*60 as exp
|
extract(epoch from now())::integer + 60*60 as exp
|
||||||
) r
|
) r
|
||||||
into result;
|
into result;
|
||||||
return result;
|
return result;
|
||||||
END;
|
END;
|
||||||
$telegram_bot$ language plpgsql security definer;
|
$telegram_jwt$ language plpgsql security definer;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
api.bot
|
api.telegram
|
||||||
IS 'Generate a JWT user_role token from email for telegram bot';
|
IS 'Generate a JWT user_role token based on chat_id from telegram';
|
||||||
|
|
||||||
-- Telegram chat_id Session validation
|
-- Telegram chat_id session validation
|
||||||
DROP FUNCTION IF EXISTS auth.telegram_session_exists_fn;
|
DROP FUNCTION IF EXISTS auth.telegram_session_exists_fn;
|
||||||
CREATE OR REPLACE FUNCTION auth.telegram_session_exists_fn(IN user_id BIGINT) RETURNS BOOLEAN
|
CREATE OR REPLACE FUNCTION auth.telegram_session_exists_fn(IN user_id BIGINT) RETURNS BOOLEAN
|
||||||
AS $telegram_session_exists$
|
AS $telegram_session_exists$
|
||||||
DECLARE
|
DECLARE
|
||||||
_id TEXT := NULL;
|
_id BIGINT := NULL;
|
||||||
_user_id BIGINT := user_id;
|
_user_id BIGINT := user_id;
|
||||||
|
_email TEXT := NULL;
|
||||||
BEGIN
|
BEGIN
|
||||||
IF _chat_id IS NULL THEN
|
IF user_id IS NULL THEN
|
||||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
@@ -489,10 +497,10 @@ AS $telegram_session_exists$
|
|||||||
SELECT preferences->'telegram'->'from'->'id' INTO _id
|
SELECT preferences->'telegram'->'from'->'id' INTO _id
|
||||||
FROM auth.accounts a
|
FROM auth.accounts a
|
||||||
WHERE cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
WHERE cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
||||||
IF NOT FOUND then
|
IF FOUND THEN
|
||||||
RETURN False;
|
|
||||||
END IF;
|
|
||||||
RETURN True;
|
RETURN True;
|
||||||
|
END IF;
|
||||||
|
RETURN FALSE;
|
||||||
END;
|
END;
|
||||||
$telegram_session_exists$ language plpgsql security definer;
|
$telegram_session_exists$ language plpgsql security definer;
|
||||||
-- Description
|
-- Description
|
||||||
|
Reference in New Issue
Block a user