Project

General

Profile

Feature #290 » sql.sql

Junaid M, 02/19/2024 05:46 PM

 
-- @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@
-- @@@@@@@@@ SERVICE->TBL_MASTER_GROUPING TBL_MASTER_GROUPING TBL_MASTER_GROUPING @@@@@@@@@
-- @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@@
------------------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION fn_get_all_master_grouping() RETURNS SETOF service.tbl_master_grouping AS $$
DECLARE

BEGIN
RETURN QUERY SELECT * FROM service.tbl_master_grouping WHERE int_sys_action_id != -1;
END;
$$ LANGUAGE plpgsql;

------------------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION fn_get_all_master_grouping_with_action_user()
RETURNS TABLE (pk_master_grouping_id BIGINT,

vhr_grouping_name VARCHAR,
sin_grouping_sys_type SMALLINT,
sin_grouping_gui SMALLINT,
txt_remarks TEXT,

sin_record_status SMALLINT,
sin_order SMALLINT,

int_sys_action_id INT,
fk_created_user_id BIGINT,
vhr_created_user VARCHAR,
dtm_created TIMESTAMP WITH TIME ZONE,
fk_last_modified_user_id BIGINT,
vhr_last_modified_user VARCHAR,
dtm_last_modified TIMESTAMP WITH TIME ZONE,
fk_deleted_user_id BIGINT,
vhr_deleted_user VARCHAR,
dtm_deleted TIMESTAMP WITH TIME ZONE) AS $$
DECLARE

BEGIN
RETURN QUERY SELECT mt.pk_master_grouping_id,

mt.vhr_grouping_name,
mt.sin_grouping_sys_type,
mt.sin_grouping_gui,
mt.txt_remarks,

mt.sin_record_status,
mt.sin_order,

mt.int_sys_action_id,
mt.fk_created_user_id,
u1.vhr_login_name AS vhr_created_user,
mt.dtm_created,
mt.fk_last_modified_user_id,
u2.vhr_login_name AS vhr_last_modified_user,
mt.dtm_last_modified,
mt.fk_deleted_user_id,
u3.vhr_login_name AS vhr_deleted_user,
mt.dtm_deleted
FROM service.tbl_master_grouping mt
LEFT JOIN authentication.tbl_user u1
ON mt.fk_created_user_id = u1.pk_user_id
LEFT JOIN authentication.tbl_user u2
ON mt.fk_last_modified_user_id = u2.pk_user_id
LEFT JOIN authentication.tbl_user u3
ON mt.fk_deleted_user_id = u3.pk_user_id
WHERE mt.int_sys_action_id != -1
ORDER BY sin_order, vhr_grouping_name;
END;
$$ LANGUAGE plpgsql;

------------------------------------------------------------------------------------------

CREATE OR REPLACE PROCEDURE sp_insert_or_update_master_grouping(jsnMasterGrouping JSONB, jsnSqlRes OUT JSON) AS $$
DECLARE
objSpOutRes TYP_SP_OUT_RES;
objFnCheckRes TYP_FN_CHECK_RES;
dtmCurrent TIMESTAMP WITH TIME ZONE;
BEGIN
SELECT NOW() INTO dtmCurrent;

-- // Duplication Checking in DB FUCTION(Insert and Update)
SELECT * FROM fn_check_data_uniqueness('service.tbl_master_grouping'::VARCHAR, ''::VARCHAR, ::VARCHAR, 'pk_master_grouping_id'::VARCHAR, CAST(jsnMasterGrouping->>'binMasterGroupingId' AS BIGINT)::BIGINT) INTO objFnCheckRes;
IF objFnCheckRes.sin_sql_check_status = -1::SMALLINT THEN
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := objFnCheckRes.vhr_sql_check_message;

objSpOutRes.strSqlCustomErrorType := 'DATABASE_VALIDATION_ERROR';

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END IF;

IF CAST(jsnMasterGrouping->>'binMasterGroupingId' AS BIGINT)::BIGINT = 0::BIGINT THEN
-- // Count Exced or other checking License related in DB FUCTION(Insert)

--jsnMasterGrouping.intSysActionId = 0;
--jsnMasterGrouping.binCreatedUserId = jsnMasterGrouping.linLoginUserId;
--jsnMasterGrouping.dtmCreated = jsnMasterGrouping.dtmCurrentDateTime; --SELECT NOW();

INSERT INTO service.tbl_master_grouping (vhr_grouping_name,
sin_grouping_sys_type,
sin_grouping_gui,
txt_remarks,

sin_record_status,
sin_order,

int_sys_action_id,
fk_created_user_id,
dtm_created)
VALUES(jsnMasterGrouping->>'strGroupingName',
CAST(jsnMasterGrouping->>'sinGroupingSysType' AS SMALLINT),
CAST(jsnMasterGrouping->>'sinGroupingGui' AS SMALLINT),
CAST(jsnMasterGrouping->>'strRemarks' AS TEXT),

CAST(jsnMasterGrouping->>'sinRecordStatus' AS SMALLINT),
CAST(jsnMasterGrouping->>'sinOrder' AS SMALLINT),

0,
CAST(jsnMasterGrouping->>'binCreatedUserId' AS BIGINT),
dtmCurrent) RETURNING pk_master_grouping_id INTO objSpOutRes.binSqlPk;
ELSE
-- // UPDATE Check already update another usersin DB FUCTION(Update and Delete)
SELECT * FROM fn_check_already_update_or_delete_another_user('service.tbl_master_grouping'::VARCHAR, 'pk_master_grouping_id'::VARCHAR, CAST(jsnMasterGrouping->>'binMasterGroupingId' AS BIGINT)::BIGINT, CAST(jsnMasterGrouping->>'intSysActionId' AS INT)::INT) INTO objFnCheckRes;
IF objFnCheckRes.sin_sql_check_status = -1::SMALLINT THEN
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := objFnCheckRes.vhr_sql_check_message;

objSpOutRes.strSqlCustomErrorType := 'DATABASE_VALIDATION_ERROR';

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END IF;

--jsnMasterGrouping.intSysActionId = jsnMasterGrouping.intSysActionId + 1;
--jsnMasterGrouping.binLastModifiedUserId = jsnMasterGrouping.linLoginUserId;
--jsnMasterGrouping.dtmLastModified = jsnMasterGrouping.dtmCurrentDateTime; --SELECT NOW();

UPDATE service.tbl_master_grouping SET vhr_grouping_name = jsnMasterGrouping->>'strGroupingName',
sin_grouping_sys_type = CAST(jsnMasterGrouping->>'sinGroupingSysType' AS SMALLINT),
sin_grouping_gui = CAST(jsnMasterGrouping->>'sinGroupingGui' AS SMALLINT),
txt_remarks = jsnMasterGrouping->>'strRemarks',

sin_record_status = CAST(jsnMasterGrouping->>'sinRecordStatus' AS SMALLINT),
sin_order = CAST(jsnMasterGrouping->>'sinOrder' AS SMALLINT),

int_sys_action_id = int_sys_action_id + 1,
fk_last_modified_user_id = CAST(jsnMasterGrouping->>'binLastModifiedUserId' AS BIGINT),
dtm_last_modified = dtmCurrent
WHERE pk_master_grouping_id = CAST(jsnMasterGrouping->>'binMasterGroupingId' AS BIGINT);
END IF;

--COMMIT;
objSpOutRes.sinSqlCustomStatus := 1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'SUCCESS';
objSpOutRes.strSqlCustomMessage := 'MasterGrouping Saved';
objSpOutRes.dtmCurrent = dtmCurrent;
SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
EXCEPTION WHEN OTHERS THEN
ROLLBACK;
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := 'MasterGrouping Save Failed';

objSpOutRes.strSqlCustomErrorType := 'DATABASE_SYSTEM_ERROR';

GET STACKED DIAGNOSTICS
objSpOutRes.strSqlSysMessage := MESSAGE_TEXT,
objSpOutRes.strSqlSysExceptionDetail := PG_EXCEPTION_DETAIL,
objSpOutRes.strSqlSysExceptionHint := PG_EXCEPTION_CONTEXT;
SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE EXCEPTION 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END;
$$ LANGUAGE plpgsql;

------------------------------------------------------------------------------------------

CREATE OR REPLACE PROCEDURE sp_delete_master_grouping(binMasterGroupingId BIGINT, intSysActionId INT, binDeletedUserId BIGINT, jsnSqlRes OUT JSON) AS $$
DECLARE
objSpOutRes TYP_SP_OUT_RES;
objFnCheckRes TYP_FN_CHECK_RES;
dtmCurrent TIMESTAMP WITH TIME ZONE;
BEGIN
SELECT NOW() INTO dtmCurrent;

-- // FOREIGN KEY REFERENCES Checking in DB FUCTION(Delete)
SELECT * FROM fn_check_foreignkey_referance('tbl_master_grouping'::VARCHAR, 'pk_master_grouping_id'::VARCHAR, binMasterGroupingId::BIGINT, '{}'::VARCHAR ARRAY) INTO objFnCheckRes;
IF objFnCheckRes.sin_sql_check_status = -1::SMALLINT THEN
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := objFnCheckRes.vhr_sql_check_message;

objSpOutRes.strSqlCustomErrorType := 'DATABASE_VALIDATION_ERROR';

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END IF;

-- // UPDATE Check already update another users in DB FUCTION(Update and Delete)
SELECT * FROM fn_check_already_update_or_delete_another_user('service.tbl_master_grouping'::VARCHAR, 'pk_master_grouping_id'::VARCHAR, CAST(binMasterGroupingId AS BIGINT)::BIGINT, intSysActionId::INT) INTO objFnCheckRes;
IF objFnCheckRes.sin_sql_check_status = -1::SMALLINT THEN
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := objFnCheckRes.vhr_sql_check_message;

objSpOutRes.strSqlCustomErrorType := 'DATABASE_VALIDATION_ERROR';

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END IF;

--dtmDeleted = SELECT NOW();
UPDATE service.tbl_master_grouping SET int_sys_action_id = -1::INT,
fk_deleted_user_id = binDeletedUserId,
dtm_deleted = dtmCurrent
WHERE pk_master_grouping_id = binMasterGroupingId;

--COMMIT;
objSpOutRes.sinSqlCustomStatus := 1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'SUCCESS';
objSpOutRes.strSqlCustomMessage := 'MasterGrouping Deleted';
objSpOutRes.dtmCurrent = dtmCurrent;

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE NOTICE 'jsnSqlRes: %', jsnSqlRes;
RETURN;
EXCEPTION WHEN OTHERS THEN
ROLLBACK;
objSpOutRes.sinSqlCustomStatus := -1::SMALLINT;
objSpOutRes.strSqlCustomStatusCode := 'ERROR';
objSpOutRes.strSqlCustomMessage := 'MasterGrouping Delete Failed';

objSpOutRes.strSqlCustomErrorType := 'DATABASE_SYSTEM_ERROR';

GET STACKED DIAGNOSTICS
objSpOutRes.strSqlSysMessage := MESSAGE_TEXT,
objSpOutRes.strSqlSysExceptionDetail := PG_EXCEPTION_DETAIL,
objSpOutRes.strSqlSysExceptionHint := PG_EXCEPTION_CONTEXT;

SELECT * FROM fn_convert_type_out_object_to_out_json(objSpOutRes) INTO jsnSqlRes;
RAISE EXCEPTION 'jsnSqlRes: %', jsnSqlRes;
RETURN;
END;
$$ LANGUAGE plpgsql;

(7-7/10)