diff --git a/README.md b/README.md index e88f7e4b7814215d3ff477850ddc16c8edb2b119..6233ec3bc8f318d00be1d3563e9bee3696150c2e 100644 --- a/README.md +++ b/README.md @@ -27,7 +27,6 @@ Here's a reminder of the topics covered in each lab session. Please note, topics ### Lab 4: Security and integrity! (27/28 Oct) - Data normalisation -- Transactions (SQL) - Backup/restore ### Lab 5: Using PHP to interact with a MySQL database (10/11 Nov) @@ -45,7 +44,7 @@ Here's a reminder of the topics covered in each lab session. Please note, topics - Basic data sanitization methods ### Lab 8: Implementing transactions in PHP (1/2 Dec) -- Examples +- Transaction examples ### Lab 9: Introduction to MongoDB (non-assessed) (8/9 Dec) - Document structure diff --git a/lab-2/music-store-app/sql/schema.sql b/lab-2/music-store-app/sql/schema.sql index 8e1df6cfc50d37c27b438d50379bd5ee083ed2ec..7c6fa10e2814c390caf1b4310e468b810ad0febd 100644 --- a/lab-2/music-store-app/sql/schema.sql +++ b/lab-2/music-store-app/sql/schema.sql @@ -10,8 +10,9 @@ CREATE TABLE Genre ( ); /* Define table for storing act (i.e. a group or solo artist) -ON DELETE CASCADE not needed in this -case as a Band does not HAVE to have an associated genre */ +ON DELETE CASCADE not used in this case as we don't want bands +being deleted if their genre is deleted. We'd rather an error +was raised. */ CREATE TABLE Band ( id INT AUTO_INCREMENT, name VARCHAR(50) NOT NULL, diff --git a/lab-3/music-store-app/sql/dummy_data.sql b/lab-3/music-store-app/sql/dummy_data.sql new file mode 100644 index 0000000000000000000000000000000000000000..1656b269bf9aac0f23d46d0045e92d0cbdc6b0aa --- /dev/null +++ b/lab-3/music-store-app/sql/dummy_data.sql @@ -0,0 +1,62 @@ +INSERT INTO Genre (name) +VALUES +('Reggae'), +('Funk and Soul'), +('Jazz'), +('Classical'), +('Electronic'), +('Pop'); + +INSERT INTO Band (name, genre_id) +VALUES +('The Wailers', 1), +('The Aces', 2), +('The Beatles', 6); + +INSERT INTO Artist (first_name, last_name, band_id) +VALUES +('Bob', 'Marley', 1), +('Peter', 'Tosh', 1), +('Burning', 'Spear', NULL), +('Alton', 'Ellis', NULL), +('Gregory', 'Issacs', NULL), +('Desmond', 'Dekker', 2), +('John', 'Lennon', 3), +('Madonna', NULL, NULL); + +INSERT INTO Album (upc, title, year, artist_id, price, genre_id) +VALUES +('123425364732', 'Soul Rebel', 1970, 1, 25.99, 1 ), +('017263547261', 'Catch A Fire', 1973, 1, 25.99, 1 ), +('018263526272', 'Natty Dread', 1974, 1, 20.99, 1 ), +('018273527273', 'Babylon By Bus', 1978, 1, 24.99, 1 ), +('491827364626', 'Night Nurse', 1982, 5, 17.99, 1 ), +('018276272828', 'Mr Issacs', 1982, 5, 9.99, 1 ), +('018273662728', 'Black and Dekker', 1980, 6, 19.99, 1 ), +('726517237627', 'Sunday Coming', 1970, 4, 15.99, 1 ), +('018274372722', 'Imagine', 1971, 7, 11.99, 6 ), +('018273727287', 'Like a Virgin', 1984, 8, 9.99, 6 ); + +INSERT INTO Track (name, album_upc, track_number) +VALUES +('Sunday Coming', '726517237627', 1), +('Imagine', '018274372722', 1), +('Material Girl', '018273727287', 1), +('Angel', '018273727287', 2), +('Like a Virgin', '018273727287', 3), +('Crippled Inside', '018274372722', 2), +('These Eyes', '726517237627', 2), +('Hurting Me', '726517237627', 3); + +INSERT INTO Customer (username, email_address, password, first_name, last_name, address_1, address_2, postcode) +VALUES +('sharr003', 's.harriet@gold.ac.uk', 'SOME_HASHED_VALUE', 'Sorrel', 'Harriet', '12 Fake Street', 'London', 'SE140PL'); + +INSERT INTO Transaction (customer_id, delivery) +VALUES +(1, 'next working day'); + +INSERT INTO LineItem (trans_id, album_upc, quantity) +VALUES +(1, '018273727287', 1), +(1, '018274372722', 2); diff --git a/lab-3/music-store-app/sql/practice_queries.sql b/lab-3/music-store-app/sql/practice_queries.sql new file mode 100644 index 0000000000000000000000000000000000000000..ba75d156b070e92aca73bb83d2f521cbf7f564d8 --- /dev/null +++ b/lab-3/music-store-app/sql/practice_queries.sql @@ -0,0 +1,69 @@ +/* Minimum functional requirements of +Music Store App and their associated queries. +Where variations are given they are +given in order of increasing complexity */ + +/* 1a. Retrieve a list of Albums +Include the UPC, title, price, artist name +and genre in the result-set. +Order by title (a-z) */ +SELECT Album.title, Album.price, Artist.first_name, Artist.last_name, Genre.name AS genre +FROM Album /* notice the use of a column alias! */ +INNER JOIN Artist + ON Album.artist_id=Artist.id +INNER JOIN Genre + ON Album.genre_id=Genre.id +ORDER BY title ASC; /* causes results to be ordered by album title */ + +/* 1b. Retrieve a list of Albums +Include the UPC, title, price, artist name, +genre, and number of tracks in the result-set. +Include only albums which have tracks in DB. +Order by title (a-z) */ +SELECT Album.title, Album.price, Artist.first_name, Artist.last_name, Genre.name AS genre, (SELECT COUNT(*) FROM Track WHERE Album.upc=Track.album_upc) AS num_tracks +FROM Album /* notice the nested query, aggregate function and aliases! */ +INNER JOIN Track + ON Album.upc=Track.album_upc +INNER JOIN Artist + ON Album.artist_id=Artist.id +INNER JOIN Genre + ON Album.genre_id=Genre.id +ORDER BY title ASC; + +/* 1c. Retrieve a list of Albums +Include the UPC, title, price, artist name, +genre, and number of tracks in the result-set. +Include ALL albums, even those without tracks. +Order by title (a-z) */ +SELECT Album.title, Album.price, Artist.first_name, Artist.last_name, Genre.name AS genre, (SELECT COUNT(*) FROM Track WHERE Album.upc=Track.album_upc) AS num_tracks +FROM Album /* notice the nested query, aggregate function and aliases! */ +LEFT JOIN Track /* LEFT JOIN causes all Albums to be returned, even when no matching record in Track table */ + ON Album.upc=Track.album_upc +INNER JOIN Artist + ON Album.artist_id=Artist.id +INNER JOIN Genre + ON Album.genre_id=Genre.id +ORDER BY title ASC; + +/* ------------------------------------ */ + +/* 2. Retrieve a list of tracks +associated with a specific album */ +SELECT t.name AS track, t.track_number, a.title AS album /* notice use of column aliases! */ +FROM Track t /* notice use of table aliases! */ +INNER JOIN Album a + ON t.album_upc=a.upc +WHERE a.upc='018274372722' /* EXAMPLE */ +ORDER BY track_number ASC; + +/* ------------------------------------ */ + +/* 3. Insert a new track */ +INSERT INTO Track (name, album_upc, track_number) +VALUES +('Sunday Coming', '726517237627', 1); /* EXAMPLE */ + +/* ------------------------------------ */ + +/* 4. Delete a track */ +DELETE FROM Track WHERE album_upc='726517237627'; /* EXAMPLE */ diff --git a/lab-3/music-store-app/sql/schema.sql b/lab-3/music-store-app/sql/schema.sql new file mode 100644 index 0000000000000000000000000000000000000000..7c6fa10e2814c390caf1b4310e468b810ad0febd --- /dev/null +++ b/lab-3/music-store-app/sql/schema.sql @@ -0,0 +1,110 @@ +/* Delete existing tables in reverse order of creation +so as not to violate any foreign key constraints */ +DROP TABLE IF EXISTS LineItem, Transaction, Customer, Track, Album, Artist, Band, Genre; + +/* Define table for genres */ +CREATE TABLE Genre ( + id INT AUTO_INCREMENT, + name VARCHAR(25) UNIQUE NOT NULL, + PRIMARY KEY (id) +); + +/* Define table for storing act (i.e. a group or solo artist) +ON DELETE CASCADE not used in this case as we don't want bands +being deleted if their genre is deleted. We'd rather an error +was raised. */ +CREATE TABLE Band ( + id INT AUTO_INCREMENT, + name VARCHAR(50) NOT NULL, + genre_id INT, + PRIMARY KEY (id), + FOREIGN KEY (genre_id) + REFERENCES Genre (id) +); + +/* Define table for storing artists */ +CREATE TABLE Artist ( + id INT AUTO_INCREMENT, + first_name VARCHAR(25) NOT NULL, + last_name VARCHAR(25), + band_id INT, + PRIMARY KEY (id), + FOREIGN KEY (band_id) + REFERENCES Band (id) +); + +/* Define table for storing albums */ +CREATE TABLE Album ( + upc CHAR(12), + title VARCHAR(50) NOT NULL, + year YEAR(4), + artist_id INT, + compilation BOOLEAN NOT NULL DEFAULT 0, + price DECIMAL(5, 2) unsigned NOT NULL, + genre_id INT, + PRIMARY KEY (upc), + FOREIGN KEY (artist_id) + REFERENCES Artist (id), + FOREIGN KEY (genre_id) + REFERENCES Genre (id) +); + + +/* Define table for storing single tracks +ON DELETE CASCADE will ensure no track +is left that isn't linked to an album. +ON UPDATE CASCADE will inherit any changes +to the Album UPC (Universal Product Code). +A composite PRIMARY KEY is used here to +ensure the track_number is unique +on any given album */ +CREATE TABLE Track ( + name VARCHAR(50) NOT NULL, + album_upc CHAR(12) NOT NULL, + track_number INT, + PRIMARY KEY (album_upc, track_number), + FOREIGN KEY (album_upc) + REFERENCES Album (upc) + ON UPDATE CASCADE + ON DELETE CASCADE +); + +/* Define table for storing customers */ +CREATE TABLE Customer ( + id INT AUTO_INCREMENT, + username VARCHAR(25) UNIQUE NOT NULL, + email_address VARCHAR(50) UNIQUE NOT NULL, + password VARCHAR(64), + first_name VARCHAR(50) NOT NULL, + last_name VARCHAR(50) NOT NULL, + address_1 VARCHAR(50) NOT NULL, + address_2 VARCHAR(50), + postcode VARCHAR(10) NOT NULL, + PRIMARY KEY (id) +); + +/* Define table for storing orders */ +CREATE TABLE Transaction ( + id INT AUTO_INCREMENT, + customer_id INT NOT NULL, + delivery ENUM('first class','second class','next working day'), + PRIMARY KEY (id), + FOREIGN KEY (customer_id) + REFERENCES Customer(id) + ON DELETE CASCADE +); + +/* Define table for storing line items */ +CREATE TABLE LineItem ( + id INT AUTO_INCREMENT, + trans_id INT NOT NULL, + album_upc CHAR(12) NOT NULL, + quantity INT NOT NULL DEFAULT 1, + PRIMARY KEY (id), + FOREIGN KEY (trans_id) + REFERENCES Transaction (id) + ON DELETE CASCADE, + FOREIGN KEY (album_upc) + REFERENCES Album (upc) + ON DELETE CASCADE +);