For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!
try -
select person, id_state from project where id_state in (2, 3, 4) order by 1, 2;
Amiel oppes -misedd the part that syas all state...
Message was edited by: Amiel D.
select person from project where id_state in (2, 3, 4) group by person having count(*) = 3
SQL> with t as (select 'Carl' PERSON, 3 ID_STATE from dual union all 2 select 'Carl' PERSON, 4 ID_STATE from dual union all 3 select 'Joe' PERSON, 3 ID_STATE from dual union all 4 select 'Mark' PERSON, 2 ID_STATE from dual union all 5 select 'Mark' PERSON, 3 ID_STATE from dual union all 6 select 'Mark' PERSON, 4 ID_STATE from dual union all 7 select 'Paul' PERSON, 1 ID_STATE from dual union all 8 select 'Paul' PERSON, 2 ID_STATE from dual union all 9 select 'Sam' PERSON, 2 ID_STATE from dual union all 10 select 'Sam' PERSON, 3 ID_STATE from dual) 11 -- 12 select person from t 13 where id_state in (2,3,4) 14 group by person 15 having count(distinct id_state)=3 16 / PERSON ------ Mark SQL>
with t as (select 'Carl' as PERSON,3 as ID_STATE from dual union all select 'Carl',4 from dual union all select 'Joe' ,3 from dual union all select 'Mark',2 from dual union all select 'Mark',3 from dual union all select 'Mark',4 from dual union all select 'Paul',1 from dual union all select 'Paul',2 from dual union all select 'Sam' ,2 from dual union all select 'Sam' ,3 from dual union all select 'Wendy' ,2 from dual union all select 'Wendy' ,2 from dual union all select 'Wendy' ,3 from dual union all select 'Wendy' ,3 from dual union all select 'Wendy' ,4 from dual union all select 'John' ,1 from dual union all select 'John' ,2 from dual union all select 'John' ,2 from dual union all select 'John' ,3 from dual union all select 'Tom' ,1 from dual union all select 'Tom' ,2 from dual union all select 'Tom' ,3 from dual union all select 'Tom' ,4 from dual) select person from t group by person having max(case when ID_STATE = 2 then 1 else 0 end) * max(case when ID_STATE = 3 then 1 else 0 end) * max(case when ID_STATE = 4 then 1 else 0 end) * min(case when ID_STATE in(2,3,4) then 1 else 0 end) = 1;
PERSON ------ Mark Wendy
I have used this Logic. http://en.wikipedia.org/wiki/First-order_logic
"max(case when P(X) then 1 else 0 end) = 1" is for some X:P(X) "min(case when P(X) then 1 else 0 end) = 1" is for all X:P(X) "max(case when P(X) then 0 else 1 end) = 1" is for some X:not(P(X)) "min(case when P(X) then 0 else 1 end) = 1" is for all X:not(P(X))
therefore, in having clause I have used Boolean arithmetic (http://www.allaboutcircuits.com/vol_4/chpt_7/2.html) which "a And b And c And D" is "a * b * c * d = 1"
similar threads 551061 550921 526715
select person from project group by person having max(case when ID_STATE = 2 then 1 else 0 end) * max(case when ID_STATE = 3 then 1 else 0 end) * max(case when ID_STATE = 4 then 1 else 0 end) = 1
select person from project group by person having max(case when ID_STATE = 2 then 1 else 0 end) = 1 and max(case when ID_STATE = 3 then 1 else 0 end) = 1 and max(case when ID_STATE = 4 then 1 else 0 end) = 1
Hi, lets suppose we have data as
SQL> select * from PROJECT6030 order by 2; ID_PROJECT PERSON ID_STATE LAST_UPDA ---------- ---------- ---------- --------- 6 Carl 4 22-JAN-05 5 Carl 3 08-DEC-04 1 Joe 3 08-AUG-07 2 Mark 2 05-JUL-07 4 Mark 4 14-MAR-07 3 Mark 3 27-JUN-07 8 Mark 3 10-MAY-07 8 Paul 1 30-JUL-07 9 Paul 2 02-JUN-06 7 Sam 3 11-JUL-06 7 Sam 2 15-JUN-06 11 rows selected.
In this case our quiery should select Mark as Mark has all three Id states.
Now consider the quiery.
SQL> ed Wrote file afiedt.buf 1 select person from project6030 2 where id_state in (2, 3, 4) 3 group by person 4* having count(*) = 3 5 / no rows selected
when you group by count(*) we see that no person is having 3 rows of data.
now lets see another quiery which Volder had posted in the begining.
SQL> ed Wrote file afiedt.buf 1 select person from project6030 2 where id_state in (2, 3, 4) 3 group by person 4* having count(distinct id_state) = 3 SQL> / PERSON ---------- Mark
Thank you all for your responses!!
...so using COLLECT and SUBMULTISET as in Maxim Demenko's post on c.d.o.m, we get this:
WITH project AS ( select 'Carl' person, 3 id_state from dual union all select 'Carl', 4 from dual union all select 'Joe', 3 from dual union all select 'Mark', 2 from dual union all select 'Mark', 3 from dual union all select 'Mark', 4 from dual union all select 'Paul', 1 from dual union all select 'Paul', 2 from dual union all select 'Sam', 2 from dual union all select 'Sam', 3 from dual ) -- SELECT person FROM project GROUP BY person HAVING integer_tt(2,3,4) SUBMULTISET OF CAST(COLLECT(id_state) AS integer_tt) ;
"INTEGER_TT" is my nested table collection type, defined as
CREATE TYPE integer_tt AS TABLE OF INTEGER
select distinct Name from ApplicantSkills i where (select Language from JobRequirements ii where ii.Name = i.Name) IN (select Language from ApplicantSkills)
select distinct Name from ApplicantSkills i where not exists ( select Language from ApplicantSkills minus select Language from JobRequirements ii where ii.Name = i.Name )
So in our people/states example with an explicitly specified set of states, that becomes:
WITH projects AS ( select 'Carl' person, 3 id_state from dual union all select 'Carl', 4 from dual union all select 'Joe', 3 from dual union all select 'Mark', 2 from dual union all select 'Mark', 3 from dual union all select 'Mark', 4 from dual union all select 'Paul', 1 from dual union all select 'Paul', 2 from dual union all select 'Sam', 2 from dual union all select 'Sam', 3 from dual ) , people AS ( SELECT DISTINCT person FROM projects ) -- SELECT person FROM people p WHERE NOT EXISTS ( SELECT column_value FROM TABLE(INTEGER_TT(2,3,4)) MINUS SELECT id_state FROM projects WHERE person = p.person );
Nice.
satyaki> satyaki>CREATE TYPE integer_tt AS TABLE OF INTEGER; 2 / Type created. satyaki> satyaki> satyaki>WITH project AS 2 ( select 'Carl' person, 3 id_state from dual union all 3 select 'Carl', 4 from dual union all 4 select 'Joe', 3 from dual union all 5 select 'Mark', 2 from dual union all 6 select 'Mark', 3 from dual union all 7 select 'Mark', 4 from dual union all 8 select 'Paul', 1 from dual union all 9 select 'Paul', 2 from dual union all 10 select 'Sam', 2 from dual union all 11 select 'Sam', 3 from dual ) 12 SELECT person 13 FROM project 14 GROUP BY person 15 HAVING integer_tt(2,3,4) SUBMULTISET OF CAST(COLLECT(id_state) AS integer_tt) ; HAVING integer_tt(2,3,4) SUBMULTISET OF CAST(COLLECT(id_state) AS integer_tt) * ERROR at line 15: ORA-00920: invalid relational operator satyaki>