Commit 18027778 authored by Sorrel Harriet's avatar Sorrel Harriet
Browse files

archiving lab exercise contents from 2016-2017

parent 59dadecd
*********************************
* A TEST APPLICATION *
*********************************
Description
-----------
This is a test PHP application. You can upload use it to test your LAMP stack. You can also browse the directory structure to get an idea of how PHP web applications are commonly structured. You can also read this README file to find out the sorts of things that should be included in a README file!
Author & Contact
----------------
Sorrel Harriet s.harriet@gold.ac.uk
Installation Instructions
-------------------------
Upload the application to your web root folder. No further actions needed!
Configuration Instructions
--------------------------
There is nothing to configure.
\ No newline at end of file
<?php
# Write some helper functions here...
?>
<?php
// Code to detect whether index.php has been requested without query string
// If no page parameter detected...
if (!isset($_GET['page'])) {
$id = 'home'; // display home page
} else {
$id = $_GET['page']; // else requested page
}
$content = '';
// Switch statement to decide content of page will go here.
// Regardless of which "view" is displayed, the variable $content will
switch ($id) {
case 'home' :
include 'views/home.php';
break;
case 'page_2' :
include 'views/page_2.php';
break;
default :
include 'views/404.php';
}
?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Strict//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd">
<html xmlns="http://www.w3.org/1999/xhtml" xml:lang="en" lang="en">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=UTF-8" />
<title>Test Application</title>
</head>
<body>
<ul>
<li><a href="index.php">Home</a></li>
<li><a href="index.php?page=page_2">Page 2</a></li>
</ul>
<?php
// Display content for requested view.
echo $content;
?>
</body>
</html>
<?php
$content = "<h1>Page not found</h1>";
$content .= "<p>Sorry, the page you requested could not be found.</p>";
?>
<?php
$content = '<h1>Hello world!</h1>';
$content .= '<p>If you\'re reading this, it means you have successfully launched the <b>test app</b>.</p>'
?>
<?php
$content = '<h1>Welcome to page 2!</h1>';
?>
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);
/* Here are some example RUD operations!
They're not all that sensible...maybe you'll
figure out why as we progress through the labs! */
/* Select all columns from Album table */
SELECT * FROM Album;
/* Selct only name and year columns from Album table
and where price > £15 */
SELECT name, year FROM Album WHERE price > 15;
/* Update the price of albums called 'Soul Rebel' */
UPDATE Album SET price=21.99 WHERE name='Soul Rebel';
/* Delete artists with first_name Madonna (Yay!) */
DELETE FROM Artist WHERE first_name='Madonna';
/* Example use of ORDER BY key-word */
SELECT title, year, price FROM Album
ORDER BY year ASC, price DESC;
/* Example simple table join.
Gets title, price and year of albums
where Artist last name is 'Marley'
and orders by year ascending */
SELECT title, price, year FROM Album
INNER JOIN Artist
ON Artist.id=Album.artist_id
WHERE Artist.last_name='Marley'
ORDER BY year ASC;
/* Example multi table join
Gets track names, track numbers
and titles of all pop albums */
SELECT t.name, t.track_number, a.title
FROM Track t
INNER JOIN Album a
ON a.upc=t.album_upc
INNER JOIN Genre g
ON g.id=a.genre_id
WHERE g.name='Pop';
/* Example multi table join
Gets album title, genre and name
of first track on every album.
Uses both column and table aliases
to make result-set more readable */
SELECT a.title AS album, g.name AS genre, t.name AS track FROM Album a
INNER JOIN Genre g
ON a.genre_id=g.id
INNER JOIN Track t
ON a.upc=t.album_upc
WHERE t.track_number=1;
/* 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
);
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'),
('ktack001', 'k.tackie@hotmail.com', 'SOME_HASHED_VALUE', 'Kobi', 'Tackie', '12 Fake Street', 'London', 'SE140PL');
INSERT INTO Transaction (customer_id, delivery)
VALUES
(1, 'next working day'),
(1, 'first class'),
(2, 'second class');
INSERT INTO LineItem (trans_id, album_upc, quantity)
VALUES
(1, '018273727287', 1),
(2, '018273727287', 1),
(3, '491827364626', 1),
(1, '018274372722', 2);
/* 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
GROUP BY title /* group by album title to avoid duplicate rows */
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! */
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 */
/* ------------------------------------ */
/* 5a. Retrieve details about an order
Include the customer_id, delivery method
and total order value in the result-set */
SELECT Transaction.customer_id, Transaction.delivery, SUM(Album.price*LineItem.quantity) AS order_total /* notice use of aggregate function! */
FROM Transaction
INNER JOIN LineItem
ON Transaction.id=LineItem.trans_id
INNER JOIN Album
ON Album.upc=LineItem.album_upc
WHERE Transaction.id=1; /* EXAMPLE */
/* 5b. Retrieve details about an order
Include the transaction id, customer_id
and the number of items ordered in the
result-set */
SELECT t.id, t.customer_id, SUM(li.quantity) AS num_items
FROM Transaction t
INNER JOIN LineItem li
ON t.id=li.trans_id
GROUP BY t.id; /* group results by transaction id */
/* 5c. Does the same as the previous query
but using a nested query rather than a JOIN */
SELECT t.id, t.customer_id,
(SELECT SUM(li.quantity) FROM LineItem li
WHERE li.trans_id=t.id) AS num_items
FROM Transaction t;
/* 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
);
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),