|
| 1 | += FUZZY_MATCH operator |
| 2 | +:database-version: 23.2 |
| 3 | +:database-category: sql |
| 4 | + |
| 5 | +[[feature_summary]] |
| 6 | + |
| 7 | +The `FUZZY_MATCH` operator enables you to compare strings for similarity using algorithms such as Jaro-Winkler and Levenshtein distance. |
| 8 | + |
| 9 | +[source,sql] |
| 10 | +[subs="verbatim"] |
| 11 | +---- |
| 12 | +/* Compare the team names to "Champions City" with the different fuzzy matching algorithms */ |
| 13 | +with teams as ( |
| 14 | + select * from ( |
| 15 | + values ( 'Champions United' ), |
| 16 | + ( 'Runner-up City' ), |
| 17 | + ( 'Midtable Town' ), |
| 18 | + ( 'Underdogs United' ), |
| 19 | + ( 'Upstart FC' ), |
| 20 | + ( 'Relegated Athletic' ) |
| 21 | + ) t ( team_name ) |
| 22 | +), match_value as ( |
| 23 | + select 'Champions City' match_team |
| 24 | +) |
| 25 | + select team_name, match_team, |
| 26 | + fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein, |
| 27 | + fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler, |
| 28 | + fuzzy_match ( bigram, team_name, match_team ) as bigram, |
| 29 | + fuzzy_match ( trigram, team_name, match_team ) as trigram, |
| 30 | + fuzzy_match ( whole_word_match, team_name, match_team ) as wwm, |
| 31 | + fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs |
| 32 | + from teams |
| 33 | + cross join match_value; |
| 34 | + |
| 35 | + |
| 36 | +/* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */ |
| 37 | +with teams as ( |
| 38 | + select * from ( |
| 39 | + values ( 'Champions United' ), |
| 40 | + ( 'Runner-up City' ), |
| 41 | + ( 'Midtable Town' ), |
| 42 | + ( 'Underdogs United' ), |
| 43 | + ( 'Upstart FC' ), |
| 44 | + ( 'Relegated Athletic' ) |
| 45 | + ) t ( team_name ) |
| 46 | +), match_value as ( |
| 47 | + select 'Champions City' match_team |
| 48 | +) |
| 49 | + select team_name, match_team |
| 50 | + from teams |
| 51 | + join match_value |
| 52 | + on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90; |
| 53 | +---- |
| 54 | + |
| 55 | +.Result |
| 56 | +[source,sql] |
| 57 | +[subs="verbatim"] |
| 58 | +---- |
| 59 | +SQL> /* Compare the team names to "Champions City" for the different fuzzy matching algorithms */ |
| 60 | +SQL> with teams as ( |
| 61 | + 2 select * from ( |
| 62 | + 3 values ( 'Champions United' ), |
| 63 | + 4 ( 'Runner-up City' ), |
| 64 | + 5 ( 'Midtable Town' ), |
| 65 | + 6 ( 'Underdogs United' ), |
| 66 | + 7 ( 'Upstart FC' ), |
| 67 | + 8 ( 'Relegated Athletic' ) |
| 68 | + 9 ) t ( team_name ) |
| 69 | + 10 ), match_value as ( |
| 70 | + 11 select 'Champions City' match_team |
| 71 | + 12 ) |
| 72 | + 13 select team_name, match_team, |
| 73 | + 14 fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein, |
| 74 | + 15 fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler, |
| 75 | + 16 fuzzy_match ( bigram, team_name, match_team ) as bigram, |
| 76 | + 17 fuzzy_match ( trigram, team_name, match_team ) as trigram, |
| 77 | + 18 fuzzy_match ( whole_word_match, team_name, match_team ) as wwm, |
| 78 | + 19 fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs |
| 79 | + 20 from teams |
| 80 | + 21 cross join match_value; |
| 81 | +
|
| 82 | +TEAM_NAME MATCH_TEAM LEVENSHTEIN JARO_WINKLER BIGRAM TRIGRAM WWM LCS |
| 83 | +------------------ -------------- ----------- ------------ ---------- ---------- ---------- ---------- |
| 84 | +Champions United Champions City 75 92 66 57 50 62 |
| 85 | +Runner-up City Champions City 36 57 30 25 50 35 |
| 86 | +Midtable Town Champions City 8 44 0 0 0 7 |
| 87 | +Underdogs United Champions City 32 49 13 0 0 12 |
| 88 | +Upstart FC Champions City 8 56 0 0 0 7 |
| 89 | +Relegated Athletic Champions City 12 41 0 0 0 5 |
| 90 | +
|
| 91 | +6 rows selected. |
| 92 | +
|
| 93 | +SQL> |
| 94 | +SQL> /* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */ |
| 95 | +SQL> with teams as ( |
| 96 | + 2 select * from ( |
| 97 | + 3 values ( 'Champions United' ), |
| 98 | + 4 ( 'Runner-up City' ), |
| 99 | + 5 ( 'Midtable Town' ), |
| 100 | + 6 ( 'Underdogs United' ), |
| 101 | + 7 ( 'Upstart FC' ), |
| 102 | + 8 ( 'Relegated Athletic' ) |
| 103 | + 9 ) t ( team_name ) |
| 104 | + 10 ), match_value as ( |
| 105 | + 11 select 'Champions City' match_team |
| 106 | + 12 ) |
| 107 | + 13 select team_name, match_team |
| 108 | + 14 from teams |
| 109 | + 15 join match_value |
| 110 | + 16 on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90; |
| 111 | +
|
| 112 | +TEAM_NAME MATCH_TEAM |
| 113 | +------------------ -------------- |
| 114 | +Champions United Champions City |
| 115 | +---- |
| 116 | + |
| 117 | +== Benefits |
| 118 | + |
| 119 | +This operator makes it easier to find similar strings with SQL. |
| 120 | + |
| 121 | +== Further information |
| 122 | + |
| 123 | +* Availability: All Offerings |
| 124 | +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/data-quality-operators.html#GUID-C13A179C-1F82-4522-98AA-E21C6504755E[FUZZY_MATCH Documentation] |
0 commit comments