Using SQLRetrieve to Return Data to a Protected Worksheet (149027)
The information in this article applies to:
- Microsoft Excel 97 for Windows
This article was previously published under Q149027 SYMPTOMS
In Microsoft Excel, when you use the SQLRetrieve function in a Microsoft
Visual Basic for Applications procedure to return data from an ODBC data
source to a Microsoft Excel worksheet, you may receive the following error
message twice and no data will be retrieved:
Cannot paste data.
This error only occurs when you use Microsoft Excel for Windows, version
5.0.
For all other versions of Microsoft Excel listed at the beginning of
this article, the SQLRetrieve function returns an Error 2015, which
indicates that the function was unable to paste the data to the
worksheet. Also, no data is returned to the worksheet.
CAUSE
The error message stated above occurs in Microsoft Excel version 5.0,
only when the destination worksheet has been protected and any or all
cells in the destination range have been locked.
For Microsoft Excel versions 5.0c and later, SQLRetrieve fails when you
attempt to retrieve data to a protected worksheet, regardless of whether
the cells have been locked or not.
WORKAROUNDMicrosoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
To avoid this problem, unprotect the worksheet before you use the
SQLRetrieve function. The following macro example shows how to unprotect
a worksheet, retrieve the data, and then protect the sheet again.
Visual Basic Macro Code Example
Sub SQLOpen_Example()
Dim Chan As Variant
Dim NumberOfColumns As Variant, NumberOfRows As Variant
Dim ContentsProtected As Boolean
Dim ObjectsProtected As Boolean, ScenariosProtected As Boolean
' Open the Nwind data source and check for connection errors
Chan = SQLOpen("DSN=Nwind")
If IsError(channel) Then
MsgBox SQLError()(3)
Exit Sub
End If
' Execute the query statement and check for SQL statement errors
NumberOfColumns = SQLExecQuery(Chan, "SELECT * FROM Customer")
If IsError(NumberOfColumns) Then
MsgBox SQLError()(3)
SQLClose channel
Exit Sub
End If
' Set an object variable to reference Sheet1
Set thesheet = Worksheets("Sheet1")
With thesheet
' If sheet is protected, then store the current values
' of the ProtectDrawingObjects and ProtectScenarios
' properties so they can be reset later.
If .ProtectContents = True Then
ContentsProtected = True
ObjectsProtected = .ProtectDrawingObjects
ScenariosProtected = .ProtectScenarios
' Unprotect the sheet and assume no password is needed
.Unprotect
End If
End With
' Retrieve data to worksheet and check for retrieval errors
NumberOfRows = SQLRetrieve(Chan, Range("Sheet1!A1"), , , True)
If IsError(NumberOfRows) Then
MsgBox SQLError()(3)
End If
' Close the connection
SQLClose Chan
' If the sheet was previously protected, then reprotect it
' with the original settings. No password is used in this
' example.
If ContentsProtected = True Then
thesheet.Protect DrawingObjects:=ObjectsProtected, _
Contents:=True, Scenarios:=ScenariosProtected
End If
End Sub
STATUS
Microsoft is researching this problem and will post new information here
in the Microsoft Knowledge Base as it becomes available.
REFERENCES
For more information on SQLRetrieve, click the Search button in
Microsoft Excel Visual Basic Help and type:
For more information on protecting and unprotecting a worksheet, click
the Search button in Microsoft Excel Visual Basic Help and type:
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbdtacode kbpending kbprb kbProgramming KB149027 |
---|
|