Skip to content

Commit

Permalink
Merge branch 'issue-182' of https://github.com/erikbra/roundhouse int…
Browse files Browse the repository at this point in the history
…o erikbra-issue-182
  • Loading branch information
BiggerNoise committed Oct 12, 2017
2 parents 4a63a35 + a203f3f commit 0f8ab2a
Show file tree
Hide file tree
Showing 79 changed files with 96,179 additions and 6,737 deletions.
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
DROP USER 'rob'@'%';
DROP USER IF EXISTS 'rob'@'%';

CREATE USER 'rob'@'%' IDENTIFIED BY 'RHr0x0r!';

Expand Down
46 changes: 46 additions & 0 deletions db/MySQL/sakila/functions/get_customer_balance.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
DROP FUNCTION IF EXISTS get_customer_balance;
DELIMITER $$
;
CREATE FUNCTION get_customer_balance (
p_customer_id INT,
p_effective_date DATETIME
) RETURNS DECIMAL(5, 2)
BEGIN

#OK, WE NEED TO CALCULATE THE CURRENT BALANCE GIVEN A CUSTOMER_ID AND A DATE
#THAT WE WANT THE BALANCE TO BE EFFECTIVE FOR. THE BALANCE IS:
# 1) RENTAL FEES FOR ALL PREVIOUS RENTALS
# 2) ONE DOLLAR FOR EVERY DAY THE PREVIOUS RENTALS ARE OVERDUE
# 3) IF A FILM IS MORE THAN RENTAL_DURATION * 2 OVERDUE, CHARGE THE REPLACEMENT_COST
# 4) SUBTRACT ALL PAYMENTS MADE BEFORE THE DATE SPECIFIED

DECLARE v_rentfees DECIMAL(5,2); #FEES PAID TO RENT THE VIDEOS INITIALLY
DECLARE v_overfees INTEGER; #LATE FEES FOR PRIOR RENTALS
DECLARE v_payments DECIMAL(5,2); #SUM OF PAYMENTS MADE PREVIOUSLY

SELECT IFNULL(SUM(film.rental_rate),0) INTO v_rentfees
FROM film, inventory, rental
WHERE film.film_id = inventory.film_id
AND inventory.inventory_id = rental.inventory_id
AND rental.rental_date <= p_effective_date
AND rental.customer_id = p_customer_id;

SELECT IFNULL(SUM(IF((TO_DAYS(rental.return_date) - TO_DAYS(rental.rental_date)) > film.rental_duration,
((TO_DAYS(rental.return_date) - TO_DAYS(rental.rental_date)) - film.rental_duration),0)),0) INTO v_overfees
FROM rental, inventory, film
WHERE film.film_id = inventory.film_id
AND inventory.inventory_id = rental.inventory_id
AND rental.rental_date <= p_effective_date
AND rental.customer_id = p_customer_id;


SELECT IFNULL(SUM(payment.amount),0) INTO v_payments
FROM payment

WHERE payment.payment_date <= p_effective_date
AND payment.customer_id = p_customer_id;

RETURN v_rentfees + v_overfees - v_payments;
END$$
DELIMITER ;
;
19 changes: 19 additions & 0 deletions db/MySQL/sakila/functions/inventory_held_by_customer.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
DROP FUNCTION IF EXISTS inventory_held_by_customer;
DELIMITER $$
;
CREATE FUNCTION inventory_held_by_customer (
p_inventory_id INT
) RETURNS INT
BEGIN
DECLARE v_customer_id INT;
DECLARE EXIT HANDLER FOR NOT FOUND RETURN NULL;

SELECT customer_id INTO v_customer_id
FROM rental
WHERE return_date IS NULL
AND inventory_id = p_inventory_id;

RETURN v_customer_id;
END$$
DELIMITER ;
;
34 changes: 34 additions & 0 deletions db/MySQL/sakila/functions/inventory_in_stock.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
DROP FUNCTION IF EXISTS inventory_in_stock;
DELIMITER $$
;
CREATE FUNCTION inventory_in_stock (
p_inventory_id INT
) RETURNS TINYINT
BEGIN
DECLARE v_rentals INT;
DECLARE v_out INT;

#AN ITEM IS IN-STOCK IF THERE ARE EITHER NO ROWS IN THE rental TABLE
#FOR THE ITEM OR ALL ROWS HAVE return_date POPULATED

SELECT COUNT(*) INTO v_rentals
FROM rental
WHERE inventory_id = p_inventory_id;

IF v_rentals = 0 THEN
RETURN TRUE;
END IF;

SELECT COUNT(rental_id) INTO v_out
FROM inventory LEFT JOIN rental USING(inventory_id)
WHERE inventory.inventory_id = p_inventory_id
AND rental.return_date IS NULL;

IF v_out > 0 THEN
RETURN FALSE;
ELSE
RETURN TRUE;
END IF;
END$$
DELIMITER ;
;
23 changes: 23 additions & 0 deletions db/MySQL/sakila/indexes/idx_actor_last_name.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@

DELIMITER $$
;
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists $$
;
CREATE PROCEDURE powerup_drop_index_if_exists(in tableschema varchar(128), in theTable varchar(128), in theIndexName varchar(128) )
BEGIN
IF((SELECT COUNT(*) AS index_exists FROM information_schema.statistics WHERE TABLE_SCHEMA = tableschema and table_name =
theTable AND index_name = theIndexName) > 0) THEN
SET @s = CONCAT('DROP INDEX ' , theIndexName , ' ON ' , theTable);
PREPARE stmt FROM @s;
EXECUTE stmt;
END IF;
END $$
;
DELIMITER ;
;
CALL powerup_drop_index_if_exists('sakila', 'actor', 'idx_actor_last_name');
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists;

CREATE INDEX idx_actor_last_name ON actor(
last_name
);
23 changes: 23 additions & 0 deletions db/MySQL/sakila/indexes/idx_last_name.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@

DELIMITER $$
;
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists $$
;
CREATE PROCEDURE powerup_drop_index_if_exists(in tableschema varchar(128), in theTable varchar(128), in theIndexName varchar(128) )
BEGIN
IF((SELECT COUNT(*) AS index_exists FROM information_schema.statistics WHERE TABLE_SCHEMA = tableschema and table_name =
theTable AND index_name = theIndexName) > 0) THEN
SET @s = CONCAT('DROP INDEX ' , theIndexName , ' ON ' , theTable);
PREPARE stmt FROM @s;
EXECUTE stmt;
END IF;
END $$
;
DELIMITER ;
;
CALL powerup_drop_index_if_exists('sakila', 'customer', 'idx_last_name');
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists;

CREATE INDEX idx_last_name ON customer(
last_name
);
23 changes: 23 additions & 0 deletions db/MySQL/sakila/indexes/idx_title.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@

DELIMITER $$
;
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists $$
;
CREATE PROCEDURE powerup_drop_index_if_exists(in tableschema varchar(128), in theTable varchar(128), in theIndexName varchar(128) )
BEGIN
IF((SELECT COUNT(*) AS index_exists FROM information_schema.statistics WHERE TABLE_SCHEMA = tableschema and table_name =
theTable AND index_name = theIndexName) > 0) THEN
SET @s = CONCAT('DROP INDEX ' , theIndexName , ' ON ' , theTable);
PREPARE stmt FROM @s;
EXECUTE stmt;
END IF;
END $$
;
DELIMITER ;
;
CALL powerup_drop_index_if_exists('sakila', 'film', 'idx_title');
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists;

CREATE INDEX idx_title ON film(
title
);
24 changes: 24 additions & 0 deletions db/MySQL/sakila/indexes/idx_title_description.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@

DELIMITER $$
;
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists $$
;
CREATE PROCEDURE powerup_drop_index_if_exists(in tableschema varchar(128), in theTable varchar(128), in theIndexName varchar(128) )
BEGIN
IF((SELECT COUNT(*) AS index_exists FROM information_schema.statistics WHERE TABLE_SCHEMA = tableschema and table_name =
theTable AND index_name = theIndexName) > 0) THEN
SET @s = CONCAT('DROP INDEX ' , theIndexName , ' ON ' , theTable);
PREPARE stmt FROM @s;
EXECUTE stmt;
END IF;
END $$
;
DELIMITER ;
;
CALL powerup_drop_index_if_exists('sakila', 'film_text', 'idx_title_description');
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists;

CREATE FULLTEXT INDEX idx_title_description ON film_text(
title,
description
);
25 changes: 25 additions & 0 deletions db/MySQL/sakila/indexes/rental_date.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@

DELIMITER $$
;
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists $$
;
CREATE PROCEDURE powerup_drop_index_if_exists(in tableschema varchar(128), in theTable varchar(128), in theIndexName varchar(128) )
BEGIN
IF((SELECT COUNT(*) AS index_exists FROM information_schema.statistics WHERE TABLE_SCHEMA = tableschema and table_name =
theTable AND index_name = theIndexName) > 0) THEN
SET @s = CONCAT('DROP INDEX ' , theIndexName , ' ON ' , theTable);
PREPARE stmt FROM @s;
EXECUTE stmt;
END IF;
END $$
;
DELIMITER ;
;
CALL powerup_drop_index_if_exists('sakila', 'rental', 'rental_date');
DROP PROCEDURE IF EXISTS powerup_drop_index_if_exists;

CREATE UNIQUE INDEX rental_date ON rental(
rental_date,
inventory_id,
customer_id
);
19 changes: 19 additions & 0 deletions db/MySQL/sakila/sprocs/film_in_stock.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
DROP PROCEDURE IF EXISTS film_in_stock;
DELIMITER $$
;
CREATE PROCEDURE film_in_stock (
IN p_film_id INT,
IN p_store_id INT,
OUT p_film_count INT
)
BEGIN
SELECT inventory_id
FROM inventory
WHERE film_id = p_film_id
AND store_id = p_store_id
AND inventory_in_stock(inventory_id);

SELECT FOUND_ROWS() INTO p_film_count;
END$$
DELIMITER ;
;
19 changes: 19 additions & 0 deletions db/MySQL/sakila/sprocs/film_not_in_stock.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
DROP PROCEDURE IF EXISTS film_not_in_stock;
DELIMITER $$
;
CREATE PROCEDURE film_not_in_stock (
IN p_film_id INT,
IN p_store_id INT,
OUT p_film_count INT
)
BEGIN
SELECT inventory_id
FROM inventory
WHERE film_id = p_film_id
AND store_id = p_store_id
AND NOT inventory_in_stock(inventory_id);

SELECT FOUND_ROWS() INTO p_film_count;
END$$
DELIMITER ;
;
62 changes: 62 additions & 0 deletions db/MySQL/sakila/sprocs/rewards_report.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
DROP PROCEDURE IF EXISTS rewards_report;
DELIMITER $$
;
CREATE PROCEDURE rewards_report (
IN min_monthly_purchases TINYINT,
IN min_dollar_amount_purchased DECIMAL(10, 2),
OUT count_rewardees INT
)
proc: BEGIN

DECLARE last_month_start DATE;
DECLARE last_month_end DATE;

/* Some sanity checks... */
IF min_monthly_purchases = 0 THEN
SELECT 'Minimum monthly purchases parameter must be > 0';
LEAVE proc;
END IF;
IF min_dollar_amount_purchased = 0.00 THEN
SELECT 'Minimum monthly dollar amount purchased parameter must be > $0.00';
LEAVE proc;
END IF;

/* Determine start and end time periods */
SET last_month_start = DATE_SUB(CURRENT_DATE(), INTERVAL 1 MONTH);
SET last_month_start = STR_TO_DATE(CONCAT(YEAR(last_month_start),'-',MONTH(last_month_start),'-01'),'%Y-%m-%d');
SET last_month_end = LAST_DAY(last_month_start);

/*
Create a temporary storage area for
Customer IDs.
*/
CREATE TEMPORARY TABLE tmpCustomer (customer_id SMALLINT UNSIGNED NOT NULL PRIMARY KEY);

/*
Find all customers meeting the
monthly purchase requirements
*/
INSERT INTO tmpCustomer (customer_id)
SELECT p.customer_id
FROM payment AS p
WHERE DATE(p.payment_date) BETWEEN last_month_start AND last_month_end
GROUP BY customer_id
HAVING SUM(p.amount) > min_dollar_amount_purchased
AND COUNT(customer_id) > min_monthly_purchases;

/* Populate OUT parameter with count of found customers */
SELECT COUNT(*) FROM tmpCustomer INTO count_rewardees;

/*
Output ALL customer information of matching rewardees.
Customize output as needed.
*/
SELECT c.*
FROM tmpCustomer AS t
INNER JOIN customer AS c ON t.customer_id = c.customer_id;

/* Clean up */
DROP TABLE tmpCustomer;
END$$
DELIMITER ;
;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/actor_info.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS actor_info;
CREATE VIEW actor_info AS
select `a`.`actor_id` AS `actor_id`,`a`.`first_name` AS `first_name`,`a`.`last_name` AS `last_name`,group_concat(distinct concat(`c`.`name`,': ',(select group_concat(`f`.`title` order by `f`.`title` ASC separator ', ') from ((`sakila`.`film` `f` join `sakila`.`film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `sakila`.`film_actor` `fa` on((`f`.`film_id` = `fa`.`film_id`))) where ((`fc`.`category_id` = `c`.`category_id`) and (`fa`.`actor_id` = `a`.`actor_id`)))) order by `c`.`name` ASC separator '; ') AS `film_info` from (((`sakila`.`actor` `a` left join `sakila`.`film_actor` `fa` on((`a`.`actor_id` = `fa`.`actor_id`))) left join `sakila`.`film_category` `fc` on((`fa`.`film_id` = `fc`.`film_id`))) left join `sakila`.`category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `a`.`actor_id`,`a`.`first_name`,`a`.`last_name`;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/customer_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS customer_list;
CREATE VIEW customer_list AS
select `cu`.`customer_id` AS `ID`,concat(`cu`.`first_name`,' ',`cu`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`sakila`.`city`.`city` AS `city`,`sakila`.`country`.`country` AS `country`,if(`cu`.`active`,'active','') AS `notes`,`cu`.`store_id` AS `SID` from (((`sakila`.`customer` `cu` join `sakila`.`address` `a` on((`cu`.`address_id` = `a`.`address_id`))) join `sakila`.`city` on((`a`.`city_id` = `sakila`.`city`.`city_id`))) join `sakila`.`country` on((`sakila`.`city`.`country_id` = `sakila`.`country`.`country_id`)));
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/film_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS film_list;
CREATE VIEW film_list AS
select `sakila`.`film`.`film_id` AS `FID`,`sakila`.`film`.`title` AS `title`,`sakila`.`film`.`description` AS `description`,`sakila`.`category`.`name` AS `category`,`sakila`.`film`.`rental_rate` AS `price`,`sakila`.`film`.`length` AS `length`,`sakila`.`film`.`rating` AS `rating`,group_concat(concat(`sakila`.`actor`.`first_name`,' ',`sakila`.`actor`.`last_name`) separator ', ') AS `actors` from ((((`sakila`.`category` left join `sakila`.`film_category` on((`sakila`.`category`.`category_id` = `sakila`.`film_category`.`category_id`))) left join `sakila`.`film` on((`sakila`.`film_category`.`film_id` = `sakila`.`film`.`film_id`))) join `sakila`.`film_actor` on((`sakila`.`film`.`film_id` = `sakila`.`film_actor`.`film_id`))) join `sakila`.`actor` on((`sakila`.`film_actor`.`actor_id` = `sakila`.`actor`.`actor_id`))) group by `sakila`.`film`.`film_id`,`sakila`.`category`.`name`;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/nicer_but_slower_film_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS nicer_but_slower_film_list;
CREATE VIEW nicer_but_slower_film_list AS
select `sakila`.`film`.`film_id` AS `FID`,`sakila`.`film`.`title` AS `title`,`sakila`.`film`.`description` AS `description`,`sakila`.`category`.`name` AS `category`,`sakila`.`film`.`rental_rate` AS `price`,`sakila`.`film`.`length` AS `length`,`sakila`.`film`.`rating` AS `rating`,group_concat(concat(concat(ucase(substr(`sakila`.`actor`.`first_name`,1,1)),lcase(substr(`sakila`.`actor`.`first_name`,2,length(`sakila`.`actor`.`first_name`))),' ',concat(ucase(substr(`sakila`.`actor`.`last_name`,1,1)),lcase(substr(`sakila`.`actor`.`last_name`,2,length(`sakila`.`actor`.`last_name`)))))) separator ', ') AS `actors` from ((((`sakila`.`category` left join `sakila`.`film_category` on((`sakila`.`category`.`category_id` = `sakila`.`film_category`.`category_id`))) left join `sakila`.`film` on((`sakila`.`film_category`.`film_id` = `sakila`.`film`.`film_id`))) join `sakila`.`film_actor` on((`sakila`.`film`.`film_id` = `sakila`.`film_actor`.`film_id`))) join `sakila`.`actor` on((`sakila`.`film_actor`.`actor_id` = `sakila`.`actor`.`actor_id`))) group by `sakila`.`film`.`film_id`,`sakila`.`category`.`name`;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/sales_by_film_category.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS sales_by_film_category;
CREATE VIEW sales_by_film_category AS
select `c`.`name` AS `category`,sum(`p`.`amount`) AS `total_sales` from (((((`sakila`.`payment` `p` join `sakila`.`rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `sakila`.`inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `sakila`.`film` `f` on((`i`.`film_id` = `f`.`film_id`))) join `sakila`.`film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `sakila`.`category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `c`.`name` order by sum(`p`.`amount`) desc;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/sales_by_store.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS sales_by_store;
CREATE VIEW sales_by_store AS
select concat(`c`.`city`,',',`cy`.`country`) AS `store`,concat(`m`.`first_name`,' ',`m`.`last_name`) AS `manager`,sum(`p`.`amount`) AS `total_sales` from (((((((`sakila`.`payment` `p` join `sakila`.`rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `sakila`.`inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `sakila`.`store` `s` on((`i`.`store_id` = `s`.`store_id`))) join `sakila`.`address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `sakila`.`city` `c` on((`a`.`city_id` = `c`.`city_id`))) join `sakila`.`country` `cy` on((`c`.`country_id` = `cy`.`country_id`))) join `sakila`.`staff` `m` on((`s`.`manager_staff_id` = `m`.`staff_id`))) group by `s`.`store_id` order by `cy`.`country`,`c`.`city`;
3 changes: 3 additions & 0 deletions db/MySQL/sakila/views/staff_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP VIEW IF EXISTS staff_list;
CREATE VIEW staff_list AS
select `s`.`staff_id` AS `ID`,concat(`s`.`first_name`,' ',`s`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`sakila`.`city`.`city` AS `city`,`sakila`.`country`.`country` AS `country`,`s`.`store_id` AS `SID` from (((`sakila`.`staff` `s` join `sakila`.`address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `sakila`.`city` on((`a`.`city_id` = `sakila`.`city`.`city_id`))) join `sakila`.`country` on((`sakila`.`city`.`country_id` = `sakila`.`country`.`country_id`)));
Binary file removed lib/references/PostgreSQL/Mono.Security.dll
Binary file not shown.
Binary file removed lib/references/PostgreSQL/Npgsql.dll
Binary file not shown.
Loading

0 comments on commit 0f8ab2a

Please sign in to comment.