I always know where the table beigins so thats ok.
I could not find any method for recordset (in the book that I have)
related to row count and column count
Appreciate a little more clarification please.
Money where mouth is:
Sub test()
Const FULL_FILENAME As String = "" & _
"C:\Tempo\db.xls"
Dim strLastColName As String
strLastColName = LastColumnName( _
FULL_FILENAME, "Sheet1$")
MsgBox strLastColName
Dim vntLastColLastval As Variant
vntLastColLastval = LastValueInColumn( _
FULL_FILENAME, "Sheet1$", _
strLastColName)
If IsNull(vntLastColLastval) Then
MsgBox "(Value is null)"
Else
MsgBox CStr(vntLastColLastval)
End If
Dim lngCols As Long
lngCols = ColumnCount( _
FULL_FILENAME, "Sheet1$")
MsgBox CStr(lngCols)
Dim lngRows As Long
lngRows = RowCount( _
FULL_FILENAME, "Sheet1$")
MsgBox CStr(lngRows)
End Sub
Public Function LastColumnName( _
ByVal FullFilename As String, _
ByVal TableName As String _
) As String
Dim Con As Object
Dim rs As Object
Dim strCon As String
Const CONN_STRING As String = "" & _
"Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=<FULL_FILENAME>;" & _
"Extended Properties='Excel 8.0;HDR=YES'"
' Build connection string
strCon = CONN_STRING
strCon = Replace(strCon, _
"<FULL_FILENAME>", FullFilename)
' Open connection to workbook
Set Con = CreateObject("ADODB.Connection")
With Con
.CursorLocation = 3 ' client-side
.ConnectionString = strCon
.Open
' Get column schema details
Set rs = .OpenSchema(4, _
Array(Empty, Empty, TableName, Empty))
End With
With rs
.ActiveConnection = Nothing
Con.Close
.Sort = "ORDINAL_POSITION DESC"
LastColumnName = _
.Fields("COLUMN_NAME").Value
End With
End Function
Public Function LastValueInColumn( _
ByVal FullFilename As String, _
ByVal TableName As String, _
ByVal ColumnName As String _
) As Variant
Dim Con As Object
Dim rs As Object
Dim strCon As String
Dim strSql1 As String
Const CONN_STRING As String = "" & _
"Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=<FULL_FILENAME>;" & _
"Extended Properties='Excel 8.0;HDR=YES'"
Const SQL As String = "" & _
"SELECT <COL_NAME> FROM [<TABLE_NAME>];"
' Build connection string
strCon = CONN_STRING
strCon = Replace(strCon, _
"<FULL_FILENAME>", FullFilename)
' Build sql
strSql1 = SQL
strSql1 = Replace(strSql1, "<TABLE_NAME>", TableName)
strSql1 = Replace(strSql1, "<COL_NAME>", ColumnName)
' Open connection to workbook
Set Con = CreateObject("ADODB.Connection")
With Con
.CursorLocation = 3 ' client-side
.ConnectionString = strCon
.Open
Set rs = .Execute(strSql1)
End With
With rs
.ActiveConnection = Nothing
Con.Close
.MoveLast
LastValueInColumn = _
.Fields(0).Value
End With
End Function
Public Function ColumnCount( _
ByVal FullFilename As String, _
ByVal TableName As String _
) As Long
Dim Con As Object
Dim rs As Object
Dim strCon As String
Const CONN_STRING As String = "" & _
"Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=<FULL_FILENAME>;" & _
"Extended Properties='Excel 8.0;HDR=YES'"
' Build connection string
strCon = CONN_STRING
strCon = Replace(strCon, _
"<FULL_FILENAME>", FullFilename)
' Open connection to workbook
Set Con = CreateObject("ADODB.Connection")
With Con
.CursorLocation = 3 ' client-side
.ConnectionString = strCon
.Open
' Get column schema details
Set rs = .OpenSchema(4, _
Array(Empty, Empty, TableName, Empty))
End With
With rs
.ActiveConnection = Nothing
Con.Close
ColumnCount = _
.RecordCount
End With
End Function
Public Function RowCount( _
ByVal FullFilename As String, _
ByVal TableName As String _
) As Variant
Dim Con As Object
Dim rs As Object
Dim strCon As String
Dim strSql1 As String
Const CONN_STRING As String = "" & _
"Provider=Microsoft.Jet.OLEDB.4.0;" & _
"Data Source=<FULL_FILENAME>;" & _
"Extended Properties='Excel 8.0;HDR=YES'"
Const SQL As String = "" & _
"SELECT COUNT(*) FROM [<TABLE_NAME>];"
' Build connection string
strCon = CONN_STRING
strCon = Replace(strCon, _
"<FULL_FILENAME>", FullFilename)
' Build sql
strSql1 = SQL
strSql1 = Replace(strSql1, "<TABLE_NAME>", TableName)
' Open connection to workbook
Set Con = CreateObject("ADODB.Connection")
With Con
.CursorLocation = 3 ' client-side
.ConnectionString = strCon
.Open
Set rs = .Execute(strSql1)
End With
With rs
.ActiveConnection = Nothing
Con.Close
.MoveLast
RowCount = _
.Fields(0).Value
End With
End Function
Jamie.