Skip to content

Instantly share code, notes, and snippets.

@alsma
Last active June 18, 2017 06:44
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 1 You must be signed in to fork a gist
  • Save alsma/80397974e355a6b7e4ec7648193be238 to your computer and use it in GitHub Desktop.
Save alsma/80397974e355a6b7e4ec7648193be238 to your computer and use it in GitHub Desktop.
Many-to-many interview question
-- select all query --
SELECT b.bookTitle, a.authorName FROM book b
INNER JOIN author_book ab ON ab.bookID = b.bookID
INNER JOIN author a ON a.authorID = ab.authorID
ORDER BY b.bookTitle
-- select all with authors concantenated --
SELECT b.bookTitle, GROUP_CONCAT(a.authorName) authors FROM book b
INNER JOIN author_book ab ON (ab.bookID = b.bookID)
INNER JOIN author a ON (ab.authorID = a.authorID)
GROUP BY b.bookID
-- select books written by 2 authors only --
SELECT b.bookTitle FROM author_book ab
INNER JOIN book b ON ab.bookID = b.bookID
GROUP BY ab.bookID HAVING COUNT(1) = 2
-- select books written by exact 2 authors --
SELECT b.bookTitle FROM book b
INNER JOIN (
SELECT ab.bookID FROM author_book ab
WHERE ab.bookID IN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON a.authorID = ab.authorID
GROUP BY ab.bookID HAVING COUNT(1) = 2
) AND ab.authorID IN (
SELECT a.authorID FROM author a
WHERE a.authorName IN ('A', 'B')
) GROUP BY ab.bookID HAVING COUNT(1) = 2
) bb ON b.bookID = bb.bookID
# ONE MOR WITH GROUP BY AND JOINS
SELECT b.bookTitle FROM book b
INNER JOIN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON (ab.authorID = a.authorID) AND a.authorName = 'A'
) aa ON aa.bookID = b.bookID
INNER JOIN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON (ab.authorID = a.authorID) AND a.authorName = 'B'
) aa2 ON aa2.bookID = b.bookID
INNER JOIN author_book ab ON (ab.bookID = b.bookID)
GROUP BY b.bookID, b.bookTitle HAVING COUNT(1) = 2
-- select books written by particular 2 authors, but some other one could be invloved --
# USING GROUP BY
SELECT b.bookTitle FROM book b
INNER JOIN author_book ab ON ab.bookID = b.bookID
INNER JOIN author a ON a.authorID = ab.authorID
WHERE a.authorName IN ('A', 'B')
GROUP BY ab.bookID HAVING COUNT(1) = 2
# USING SUBSELECT
SELECT b.bookTitle FROM book b
INNER JOIN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON a.authorID = ab.authorID
WHERE a.authorName IN ('A', 'B')
GROUP BY ab.bookID HAVING COUNT(1) = 2
) bb ON b.bookID = bb.bookID
# USING 4 JOINS
# CONS: it does not scale if we need condition with N authors
SELECT b.bookTitle FROM book b
INNER JOIN author_book ab ON (ab.bookID = b.bookID)
INNER JOIN author a ON (ab.authorID = a.authorID) AND a.authorName = 'A'
INNER JOIN author_book ab2 ON (ab2.bookID = b.bookID)
INNER JOIN author a2 ON (ab2.authorID = a2.authorID) AND a2.authorName = 'B'
# USING JOINS AND SUBQUERIES
SELECT b.bookTitle FROM book b
INNER JOIN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON (ab.authorID = a.authorID) AND a.authorName = 'A'
) aa ON aa.bookID = b.bookID
INNER JOIN (
SELECT ab.bookID FROM author_book ab
INNER JOIN author a ON (ab.authorID = a.authorID) AND a.authorName = 'B'
) aa2 ON aa2.bookID = b.bookID
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
DROP TABLE IF EXISTS `author`;
CREATE TABLE `author` (
`authorID` int(11) NOT NULL,
`authorName` varchar(100) DEFAULT NULL,
PRIMARY KEY (`authorID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
LOCK TABLES `author` WRITE;
/*!40000 ALTER TABLE `author` DISABLE KEYS */;
INSERT INTO `author` (`authorID`, `authorName`)
VALUES
(1,'A'),
(2,'B'),
(3,'C');
/*!40000 ALTER TABLE `author` ENABLE KEYS */;
UNLOCK TABLES;
DROP TABLE IF EXISTS `author_book`;
CREATE TABLE `author_book` (
`authorID` int(11) NOT NULL,
`bookID` int(11) NOT NULL,
PRIMARY KEY (`authorID`,`bookID`),
UNIQUE KEY `UNQ_AUTHOR_BOOK` (`authorID`,`bookID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
LOCK TABLES `author_book` WRITE;
/*!40000 ALTER TABLE `author_book` DISABLE KEYS */;
INSERT INTO `author_book` (`authorID`, `bookID`)
VALUES
(1,1),
(1,2),
(1,5),
(1,7),
(2,1),
(2,2),
(2,3),
(2,6),
(2,7),
(3,2),
(3,3),
(3,4),
(3,5);
/*!40000 ALTER TABLE `author_book` ENABLE KEYS */;
UNLOCK TABLES;
DROP TABLE IF EXISTS `book`;
CREATE TABLE `book` (
`bookID` int(11) NOT NULL,
`bookTitle` varchar(100) DEFAULT NULL,
PRIMARY KEY (`bookID`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
LOCK TABLES `book` WRITE;
/*!40000 ALTER TABLE `book` DISABLE KEYS */;
INSERT INTO `book` (`bookID`, `bookTitle`)
VALUES
(1,'AB'),
(2,'ABC'),
(3,'BC'),
(4,'C'),
(5,'AC'),
(6,'B'),
(7,'AB-dup');
/*!40000 ALTER TABLE `book` ENABLE KEYS */;
UNLOCK TABLES;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
@alsma
Copy link
Author

alsma commented Sep 1, 2016

Initial data

screen shot 2016-09-01 at 20 34 49

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment