fundamental_user_schema.sql 9.07 KB
Newer Older
O'Reilly Media, Inc. committed
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345
-- The SQL*Plus script fundamental_user_schema.sql performs the following:
--   1. Creates the fundamental_user.
--   2. Creates the database objects.
--   3. Populates the database tables with example data.

-- This script should be run by the system user (or the DBA).
CONNECT system/manager;

-- drop fundamental_user
DROP USER fundamental_user CASCADE;

-- create fundamental_user
CREATE USER fundamental_user IDENTIFIED BY fundamental_password;

-- allow fundamental_user to connect and create database objects
GRANT connect, resource TO fundamental_user;

-- connect as the fundamental_user
CONNECT fundamental_user/fundamental_password;

-- create the tables
CREATE TABLE customers (
  id         NUMBER CONSTRAINT customers_pk PRIMARY KEY,
  first_name VARCHAR2(50) NOT NULL,
  last_name  VARCHAR2(50) NOT NULL,
  dob        DATE,
  phone      VARCHAR2(20)
);

CREATE TABLE product_types (
  id   NUMBER CONSTRAINT product_types_pk PRIMARY KEY,
  name VARCHAR2(50) NOT NULL
);

CREATE TABLE products (
  id          NUMBER CONSTRAINT products_pk PRIMARY KEY,
  type_id     NUMBER
    CONSTRAINT products_fk_product_types
    REFERENCES product_types(id),
  name        VARCHAR2(50) NOT NULL,
  description VARCHAR2(500),
  price       NUMBER(10, 2)
);

CREATE TABLE purchases (
  product_id   NUMBER
    CONSTRAINT purchases_fk_products
    REFERENCES products(id),
  purchased_by NUMBER
    CONSTRAINT purchases_fk_customers
    REFERENCES customers(id),
  quantity     NUMBER NOT NULL,
  CONSTRAINT   purchases_pk PRIMARY KEY (product_id, purchased_by)
);

CREATE TABLE price_audit (
  product_id NUMBER CONSTRAINT price_audit_fk_products REFERENCES products(id),
  old_price  NUMBER(10, 2),
  new_price  NUMBER(10, 2)
);

-- create the functions, procedures and packages

-- procedure update_product_price() updates the price of
-- a product by a given factor (both specified as parameters)
CREATE PROCEDURE update_product_price(

  p_product_id IN products.id%TYPE,
  p_factor     IN NUMBER

) AS

  product_count INTEGER;

BEGIN

  -- ensure that the product exists
  SELECT
    COUNT(*)
  INTO
    product_count
  FROM
    products
  WHERE
    id = p_product_id;

  -- if the product doesn't exist then return
  IF product_count = 0 THEN
    RETURN;
  END IF;

  -- if the product does exist then perform the update
  UPDATE
    products
  SET
    price = price * p_factor;

  -- commit the transaction
  COMMIT;

END update_product_price;
/


-- function update_product_price_func() updates the price of
-- a product by a given factor (both specified as a parameters),
-- and returns 0 if successful, otherwise returns 1 (indicating that the
-- product was not found)
CREATE FUNCTION update_product_price_func(

  p_product_id IN products.id%TYPE,
  p_factor     IN NUMBER

) RETURN INTEGER AS

  product_count INTEGER;

BEGIN

  -- ensure that the product exists
  SELECT
    COUNT(*)
  INTO
    product_count
  FROM
    products
  WHERE
    id = p_product_id;

  -- if the product doesn't exist then return 1
  IF product_count = 0 THEN

    -- return 1, indicating that the function was unsuccessful
    RETURN 1;

  END IF;

  -- if the product does exist then perform the update
  UPDATE
    products
  SET
    price = price * p_factor;

  -- commit the transaction
  COMMIT;

  -- return 0, indication that the function was successful
  RETURN 0;

END update_product_price_func;
/


-- package ref_cursor_package illustrates the use of the
-- REF CURSOR type
CREATE PACKAGE ref_cursor_package AS

  TYPE t_ref_cursor IS REF CURSOR;
  FUNCTION get_customers_ref_cursor RETURN t_ref_cursor;

END ref_cursor_package;
/

CREATE PACKAGE BODY ref_cursor_package AS

  -- function get_customers_ref_cursor() returns a REF CURSOR
  FUNCTION get_customers_ref_cursor
  RETURN t_ref_cursor IS

    customers_ref_cursor t_ref_cursor;

  BEGIN

    -- get the REF CURSOR
    OPEN customers_ref_cursor FOR
      SELECT
        id, first_name, last_name, dob, phone
      FROM
        customers;

    -- return the REF CURSOR
    RETURN customers_ref_cursor;

  END get_customers_ref_cursor;

END ref_cursor_package;
/


-- insert sample data into customers table

INSERT INTO customers (id, first_name, last_name, dob, phone)
VALUES (1, 'John', 'Smith', '01-JAN-1965', '650-555-1212');

INSERT INTO customers (id, first_name, last_name, dob, phone)
VALUES (2, 'Cynthia', 'Stevens', '05-MAR-1968', '650-555-1213');

INSERT INTO customers (id, first_name, last_name, dob, phone)
VALUES (3, 'Steve', 'Seymour', '16-JUN-1971', '650-555-1214');

INSERT INTO customers (id, first_name, last_name, dob, phone)
VALUES (4, 'Gail', 'Williams', '01-DEC-1975', '650-555-1215');

INSERT INTO customers (id, first_name, last_name, dob, phone)
VALUES (5, 'Doreen', 'Heyson', '20-AUG-1970', '650-555-1216');


-- insert sample data into product_types table

INSERT INTO product_types (id, name)
VALUES (1, 'Book');

INSERT INTO product_types (id, name)
VALUES (2, 'Video');

INSERT INTO product_types (id, name)
VALUES (3, 'DVD');

INSERT INTO product_types (id, name)
VALUES (4, 'CD');


-- insert sample data into products table

INSERT INTO products (id, type_id, name, description, price)
VALUES (1, 1, 'Beyond Understanding', 'The frontiers of human knowledge', 19.95);

INSERT INTO products (id, type_id, name, description, price)
VALUES (2, 1, 'Physics', 'Fundamental understanding of the natural world', 30.00);

INSERT INTO products (id, type_id, name, description, price)
VALUES (3, 1, 'Star Travelers', 'The adventures of futuristic astronauts', 25.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (4, 2, 'Seventh Sense', 'Supernatural tale of the unknown', 13.95);

INSERT INTO products (id, type_id, name, description, price)
VALUES (5, 2, 'Quantum Jump', 'The physics of the quantum world', 49.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (6, 2, '2002: A Space Journey', 'The year after 2001', 14.95);

INSERT INTO products (id, type_id, name, description, price)
VALUES (7, 3, 'Super Force', 'The adventures of Super Force Man', 13.49);

INSERT INTO products (id, type_id, name, description, price)
VALUES (8, 3, 'The Man from Another Planet', 'A man from another planet lands on Earth', 12.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (9, 4, 'Classical Music', 'The best classical music', 10.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (10, 4, 'Pop 2000', 'The best popular music from 2000', 15.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (11, 4, 'Creative Riot', 'Debut album', 14.99);

INSERT INTO products (id, type_id, name, description, price)
VALUES (12, 4, 'Front Line', 'Their greatest hits', 13.49);

-- insert sample data into purchases table

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 1, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 2, 3);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 3, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 4, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 5, 4);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 6, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 7, 3);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 8, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 9, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 10, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 11, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (1, 12, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (2, 1, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (2, 2, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (2, 3, 3);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (2, 4, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (2, 5, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (3, 1, 4);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (3, 2, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (3, 3, 2);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (3, 4, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (3, 5, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (4, 1, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (4, 2, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (4, 3, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (5, 1, 1);

INSERT INTO purchases (purchased_by, product_id, quantity)
VALUES (5, 2, 1);

-- commit the transaction
COMMIT;