home *** CD-ROM | disk | FTP | other *** search
- /*
- THIS FILE IS FOR USE WITH THE TUTORIAL IN "GETTING STARTED",
- IT IS NOT MEANT TO BE USED WITHOUT REFERRING TO THE MANUAL.
-
- * You must change the parameters below to match your
- * server name, database name , username, and password.
- * This file defines tables for the EMPLOYEE database.
- */
-
- CONNECT "server:\dir\mydb.gdb"
- USER "USERNAME" PASSWORD "password";
-
- /*
- * You are supposed to create the COUNTRY table by hand.
- *
- * CREATE TABLE country
- * (
- * country COUNTRYNAME NOT NULL PRIMARY KEY,
- * currency VARCHAR(10) NOT NULL)
- *
- */
-
- CREATE TABLE department
- (
- dept_no DEPTNO NOT NULL,
- department VARCHAR(25) NOT NULL UNIQUE,
- head_dept DEPTNO,
- mngr_no EMPNO,
- budget BUDGET,
- location VARCHAR(15),
- phone_no PHONENUMBER DEFAULT '555-1234',
-
- PRIMARY KEY (dept_no),
- FOREIGN KEY (head_dept) REFERENCES department (dept_no)
- );
- COMMIT;
-
- CREATE DESCENDING INDEX budgetx ON department (budget);
-
- /* Create JOB Table.
- * Job id, job title, minimum and maximum salary, job description,
- * and required languages.
- *
- * A job is defined by a multiple key, consisting of a job_code
- * (a 5-letter job abbreviation), a job grade, and a country name
- * indicating the salary currency type.
- *
- * The salary range is expressed in the appropriate country's currency.
- *
- * The job requirement is a text blob.
- *
- * The job may also require some knowledge of foreign languages,
- * stored in a character array.
- */
-
- CREATE TABLE JOB (JOB_CODE JOBCODE NOT NULL,
- JOB_GRADE JOBGRADE NOT NULL,
- JOB_COUNTRY COUNTRYNAME NOT NULL,
- JOB_TITLE VARCHAR(25) NOT NULL,
- MIN_SALARY SALARY NOT NULL,
- MAX_SALARY SALARY NOT NULL,
- JOB_REQUIREMENT BLOB SUB_TYPE TEXT SEGMENT SIZE 400,
- LANGUAGE_REQ VARCHAR(15)[1:5] ,
- PRIMARY KEY (JOB_CODE, JOB_GRADE, JOB_COUNTRY),
- FOREIGN KEY (job_country) REFERENCES country (country),
- CHECK (min_salary < max_salary) );
- COMMIT;
-
- /* Create EMPLOYEE Table
- * Employee id, name, phone extension, date of hire, department id,
- * job and salary information.
- *
- * Salary can be entered in any country's currency.
- * Therefore, some of the salaries can appear magnitudes larger than others,
- * depending on the currency type. Ex. Italian lira vs. U.K. pound.
- * The currency type is determined by the country code.
- *
- * job_code, job_grade, and job_country reference employee's job information,
- * illustrating two tables related by referential constraints on multiple
- * columns.
- *
- * The employee salary is verified to be in the correct salary range
- * for the given job title.
- */
-
- CREATE TABLE employee
- (
- emp_no EMPNO NOT NULL PRIMARY KEY,
- first_name FIRSTNAME NOT NULL,
- last_name LASTNAME NOT NULL,
- phone_ext VARCHAR(4),
- hire_date DATE DEFAULT 'NOW' NOT NULL,
- dept_no DEPTNO NOT NULL,
- job_code JOBCODE NOT NULL,
- job_grade JOBGRADE NOT NULL,
- job_country COUNTRYNAME NOT NULL,
- salary SALARY NOT NULL,
- full_name COMPUTED BY (last_name || ', ' || first_name),
-
- FOREIGN KEY (dept_no)
- REFERENCES department (dept_no),
- FOREIGN KEY (job_code, job_grade, job_country)
- REFERENCES job (job_code, job_grade, job_country),
-
- CHECK ( salary >= (SELECT min_salary FROM job WHERE
- job.job_code = employee.job_code AND
- job.job_grade = employee.job_grade AND
- job.job_country = employee.job_country) AND
- salary <= (SELECT max_salary FROM job WHERE
- job.job_code = employee.job_code AND
- job.job_grade = employee.job_grade AND
- job.job_country = employee.job_country))
- );
-
- CREATE INDEX namex ON employee (last_name, first_name);
- COMMIT;
-
- /*
- * Project id, project name, description, project team leader,
- * and product type.
- *
- * Project description is a text blob.
- */
-
- CREATE TABLE project
- (
- proj_id PROJNO NOT NULL,
- proj_name VARCHAR(20) NOT NULL UNIQUE,
- proj_desc BLOB(800,1),
- team_leader EMPNO,
- product PRODTYPE,
-
- PRIMARY KEY (proj_id),
- FOREIGN KEY (team_leader) REFERENCES employee (emp_no)
- );
- COMMIT;
-
- /*
- * Employee id, project id, employee's project duties.
- *
- * Employee duties is a text blob.
- */
-
- CREATE TABLE employee_project
- (
- emp_no EMPNO NOT NULL,
- proj_id PROJNO NOT NULL,
-
- PRIMARY KEY (emp_no, proj_id),
- FOREIGN KEY (emp_no) REFERENCES employee (emp_no),
- FOREIGN KEY (proj_id) REFERENCES project (proj_id)
- );
- COMMIT;
-
- /*
- * Fiscal year, project id, department id, projected head count by
- * fiscal quarter, projected budget.
- *
- * Tracks head count and budget planning by project by department.
- *
- * Quarterly head count is an array of integers.
- */
-
- CREATE TABLE proj_dept_budget
- (
- year INTEGER NOT NULL CHECK (YEAR >= 1993),
- proj_id PROJNO NOT NULL,
- dept_no DEPTNO NOT NULL,
- quart_head_cnt INTEGER [4],
- projected_budget BUDGET,
-
- PRIMARY KEY (year, proj_id, dept_no),
- FOREIGN KEY (dept_no) REFERENCES department (dept_no),
- FOREIGN KEY (proj_id) REFERENCES project (proj_id)
- );
- COMMIT;
-
- /*
- * Employee number, salary change date, updater's user id, old salary,
- * and percent change between old and new salary.
- */
-
- CREATE TABLE salary_history
- (
- emp_no EMPNO NOT NULL,
- change_date DATE DEFAULT 'NOW' NOT NULL,
- updater_id VARCHAR(20) NOT NULL,
- old_salary SALARY NOT NULL,
- percent_change DOUBLE PRECISION
- DEFAULT 0
- NOT NULL
- CHECK (percent_change between -50 and 50),
- new_salary COMPUTED BY
- (old_salary + old_salary * percent_change / 100),
-
- PRIMARY KEY (emp_no, change_date, updater_id),
- FOREIGN KEY (emp_no) REFERENCES employee (emp_no)
- );
-
- CREATE INDEX updaterx ON salary_history (updater_id);
- CREATE DESCENDING INDEX changex ON salary_history (change_date);
- COMMIT;
-
- /*
- * Customer id, customer name, contact first and last names,
- * phone number, address lines, city, state or province, country,
- * postal code or zip code, and customer status.
- */
-
- CREATE TABLE customer
- (
- cust_no CUSTNO NOT NULL,
- customer VARCHAR(25) NOT NULL,
- contact_first FIRSTNAME,
- contact_last LASTNAME,
- phone_no PHONENUMBER,
- address_line1 ADDRESSLINE,
- address_line2 ADDRESSLINE,
- city VARCHAR(25),
- state_province VARCHAR(15),
- country COUNTRYNAME,
- postal_code VARCHAR(12),
- on_hold CHAR DEFAULT NULL
- CHECK (on_hold IS NULL OR on_hold = '*'),
- PRIMARY KEY (cust_no),
- FOREIGN KEY (country)
- REFERENCES country (country)
- );
-
- CREATE INDEX custnamex ON customer (customer);
- CREATE INDEX custregion ON customer (country, city);
- COMMIT;
-
- /*
- * Purchase order number, customer id, sales representative, order status,
- * order date, date shipped, date need to ship by, payment received flag,
- * quantity ordered, total order value, type of product ordered,
- * any percent discount offered.
- *
- * Tracks customer orders.
- *
- * sales_rep is the ID of the employee handling the sale.
- *
- * Number of days passed since the order date is a computed field.
- *
- * Several checks are performed on this table, among them:
- * - A sale order must have a status: open, shipped, waiting.
- * - The ship date must be entered, if order status is 'shipped'.
- * - New orders can't be shipped to customers with 'on_hold' status.
- * - Sales rep
- */
-
- CREATE TABLE sales
- (
- po_number PONUMBER NOT NULL,
- cust_no CUSTNO NOT NULL,
- sales_rep EMPNO,
- order_status VARCHAR(7)
- DEFAULT 'new'
- NOT NULL
- CHECK (order_status in
- ('new', 'open', 'shipped', 'waiting')),
- order_date DATE
- DEFAULT 'now'
- NOT NULL,
- ship_date DATE
- CHECK (ship_date >= order_date OR ship_date IS NULL),
- date_needed DATE
- CHECK (date_needed > order_date OR date_needed IS NULL),
- paid CHAR
- DEFAULT 'n'
- CHECK (paid in ('y', 'n')),
- qty_ordered INTEGER
- DEFAULT 1
- NOT NULL
- CHECK (qty_ordered >= 1),
- total_value DECIMAL(9,2)
- NOT NULL
- CHECK (total_value >= 0),
- discount FLOAT
- DEFAULT 0
- NOT NULL
- CHECK (discount >= 0 AND discount <= 1),
- item_type PRODTYPE,
- aged COMPUTED BY
- (ship_date - order_date),
-
- PRIMARY KEY (po_number),
- FOREIGN KEY (cust_no) REFERENCES customer (cust_no),
- FOREIGN KEY (sales_rep) REFERENCES employee (emp_no),
-
- CHECK (NOT (order_status = 'shipped' AND ship_date IS NULL)),
-
- CHECK (NOT (order_status = 'shipped' AND
- EXISTS (SELECT on_hold FROM customer
- WHERE customer.cust_no = sales.cust_no
- AND customer.on_hold = '*')))
- );
-
- CREATE INDEX needx ON sales (date_needed);
- CREATE INDEX salestatx ON sales (order_status, paid);
- CREATE DESCENDING INDEX qtyx ON sales (item_type, qty_ordered);
- COMMIT;
- EXIT;
-