How to Create Log File in Oracle Using PL/SQL?

How to Create Log File in Oracle Using PL/SQL?

  • PLSQL
  • 2 mins read

You have a PL/SQL program, and you want to log information in a text file of each step of your code. Here is an example to create a log file in Oracle using PL/SQL.

Create Log File in Oracle Using PL/SQL Example

The following is a PL/SQL procedure to update product's price by a percentage value passed as a parameter. Also, it will log the information of each step happening in the program. Note, you must have a directory object created in Oracle to write the files, check this link to learn how to create a directory object in Oracle.

CREATE OR REPLACE PROCEDURE prod_price_update (increase_pct IN NUMBER)
IS
   f_file        UTL_FILE.file_type;
   v_file_name   VARCHAR2 (100);
BEGIN
   v_file_name := 'log_' || TO_CHAR (SYSDATE, 'yyyymmdd_HH24miss') || '.log';
   f_file := UTL_FILE.fopen ('LOG_FILES', v_file_name, 'w');
   UTL_FILE.put_line (f_file, 'Log file ' || v_file_name);
   UTL_FILE.new_line (f_file);
   UTL_FILE.put_line (
      f_file,
      'Job started at: ' || TO_CHAR (SYSDATE, 'dd-mm-yyyy HH24:mi:ss'));
   UTL_FILE.put_line (
      f_file,
      'Price increment percentage value: ' || increase_pct || '%');

   UPDATE products
      SET prod_list_price =
             prod_list_price + (prod_list_price * increase_pct / 100);

   UTL_FILE.put_line (f_file,
                      'Number of products updated:  ' || SQL%ROWCOUNT);

   COMMIT;
   UTL_FILE.put_line (f_file, 'Records committed.');
   UTL_FILE.put_line (
      f_file,
      'Job finished successfully at: '
      || TO_CHAR (SYSDATE, 'dd-mm-yyyy HH24:mi:ss'));
   UTL_FILE.fclose (f_file);
EXCEPTION
   WHEN OTHERS
   THEN
      IF UTL_FILE.is_open (f_file)
      THEN
         UTL_FILE.put_line (f_file, 'Job finished with errors: ' || SQLERRM);
         UTL_FILE.fclose (f_file);
      END IF;
END;

Test The Program

BEGIN
   PROD_PRICE_UPDATE (12);
END;
/

The Output of The Log File (log_20180919_214756.log)

Log file log_20180919_214756.log

Job started at: 19-09-2018 21:47:56
Price increment percentage value: 12%
Number of products updated:  72
Records committed.
Job finished successfully at: 19-09-2018 21:47:57

See also:

  • Write CSV Files in Oracle Using PL/SQL