HOWTO: Use the ADO SHAPE CommandID: Q189657
|
This article describes the ADO SHAPE command syntax for producing hierarchical recordsets, and explains how to traverse hierarchical recordsets. VBA sample code is also provided.
You can use hierarchical recordsets as an alternative to JOIN and GROUP BY
syntax when you need to access parent-child and summary data.
Hierarchical recordsets are used in many products: Xbase products use the
SET RELATION command, Access uses "Segmented Virtual Tables" internally for
reports with grouping levels, and so forth. Hierarchies give you the
ability to build one or several recordsets, define groupings, and specify
aggregate calculations over child recordsets. Although you could implement
similar functionality through code, this functionality shifts much of the
mundane work from the developer to the system.
Hierarchical recordsets are available through the MSDataShape provider,
which is implemented by the client cursor engine.
Hierarchical recordsets differ from SQL JOIN and GROUP BY statements in that with a JOIN, both the parent table fields and child table fields are represented in the same recordset. With a hierarchical recordset, the recordset contains only fields from the parent table. In addition, the recordset contains an extra field that represents the related child data,which you can assign to a second recordset variable and traverse.
When you are performing aggregate functions using GROUP BY and aggregate operators, only aggregate values appear in the recordset. With hierarchical recordsets, the aggregate values are represented in the parent recordset and the detail records are in the child recordset.
You can create three types of shapes, and each type has its own strengths
and weaknesses. You need to choose the mechanism that best fits the needs
of your application and the environment you will be running your
application in. The types of SHAPE are as follows:
SHAPE {parent-statement}
APPEND Aggregate
| ({child-statement} [As Alias]
RELATE parent-field TO child-field | parameter-marker
[, parent-field TO child-field | parameter-marker ...])
[, Aggregate | ({child statement})...]
SHAPE {non-normalized-statement} [AS Alias]
COMPUTE Aggregate
| Alias
| ({child-statement} [As Alias] RELATE parent-field TO
child-field | parameter-marker)
[, Aggregate | Alias | ({child-statement}...)]
[BY grouping-field [, grouping-field]]
SHAPE {non-normalized-statement} [AS Alias]
BY grouping-field [, grouping-field]
SHAPE {select * from customers}
APPEND ({select * from orders} AS rsOrders
RELATE customerid TO customerid)
Which yields:
Customers.*
rsOrders
|
+----Orders.*
In the previous diagram, the parent recordset contains all fields from the
Customers table and a field called rsOrders. rsOrders provides a reference
to the child recordset, and contains all the fields from the Orders table.
The other examples use a similar notation.
SHAPE {select * from customers}
APPEND ({select * from orders where customerid = ?} AS rsOrders
RELATE customerid TO PARAMETER 0)
This results in the same hierarchy as the simple relation hierarchy.
SHAPE {SELECT * from customers}
APPEND ((SHAPE {select * from orders}
APPEND ({select * from [order details]} AS rsDetails
RELATE orderid TO orderid)) AS rsOrders
RELATE customerid TO customerid)
Which yields:
Customers.*
rsOrders
|
+----Orders.*
rsDetails
|
+----[Order Details].*
SHAPE {SELECT * FROM customers}
APPEND ({SELECT *
FROM orders
WHERE orderdate < #1/1/1998# AND customerid = ?}
RELATE customerid TO PARAMETER 0) AS rsOldOrders,
({SELECT *
FROM orders
WHERE orderdate >= #1/1/1998#}
RELATE customerid TO customerid) AS rsRecentOrders
Which yields:
Customers.*
rsOldOrders
|
+----Orders.*
rsRecentOrders
|
+----Orders.*
SHAPE (select * from orders}
APPEND ({select od.orderid, od.UnitPrice * od.quantity as ExtendedPrice
from [order details] As od}
RELATE orderid TO orderid) As rsDetails,
SUM(ExtendedPrice) AS OrderTotal
Which yields:
Orders.*
rsDetails
|
+----orderid
ExtendedPrice
OrderTotal
SHAPE {select customers.customerid AS cust_id, orders.*
from customers inner join orders
on customers.customerid = orders.customerid} AS rsOrders
COMPUTE rsOrders BY cust_id
Which yields:
rsOrders
|
+----cust_id
Orders.*
cust_id
SHAPE
(SHAPE {select customers.*, orders.orderid, orders.orderdate
from customers inner join orders
on customers.customerid = orders.customerid}
APPEND ({select od.orderid,
od.unitprice * od.quantity as ExtendedPrice
from [order details] as od} AS rsDetails
RELATE orderid TO orderid),
SUM(rsDetails.ExtendedPrice) AS OrderTotal) AS rsOrders
COMPUTE rsOrders,
SUM(rsOrders.OrderTotal) AS CustTotal,
ANY(rsOrders.contactname) AS Contact
BY customerid
Which yields:
rsOrders
|
+----Customers.*
orderid
orderdate
rsDetails
|
+----orderid
ExtendedPrice
OrderTotal
CustomerTotal
Contact
customerid
SHAPE
(SHAPE {select customers.*,
od.unitprice * od.quantity as ExtendedPrice
from (customers inner join orders
on customers.customerid = orders.customerid) inner join
[order details] as od on orders.orderid = od.orderid}
AS rsDetail
COMPUTE ANY(rsDetail.contactname) AS Contact,
ANY(rsDetail.region) AS Region,
SUM(rsDetail.ExtendedPrice) AS CustTotal,
rsDetail
BY customerid) AS rsCustSummary
COMPUTE rsCustSummary
BY Region
Which yields:
rsCustSummary
|
+-----Contact
Region
CustTotal
rsDetail
|
+----Customers.*
ExtendedPrice
customerid
Region
SHAPE
(SHAPE {select customers.*,
od.unitprice * od.quantity as ExtendedPrice
from (customers inner join orders
on customers.customerid = orders.customerid) inner join
[order details] as od on orders.orderid = od.orderid}
AS rsDetail
COMPUTE ANY(rsDetail.contactname) AS Contact,
SUM(rsDetail.ExtendedPrice) AS CustTotal,
rsDetail
BY customerid) AS rsCustSummary
COMPUTE SUM(rsCustSummary.CustTotal) As GrandTotal,
rsCustSummary
Note the missing BY clause in the outer summary. This defines the Grand
Total because the parent rowset contains a single record with the grand
total and a pointer to the child recordset.
GrandTotal
rsCustSummary
|
+-----Contact
CustTotal
rsDetail
|
+----Customers.*
ExtendedPrice
customerid
SHAPE {select customers.* from customers} AS rsDetail
COMPUTE rsDetail,
ANY(rsDetail.companyname) AS Company,
({select * from orders where customerid = ?}
RELATE customerid TO PARAMETER 0) AS rsOrders,
COUNT(rsOrders.orderid) AS OrderCount
BY customerid
Which yields:
rsDetail
|
+----Customers.*
Company
rsOrders
|
+----Orders.*
OrderCount
customerid
SHAPE
(SHAPE {select * from customers}
APPEND ((SHAPE {select orders.*, year(orderdate) as OrderYear,
month(orderdate) as OrderMonth
from orders} AS rsOrders
COMPUTE rsOrders
BY customerid, OrderYear, OrderMonth)
RELATE customerid TO customerid) AS rsOrdByMonth )
AS rsCustomers
COMPUTE rsCustomers
BY region
Which yields:
rsCustomers
|
+-----customers.*
rsOrdByMonth
|
+-----rsOrders
|
+---- Orders.*
customerid
OrderYear
OrderMonth
region
<shape-command> ::= SHAPE <table-exp> [AS <alias>]
[<shape_action>]
<shape-action> ::= APPEND <aliased-field-list>
| COMPUTE <aliased-field-list>
[BY <field-list>]
| BY <field-list>
<table-exp> ::= {<native-sql-statement>}
| ( <shape-command> )
<aliased-field-list> ::= <aliased-field> [, <aliased-field...]
<aliased-field> ::= <field-exp> [AS <alias>]
<field-exp> ::= ( <relation-exp> ) | <calculated-exp>
<relation_exp> ::= <table-exp> [AS <alias>] RELATE
<relation-cond-list>
<relation-cond-list> ::= <relation-cond> [, <relation-cond>...]
<relation-cond> ::= <field-name> TO <child-ref>
<child-ref> ::= <field-name> | PARAMETER <param-ref>
<param-ref> ::= <name> | <number>
<field-list> ::= <field-name [, <filed-name>]
<calculated-exp> ::= SUM (<qualified-field-name>)
| AVG (<qualified-field-name>)
| MIN (<qualified-field-name>)
| MAX (<qualified-field-name>)
| COUNT (<alias>)
| SDEV (<qualified-field-name>)
| ANY (<qualified-field-name>)
| CALC (<expression>)
<qualified-field-name>::= <alias>.<field-name> | <field-name>
<alias> ::= <quoted-name>
<field-name> ::= <quoted-name>
<quoted-name> ::= "<string>" | '<string>' | <name>
<name> ::= alpha [ alpha | digit | _ | # ...]
<number> ::= digit [digit...]
<string> ::= unicode-char [unicode-char...]
<expression> ::= an expression recognized by the Jet
Expression service whose operands are
other non-CALC columns in the same row.
Multiline: True (Visual Basic only)
Scrollbars: Vertical
Font: Courier New 10 Point
Private Sub Command1_Click()
Dim cn As ADODB.Connection, rs As ADODB.Recordset
Me!Text2.Text = ""
Set cn = New ADODB.Connection
Set rs = New ADODB.Recordset
cn.Provider = "MSDataShape"
cn.Open "dsn=OLE_DB_NWIND_JET"
On Error Resume Next
rs.Open Me!Text1.Text, cn, adOpenStatic, adLockReadOnly, adCmdText
If Err Then MsgBox Error
ListChapteredFields rs, 0
rs.Close
cn.Close
Set rs = Nothing
Set cn = Nothing
End Sub
Private Sub LogText(ByVal sLine As String)
If Me!Text2.Text = "" Then
Me!Text2.Text = sLine
Else
Me!Text2.Text = Me!Text2.Text & vbCrLf & sLine
End If
End Sub
Private Sub ListChapteredFields(ByVal rs As ADODB.Recordset, _
ByVal Level As Long)
Dim I As Long
For I = 0 To rs.Fields.Count - 1
LogText Space$(Level * 3) & rs(I).Name
If rs(I).Type = adChapter Then
ListChapteredFields rs(I).Value, Level + 1
End If
Next I
End Sub
cn.Provider = "MSDataShape"
cn.Open "Data Provider=Microsoft.Jet.OLEDB.4.0"
NOTE: If you misspell field or table names when using the Access 97 ODBC driver or JOLT providers, you will receive the following message:
Other providers might produce a different message.Too few parameters. Expected n.
ADO 2.0 Hierarchical Cursor Specification
For additional information about SHAPE APPEND syntax and how to traversehierarchical recordsets, please see the following
article in the Microsoft Knowledge Base:
Q185425 ADO Hierarchical Recordsets via SHAPE APPEND via C++/VBA/Java
© Microsoft Corporation 1998, All Rights Reserved.
Contributions by Malcolm Stewart, Microsoft Corporation
Additional query words:
Keywords : kbADO kbADO200 kbDatabase kbVBp600 kbVBp600FAQ
Version : WINDOWS:2.0
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: June 22, 1999