Portál AbcLinuxu, 17. prosince 2025 09:55
tabulka "data"
ID---Otazka1---Otazka2---Otazka3
1-------A---------A---------E
2-------E---------A---------D
3-------B---------B---------E
tabulka "výstup"
Otazka----A---B---C---D---E
otazka1---1---1---0---0---1
otazka2---2---1---0---0---0
otazka3---0---0---0---1---2
P.S. možná by jen stačilo mě nakopnout, které klíčové pojmy mám googlit.
SELECT shop,
SUM(CASE gender WHEN 'f' THEN salary ELSE 0 END) AS f,
SUM(CASE gender WHEN 'm' THEN salary ELSE 0 END) AS m,
SUM(salary) AS total
FROM employees
INNER JOIN
shops
USING (shop_id)
GROUP BY shop
Je to starej trik, ktery jsem videl uz pro MSSQL6.5.
.
Příkaz jsem nezkoušel, takže je možné, že tam je nějaká syntaktická chyba, nebo že dělá něco úplně jiného
select 'Otazka 1' Otazka,
sum(to_number(decode(OTAZKA1,'A', '1', '0'))) A,
sum(to_number(decode(OTAZKA1,'B', '1', '0'))) B,
sum(to_number(decode(OTAZKA1,'C', '1', '0'))) C,
sum(to_number(decode(OTAZKA1,'D', '1', '0'))) D,
sum(to_number(decode(OTAZKA1,'E', '1', '0'))) E,
from data
group by 'Otazka 1'
union
select 'Otazka 2' Otazka,
sum(to_number(decode(OTAZKA2,'A', '1', '0'))) A,
sum(to_number(decode(OTAZKA2,'B', '1', '0'))) B,
sum(to_number(decode(OTAZKA3,'C', '1', '0'))) C,
sum(to_number(decode(OTAZKA4,'D', '1', '0'))) D,
sum(to_number(decode(OTAZKA5,'E', '1', '0'))) E,
from data
group by 'Otazka 2'
union
....
union
select 'Otazka 15' Otazka,
sum(to_number(decode(OTAZKA15,'A', '1', '0'))) A,
sum(to_number(decode(OTAZKA15,'B', '1', '0'))) B,
sum(to_number(decode(OTAZKA15,'C', '1', '0'))) C,
sum(to_number(decode(OTAZKA15,'D', '1', '0'))) D,
sum(to_number(decode(OTAZKA15,'E', '1', '0'))) E,
from data
group by 'Otazka 15';
SELECT COUNT(otazka1) FROM data GROUP BY otazka1 atp.
Jen pozor, mám dojem, že odpověď serveru bude "víceřádková", ale to Ti buď nevadí nebo to snadno zjistíš.
DROP TABLE data;
CREATE TABLE data (id INTEGER PRIMARY KEY, otazka1 VARCHAR(1), otazka2 VARCHAR(1), otazka3 VARCHAR(1));
INSERT INTO data VALUES (NULL, 'A', 'B', 'C');
INSERT INTO data VALUES (NULL, 'D', 'E', 'A');
INSERT INTO data VALUES (NULL, 'B', 'C', 'D');
INSERT INTO data VALUES (NULL, 'A', 'A', 'B');
INSERT INTO data VALUES (NULL, 'B', 'C', 'D');
INSERT INTO data VALUES (NULL, 'E', 'A', 'B');
INSERT INTO data VALUES (NULL, 'C', 'D', 'E');
INSERT INTO data VALUES (NULL, 'A', 'B', 'B');
INSERT INTO data VALUES (NULL, 'C', 'C', 'D');
INSERT INTO data VALUES (NULL, 'D', 'E', 'E');
DROP TABLE vystup;
CREATE TABLE vystup (otazka TEXT, a INTEGER, b INTEGER, c INTEGER, d INTEGER, e INTEGER);
INSERT INTO vystup VALUES ('otazka1',
(SELECT COUNT(*) FROM data WHERE otazka1='A'),
(SELECT COUNT(*) FROM data WHERE otazka1='B'),
(SELECT COUNT(*) FROM data WHERE otazka1='C'),
(SELECT COUNT(*) FROM data WHERE otazka1='D'),
(SELECT COUNT(*) FROM data WHERE otazka1='E'));
INSERT INTO vystup VALUES ('otazka2',
(SELECT COUNT(*) FROM data WHERE otazka2='A'),
(SELECT COUNT(*) FROM data WHERE otazka2='B'),
(SELECT COUNT(*) FROM data WHERE otazka2='C'),
(SELECT COUNT(*) FROM data WHERE otazka2='D'),
(SELECT COUNT(*) FROM data WHERE otazka2='E'));
INSERT INTO vystup VALUES ('otazka3',
(SELECT COUNT(*) FROM data WHERE otazka3='A'),
(SELECT COUNT(*) FROM data WHERE otazka3='B'),
(SELECT COUNT(*) FROM data WHERE otazka3='C'),
(SELECT COUNT(*) FROM data WHERE otazka3='D'),
(SELECT COUNT(*) FROM data WHERE otazka3='E'));
SELECT 1 AS Otazka, COUNT(CASE WHEN otazka1 = 'A' THEN TRUE END) AS A, COUNT(CASE WHEN otazka1 = 'B' THEN TRUE END) AS B, COUNT(CASE WHEN otazka1 = 'C' THEN TRUE END) AS C, COUNT(CASE WHEN otazka1 = 'D' THEN TRUE END) AS D, COUNT(CASE WHEN otazka1 = 'E' THEN TRUE END) AS E FROM data UNION ALL SELECT 2 AS Otazka, COUNT(CASE WHEN otazka2 = 'A' THEN TRUE END) AS A, COUNT(CASE WHEN otazka2 = 'B' THEN TRUE END) AS B, COUNT(CASE WHEN otazka2 = 'C' THEN TRUE END) AS C, COUNT(CASE WHEN otazka2 = 'D' THEN TRUE END) AS D, COUNT(CASE WHEN otazka2 = 'E' THEN TRUE END) AS E FROM data UNION ALL SELECT 3 AS Otazka, COUNT(CASE WHEN otazka3 = 'A' THEN TRUE END) AS A, COUNT(CASE WHEN otazka3 = 'B' THEN TRUE END) AS B, COUNT(CASE WHEN otazka3 = 'C' THEN TRUE END) AS C, COUNT(CASE WHEN otazka3 = 'D' THEN TRUE END) AS D, COUNT(CASE WHEN otazka3 = 'E' THEN TRUE END) AS E FROM dataDá se však ještě optimalizovat (a znepřehlednit) na jeden průchod tabulkou data (což je při plné tabulce data časově nejnáročnější operace). Následující příkaz spočítá všechny četnosti v jednom průchodu tabulkou data a výsledek pak pomocí CROSS JOIN rozhodí na tři řádky. (Vytvoření tabulky se třemi řádky 1, 2, 3 bude možná nutné pro SQLite upravit.)
SELECT Otazka, CASE Otazka WHEN 1 THEN A1 WHEN 2 THEN A2 WHEN 3 THEN A3 END AS A, CASE Otazka WHEN 1 THEN B1 WHEN 2 THEN B2 WHEN 3 THEN B3 END AS B, CASE Otazka WHEN 1 THEN C1 WHEN 2 THEN C2 WHEN 3 THEN C3 END AS C, CASE Otazka WHEN 1 THEN D1 WHEN 2 THEN D2 WHEN 3 THEN D3 END AS D, CASE Otazka WHEN 1 THEN E1 WHEN 2 THEN E2 WHEN 3 THEN E3 END AS E FROM ( SELECT 1 AS Otazka UNION ALL SELECT 2 UNION ALL SELECT 3 ) AS ta CROSS JOIN ( SELECT COUNT(CASE WHEN otazka1 = 'A' THEN TRUE END) AS A1, COUNT(CASE WHEN otazka1 = 'B' THEN TRUE END) AS B1, COUNT(CASE WHEN otazka1 = 'C' THEN TRUE END) AS C1, COUNT(CASE WHEN otazka1 = 'D' THEN TRUE END) AS D1, COUNT(CASE WHEN otazka1 = 'E' THEN TRUE END) AS E1, COUNT(CASE WHEN otazka2 = 'A' THEN TRUE END) AS A2, COUNT(CASE WHEN otazka2 = 'B' THEN TRUE END) AS B2, COUNT(CASE WHEN otazka2 = 'C' THEN TRUE END) AS C2, COUNT(CASE WHEN otazka2 = 'D' THEN TRUE END) AS D2, COUNT(CASE WHEN otazka2 = 'E' THEN TRUE END) AS E2, COUNT(CASE WHEN otazka3 = 'A' THEN TRUE END) AS A3, COUNT(CASE WHEN otazka3 = 'B' THEN TRUE END) AS B3, COUNT(CASE WHEN otazka3 = 'C' THEN TRUE END) AS C3, COUNT(CASE WHEN otazka3 = 'D' THEN TRUE END) AS D3, COUNT(CASE WHEN otazka3 = 'E' THEN TRUE END) AS E3 FROM data ) AS tb
Jen jsem chtěl tazateli naznačit, která klíčová slova má hledat, když už se na to ptal. A měl jsem na mysli něco takového
create view vystup(id,otazka,a,b,c,d,e) as select id,'otazka1',1,0,0,0,0 from data where otazka1='A' union select id,'otazka1',0,1,0,0,0 from data where otazka1='B' . . . union select id,'otazkaN',0,0,0,0,1 from data where otazkaN='E';
select otazka,sum(a),sum(b),sum(c),sum(d),sum(e) from vystup group by otazka
Tiskni
Sdílej:
ISSN 1214-1267, (c) 1999-2007 Stickfish s.r.o.