On 12/29/06, Jess Robinson <[EMAIL PROTECTED]> wrote:


On Tue, 26 Dec 2006, Matt LeBlanc wrote:

> On 12/26/06, Jess Robinson <[EMAIL PROTECTED]> wrote:
>>  $schema->resultset('boards')->search({
>>     'hiddenboards.userId' => 3,
>>     'me.active' => 1,
>>  }, {
>>     'join' => 'hiddenboards',
>>     '+select' => [ 'hiddenboards.userId' ],
>>     '+as' => [ 'hidden' ],
>>     'order_by' => [ 'pos' ],
>>  })
>>
>>
>>  .. and set up the relationship between board and hiddenboards to use an
>>  inner join, not a left join.
>>
>>  I've not seen the syntax "SELECT .. hiddenboards.userId IS NOT NULL as
>>  hidden" .. it's odd, why not use the proper join type?
>>
>>  Jess
>
> ... this isn't the same thing. He does not want all of the hidden
> boards, as your change to an inner join would return. He wants all
> boards with an extra field that tells him whether or not the board is
> hidden (if the left join doesn't work, hiddenboards.boardId is null
> and as such hidden is false).
>

Oh! That makes a lot more sense.. OTOH the JOIN .. ON ..
hiddenboards.userId = 3 surely negates that effect?

Jess


Sorry, I just realized I used the wrong field. Of course, this doesn't
matter as if the join condition fails, anything from hiddenboards is
null. Here is a full example of how this would work:

CREATE TABLE boards (
        id int,
        active int,
        pos int
        
);

INSERT INTO boards VALUES(1,1,1);
INSERT INTO boards VALUES(2,1,2);
INSERT INTO boards VALUES(3,1,3);

CREATE TABLE hiddenboards (
        userid int,
        boardId int     
);

INSERT INTO hiddenboards VALUES(1,1); -- not userid 3, so no join
INSERT INTO hiddenboards VALUES(3,2); -- userid 3, so valid join
-- no entry for id 3 so no join

SELECT boards.id,CASE WHEN hiddenboards.userid is not null THEN 1 ELSE
0 END AS hidden
FROM boards LEFT JOIN hiddenboards
ON hiddenboards.userid = 3
AND hiddenboards.boardid = boards.id
WHERE boards.active = 1
ORDER BY pos;

In this particular case, the rows returned are as follows:

id,hidden
1,0
2,1
3,0

_______________________________________________
List: http://lists.rawmode.org/cgi-bin/mailman/listinfo/dbix-class
Wiki: http://dbix-class.shadowcatsystems.co.uk/
IRC: irc.perl.org#dbix-class
SVN: http://dev.catalyst.perl.org/repos/bast/trunk/DBIx-Class/
Searchable Archive: http://www.mail-archive.com/[email protected]/

Reply via email to