Hierarchical Rowsets

DTS Programming

DTS Programming

Hierarchical Rowsets

A rowset is an OLE DB object that consists of data organized as a grid of rows and named, typed columns. Typically, a rowset contains a result set from a database query, but the data can come from any source.

In a hierarchical rowset, one or more columns are themselves rowsets. The individual column values are references to subsets, called chapters, of the column rowset. A chapter can include none, some, or all of its rows. The column rowsets can themselves have one or more columns that are rowsets, nested to an arbitrary level.

Using the Data Shaping Service for OLE DB

Hierarchical rowsets are often generated with the Microsoft® Data Shaping Service for OLE DB. This provider supports the Shape language, which allows rowset hierarchies to be constructed from rowsets obtained from an OLE DB data provider. The Shape Append command appends one or more child rowsets as columns to a parent rowset, and assigns a reference to a chapter to each row value in each appended column. For example:

SHAPE {SELECT au_id, au_lname, au_fname FROM authors}
APPEND ({SELECT au_id, title FROM titleauthor TA, titles TS
            WHERE TA.title_id = TS.title_id}
        AS title_chap RELATE au_id TO au_id)

This command creates a parent rowset from table authors and appends a child rowset in a column named title_chap. Each row value in title_chap is a reference to the subset of the child rowset that has the same value in its au_id column as in the au_id column of the parent rowset for that row. The tables referenced by this command are in the pubs database that is supplied with Microsoft SQL Server™ 2000.

Writing sGetTitleAuthors Code

This is the Microsoft Visual Basic® source code for the sGetTitleAuthors function:

Private Function sGetTitleAuthors() As String
Dim rstParent   As ADODB.Recordset
Dim rstChild    As ADODB.Recordset
Dim sBuf        As String
   
Const CONNECT_PUBS = "PROVIDER=MSDataShape;DATA PROVIDER=SQLOLEDB;" & _
    "SERVER=;DATABASE=pubs;UID=sa;PWD=;"
Const SHAPE_TITLEAUTHORS = _
    "SHAPE {SELECT au_id, au_lname, au_fname FROM authors} " & _
    "APPEND ({SELECT au_id, title FROM titleauthor TA, titles TS " & _
             "WHERE TA.title_id = TS.title_id} " & _
            "AS title_chap RELATE au_id TO au_id)"
            
    '----- create rowsets
    Set rstParent = New ADODB.Recordset
    rstParent.Open SHAPE_TITLEAUTHORS, CONNECT_PUBS
            
    '----- process parent rowset
    Do While Not rstParent.EOF
        sBuf = sBuf & rstParent("au_id") & vbTab & _
            rstParent("au_lname") & ", " & rstParent("au_fname") & vbCrLf
            
        '----- process chapter of child rowset
        Set rstChild = rstParent("title_chap").Value
        Do While Not rstChild.EOF
            sBuf = sBuf & vbTab & vbTab & rstChild("title") & vbCrLf
            rstChild.MoveNext
        Loop
        rstParent.MoveNext
    Loop
    sGetTitleAuthors = sBuf
End Function
Running sGetTitleAuthors

This Microsoft Visual Basic function creates and processes the hierarchical rowset described earlier. It returns a string consisting of each author name, followed by the titles associated with that author in the pubs database.

This example can be run on a computer on which Visual Basic 6.0 and SQL Server 2000 have been installed.

The steps for running this example are as follows:

  1. Create a new Standard EXE project in the Visual Basic development environment.

  2. In the Project/References dialog box, select Microsoft ActiveX Data Objects 2.5 Library.

  3. Place a command button and a textbox on the form Form1. Set the ScrollBars property of the textbox to 3 – Both and the MultiLine property to TRUE.

  4. Copy the following code for function sGetTitleAuthors to the code window for Form1.

  5. In the _Click sub for the command button, call sGetTitleAuthors, and assign the string it returns to the Text property of the text box.

  6. Run the project and click the command button.