Skip site navigation (1) Skip section navigation (2)

Re: join and sort on 'best match'

From: Ragnar <gnari(at)hive(dot)is>
To: Dirk Griffioen <dirk(at)code-shop(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: join and sort on 'best match'
Date: 2006-12-13 10:29:47
Message-ID: 1166005787.6369.79.camel@localhost.localdomain (view raw or flat)
Thread:
Lists: pgsql-sql
On miĆ°, 2006-12-13 at 10:26 +0100, Dirk Griffioen wrote:

> I have been breaking my head on the following problem: how to join 2
> tables and sort the results on the best match.
  ^^^^^^^^^^^^^
> - there are 3 tables, items, tags and items_tags. The items_tags table
> links items to tags.
> - I have one item which has certain tags, and I want to look up all
> the other items that have those tags as well

looks to me like you want to join:
items->item_tags->tags->item_tags->items

so the basic select is:
SELECT *
  FROM      items AS i1
       JOIN items_tags AS it1 ON (it1.item_id = i1.id)
       JOIN tags AS t ON (t.tag_id = it1.tag_id)
       JOIN items_tags AS it2 ON (it2.tag_id = t.tag_id)
       JOIN items AS i2 ON (i2.id = it2.item_id)
  WHERE i1.id=?

> - results should be sorted and presented by 'best match': first all
> the items that have 3 tags in common, then 2 and last 1

this would be: 

SELECT i1.id,i2.id,COUNT(*) as quantity
  FROM      items AS i1
       JOIN items_tags AS it1 ON (it1.item_id = i1.id)
       JOIN tags AS t ON (t.tag_id = it1.tag_id)
       JOIN items_tags AS it2 ON (it2.tag_id = t.tag_id)
       JOIN items AS i2 ON (i2.id = it2.item_id)
  WHERE i1.id=?
  GROUP by i1.id,i2.id
  ORDER BY quantity DESC

> I thought I had found the solution (my test cases worked), but I now
> find cases that should be found by the query but are not.

if this does not work, please provide us with a counter example.

gnari



In response to

Responses

pgsql-sql by date

Next:From: William Scott JordanDate: 2006-12-14 02:04:47
Subject: Rule for multiple entries
Previous:From: Dirk GriffioenDate: 2006-12-13 09:26:41
Subject: join and sort on 'best match'

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group