Portál AbcLinuxu, 10. května 2025 17:03
select K.autor,count(*) from komentar K, reseni RS, relace R, spolecne S where RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and (S.pridal<>RS.kdo or S.pridal is null) and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor
| autor | count(*) | +-------+----------+ | 1 | 1 | | 11 | 1 | | 20 | 2 | | 151 | 4 | | 595 | 2 |
select K.autor,count(*) from komentar K, reseni RS, relace R, spolecne S where RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and S.pridal=RS.kdo and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor
| autor | count(*) | +-------+----------+ | 1 | 3 | | 151 | 2 | | 421 | 1 | | 595 | 2 | | 868 | 1 |Chtel bych dostat takovyto vysledek:
| autor | count(*) | count(*) | +-------+----------+----------+ | 1 | 3 | 1 | | 151 | 2 | 4 | | 421 | 1 | 0 | | 595 | 2 | 2 | | 868 | 1 | 3 |Diky
Řešení dotazu:
select K.autor, sum(decode(S.pridal, null, 1, RS.kdo, 0, 1)) cnt1, sum(decode(S.pridal, null, 0, RS.kdo, 1, 0)) cnt2 from komentar K, reseni RS, relace R, spolecne S where RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor
select t1.autor, t1.c1, t2.c2
FROM
(select K.autor,count(*) as c1 from komentar K, reseni RS, relace R, spolecne S where
RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and
(S.pridal<>RS.kdo or S.pridal is null) and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor) t1
JOIN
(select K.autor,count(*) as c2 from komentar K, reseni RS, relace R, spolecne S where
RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and
S.pridal=RS.kdo and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor) t2
ON t2.autor = t1.autor
select K.autor, sum( CASE WHEN S.pridal=RS.kdo and K.cislo=RS.komentar THEN 1 ELSE 0 END ) cnt1, sum( CASE WHEN S.pridal<>RS.kdo or S.pridal is null THEN 1 ELSE 0 END ) cnt2 from komentar K, reseni RS, relace R, spolecne S where RS.zaznam=R.potomek and R.typ_potomka='Z' and R.predek=S.cislo and S.typ='P' and K.cislo=RS.komentar and RS.kdo<>K.autor group by K.autor
SELECT K.autor, SUM( CASE WHEN S.pridal = RS.kdo AND K.cislo = RS.komentar THEN 1 ELSE 0 END ) cnt1, SUM( CASE WHEN S.pridal <> RS.kdo OR S.pridal IS NULL THEN 1 ELSE 0 END ) cnt2 FROM komentar K JOIN reseni RS ON RS.komentar = K.cislo JOIN relace R ON R.potomek = RS.zaznam AND R.typ_potomka='Z' JOIN spolecne S ON s.cislo = r.predek AND S.typ='P' WHERE RS.kdo <> K.autor GROUP BY K.autor
Tiskni
Sdílej:
ISSN 1214-1267, (c) 1999-2007 Stickfish s.r.o.