Help searching a string within a set number of words apart

  • Hi,

    I'd be very grateful if someone could help me with this, I do hope someone can 🙂 I'll try and provide as much info as possible so to avoid confusion as to what my question is.

    Client requirement: Client has a table that holds articles in one column, think of them as digital newspaper articles. They have a search webpage to find articles that match the user's keywords. Along with this search functionality the user can specify the proximity that the keywords must be from each other to qualify. Basically how many words (not characters) one word must be from the other to return true.

    Search Example: If the user specifies 5 words apart and enters the search term as 'search word', then the query should return all rows where an article contains the words 'search' and 'word' and they are no more than 5 words apart.

    Result example

    True because only 2 words apart from each other: 'This is a search that has word in it'

    False because 7 words apart from each other: 'The search will not come out true because the word is more than 5 words apart.'

    Added complexity 1: This seems reasonable enough however there is the added complexity that you could have more than two search keywords, in which case they must all be within the specified word proximity.

    Added complexity 2: The whole article must be searched not just the first occurance of a keyword.

    i.e. if we use the example:

    Search keyword: 'search word' within 5 words...

    Article: 'The search will not come out true because the word is more than 5 words apart. But this is a search that has word in it.'

    The above is true because the second sentence contains the keywords within 5 words proximity even if the first sentence did not.

    I know that Full Text Search has the ability to use the operator NEAR however in 2008 you can not set a proximity limit that the words must be from each other. I know that 2012 does but because I am running on 2008 I need to find a way to programatically do this.

    Please oh please can someone help me. Right now I am stuck and do not know how to do this.

    Many thanks in advance, 🙂

    Lewis

  • I think I would look to write a full-text query to get results that might match (i.e. the text has all the words specified, perhaps using NEAR, perhaps not) and then pass that through a function (probably a streaming CLR one) to further filter the results to those that have all the words within x words of each other. Something like that.

  • Hi,

    Thanks Paul.

    With out sounding like an SOB that's the problem I am having, finding all those that have words within a set distance from each other. The pre-filter is easily done, it's that second stage I can not get my head around.

    Lewis

  • The only way i can think of to do this, is to use the filtered list as suggested then in your CLR or Application you would need to loop through each string and count the number of spaces to determine the number of words.

  • Regular expressions! They are perfect for things like this. You can't use them directly in SQL of course, but they work fine in the application or CLR. For example: http://www.regular-expressions.info/near.html

  • lewisdow123 (11/8/2011)


    With out sounding like an SOB that's the problem I am having, finding all those that have words within a set distance from each other. The pre-filter is easily done, it's that second stage I can not get my head around.

    Hi Lewis,

    Well the first part of the process is relatively easy:

    DECLARE @strings TABLE

    (

    id INTEGER IDENTITY PRIMARY KEY,

    string VARCHAR(4000) NOT NULL

    )

    INSERT @strings (string)

    VALUES

    ('This is a search that has word in it'),

    ('The search will not come out true because the word is more than 5 words apart.')

    DECLARE @terms TABLE

    (

    word VARCHAR(50) NOT NULL

    )

    INSERT @terms (word)

    VALUES ('search'), ('word'), ('is')

    DECLARE @words TABLE

    (

    string_id INTEGER NOT NULL,

    position INTEGER NOT NULL,

    word VARCHAR(50) NOT NULL,

    PRIMARY KEY (string_id, position)

    )

    -- Split input strings into words

    INSERT @words (string_id, position, word)

    SELECT

    s2.id,

    ROW_NUMBER() OVER (PARTITION BY s2.id ORDER BY s.number),

    f2.word

    FROM @strings AS s2

    JOIN master.dbo.spt_values AS s ON s.number BETWEEN 1 AND DATALENGTH(s2.string)

    CROSS APPLY (SELECT SPACE(1) + s2.string + SPACE(1)) AS f (wrapped)

    CROSS APPLY (SELECT SUBSTRING(f.wrapped, s.number + 1, CHARINDEX(SPACE(1), f.wrapped, s.number + 1) - s.number)) AS f2 (word)

    WHERE

    s.[type] = N'P'

    AND SUBSTRING(f.wrapped, s.number, 1) = SPACE(1)

    ORDER BY

    s.number

    -- Remove words we're not interested in

    DELETE @words

    WHERE

    NOT EXISTS

    (SELECT 1 FROM @terms AS t WHERE t.word = [@words].word)

    -- Results

    SELECT

    *

    FROM @words AS w

    Working out a robust and efficient algorithm to check whether the 'all words within x' condition is met, where more than one instance of each word occurs, is less trivial. Perhaps start with a brute-force iterative method (per string, construct all permutations, select those that match the conditions).

  • Thanks for your input folks...

    I'm leading down the regex path first using the link provided and http://www.sqlteam.com/article/regular-expressions-in-t-sql

    if this fails then i'll start with Paul's suggestion.

    Again, thank you guys 🙂

  • lewisdow123 (11/8/2011)


    I'm leading down the regex path first using the link provided and http://www.sqlteam.com/article/regular-expressions-in-t-sql%5B/quote%5D

    Yes that's the CLR route I would try too. The T-SQL code I posted was more to illustrate a concept, as I'm sure you guessed anyway...:-)

  • The complication is in allowing more than 2 words.

    The following checks for 2 words that are 5 or less words apart.

    using System;

    using Microsoft.SqlServer.Server;

    using System.Data.SqlTypes;

    using System.Text.RegularExpressions;

    namespace searchFeatures

    {

    public class UserDefinedFunctions

    {

    [SqlFunction]

    public static SqlString SearchFeatures(SqlString txtIn, SqlString word1, SqlString word2)

    {

    try

    {

    var regex = new Regex(@"\b" + word1.Value + @"\W+(?:\w+\W+){1,5}?" + word2.Value + @"\b", RegexOptions.Compiled);

    return regex.IsMatch(txtIn.Value) ? txtIn.Value : SqlString.Null;

    }

    catch (Exception)

    {

    return SqlString.Null;

    }

    }

    }

    }

    IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[SearchFeatures]') AND type in (N'FN', N'IF', N'TF', N'FS', N'FT'))

    DROP FUNCTION [dbo].[SearchFeatures]

    GO

    IF EXISTS (SELECT * FROM sys.assemblies asms WHERE asms.name = N'searchFeatures' and is_user_defined = 1)

    DROP ASSEMBLY [searchFeatures]

    GO

    CREATE ASSEMBLY [searchFeatures]

    AUTHORIZATION [dbo]

    FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C0103007D3CB94E0000000000000000E00002210B010800000A00000006000000000000AE280000002000000040000000004000002000000002000004000000000000000400000000000000008000000002000000000000030040850000100000100000000010000010000000000000100000000000000000000000542800005700000000400000B003000000000000000000000000000000000000006000000C000000AC2700001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E74657874000000B408000000200000000A000000020000000000000000000000000000200000602E72737263000000B00300000040000000040000000C0000000000000000000000000000400000402E72656C6F6300000C000000006000000002000000100000000000000000000000000000400000420000000000000000000000000000000090280000000000004800000002000500E8200000C406000001000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001B300300740000000100001100001B8D120000010C08167201000070A208170F01280F00000AA208187207000070A208190F02280F00000AA2081A7201000070A208281000000A1E731100000A0A060F00280F00000A6F1200000A2D077E1300000A2B0C0F00280F00000A281400000A0BDE0A26007E1300000A0BDE0000072A01100000000001006667000A150000011E02281500000A2A42534A4201000100000000000C00000076322E302E35303732370000000005006C00000030020000237E00009C0200001003000023537472696E677300000000AC0500003000000023555300DC050000100000002347554944000000EC050000D800000023426C6F620000000000000002000001471502000900000000FA2533001600000100000015000000020000000200000003000000150000000C00000001000000010000000300000000000A00010000000000060051004A000A00790064000600BC00AA000600D300AA000600F000AA0006000F01AA0006002801AA0006004101AA0006005C01AA0006007701AA000600AF0190010600C301AA000600EF01DC013700030200000600320212020600520212020A008B0270020600A0024A000E00D702B8020E00DD02B802060003034A000000000001000000000001000100010010001D003200050001000100502000000000960083000A000100E020000000008618920015000400000001009800000002009E0000000300A400190092001900210092001900290092001900310092001900390092001900410092001900490092001900510092001900590092001E006100920019006900920023007900920029008100920015008900920015001100A70233009100B1023700990092003D009900EA0244001100F20249001100F7024D00090092001500200073002E002E002B005C002E00130070002E001B0070002E00230076002E000B005C002E00330085002E003B0070002E004B0070002E005B00A6002E006300AF002E006B00B80053000480000001000000E910BE65000000000000320000000200000000000000000000000100410000000000020000000000000000000000010058000000000002000000000000000000000001004A000000000000000000003C4D6F64756C653E0073656172636846656174757265732E646C6C0055736572446566696E656446756E6374696F6E73007365617263684665617475726573006D73636F726C69620053797374656D004F626A6563740053797374656D2E446174610053797374656D2E446174612E53716C54797065730053716C537472696E67005365617263684665617475726573002E63746F7200747874496E00776F72643100776F7264320053797374656D2E5265666C656374696F6E00417373656D626C795469746C6541747472696275746500417373656D626C794465736372697074696F6E41747472696275746500417373656D626C79436F6E66696775726174696F6E41747472696275746500417373656D626C79436F6D70616E7941747472696275746500417373656D626C7950726F6475637441747472696275746500417373656D626C79436F7079726967687441747472696275746500417373656D626C7954726164656D61726B41747472696275746500417373656D626C7943756C747572654174747269627574650053797374656D2E52756E74696D652E496E7465726F70536572766963657300436F6D56697369626C6541747472696275746500417373656D626C7956657273696F6E4174747269627574650053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C697479417474726962757465004D6963726F736F66742E53716C5365727665722E5365727665720053716C46756E6374696F6E41747472696275746500537472696E67006765745F56616C756500436F6E6361740053797374656D2E546578742E526567756C617245787072657373696F6E730052656765780052656765784F7074696F6E730049734D61746368004E756C6C006F705F496D706C6963697400457863657074696F6E0000000000055C00620000275C0057002B0028003F003A005C0077002B005C0057002B0029007B0031002C0035007D003F0000001C5F35F1CC3FF64A8502B0F803DD02530008B77A5C561934E0890A0003110911091109110903200001042001010E0420010102052001011139042001010804010000000320000E0500010E1D0E062002010E1151042001020E0306110905000111090E080703124D11091D0E1301000E736561726368466561747572657300000501000000000E0100094D6963726F736F667400002001001B436F7079726967687420C2A9204D6963726F736F6674203230313100000801000701000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F77730100000000007D3CB94E000000000200000089000000C8270000C8090000525344536E7FEC9C92BFF84FA715B1A90BFB149106000000633A5C75736572735C6372616967775C646F63756D656E74735C76697375616C2073747564696F20323031305C50726F6A656374735C73656172636846656174757265735C73656172636846656174757265735C6F626A5C44656275675C73656172636846656174757265732E706462000000007C28000000000000000000009E280000002000000000000000000000000000000000000000000000902800000000000000000000000000000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF2500204000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000100100000001800008000000000000000000000000000000100010000003000008000000000000000000000000000000100000000004800000058400000580300000000000000000000580334000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE0000010000000100BE65E91000000100BE65E9103F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004B8020000010053007400720069006E006700460069006C00650049006E0066006F00000094020000010030003000300030003000340062003000000034000A00010043006F006D00700061006E0079004E0061006D006500000000004D006900630072006F0073006F0066007400000048000F000100460069006C0065004400650073006300720069007000740069006F006E0000000000730065006100720063006800460065006100740075007200650073000000000040000F000100460069006C006500560065007200730069006F006E000000000031002E0030002E0034003300320039002E00320036003000340036000000000048001300010049006E007400650072006E0061006C004E0061006D0065000000730065006100720063006800460065006100740075007200650073002E0064006C006C00000000005C001B0001004C006500670061006C0043006F007000790072006900670068007400000043006F0070007900720069006700680074002000A90020004D006900630072006F0073006F006600740020003200300031003100000000005000130001004F0072006900670069006E0061006C00460069006C0065006E0061006D0065000000730065006100720063006800460065006100740075007200650073002E0064006C006C000000000040000F000100500072006F0064007500630074004E0061006D00650000000000730065006100720063006800460065006100740075007200650073000000000044000F000100500072006F006400750063007400560065007200730069006F006E00000031002E0030002E0034003300320039002E00320036003000340036000000000048000F00010041007300730065006D0062006C0079002000560065007200730069006F006E00000031002E0030002E0034003300320039002E0032003600300034003600000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000002000000C000000B03800000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000

    WITH PERMISSION_SET = SAFE

    GO

    CREATE FUNCTION [dbo].[SearchFeatures](@txtIn [nvarchar](4000), @word1 [nvarchar](4000), @word2 [nvarchar](4000))

    RETURNS [nvarchar](4000) WITH EXECUTE AS CALLER

    AS

    EXTERNAL NAME [searchFeatures].[searchFeatures.UserDefinedFunctions].[SearchFeatures]

    GO

    DECLARE @strings TABLE (

    id INTEGER IDENTITY PRIMARY KEY

    ,string VARCHAR(4000) NOT NULL

    )

    INSERT @strings (string)

    VALUES ('This is a search that has word in it')

    ,('The search will not come out true because the word is more than 5 words apart.')

    SELECT id, string

    FROM @strings

    WHERE dbo.SearchFeatures(string,'search','word') IS NOT NULL


    Forever trying to learn
    My blog - http://www.cadavre.co.uk/
    For better, quicker answers on T-SQL questions, click on the following...http://www.sqlservercentral.com/articles/Best+Practices/61537/
    For better, quicker answers on SQL Server performance related questions, click on the following...http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

  • Wow very nice!!!!

    Top answer by far. I've done the same thing but without the .Net instead I used the first function in this link....

    http://www.sqlteam.com/article/regular-expressions-in-t-sql

    Thanks to all who have helped me out, you're all very kind

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply