Microsoft KB Archive/309361

From BetaArchive Wiki

Article ID: 309361

Article Last Modified on 7/15/2004



APPLIES TO

  • Microsoft .NET Framework 1.1 Service Pack 1
  • Microsoft ADO.NET 1.1
  • Microsoft Visual C# .NET 2002 Standard Edition
  • Microsoft Visual C# .NET 2003 Standard Edition



This article was previously published under Q309361

For a Microsoft Visual Basic .NET version of this article, see 308073.
For a Microsoft Visual C++ .NET version of this article, see 309362.

This article refers to the following Microsoft .NET Framework Class Library namespaces:

  • System.Data.OleDb

IN THIS TASK

SUMMARY

REFERENCES

SUMMARY

This step-by-step article uses the DataReader object to retrieve data from an Oracle stored procedure. You can use the DataReader to retrieve a read-only, forward-only stream of data from a database. Using the DataReader can increase application performance and reduce system overhead because only one row is kept in memory.

back to the top

Requirements

The following list outlines the recommended hardware, software, network infrastructure, and service packs that you need:

  • Microsoft Windows 2000 Professional, Windows 2000 Server, Windows 2000 Advanced Server, or Windows NT 4.0 Server
  • Microsoft Visual Studio .NET

This article assumes that you are familiar with the following topics:

  • Visual C# .NET
  • ADO.NET fundamentals and syntax

back to the top

Create the Oracle Tables

This sample uses tables that are defined in the Oracle Scott/Tiger schema. The Oracle Scott/Tiger schema is included with the default Oracle installation.

If this schema does not exist, you must run the following table and insert scripts for the tables:

   CREATE TABLE DEPT
   (DEPTNO NUMBER(2,0) NOT NULL, 
   DNAME VARCHAR2(14) NULL, 
   LOC VARCHAR2(13) NULL,
   PRIMARY KEY (DEPTNO)
   );

   INSERT INTO Dept VALUES(11,'Sales','Texas');
   INSERT INTO Dept VALUES(22,'Accounting','Washington');
   INSERT INTO Dept VALUES(33,'Finance','Maine');

   CREATE TABLE EMP
   (EMPNO NUMBER(4,0) NOT NULL, 
   ENAME VARCHAR2(10) NULL, 
   JOB VARCHAR2(9) NULL, 
   MGR NUMBER(4,0) NULL, 
   SAL NUMBER(7,2) NULL, 
   COMM NUMBER(7,2) NULL, 
   DEPTNO NUMBER(2,0) NULL,
   FOREIGN KEY (DEPTNO) REFERENCES DEPT(DEPTNO),  
   PRIMARY KEY (EMPNO)
   );

   INSERT INTO Emp VALUES(123,'Bob','Sales',555,35000,12,11);
   INSERT INTO Emp VALUES(321,'Sue','Finance',555,42000,12,33);
   INSERT INTO Emp VALUES(234,'Mary','Account',555,33000,12,22);
                

back to the top

Create the Oracle Packages

Create the following Oracle package on the Oracle server:

CREATE OR REPLACE PACKAGE curspkg_join AS 
    TYPE t_cursor IS REF CURSOR ; 
    Procedure open_join_cursor1 (n_EMPNO IN NUMBER, io_cursor IN OUT t_cursor); 
   END curspkg_join;
   / 
                

Create the following Oracle package body on the Oracle server:

   CREATE OR REPLACE PACKAGE BODY curspkg_join AS
   Procedure open_join_cursor1 (n_EMPNO IN NUMBER, io_cursor IN OUT t_cursor) 
   IS 
    v_cursor t_cursor; 
   BEGIN 
    IF n_EMPNO <> 0 
    THEN
        OPEN v_cursor FOR 
        SELECT EMP.EMPNO, EMP.ENAME, DEPT.DEPTNO, DEPT.DNAME 
            FROM EMP, DEPT 
            WHERE EMP.DEPTNO = DEPT.DEPTNO 
            AND EMP.EMPNO = n_EMPNO;

    ELSE 
        OPEN v_cursor FOR 
        SELECT EMP.EMPNO, EMP.ENAME, DEPT.DEPTNO, DEPT.DNAME 
            FROM EMP, DEPT 
            WHERE EMP.DEPTNO = DEPT.DEPTNO;

    END IF;
    io_cursor := v_cursor; 
   END open_join_cursor1; 
   END curspkg_join;
   / 
                

back to the top

Create the Visual C# .NET Application

  1. Create a new Visual C# Windows Application project. Form1 is added to the project by default.
  2. Add the following code to the top of the Code window:

    using System.Data.OleDb;
                        
  3. Add the following code to the Form_Load event of Form1:

    OleDbConnection Oraclecon = new OleDbConnection("Provider=MSDAORA.1;Password=tiger;"
                  + "User ID=scott;Data Source=OracleServer;Persist Security Info=True");
    Oraclecon.Open();
    OleDbCommand myCMD =  new OleDbCommand
    ("{call curspkg_join.open_join_cursor1(?, {resultset 0, io_cursor})}", Oraclecon);
    myCMD.Parameters.Add("ID", OleDbType.Numeric, 4).Value = 0;
    OleDbDataReader myReader;
    myReader = myCMD.ExecuteReader();
    int x; 
    int count;
    count = 0;
    while (myReader.Read())
                    
    {   
        for (x = 0; x <= myReader.FieldCount - 1; x++) 
            Console.Write(myReader.GetValue(x) + " ");
    
          
        Console.WriteLine();
        count += 1;
    }
    
    
    MessageBox.Show(count + " Rows Returned.");
    myReader.Close();
    Oraclecon.Close();
                        
  4. Modify the OleDbConnection string as appropriate for your environment.
  5. Press the F5 key to compile and run the application. Notice that the data from the Oracle stored procedure appears in the Debug window, and a row count appears in a message box.

back to the top

Additional Information

Notice that the code loops through the DataReader:

while (myReader.Read())
                

This is because the DataReader reads only one line at a time.

back to the top

REFERENCES

For additional information%1, click the article number%2 below to view the article%2 in the Microsoft Knowledge Base:

176086 How To Retrieve Recordsets from Oracle Stored Procedures Using ADO


For more information about the DataReader, refer to the following topic in the Microsoft .NET Software Development Kit (SDK) documentation:

back to the top

Keywords: kbhowtomaster kbsystemdata KB309361