Note, this is all with ADO.NET using the ODBC and OleDb drivers
We've been using DataTable schemaTable = conn.GetSchema("views");
which was working ok and now we are finding some drivers where under
both ODBC and OleDb it is now returning hundreds of system views -
while table still seems to be ok (for now).
So my question is, how do I get the following from ODBC and OleDb in a
way that will work on all databases. And if there is no way to do
that, how do I do it for Sql Server 2000, Sql Server 2005, and Access.
1) Enumerate all user tables in a database.
2) Enumerate all tables (user & system) in a database.
3) Enumerate all user views in a database.
4) Enumerate all views (user & system) in a database.
5) Enumerate all columns in a table or view.
6) For a column, get it's data type.
7) Enumerate all user stored procedures in a database
8) Enumerate all stored procedures (user & system) in a database.
9) For a stored procedure, get all parameters and their data type.
10) For all objects - get the description of it in the metadata.
From reading the specs for ODBC and OleDb it seems that everything
above (with the possible exception of item 9) should be doable in a
standard way that works for every implementation.
Help please.
thanks - dave
david@at-at-at@windward.dot.dot.net
Windward Reports -- http://www.WindwardReports.com
me -- http://dave.thielen.com
Cubicle Wars - http://www.windwardreports.com/film.htm
The collection of DB schema information VARIES in different providers and 
drivers. The common schema collection that are supported by all the managed 
providers is documented at:
Understanding the Common Schema Collections
http://msdn.microsoft.com/en-us/library/ms254501(VS.80).aspx
But this collection does not include your requested information like all 
user tables in a DB. To get the detailed schema info, we would need to 
first decide the DB (SQL Server/Oracle/Access, etc) and the provider 
(OLEDB/ODBC/ Microsoft .NET Framework Data Provider). For each combination, 
we have provider-specific schema collections:
Understanding the Provider-Specific Schema Collections  
http://msdn.microsoft.com/en-us/library/ms254969(VS.80).aspx
Some of them provide restricted collection of info; some provide the 
details that may meet our needs.
So back to your questions:
1. how do I get the following from ODBC and OleDb in a way that will work 
on all databases
This is hard to do because each provider supplies different set of schema 
info.
2. how do I do it for Sql Server 2000, Sql Server 2005, and Access
OLEDB provider for SQL server may better fit the need. 
(see "Microsoft SQL Server OLEDB Provider" and "Microsoft Jet OLEDB 
Provider" sections in the article 
http://msdn.microsoft.com/en-us/library/ms254969(VS.80).aspx). 
1) Enumerate all user tables in a database.
We can call conn.GetSchema("Tables"); and filter the outputs by 
TABLE_TYPE=="TABLE"
2) Enumerate all tables (user & system) in a database.
We can call conn.GetSchema("Tables"); and filter the outputs by 
TABLE_TYPE=="TABLE" OR TABLE_TYPE=="SYSTEM TABLE"
3) Enumerate all user views in a database.
We can call conn.GetSchema("Tables"); and filter the outputs by 
TABLE_TYPE=="VIEW" 
4) Enumerate all views (user & system) in a database.
We can call conn.GetSchema("Tables"); and filter the outputs by 
TABLE_TYPE=="VIEW" OR TABLE_TYPE=="SYSTEM VIEW"
5) Enumerate all columns in a table or view.
We can call conn.GetSchema("Columns"); and filter the outputs by 
TABLE_NAME=="our table/view name"
6) For a column, get it's data type.
The DATA_TYPE field of question 5) provides the data type info of the 
column.
7) Enumerate all user stored procedures in a database
8) Enumerate all stored procedures (user & system) in a database.
We can call conn.GetSchema("Procedures"); to get all the stored procedures. 
As far as I know, there's no strict criteria to distinguish the user/system 
stored procedure. A possible solution is to filter by SP name because all 
the system SPs starts with "dt_" or "sp_".
9) For a stored procedure, get all parameters and their data type.
conn.GetSchema("ProcedureParameters"); and filter the outputs by 
PROCEDURE_NAME="our procedure name"
10) For all objects - get the description of it in the metadata.
Do you mean MetaDataCollections?
http://msdn.microsoft.com/en-us/library/ms254501(VS.80).aspx
Apart from the above, OLEDB provider has an additional set of methods to 
retrieve the schema info:
http://support.microsoft.com/kb/309681/en-us
If you have any other questions or concerns, please DON'T hesitate to tell 
me.
Regards,
Jialiang Ge (jia...@online.microsoft.com, remove 'online.')
Microsoft Online Community Support
Delighting our customers is our #1 priority. We welcome your comments and 
suggestions about how we can improve the support we provide to you. Please 
feel free to let my manager know what you think of the level of service 
provided. You can send feedback directly to my manager at: 
msd...@microsoft.com.
==================================================
Get notification to my posts through email? Please refer to 
http://msdn.microsoft.com/en-us/subscriptions/aa948868.aspx#notifications.
Note: The MSDN Managed Newsgroup support offering is for non-urgent issues 
where an initial response from the community or a Microsoft Support 
Engineer within 1 business day is acceptable. Please note that each follow 
up response may take approximately 2 business days as the support 
professional working with you may need further investigation to reach the 
most efficient resolution. The offering is not appropriate for situations 
that require urgent, real-time or phone-based interactions or complex 
project analysis and dump analysis issues. Issues of this nature are best 
handled working with a dedicated Microsoft Support Engineer by contacting 
Microsoft Customer Support Services (CSS) at 
http://support.microsoft.com/select/default.aspx?target=assistance&ln=en-us.
==================================================
This posting is provided "AS IS" with no warranties, and confers no rights.
Oh well, it's a very old spec so it makes sense that it isn't that
complete.
thanks - dave
For example, if you want to get all table information, you can use the API 
SQLTables:
http://msdn.microsoft.com/en-us/library/ms711831(VS.85).aspx
Note that field TABLE_TYPE in the result set. This tells you whether a table 
is system or user.
Let's try those catalog APIs and see whether this can solve your problem.
Ming.
MDAC Team, Microsoft.
For views we need to do:
				DataTable schemaTable =
conn.GetSchema("views");
				foreach (DataRow rowOn in
schemaTable.Rows)
					if
((((string)rowOn["TABLE_TYPE"]).ToUpper() == "VIEW") && 
(((string)rowOn["TABLE_SCHEM"]).ToUpper() != "INFORMATION_SCHEMA") &&
(((string)rowOn["TABLE_SCHEM"]).ToUpper() != "SYS"))
						rtn.Add(new
WrView((string)rowOn["TABLE_NAME"], "", false));
For stored procedures we need to do:
				DataTable schemaTable =
conn.GetSchema("procedures");
				foreach (DataRow rowOn in
schemaTable.Rows)
				{
					if
((((string)rowOn["PROCEDURE_SCHEM"]).ToUpper() ==
"INFORMATION_SCHEMA") ||
(((string)rowOn["PROCEDURE_SCHEM"]).ToUpper() == "SYS"))
						continue;
					string name =
(string)rowOn["PROCEDURE_NAME"];
					if (name.StartsWith("dt_")) //
only way I could find to skip system ones
						continue;
					if (name.IndexOf(';') != -1)
						name =
name.Substring(0, name.IndexOf(';'));
					rtn.Add(new
WrStoredProcedure(name, "", false));
				}
And for both views & stored procedures we don't know how well that
will work with all ODBC drivers as INFORMATION_SCHEMA is a SqlServer
table.
thanks - dave