cw,
A while back, I wrote a function (fnSimilarity) that might help. Basically,
it accepts two variants (to accomdate NULL values in my fields) and parses
them into their component parts (delimited by a space). Then compares each
'word' in each string and counts the number of matches compared to the number
of combinations. Unfortunately, the more words in the values passed, the
lower the "similarity", unless they are exact matches. You could modify this
to ignore 'and', 'the', or other words in both parameters. It might at least
give you a start. You might use it like:
SELECT tbl1.*, tbl2.*
FROM tbl1, tbl2
WHERE Similarity(tbl1.field1, tbl2.Field1) > csng([Cutoff value?])
Order by Similarity(tbl1.field1, tbl2.field1) DESC
Public Function Similarity(FirstValue As Variant, SecondValue As Variant) As
Single
Dim FArray() As String, SArray() As String
Dim intCounter As Integer, intMatches As Integer
Dim intLoop1 As Integer, intLoop2 As Integer
If IsNull(FirstValue) Or IsNull(SecondValue) Then
Similarity = 0
Exit Function
ElseIf FirstValue = SecondValue Then
Similarity = 99
Exit Function
End If
FArray() = Split(FirstValue, " ")
SArray() = Split(SecondValue, " ")
For intLoop1 = LBound(FArray) To UBound(FArray)
For intLoop2 = LBound(SArray) To UBound(SArray)
intCounter = intCounter + 1
If FArray(intLoop1) = SArray(intLoop2) Then
intMatches = intMatches + 2
ElseIf InStr(FArray(intLoop1), SArray(intLoop2)) > 0 Then
intMatches = intMatches + 1
ElseIf InStr(SArray(intLoop2), FArray(intLoop1)) > 0 Then
intMatches = intMatches + 1
End If
Next intLoop2
Next intLoop1
Similarity = IIf(intCounter = 0, 0, CSng(intMatches) / CSng(intCounter))
End Function
--
Email address is not valid.
Please reply to newsgroup only.
cw said:
I would like to develop a query that finds similar match's across 2 files.
Table 1
Company Name: The Atlas Company
Table 2
Company Name: Atlas
Query would see these as possible match and display them in the query
results. I can not figure out how to get this to work.
Any help is Greatly Appreciated.