HOWTO: Handle Quotes and Pipes in Concatenated SQL LiteralsID: Q178070
|
Building concatenated SQL statements based on user-typed text values can result in invalid SQL statements. This article provides a solution to the problem of building concatenated SQL.
When building concatenated SQL statements, you can run into the following problems based on incorporating user-typed text into the SQL statement:
SQL = "SELECT * FROM Employees WHERE LastName='" & LName & "'"
SELECT * FROM Employees WHERE LastName='O'Brien'
this can result in the following error message when you execute the SQL
statement:
One solution is to replace the apostrophe delimiter with quotes ("), such as:Run-time error 3075 Syntax error in query expression '...'
SQL = "SELECT * FROM Employees WHERE LastName=""" & LName & """"
However, the user could easily type O"Brien by mistake (forgetting to
release the SHIFT key when typing the apostrophe) and the problem
reappears. In addition, SQL Server uses " to delimit table and field names.
If the user-supplied value exceeds the maximum length of an identifier
name, SQL Server will return a syntax error.
SELECT * FROM Employees WHERE LastName='O''Brien'
LastName = 'O'Brien'
LastName = 'O''Brien'
LastName = 'O' & chr(39) & 'Brien'
SQL = "SELECT * FROM SecurityLevel WHERE UID='" & UserID & "'"
SQL = SQL & " AND PWD='" & Password & "'"
SELECT * FROM SecurityLevel WHERE UID='JohnDoe'
AND PWD='A2|45'
The pipe symbol causes problems because Jet uses pipe symbols to delimit field or parameter names embedded in a literal string, such as:Run-time error 3061 Too few parameters. Expected n.
SELECT "|LastName|, |FirstName|" FROM Employees
SELECT * FROM SecurityLevel WHERE UID='JohnDoe'
AND PWD='A2' & chr(124) & '45'
Function ReplaceStr (TextIn, ByVal SearchStr As String, _
ByVal Replacement As String, _
ByVal CompMode As Integer)
Dim WorkText As String, Pointer As Integer
If IsNull(TextIn) Then
ReplaceStr = Null
Else
WorkText = TextIn
Pointer = InStr(1, WorkText, SearchStr, CompMode)
Do While Pointer > 0
WorkText = Left(WorkText, Pointer - 1) & Replacement & _
Mid(WorkText, Pointer + Len(SearchStr))
Pointer = InStr(Pointer + Len(Replacement), WorkText, _
SearchStr, CompMode)
Loop
ReplaceStr = WorkText
End If
End Function
Function SQLFixup(TextIn)
SQLFixup = ReplaceStr(TextIn, "'", "''", 0)
End Function
Function JetSQLFixup(TextIn)
Dim Temp
Temp = ReplaceStr(TextIn, "'", "''", 0)
JetSQLFixup = ReplaceStr(Temp, "|", "' & chr(124) & '", 0)
End Function
Function FindFirstFixup(TextIn)
Dim Temp
Temp = ReplaceStr(TextIn, "'", "' & chr(39) & '", 0)
FindFirstFixup = ReplaceStr(Temp, "|", "' & chr(124) & '", 0)
End Function
SQL = "SELECT * FROM Employees WHERE LastName='" & _
SQLFixup(LName)& "'"
SQL now contains:
SELECT * FROM Employees WHERE LastName='O''Brien'
JetSQLFixup should be used if Jet is your database back-end, or if doing a
non-Pass-through query to an ODBC datasource:
UserID cntains: JohnDoe
Password contains: A2|4'5
SQL = "SELECT * FROM SecurityLevel WHERE UID='" & _
JetSQLFixup(UserID) & "' AND PWD='" & JetSQLFixup(Password) & "'"
SELECT * FROM SecurityLevel WHERE UID='JohnDoe'
AND PWD='A2' & chr(124)&'4''5'
Criteria = "LastName = '" & FindFirstFixup(LName) & "'"
Microsoft Jet Database Engine Programmer's Guide
Visual Basic Help topic: InStr
For additional information, please see the following article in the
Microsoft Knowledge Base:
Q147687 HOWTO: Query for Literal Special Characters in a Where Clause
© Microsoft Corporation 1999, All Rights Reserved.
Contributions by Malcolm Stewart, Microsoft Corporation
Additional query words:
Keywords : kbVBp300 kbVBp400 kbVBp500 kbVBp600 kbGrpVB
Version : WINDOWS:1.0,1.1,2.0,3.0,4.0,5.0,6.0,7.0,97
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: May 13, 1999