<% Dim columnTypes(205) columnTypes(0) = "Empty" columnTypes(2) = "SmallInt" columnTypes(3) = "Long Integer" columnTypes(4) = "Real" columnTypes(5) = "Double" columnTypes(6) = "Currency" columnTypes(7) = "Date" columnTypes(8) = "BSTR" columnTypes(9) = "IDispatch" columnTypes(10) = "Error Code" columnTypes(11) = "Boolean" columnTypes(12) = "Variant" columnTypes(13) = "IUnknown" columnTypes(14) = "Decimal" columnTypes(16) = "TinyInt" columnTypes(17) = "Unsigned TinyInt (BYTE)" columnTypes(18) = "Unsigned Small Int (WORD)" columnTypes(19) = "Unsigned Int (DWORD)" columnTypes(20) = "BigInt" columnTypes(21) = "Unsigned Big Int" columnTypes(64) = "FileTime" columnTypes(72) = "Unique Identifier (GUID)" columnTypes(128) = "Binary" columnTypes(129) = "Char" columnTypes(130) = "nChar" columnTypes(131) = "Numeric" columnTypes(132) = "User Defined (UDT)" columnTypes(133) = "DBDate" columnTypes(134) = "DBTime" columnTypes(135) = "SmallDateTime" columnTypes(136) = "Chapter" columnTypes(138) = "Automation (PropVariant)" columnTypes(139) = "VarNumeric" columnTypes(200) = "VarChar" columnTypes(201) = "Text" columnTypes(202) = "Text" columnTypes(203) = "Memo" columnTypes(204) = "VarBinary" columnTypes(205) = "Image" Dim Connstr, adox, Conn, tbl ConnStr = "Provider=Microsoft.Jet.OLEDB.4.0;" & _ "Data Source=" & Server.Mappath("NWind.mdb") Set adox = CreateObject("ADOX.Catalog") Set Conn = CreateObject("ADODB.Connection") Conn.open ConnStr adox.activeConnection = Conn Response.Write "<table><tr><td width=""25%"" valign=""top"">" Response.Write "<h2>Tables</h2>" For Each tbl In adox.Tables On Error Resume Next If tbl.Type = "TABLE" Then Response.Write "<strong>" & tbl.Name & "</strong><br />" Response.Write "Date Created: " & tbl.DateCreated & "<br />" sql = "SELECT Count(*) FROM " & tbl.Name If Err.Number <> 0 Then REsponse.Write "!!!!!!!" & sql Set rs = Conn.Execute(sql) Response.Write "Total Rows: " & rs(0) & "<br /><br /><strong>Columns</strong><br/>" rs.Close : Set rs = Nothing Set table = adox.Tables(tbl.Name) For Each column in table.columns On Error Resume Next Response.Write column.name & " (" & columnTypes(column.type) & ") <br>" If err.Number<>0 Then Response.Write err.Description On Error Goto 0 Next If Not Left(tbl.Name,1) = "q" Then Response.Write "<br /><strong>" & tbl.Name & " Indexes</strong><br />" For Each index In tbl.Indexes colNames = "" sortOrders = "" For Each col In index.Columns colNames = colNames & col.Name so = "ASC" If col.SortOrder = 2 Then so = "DESC" sortOrders = sortOrders & so Next Response.Write "Column Name(s): " & colNames & _ "<br />Sort Order: " & sortOrders Response.Write "<br/ >Index: " & index.Name & _ "<br />Unique: " & index.Unique & _ "<br />Clustered: " & index.Clustered & _ "<br />Primary Key: " & index.PrimaryKey & "<br /><br />" Next End If Response.Write "<br />" End If Next Response.Write "</td><td width=""25%"" valign=""top"">" Dim proc Response.Write "<h2>Procedures</h2>" For Each proc in adox.Procedures Response.Write "<strong>" & proc.Name & "</strong><br>" Response.Write "Date Created: " & proc.DateCreated & "<br />" Response.Write Replace(proc.Command.CommandText,chr(13),"<br />") Response.Write "<p>" Next Response.Write "</td><td width=""33%"" valign=""top"">" Response.Write "<h2>Views</h2>" For Each v in adox.Views Response.Write "<strong>" & v.Name & "</strong><br>" Response.Write "Date Created: " & v.DateCreated & "<br />" Response.Write Replace(v.Command.CommandText,chr(13),"<br />") Response.Write "<p>" Next Response.write "</td></tr></table>" Set table = nothing Conn.close: Set Conn = nothing Set adox = nothing %>
Analyse the tables and saved queries in an Access database with ADOX
The following code will enumerate the tables and their properties, together with the queries in an Access database. Saved SELECT queries are referenced using the Views collection, and INSERT, UPDATE and DELETE queries are referenced from the Procedures collection.