PL/SQL validation routine can be called to replace the default "submit" function on a timesheet. When a timesheet is submitted, if the timesheet does not meet the criteria of the validation routine, a customer-defined message will appear as a pop-up dialog and the timesheet will not change status.

Required Set up#

Maintain System Messages (IMMS)#

A user-defined system message must be created on IMMS. The message should be prefixed with PTSV_###### When the PL/SQL function is created, the return value will be the ##### portion of the IMMS code. The "PTSV_" will be assumed by the process calling the custom code. The message will be text and will need to be a predefined hardcoded value built into the MESSAGE_TEXT field.

Function Definition (PL/SQL)#

The function must be defined in the database as a PL/SQL function.
  • The PL/SQL function must receive exactly one parameter, the ID of the P2K_PR_TIME_SHEETS record to be examined
  • The function must return either a NULL or the number portion of a code name of a user-defined message defined in the IMMS screen.
  • Best Practices and Recommendations
    • The function should be added to the P2K schema (i.e. the function is created by the P2K user) so that it is carried forward in any export/import operations.
    • The function name should NOT start with P2K_ so as to preclude any confusion about its source (P2K_xxxx is reserved for those supplied with the application).
    • Your function names start with an identifiable code that will distinguish this as yours (i.e. if your company is Acme Corp, call the functions you create ACME_xxxx)
    • If you are going to have many conditions that will require validation, you may find it advantageous to create a package with your customer prefix, and then include all the different validation routines as separate functions within that package. This keeps all your work together in one place.
    • It is important to ensure that all error conditions are trapped or any errors that arise may cause unexpected or unexplainable screen errors.
    • It is important to ensure that a public synonym is created and grants made to the P2K_USER or users will get unexpected results in the screens where you may be using them.

Form Definition (IMFDH)#

Once the function and system message have been established, all the functions that will use the routine must be set up. There are two steps required on each function in which the routine is to be called 1) On the Function Info tab, add the preference "PTS_CHK_ROUTINE". The value will be the name of the Function or Package to be called. 2) On the Form Layout tab, add the PTS.ACT_VALIDATE_SUBMIT_TIME_SHEET_NO_DLG to the form. If the form is "Pre-Loaded" use object security to remove the default PTS.ACT_SUBMIT_TIME_SHEET option (If custom, the PTS.ACT_SUBMIT_TIME_SHEET can be deleted from the form).

Example#

  • In this example employees must account for all the time in their timesheet based on their hours per pay set up on IEAS.
  • If the total number of hours in the timesheet is less than the number 40, the function will return the number "0001".
  • On IMMS a user defined system message has been created as "PTSV_0001" and contains the message "The hours in your timesheet do not match your scheduled hours. Please make to account for all daily hours."
  • Built into this function is a requirement for a TIME_CODE_SET set up on IDTCS called "TIME_SHEET_TOTALS"

The following function will take the ID of the P2K_PR_TIME_SHEETS record and return a null or the value on IMMS for the MESSAGE_CODE of "0001". Any exceptional condition (no records found, etc.) will result in NULL being returned.

 CREATE OR REPLACE
  FUNCTION ACME_PTS_SCHED_HOURS(P_PTS_ID IN NUMBER) 
    RETURN VARCHAR2 AS
    --Return system message 0001 if the TS total is less than 40.
    
    v_return        VARCHAR2(60);
    v_pts_id        NUMBER(10):=P_PTS_ID;
    v_total_hrs     NUMBER(10,2);
  
  BEGIN
    SELECT SUM(TIME_OR_AMOUNT)
    INTO v_total_hrs
    FROM p2k_PR_TIME_SHEET_ENTRIES
    WHERE TIME_SHEET_ENTRY_SOURCE <> '05'
    AND PTS_ID = v_pts_id
    AND DTC_ID IN 
        (SELECT DTCD.DTC_ID
          FROM P2K_CM_TIME_CODE_SETS DTCS, P2K_CM_TIME_CODE_SET_DETAILS DTCD
          WHERE DTCS.TIME_CODE_SET_CODE = 'TIME_SHEET_TOTALS'
          AND DTCS.ID = DTCD.DTCS_ID);
          
    IF v_total_hrs > 40 
        THEN v_return:='0001';
    END IF;
    
    RETURN v_return;
    
    EXCEPTION
        WHEN OTHERS THEN
        RETURN '0000';
  END ACME_PTS_SCHED_HOURS;
//
The two slashes are an indicator to SQL to execute the lines preceding.

The creation of a Public Synonym means that users other than P2K (the schema owner) will have access to the function. The grant of the execute privilege is required so that other users (other than P2K) will be able to execute this. All users of the application must have the P2K_USER role granted in IMUS or IMUR.

create public synonym ACME_PTS_SCHED_HOURSfor ACME_PTS_SCHED_HOURS;
grant execute on ACME_PTS_SCHED_HOURSto P2K_USER;


Notes #

Click to create a new notes page