Elem, otvorena nova skola. Skola nudi odredjen broj kurseva za studente. Naravno, napravljena je baza podataka i u bazi tri tabele - z_Studen, z_Course StudentCourse (ko je uzeo koji kurs). Kursevi nisu obavezni, pa svaki student uzima sta hoce. Skola je naravno privatna i kursevi se placaju. Direktor skole zeli da svima koji su upisali SVE raspolozive kurseve ucini popust.
Pitanje glasi: izlistati studente koji su uzeli sve raspolozive kurseve. Evo pocetnih podatka (sa MS SQL Servera)
CREATE TABLE z_Student (Student varchar(10) NOT NULL PRIMARY KEY)
CREATE TABLE z_Course (Course varchar(10) NOT NULL PRIMARY KEY)
CREATE TABLE z_StudentCourse
(Student varchar(10) NOT NULL
, Course varchar(10) NOT NULL)
ALTER TABLE z_StudentCourse
ADD CONSTRAINT PK_z_StudentCourse PRIMARY KEY (Student, Course)
Popunjavanje tabela:
INSERT INTO z_Student (Student) VALUES ('Pera')
INSERT INTO z_Student (Student) VALUES ('Laza')
INSERT INTO z_Student (Student) VALUES ('Mirko')
INSERT INTO z_Student (Student) VALUES ('Slavko')
INSERT INTO z_Student (Student) VALUES ('Ana')
INSERT INTO z_Student (Student) VALUES ('Mira')
INSERT INTO z_Student (Student) VALUES ('Zora')
INSERT INTO z_Student (Student) VALUES ('Goca')
INSERT INTO z_Student (Student) VALUES ('Joca')
INSERT INTO z_Course (Course) VALUES ('Matematika')
INSERT INTO z_Course (Course) VALUES ('Fizika')
INSERT INTO z_Course (Course) VALUES ('Hemija')
INSERT INTO z_StudentCourse VALUES ('Pera','Matematika')
INSERT INTO z_StudentCourse VALUES ('Pera','Fizika')
INSERT INTO z_StudentCourse VALUES ('Pera','Hemija')
INSERT INTO z_StudentCourse VALUES ('Laza','Fizika')
INSERT INTO z_StudentCourse VALUES ('Laza','Hemija')
INSERT INTO z_StudentCourse VALUES ('Mirko','Matematika')
INSERT INTO z_StudentCourse VALUES ('Mirko','Fizika')
INSERT INTO z_StudentCourse VALUES ('Slavko','Hemija')
INSERT INTO z_StudentCourse VALUES ('Ana','Fizika')
INSERT INTO z_StudentCourse VALUES ('Ana','Hemija')
INSERT INTO z_StudentCourse VALUES ('Mira','Matematika')
INSERT INTO z_StudentCourse VALUES ('Mira','Fizika')
INSERT INTO z_StudentCourse VALUES ('Mira','Hemija')
INSERT INTO z_StudentCourse VALUES ('Zora','Matematika')
INSERT INTO z_StudentCourse VALUES ('Zora','Fizika')
INSERT INTO z_StudentCourse VALUES ('Zora','Hemija')
INSERT INTO z_StudentCourse VALUES ('Goca','Hemija')
INSERT INTO z_StudentCourse VALUES ('Goca','Matematika')
Vidimo da postoje tri kursa i da su Pera, Mira i Zora upisali sva tri kursa. Ostali manje, a Joca ni jedan, on se tek upisao i jos razmislja.
Posto postavljac mozgalice treba da ponudi resenje, evo ovako. Zamislicu da je svaki student zaista upisao sve kurseve. Taj zamisljeni skup uporedicu sa tabelom StudentCourse i videcu kome koji kurs nedostaje. Kome ne nedostaje ni jedan kurs - to je resenje zadatka.
Situacija "svaki student upisao svaki kurs" moze se simulirati dekartovim proizvodom tabela z_Student i z_Course, ovako:
SELECT Student, Course
FROM z_Student , z_Course
ORDER BY Student, Course -- ORDER je samo zbog jasnoce prikaza u ovom koraku, inace se nece koristiti u medjukoracima
Dobijeni dekartov proizvod dve tabele treba uporediti sa tabelom z_StudentCourse:
SELECT A.Student, A.Course AS MoguciKurs, B.Course AS UpisaniKurs
FROM
(
SELECT Student, Course
FROM z_Student , z_Course
) AS A
LEFT JOIN z_StudentCourse AS B ON A.Student = B.student AND A.Course = B.Course
ORDER BY 1,2 -- ORDER je samo zbog jasnoce prikaza u ovom koraku, inace se nece koristiti u medjukoracima
Ako izvrsite ovaj upit, dobicete 27 redova koji u trecoj koloni imaju ponegde NULL. To su kursevi koje doticni student niej upisao.
Student koji je upisao sve kurseve, nema ni jednu NULL vrednost u trecoj koloni polednjeg upita. Kako izdvojiti studente koji nemaju ni jednu NULL vrednost u poseldnjem upitu? Ima vise nacina, trenutno mi pada na pamaet nesto ovako:
SELECT Student, COUNT(*) AS NumCourses
FROM
(
SELECT A.Student, A.Course AS CourseDesired, B.Course AS CourseActual
FROM
(
SELECT Student, Course
FROM z_Student , z_Course
) AS A
LEFT JOIN z_StudentCourse AS B ON A.Student = B.student AND A.Course = B.Course
) AS X
WHERE X.CourseActual IS NOT NULL
GROUP BY Student
Prebrojali smo koliko je ko uzeo realnih kurseva. Vidmo da su neki studeni uzeli 3 a neki manje.
Student NumCourses
---------- -----------
Ana 2
Goca 2
Laza 2
Mira 3
Mirko 2
Pera 3
Slavko 1
Zora 3
Trebju nam oni sa 3, pa moze ovako:
SELECT Student, COUNT(*) AS NumCourses
FROM
(
SELECT A.Student, A.Course AS CourseDesired, B.Course AS CourseActual
FROM
(
SELECT Student, Course
FROM z_Student , z_Course
) AS A
LEFT JOIN z_StudentCourse AS B ON A.Student = B.student AND A.Course = B.Course
) AS X
WHERE X.CourseActual IS NOT NULL
GROUP BY Student
HAVING COUNT(*) = 3
Ocigledno je da dobijamo sta smo trazili:
Student BrojKurseva
---------- -----------
Mira 3
Pera 3
Zora 3
Lepo, ali nama treba neko genericko resenje. Sta ako skola ponudi 5 kurseva?
Mozemo da umesto konstante (trojka) jednostavno prebrojimo koliko ima ponudjenih kurseva, ovako:
SELECT Student, COUNT(*) AS BrojKurseva
FROM
(
SELECT A.Student, A.Course AS CourseDesired, B.Course AS CourseActual
FROM
(
SELECT Student, Course
FROM z_Student , z_Course
) AS A
LEFT JOIN z_StudentCourse AS B ON A.Student = B.student AND A.Course = B.Course
) AS X
WHERE X.CourseActual IS NOT NULL
GROUP BY Student
HAVING COUNT(*) = (SELECT COUNT(*) FROM z_Course)
Time dobijamo konacan rezultat:
Student BrojKurseva
---------- -----------
Mira 3
Pera 3
Zora 3
Ponudjeno resenje se svodi na prebrojavanje kurseva koje je uzeo student i uporedjivanje tog broja sa brojem ponudjenih kurseva. Ovo sigurno moze da se napise krace i/ili efikasnije nego sto sam ja uradio. Kako?
A mozda ima i neki potpuno drugaciji pristup?
Izvolite
