Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
C
custom-sql
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
3
Merge Requests
3
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
CI / CD Analytics
Repository Analytics
Value Stream Analytics
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Uma Badkar
custom-sql
Commits
f0ece38e
Commit
f0ece38e
authored
Sep 03, 2025
by
Uma Badkar
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Upload New File
parent
bc622a34
Changes
1
Show whitespace changes
Inline
Side-by-side
Showing
1 changed file
with
426 additions
and
0 deletions
+426
-0
twasta/Objects/AMS_asset_requests_model/AMS_asset_requests_model.sql
...cts/AMS_asset_requests_model/AMS_asset_requests_model.sql
+426
-0
No files found.
twasta/Objects/AMS_asset_requests_model/AMS_asset_requests_model.sql
0 → 100644
View file @
f0ece38e
/*
* Function: approve_request
* Purpose: Approves an asset request and initiates the asset allocation process
*
* Parameters:
* p_request_id - The unique identifier of the asset request
* p_approver_id - The employee ID of the person approving the request
* p_comments - Optional approval comments
*
* Returns:
* 1 - Success
* 0 - Failure
*
* Exception Handling:
* - Validates request existence and current status
* - Handles concurrent updates
* - Logs errors in error_log table
*
* Revision History:
* Date Author Description
* ---------- ------------- ----------------------------------------
* 2024-01-10 System Initial Creation
*/
CREATE
OR
REPLACE
FUNCTION
APPROVE_REQUEST
(
p_request_id
IN
NUMBER
,
p_approver_id
IN
NUMBER
,
p_comments
IN
VARCHAR2
DEFAULT
NULL
)
RETURN
NUMBER
IS
-- Local variables for validation and processing
v_current_status
VARCHAR2
(
50
);
v_requestor_id
NUMBER
;
v_result
NUMBER
:
=
0
;
-- Custom exceptions
e_invalid_request
EXCEPTION
;
e_invalid_status
EXCEPTION
;
BEGIN
-- Validate request existence and get current status
SELECT
status
,
requestor_id
INTO
v_current_status
,
v_requestor_id
FROM
ams_asset_requests
WHERE
request_id
=
p_request_id
FOR
UPDATE
NOWAIT
;
-- Lock row to prevent concurrent updates
-- Validate request status (can only approve pending requests)
IF
v_current_status
!=
'PENDING'
THEN
RAISE
e_invalid_status
;
END
IF
;
-- Update request status to Approved
UPDATE
ams_asset_requests
SET
status
=
'APPROVED'
,
approved_by
=
p_approver_id
,
approved_date
=
SYSDATE
,
approval_comments
=
p_comments
,
last_updated_by
=
p_approver_id
,
last_updated_date
=
SYSDATE
WHERE
request_id
=
p_request_id
;
-- Insert record in approval history
INSERT
INTO
ams_request_history
(
request_id
,
action_type
,
action_by
,
action_date
,
comments
)
VALUES
(
p_request_id
,
'APPROVAL'
,
p_approver_id
,
SYSDATE
,
p_comments
);
-- Trigger asset allocation process
BEGIN
-- Call asset allocation procedure
asset_allocation_pkg
.
initiate_allocation
(
p_request_id
=>
p_request_id
,
p_requestor_id
=>
v_requestor_id
);
EXCEPTION
WHEN
OTHERS
THEN
-- Log allocation error but continue with approval
INSERT
INTO
error_log
(
error_code
,
error_message
,
process_name
,
created_date
)
VALUES
(
SQLCODE
,
SQLERRM
,
'approve_request.asset_allocation'
,
SYSDATE
);
END
;
-- Commit transaction
COMMIT
;
v_result
:
=
1
;
-- Success
RETURN
v_result
;
EXCEPTION
WHEN
e_invalid_status
THEN
-- Log error for invalid status
INSERT
INTO
error_log
(
error_code
,
error_message
,
process_name
,
created_date
)
VALUES
(
-
20001
,
'Invalid request status for approval: '
||
v_current_status
,
'approve_request'
,
SYSDATE
);
ROLLBACK
;
RETURN
0
;
WHEN
NO_DATA_FOUND
THEN
-- Log error for invalid request
INSERT
INTO
error_log
(
error_code
,
error_message
,
process_name
,
created_date
)
VALUES
(
-
20002
,
'Invalid request ID: '
||
p_request_id
,
'approve_request'
,
SYSDATE
);
ROLLBACK
;
RETURN
0
;
WHEN
OTHERS
THEN
-- Log unexpected errors
INSERT
INTO
error_log
(
error_code
,
error_message
,
process_name
,
created_date
)
VALUES
(
SQLCODE
,
SQLERRM
,
'approve_request'
,
SYSDATE
);
ROLLBACK
;
RETURN
0
;
END
approve_request
;
/
/**
* Function to cancel a pending asset request
*
* Purpose:
* Cancels an existing asset request and updates its status to 'CANCELLED'
* Only allows cancellation of requests in 'PENDING' status
*
* Parameters:
* p_request_id - The unique identifier of the asset request
* p_cancel_reason - The reason for cancellation (optional)
* p_cancelled_by - User ID of the person cancelling the request
*
* Returns:
* 1 - Success
* 0 - Failed (request not found or not in cancellable status)
*
* Exception Handling:
* Raises application specific errors for invalid scenarios
*
* Created: [Date]
* Author: [Author]
*/
CREATE
OR
REPLACE
FUNCTION
cancel_request
(
p_request_id
IN
NUMBER
,
p_cancel_reason
IN
VARCHAR2
DEFAULT
NULL
,
p_cancelled_by
IN
NUMBER
)
RETURN
NUMBER
IS
-- Local variables
v_current_status
VARCHAR2
(
50
);
v_is_cancellable
BOOLEAN
:
=
FALSE
;
-- Constants
c_status_pending
CONSTANT
VARCHAR2
(
20
)
:
=
'PENDING'
;
c_status_cancelled
CONSTANT
VARCHAR2
(
20
)
:
=
'CANCELLED'
;
-- Custom exceptions
e_invalid_request
EXCEPTION
;
e_not_cancellable
EXCEPTION
;
PRAGMA
EXCEPTION_INIT
(
e_invalid_request
,
-
20001
);
PRAGMA
EXCEPTION_INIT
(
e_not_cancellable
,
-
20002
);
BEGIN
-- Check if request exists and get current status
SELECT
status
INTO
v_current_status
FROM
AMS_asset_requests
WHERE
request_id
=
p_request_id
;
-- Validate if request can be cancelled
v_is_cancellable
:
=
CASE
WHEN
v_current_status
=
c_status_pending
THEN
TRUE
ELSE
FALSE
END
;
-- Throw exception if request cannot be cancelled
IF
NOT
v_is_cancellable
THEN
RAISE
e_not_cancellable
;
END
IF
;
-- Update request status to cancelled
UPDATE
AMS_asset_requests
SET
status
=
c_status_cancelled
,
cancel_reason
=
p_cancel_reason
,
cancelled_by
=
p_cancelled_by
,
cancelled_date
=
SYSDATE
,
last_updated_by
=
p_cancelled_by
,
last_updated_date
=
SYSDATE
WHERE
request_id
=
p_request_id
;
-- Commit the transaction
COMMIT
;
-- Return success
RETURN
1
;
EXCEPTION
WHEN
NO_DATA_FOUND
THEN
-- Request not found
RAISE_APPLICATION_ERROR
(
-
20001
,
'Request ID '
||
p_request_id
||
' not found.'
);
RETURN
0
;
WHEN
e_not_cancellable
THEN
-- Request cannot be cancelled
RAISE_APPLICATION_ERROR
(
-
20002
,
'Request ID '
||
p_request_id
||
' cannot be cancelled. Current status: '
||
v_current_status
);
RETURN
0
;
WHEN
OTHERS
THEN
-- Log error and rollback
ROLLBACK
;
RAISE_APPLICATION_ERROR
(
-
20999
,
'Error cancelling request: '
||
SQLERRM
);
RETURN
0
;
END
cancel_request
;
/
/*
* Function: reject_request
* Purpose: Rejects an asset request and sends notification to the requesting employee
*
* Parameters:
* p_request_id - The unique identifier of the asset request
* p_rejected_by - The user ID of the person rejecting the request
* p_reject_reason - The reason for rejection
*
* Returns:
* 1 - Success
* 0 - Failure
*
* Exception Handling:
* - Handles invalid request ID
* - Handles invalid status transitions
* - Handles notification failures
*
* Audit: Creates audit trail for the rejection
*/
CREATE
OR
REPLACE
FUNCTION
reject_request
(
p_request_id
IN
NUMBER
,
p_rejected_by
IN
NUMBER
,
p_reject_reason
IN
VARCHAR2
)
RETURN
NUMBER
IS
-- Local variables for request details
v_employee_id
NUMBER
;
v_current_status
VARCHAR2
(
30
);
v_email_address
VARCHAR2
(
100
);
v_request_details
VARCHAR2
(
4000
);
-- Exception declarations
e_invalid_request
EXCEPTION
;
e_invalid_status
EXCEPTION
;
e_notification_error
EXCEPTION
;
-- Constants
c_status_rejected
CONSTANT
VARCHAR2
(
30
)
:
=
'REJECTED'
;
BEGIN
-- Validate request exists and get current status
SELECT
employee_id
,
current_status
,
email_address
INTO
v_employee_id
,
v_current_status
,
v_email_address
FROM
ams_asset_requests
ar
JOIN
employees
e
ON
ar
.
employee_id
=
e
.
employee_id
WHERE
request_id
=
p_request_id
;
-- Validate if request can be rejected (not already rejected/completed)
IF
v_current_status
=
c_status_rejected
THEN
RAISE
e_invalid_status
;
END
IF
;
-- Update request status to rejected
UPDATE
ams_asset_requests
SET
current_status
=
c_status_rejected
,
rejected_by
=
p_rejected_by
,
reject_reason
=
p_reject_reason
,
rejected_date
=
SYSDATE
,
last_updated_by
=
p_rejected_by
,
last_updated_date
=
SYSDATE
WHERE
request_id
=
p_request_id
;
-- Create audit trail
INSERT
INTO
ams_request_history
(
request_id
,
action_type
,
action_by
,
action_date
,
old_status
,
new_status
,
comments
)
VALUES
(
p_request_id
,
'REJECT'
,
p_rejected_by
,
SYSDATE
,
v_current_status
,
c_status_rejected
,
p_reject_reason
);
-- Send notification to employee
BEGIN
-- Get request details for notification
SELECT
'Asset Request #'
||
request_id
||
' - '
||
asset_description
INTO
v_request_details
FROM
ams_asset_requests
WHERE
request_id
=
p_request_id
;
-- Call notification procedure
send_email_notification
(
p_to
=>
v_email_address
,
p_subject
=>
'Asset Request Rejected'
,
p_message
=>
'Your asset request '
||
v_request_details
||
' has been rejected.'
||
CHR
(
10
)
||
'Reason: '
||
p_reject_reason
);
EXCEPTION
WHEN
OTHERS
THEN
-- Log notification error but don't fail the rejection
log_error
(
'Notification failed for request rejection: '
||
p_request_id
);
END
;
COMMIT
;
RETURN
1
;
EXCEPTION
WHEN
NO_DATA_FOUND
THEN
ROLLBACK
;
RAISE_APPLICATION_ERROR
(
-
20001
,
'Invalid request ID: '
||
p_request_id
);
RETURN
0
;
WHEN
e_invalid_status
THEN
ROLLBACK
;
RAISE_APPLICATION_ERROR
(
-
20002
,
'Request is already rejected'
);
RETURN
0
;
WHEN
OTHERS
THEN
ROLLBACK
;
log_error
(
'Error in reject_request: '
||
SQLERRM
);
RAISE_APPLICATION_ERROR
(
-
20003
,
'Error processing rejection request'
);
RETURN
0
;
END
reject_request
;
/
/*
* Object Name: AMS_asset_requests
* Event Type: Field Item Change
* Form Number: 1
* Field Name: CATEGORY_ID
* Business Logic: Fetch available models for selected category
* Function Name: fetch_models
*/
CREATE
OR
REPLACE
FUNCTION
FETCH_MODELS
(
p_category_id
IN
NUMBER
-- (1.CATEGORY_ID)
)
RETURN
VARCHAR2
IS
-- Local variables
v_result
VARCHAR2
(
32767
);
v_json_object
JSON_OBJECT_T
;
v_data_array
JSON_ARRAY_T
;
BEGIN
-- Initialize JSON objects
v_json_object
:
=
JSON_OBJECT_T
();
v_data_array
:
=
JSON_ARRAY_T
();
-- Add the data array to the main JSON object
v_json_object
.
put
(
'data'
,
v_data_array
);
-- Convert the JSON object to string
v_result
:
=
v_json_object
.
to_string
();
-- Return the JSON string
RETURN
v_result
;
EXCEPTION
WHEN
OTHERS
THEN
-- Log error and return empty JSON
-- You might want to implement proper error logging here
v_json_object
:
=
JSON_OBJECT_T
();
v_data_array
:
=
JSON_ARRAY_T
();
v_json_object
.
put
(
'data'
,
v_data_array
);
v_json_object
.
put
(
'error'
,
SQLERRM
);
RETURN
v_json_object
.
to_string
();
END
FETCH_MODELS
;
/
\ No newline at end of file
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment