getting distinct result set from unioned fulltext search

  • I am using fulltext search to get a search result but if I use containstable only, the result must have all the search terms. If I use freetexttable only, the result does not include predicts. So I am unioning the two results together and then ordering them by rank. My problem is that the union will not eliminate the duplicates because the rank value for each search is different.

    Here is psuedo code of what I am currently doing.

    @contains_srch_param = N'"Rand*" AND "Doe*"',

    @freetext_srch_param = N'Rand Doe'

    Select entityId,

    name,

    title,

    address,

    rank

    From (

    Select

    Top(50)

    e.entityId

    e.name,

    e.title,

    e.address,

    keyTable.Rank

    From

    entity e

    inner join ContainsTable(srch_param, param_val, @contains_srch_param) as keyTable on e.entityId = keyTable.key

    Order by keyTable.Rank desc

    Union

    Select

    Top(50)

    e.entityId

    e.name,

    e.title,

    e.address,

    keyTable.Rank

    From

    entity e

    inner join FreeTextTable(srch_param, param_val, @freetext_srch_param) as keyTable on e.entityId = keyTable.key

    Order by keyTable.Rank desc

    ) result

    Order by rank desc, name;

    Results in

    1 Randy Doe, director, 123 main st, 262

    2 Jane Doe, employee, 321 other st, 260

    1 Randy Doe, director, 123 main st, 160

    The first and third result are actually the same person, so I need to remove the one with the lower rank. How can I do this or can someone offer a better option of searching.

  • Pseudocode of my guess!

    Select e.entityId,

    a.name,

    a.title,

    a.address,

    e.rank

    From (

    Select entityId, max(Rank) Rank

    from (

    Select

    Top(50)

    e.entityId

    keyTable.Rank

    From

    entity e

    inner join ContainsTable(srch_param, param_val, @contains_srch_param) as keyTable on e.entityId = keyTable.key

    -- Order by keyTable.Rank desc (probably not needed)

    Union

    Select

    Top(50)

    e.entityId

    keyTable.Rank

    From

    entity e

    inner join FreeTextTable(srch_param, param_val, @freetext_srch_param) as keyTable on e.entityId = keyTable.key

    -- Order by keyTable.Rank desc (probably not needed)

    ) ranking_subquery

    Group by entityId

    ) e

    join

    entity a

    on

    e.entityId = a.entityId

    Order by rank desc, name;

    edit: Forgot a "group by"

Viewing 2 posts - 1 through 1 (of 1 total)

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