Skip to content

Instantly share code, notes, and snippets.

@suganthsundar
Created October 18, 2014 10:06
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save suganthsundar/94f3762664ae4353da55 to your computer and use it in GitHub Desktop.
Save suganthsundar/94f3762664ae4353da55 to your computer and use it in GitHub Desktop.
Function Extract_Data(p_query Varchar2,
p_directory Varchar2,
p_filename Varchar2) Return Boolean is
CursorId Pls_Integer;
RowsFetched Pls_Integer;
ColCnt Pls_Integer;
RecLimit Pls_Integer := 1000; -- No. of Records processed per fetch
delimiter Char := Chr(9); -- Field Delimiter (Tab)
buffer Varchar2(32746);
ColHeader Dbms_Sql.desc_tab2;
fPtr Utl_File.file_type;
/* Defines & Initialize 2 Level Collection */
Varchar_Tab Dbms_Sql.Varchar2_Table;
Type Column_TabType Is Table of Dbms_Sql.Varchar2_Table;
Column_Tab Column_TabType := Column_TabType();
Begin
Dbms_output.Put_Line(p_query);
/* Opens the Cursor for given SQL Query */
CursorId := Dbms_Sql.open_cursor;
Dbms_Sql.parse(CursorId, p_query, Dbms_Sql.native);
/* Opens the File in Specified Directory to write data */
fPtr := Utl_File.fopen(p_directory, p_filename, 'W');
/* Defines the Columns in SQL Statement as Varchar Type */
Dbms_Sql.describe_columns2(CursorId, ColCnt, ColHeader);
For ColNum in 1 .. ColCnt loop
Dbms_Sql.define_array(CursorId, ColNum, Varchar_Tab, RecLimit, 1);
buffer := buffer || ColHeader(ColNum).Col_Name || delimiter;
End Loop;
/* Writes the Header to Output File */
Utl_File.put_line(fPtr, buffer);
/* Process the given SQL Statement & stores the result into Collection Variable */
RowsFetched := Dbms_Sql.Execute(CursorId);
LOOP
RowsFetched := Dbms_Sql.Fetch_Rows(CursorId);
FOR ColNum IN 1 .. ColCnt LOOP
Column_Tab.Extend;
Dbms_Sql.Column_Value(CursorId, ColNum, Column_Tab(ColNum));
END LOOP;
Exit When RowsFetched <> RecLimit;
END LOOP;
/* Writes the Columns Values to the Output File */
FOR RecNum IN 1 .. Dbms_Sql.last_row_count LOOP
buffer := Null;
FOR ColNum IN 1 .. ColCnt LOOP
buffer := buffer || Column_Tab(ColNum) (RecNum) || delimiter;
END LOOP;
Utl_File.put_line(fPtr, buffer);
END LOOP;
/* Closes the Cursor & File Handler */
Dbms_Sql.Close_Cursor(CursorId);
Utl_File.fclose(fPtr);
Return True;
Exception
When Others Then
/* Closes the Cursor & File Handler if any Exceptions occurs */
If Dbms_sql.is_open(CursorId) then
Dbms_Sql.Close_Cursor(CursorId);
End If;
If Utl_File.is_open(fPtr) then
Utl_File.fclose(fPtr);
End If;
Return False;
End Extract_Data;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment