empddl.sql 23 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955
  1. /*
  2. * The contents of this file are subject to the Interbase Public
  3. * License Version 1.0 (the "License"); you may not use this file
  4. * except in compliance with the License. You may obtain a copy
  5. * of the License at http://www.Inprise.com/IPL.html
  6. *
  7. * Software distributed under the License is distributed on an
  8. * "AS IS" basis, WITHOUT WARRANTY OF ANY KIND, either express
  9. * or implied. See the License for the specific language governing
  10. * rights and limitations under the License.
  11. *
  12. * The Original Code was created by Inprise Corporation
  13. * and its predecessors. Portions created by Inprise Corporation are
  14. * Copyright (C) Inprise Corporation.
  15. *
  16. * All Rights Reserved.
  17. * Contributor(s): ______________________________________.
  18. */
  19. /*create database "employee.fdb";*/
  20. /**
  21. ** Create a sample employee database.
  22. **
  23. ** This database keeps track of employees, departments, projects, and sales
  24. ** for a small company.
  25. **
  26. **/
  27. /*
  28. * Define domains.
  29. */
  30. /* set echo on;
  31. */
  32. CREATE DOMAIN firstname AS VARCHAR(15);
  33. CREATE DOMAIN lastname AS VARCHAR(20);
  34. CREATE DOMAIN phonenumber AS VARCHAR(20);
  35. CREATE DOMAIN countryname AS VARCHAR(15);
  36. CREATE DOMAIN addressline AS VARCHAR(30);
  37. CREATE DOMAIN empno
  38. AS SMALLINT;
  39. CREATE DOMAIN deptno
  40. AS CHAR(3)
  41. CHECK (VALUE = '000' OR (VALUE > '0' AND VALUE <= '999') OR VALUE IS NULL);
  42. CREATE DOMAIN projno
  43. AS CHAR(5)
  44. CHECK (VALUE = UPPER (VALUE));
  45. CREATE DOMAIN custno
  46. AS INTEGER
  47. CHECK (VALUE > 1000);
  48. /* must begin with a letter */
  49. CREATE DOMAIN jobcode
  50. AS VARCHAR(5)
  51. CHECK (VALUE > '99999');
  52. CREATE DOMAIN jobgrade
  53. AS SMALLINT
  54. CHECK (VALUE BETWEEN 0 AND 6);
  55. /* salary is in any currency type */
  56. CREATE DOMAIN salary
  57. AS NUMERIC(10,2)
  58. DEFAULT 0
  59. CHECK (VALUE > 0);
  60. /* budget is in US dollars */
  61. CREATE DOMAIN budget
  62. AS DECIMAL(12,2)
  63. DEFAULT 50000
  64. CHECK (VALUE > 10000 AND VALUE <= 2000000);
  65. CREATE DOMAIN prodtype
  66. AS VARCHAR(12)
  67. DEFAULT 'software' NOT NULL
  68. CHECK (VALUE IN ('software', 'hardware', 'other', 'N/A'));
  69. CREATE DOMAIN PONUMBER
  70. AS CHAR(8)
  71. CHECK (VALUE STARTING WITH 'V');
  72. /*
  73. * Create generators.
  74. */
  75. CREATE GENERATOR emp_no_gen;
  76. CREATE GENERATOR cust_no_gen;
  77. SET GENERATOR cust_no_gen to 1000;
  78. COMMIT;
  79. /*
  80. * Create tables.
  81. */
  82. /*
  83. * Country name, currency type.
  84. */
  85. CREATE TABLE country
  86. (
  87. country COUNTRYNAME NOT NULL PRIMARY KEY,
  88. currency VARCHAR(10) NOT NULL
  89. );
  90. /*
  91. * Job id, job title, minimum and maximum salary, job description,
  92. * and required languages.
  93. *
  94. * A job is defined by a multiple key, consisting of a job_code
  95. * (a 5-letter job abbreviation), a job grade, and a country name
  96. * indicating the salary currency type.
  97. *
  98. * The salary range is expressed in the appropriate country's currency.
  99. *
  100. * The job requirement is a text blob.
  101. *
  102. * The job may also require some knowledge of foreign languages,
  103. * stored in a character array.
  104. */
  105. CREATE TABLE job
  106. (
  107. job_code JOBCODE NOT NULL,
  108. job_grade JOBGRADE NOT NULL,
  109. job_country COUNTRYNAME NOT NULL,
  110. job_title VARCHAR(25) NOT NULL,
  111. min_salary SALARY NOT NULL,
  112. max_salary SALARY NOT NULL,
  113. job_requirement BLOB(400,1),
  114. language_req VARCHAR(15) [5],
  115. PRIMARY KEY (job_code, job_grade, job_country),
  116. FOREIGN KEY (job_country) REFERENCES country (country),
  117. CHECK (min_salary < max_salary)
  118. );
  119. CREATE ASCENDING INDEX minsalx ON job (job_country, min_salary);
  120. CREATE DESCENDING INDEX maxsalx ON job (job_country, max_salary);
  121. /*
  122. * Department number, name, head department, manager id,
  123. * budget, location, department phone number.
  124. *
  125. * Each department is a sub-department in some department, determined
  126. * by head_dept. The head of this tree is the company.
  127. * This information is used to produce a company organization chart.
  128. *
  129. * Departments have managers; however, manager id can be null to allow
  130. * for temporary situations where a manager needs to be hired.
  131. *
  132. * Budget is allocated in U.S. dollars for all departments.
  133. *
  134. * Foreign key mngr_no is added after the employee table is created,
  135. * using 'alter table'.
  136. */
  137. CREATE TABLE department
  138. (
  139. dept_no DEPTNO NOT NULL,
  140. department VARCHAR(25) NOT NULL UNIQUE,
  141. head_dept DEPTNO,
  142. mngr_no EMPNO,
  143. budget BUDGET,
  144. location VARCHAR(15),
  145. phone_no PHONENUMBER DEFAULT '555-1234',
  146. PRIMARY KEY (dept_no),
  147. FOREIGN KEY (head_dept) REFERENCES department (dept_no)
  148. );
  149. CREATE DESCENDING INDEX budgetx ON department (budget);
  150. /*
  151. * Employee id, name, phone extension, date of hire, department id,
  152. * job and salary information.
  153. *
  154. * Salary can be entered in any country's currency.
  155. * Therefore, some of the salaries can appear magnitudes larger than others,
  156. * depending on the currency type. Ex. Italian lira vs. U.K. pound.
  157. * The currency type is determined by the country code.
  158. *
  159. * job_code, job_grade, and job_country reference employee's job information,
  160. * illustrating two tables related by referential constraints on multiple
  161. * columns.
  162. *
  163. * The employee salary is verified to be in the correct salary range
  164. * for the given job title.
  165. */
  166. CREATE TABLE employee
  167. (
  168. emp_no EMPNO NOT NULL,
  169. first_name FIRSTNAME NOT NULL,
  170. last_name LASTNAME NOT NULL,
  171. phone_ext VARCHAR(4),
  172. hire_date TIMESTAMP DEFAULT 'NOW' NOT NULL,
  173. dept_no DEPTNO NOT NULL,
  174. job_code JOBCODE NOT NULL,
  175. job_grade JOBGRADE NOT NULL,
  176. job_country COUNTRYNAME NOT NULL,
  177. salary SALARY NOT NULL,
  178. full_name COMPUTED BY (last_name || ', ' || first_name),
  179. PRIMARY KEY (emp_no),
  180. FOREIGN KEY (dept_no) REFERENCES
  181. department (dept_no),
  182. FOREIGN KEY (job_code, job_grade, job_country) REFERENCES
  183. job (job_code, job_grade, job_country),
  184. CHECK ( salary >= (SELECT min_salary FROM job WHERE
  185. job.job_code = employee.job_code AND
  186. job.job_grade = employee.job_grade AND
  187. job.job_country = employee.job_country) AND
  188. salary <= (SELECT max_salary FROM job WHERE
  189. job.job_code = employee.job_code AND
  190. job.job_grade = employee.job_grade AND
  191. job.job_country = employee.job_country))
  192. );
  193. CREATE INDEX namex ON employee (last_name, first_name);
  194. CREATE VIEW phone_list AS SELECT
  195. emp_no, first_name, last_name, phone_ext, location, phone_no
  196. FROM employee, department
  197. WHERE employee.dept_no = department.dept_no;
  198. COMMIT;
  199. SET TERM !! ;
  200. CREATE TRIGGER set_emp_no FOR employee
  201. BEFORE INSERT AS
  202. BEGIN
  203. if (new.emp_no is null) then
  204. new.emp_no = gen_id(emp_no_gen, 1);
  205. END !!
  206. SET TERM ; !!
  207. /*
  208. * Add an additional constraint to department: check manager numbers
  209. * in the employee table.
  210. */
  211. ALTER TABLE department ADD FOREIGN KEY (mngr_no) REFERENCES employee (emp_no);
  212. /*
  213. * Project id, project name, description, project team leader,
  214. * and product type.
  215. *
  216. * Project description is a text blob.
  217. */
  218. CREATE TABLE project
  219. (
  220. proj_id PROJNO NOT NULL,
  221. proj_name VARCHAR(20) NOT NULL UNIQUE,
  222. proj_desc BLOB(800,1),
  223. team_leader EMPNO,
  224. product PRODTYPE,
  225. PRIMARY KEY (proj_id),
  226. FOREIGN KEY (team_leader) REFERENCES employee (emp_no)
  227. );
  228. CREATE UNIQUE INDEX prodtypex ON project (product, proj_name);
  229. /*
  230. * Employee id, project id, employee's project duties.
  231. *
  232. * Employee duties is a text blob.
  233. */
  234. CREATE TABLE employee_project
  235. (
  236. emp_no EMPNO NOT NULL,
  237. proj_id PROJNO NOT NULL,
  238. PRIMARY KEY (emp_no, proj_id),
  239. FOREIGN KEY (emp_no) REFERENCES employee (emp_no),
  240. FOREIGN KEY (proj_id) REFERENCES project (proj_id)
  241. );
  242. /*
  243. * Fiscal year, project id, department id, projected head count by
  244. * fiscal quarter, projected budget.
  245. *
  246. * Tracks head count and budget planning by project by department.
  247. *
  248. * Quarterly head count is an array of integers.
  249. */
  250. CREATE TABLE proj_dept_budget
  251. (
  252. fiscal_year INTEGER NOT NULL CHECK (FISCAL_YEAR >= 1993),
  253. proj_id PROJNO NOT NULL,
  254. dept_no DEPTNO NOT NULL,
  255. quart_head_cnt INTEGER [4],
  256. projected_budget BUDGET,
  257. PRIMARY KEY (fiscal_year, proj_id, dept_no),
  258. FOREIGN KEY (dept_no) REFERENCES department (dept_no),
  259. FOREIGN KEY (proj_id) REFERENCES project (proj_id)
  260. );
  261. /*
  262. * Employee number, salary change date, updater's user id, old salary,
  263. * and percent change between old and new salary.
  264. */
  265. CREATE TABLE salary_history
  266. (
  267. emp_no EMPNO NOT NULL,
  268. change_date TIMESTAMP DEFAULT 'NOW' NOT NULL,
  269. updater_id VARCHAR(20) NOT NULL,
  270. old_salary SALARY NOT NULL,
  271. percent_change DOUBLE PRECISION
  272. DEFAULT 0
  273. NOT NULL
  274. CHECK (percent_change between -50 and 50),
  275. new_salary COMPUTED BY
  276. (old_salary + old_salary * percent_change / 100),
  277. PRIMARY KEY (emp_no, change_date, updater_id),
  278. FOREIGN KEY (emp_no) REFERENCES employee (emp_no)
  279. );
  280. CREATE INDEX updaterx ON salary_history (updater_id);
  281. CREATE DESCENDING INDEX changex ON salary_history (change_date);
  282. COMMIT;
  283. SET TERM !! ;
  284. CREATE TRIGGER save_salary_change FOR employee
  285. AFTER UPDATE AS
  286. BEGIN
  287. IF (old.salary <> new.salary) THEN
  288. INSERT INTO salary_history
  289. (emp_no, change_date, updater_id, old_salary, percent_change)
  290. VALUES (
  291. old.emp_no,
  292. 'NOW',
  293. user,
  294. old.salary,
  295. (new.salary - old.salary) * 100 / old.salary);
  296. END !!
  297. SET TERM ; !!
  298. COMMIT;
  299. /*
  300. * Customer id, customer name, contact first and last names,
  301. * phone number, address lines, city, state or province, country,
  302. * postal code or zip code, and customer status.
  303. */
  304. CREATE TABLE customer
  305. (
  306. cust_no CUSTNO NOT NULL,
  307. customer VARCHAR(25) NOT NULL,
  308. contact_first FIRSTNAME,
  309. contact_last LASTNAME,
  310. phone_no PHONENUMBER,
  311. address_line1 ADDRESSLINE,
  312. address_line2 ADDRESSLINE,
  313. city VARCHAR(25),
  314. state_province VARCHAR(15),
  315. country COUNTRYNAME,
  316. postal_code VARCHAR(12),
  317. on_hold CHAR
  318. DEFAULT NULL
  319. CHECK (on_hold IS NULL OR on_hold = '*'),
  320. PRIMARY KEY (cust_no),
  321. FOREIGN KEY (country) REFERENCES country (country)
  322. );
  323. CREATE INDEX custnamex ON customer (customer);
  324. CREATE INDEX custregion ON customer (country, city);
  325. SET TERM !! ;
  326. CREATE TRIGGER set_cust_no FOR customer
  327. BEFORE INSERT AS
  328. BEGIN
  329. if (new.cust_no is null) then
  330. new.cust_no = gen_id(cust_no_gen, 1);
  331. END !!
  332. SET TERM ; !!
  333. COMMIT;
  334. /*
  335. * Purchase order number, customer id, sales representative, order status,
  336. * order date, date shipped, date need to ship by, payment received flag,
  337. * quantity ordered, total order value, type of product ordered,
  338. * any percent discount offered.
  339. *
  340. * Tracks customer orders.
  341. *
  342. * sales_rep is the ID of the employee handling the sale.
  343. *
  344. * Number of days passed since the order date is a computed field.
  345. *
  346. * Several checks are performed on this table, among them:
  347. * - A sale order must have a status: open, shipped, waiting.
  348. * - The ship date must be entered, if order status is 'shipped'.
  349. * - New orders can't be shipped to customers with 'on_hold' status.
  350. * - Sales rep
  351. */
  352. CREATE TABLE sales
  353. (
  354. po_number PONUMBER NOT NULL,
  355. cust_no CUSTNO NOT NULL,
  356. sales_rep EMPNO,
  357. order_status VARCHAR(7)
  358. DEFAULT 'new'
  359. NOT NULL
  360. CHECK (order_status in
  361. ('new', 'open', 'shipped', 'waiting')),
  362. order_date TIMESTAMP
  363. DEFAULT 'NOW'
  364. NOT NULL,
  365. ship_date TIMESTAMP
  366. CHECK (ship_date >= order_date OR ship_date IS NULL),
  367. date_needed TIMESTAMP
  368. CHECK (date_needed > order_date OR date_needed IS NULL),
  369. paid CHAR
  370. DEFAULT 'n'
  371. CHECK (paid in ('y', 'n')),
  372. qty_ordered INTEGER
  373. DEFAULT 1
  374. NOT NULL
  375. CHECK (qty_ordered >= 1),
  376. total_value DECIMAL(9,2)
  377. NOT NULL
  378. CHECK (total_value >= 0),
  379. discount FLOAT
  380. DEFAULT 0
  381. NOT NULL
  382. CHECK (discount >= 0 AND discount <= 1),
  383. item_type PRODTYPE,
  384. aged COMPUTED BY
  385. (ship_date - order_date),
  386. PRIMARY KEY (po_number),
  387. FOREIGN KEY (cust_no) REFERENCES customer (cust_no),
  388. FOREIGN KEY (sales_rep) REFERENCES employee (emp_no),
  389. CHECK (NOT (order_status = 'shipped' AND ship_date IS NULL)),
  390. CHECK (NOT (order_status = 'shipped' AND
  391. EXISTS (SELECT on_hold FROM customer
  392. WHERE customer.cust_no = sales.cust_no
  393. AND customer.on_hold = '*')))
  394. );
  395. CREATE INDEX needx ON sales (date_needed);
  396. CREATE INDEX salestatx ON sales (order_status, paid);
  397. CREATE DESCENDING INDEX qtyx ON sales (item_type, qty_ordered);
  398. SET TERM !! ;
  399. CREATE TRIGGER post_new_order FOR sales
  400. AFTER INSERT AS
  401. BEGIN
  402. POST_EVENT 'new_order';
  403. END !!
  404. SET TERM ; !!
  405. COMMIT;
  406. /****************************************************************************
  407. *
  408. * Create stored procedures.
  409. *
  410. *****************************************************************************/
  411. SET TERM !! ;
  412. /*
  413. * Get employee's projects.
  414. *
  415. * Parameters:
  416. * employee number
  417. * Returns:
  418. * project id
  419. */
  420. CREATE PROCEDURE get_emp_proj (emp_no SMALLINT)
  421. RETURNS (proj_id CHAR(5)) AS
  422. BEGIN
  423. FOR SELECT proj_id
  424. FROM employee_project
  425. WHERE emp_no = :emp_no
  426. INTO :proj_id
  427. DO
  428. SUSPEND;
  429. END !!
  430. /*
  431. * Add an employee to a project.
  432. *
  433. * Parameters:
  434. * employee number
  435. * project id
  436. * Returns:
  437. * --
  438. */
  439. CREATE EXCEPTION unknown_emp_id 'Invalid employee number or project id.' !!
  440. CREATE PROCEDURE add_emp_proj (emp_no SMALLINT, proj_id CHAR(5)) AS
  441. BEGIN
  442. BEGIN
  443. INSERT INTO employee_project (emp_no, proj_id) VALUES (:emp_no, :proj_id);
  444. WHEN SQLCODE -530 DO
  445. EXCEPTION unknown_emp_id;
  446. END
  447. SUSPEND;
  448. END !!
  449. /*
  450. * Select one row.
  451. *
  452. * Compute total, average, smallest, and largest department budget.
  453. *
  454. * Parameters:
  455. * department id
  456. * Returns:
  457. * total budget
  458. * average budget
  459. * min budget
  460. * max budget
  461. */
  462. CREATE PROCEDURE sub_tot_budget (head_dept CHAR(3))
  463. RETURNS (tot_budget DECIMAL(12, 2), avg_budget DECIMAL(12, 2),
  464. min_budget DECIMAL(12, 2), max_budget DECIMAL(12, 2))
  465. AS
  466. BEGIN
  467. SELECT SUM(budget), AVG(budget), MIN(budget), MAX(budget)
  468. FROM department
  469. WHERE head_dept = :head_dept
  470. INTO :tot_budget, :avg_budget, :min_budget, :max_budget;
  471. SUSPEND;
  472. END !!
  473. /*
  474. * Delete an employee.
  475. *
  476. * Parameters:
  477. * employee number
  478. * Returns:
  479. * --
  480. */
  481. CREATE EXCEPTION reassign_sales
  482. 'Reassign the sales records before deleting this employee.' !!
  483. CREATE PROCEDURE delete_employee (emp_num INTEGER)
  484. AS
  485. DECLARE VARIABLE any_sales INTEGER;
  486. BEGIN
  487. any_sales = 0;
  488. /*
  489. * If there are any sales records referencing this employee,
  490. * can't delete the employee until the sales are re-assigned
  491. * to another employee or changed to NULL.
  492. */
  493. SELECT count(po_number)
  494. FROM sales
  495. WHERE sales_rep = :emp_num
  496. INTO :any_sales;
  497. IF (any_sales > 0) THEN
  498. BEGIN
  499. EXCEPTION reassign_sales;
  500. SUSPEND;
  501. END
  502. /*
  503. * If the employee is a manager, update the department.
  504. */
  505. UPDATE department
  506. SET mngr_no = NULL
  507. WHERE mngr_no = :emp_num;
  508. /*
  509. * If the employee is a project leader, update project.
  510. */
  511. UPDATE project
  512. SET team_leader = NULL
  513. WHERE team_leader = :emp_num;
  514. /*
  515. * Delete the employee from any projects.
  516. */
  517. DELETE FROM employee_project
  518. WHERE emp_no = :emp_num;
  519. /*
  520. * Delete old salary records.
  521. */
  522. DELETE FROM salary_history
  523. WHERE emp_no = :emp_num;
  524. /*
  525. * Delete the employee.
  526. */
  527. DELETE FROM employee
  528. WHERE emp_no = :emp_num;
  529. SUSPEND;
  530. END !!
  531. /*
  532. * Recursive procedure.
  533. *
  534. * Compute the sum of all budgets for a department and all the
  535. * departments under it.
  536. *
  537. * Parameters:
  538. * department id
  539. * Returns:
  540. * total budget
  541. */
  542. CREATE PROCEDURE dept_budget (dno CHAR(3))
  543. RETURNS (tot decimal(12,2)) AS
  544. DECLARE VARIABLE sumb DECIMAL(12, 2);
  545. DECLARE VARIABLE rdno CHAR(3);
  546. DECLARE VARIABLE cnt INTEGER;
  547. BEGIN
  548. tot = 0;
  549. SELECT budget FROM department WHERE dept_no = :dno INTO :tot;
  550. SELECT count(budget) FROM department WHERE head_dept = :dno INTO :cnt;
  551. IF (cnt = 0) THEN
  552. SUSPEND;
  553. FOR SELECT dept_no
  554. FROM department
  555. WHERE head_dept = :dno
  556. INTO :rdno
  557. DO
  558. BEGIN
  559. EXECUTE PROCEDURE dept_budget :rdno RETURNING_VALUES :sumb;
  560. tot = tot + sumb;
  561. END
  562. SUSPEND;
  563. END !!
  564. /*
  565. * Display an org-chart.
  566. *
  567. * Parameters:
  568. * --
  569. * Returns:
  570. * parent department
  571. * department name
  572. * department manager
  573. * manager's job title
  574. * number of employees in the department
  575. */
  576. CREATE PROCEDURE org_chart
  577. RETURNS (head_dept CHAR(25), department CHAR(25),
  578. mngr_name CHAR(20), title CHAR(5), emp_cnt INTEGER)
  579. AS
  580. DECLARE VARIABLE mngr_no INTEGER;
  581. DECLARE VARIABLE dno CHAR(3);
  582. BEGIN
  583. FOR SELECT h.department, d.department, d.mngr_no, d.dept_no
  584. FROM department d
  585. LEFT OUTER JOIN department h ON d.head_dept = h.dept_no
  586. ORDER BY d.dept_no
  587. INTO :head_dept, :department, :mngr_no, :dno
  588. DO
  589. BEGIN
  590. IF (:mngr_no IS NULL) THEN
  591. BEGIN
  592. mngr_name = '--TBH--';
  593. title = '';
  594. END
  595. ELSE
  596. SELECT full_name, job_code
  597. FROM employee
  598. WHERE emp_no = :mngr_no
  599. INTO :mngr_name, :title;
  600. SELECT COUNT(emp_no)
  601. FROM employee
  602. WHERE dept_no = :dno
  603. INTO :emp_cnt;
  604. SUSPEND;
  605. END
  606. END !!
  607. /*
  608. * Generate a 6-line mailing label for a customer.
  609. * Some of the lines may be blank.
  610. *
  611. * Parameters:
  612. * customer number
  613. * Returns:
  614. * 6 address lines
  615. */
  616. CREATE PROCEDURE mail_label (cust_no INTEGER)
  617. RETURNS (line1 CHAR(40), line2 CHAR(40), line3 CHAR(40),
  618. line4 CHAR(40), line5 CHAR(40), line6 CHAR(40))
  619. AS
  620. DECLARE VARIABLE customer VARCHAR(25);
  621. DECLARE VARIABLE first_name VARCHAR(15);
  622. DECLARE VARIABLE last_name VARCHAR(20);
  623. DECLARE VARIABLE addr1 VARCHAR(30);
  624. DECLARE VARIABLE addr2 VARCHAR(30);
  625. DECLARE VARIABLE city VARCHAR(25);
  626. DECLARE VARIABLE state VARCHAR(15);
  627. DECLARE VARIABLE country VARCHAR(15);
  628. DECLARE VARIABLE postcode VARCHAR(12);
  629. DECLARE VARIABLE cnt INTEGER;
  630. BEGIN
  631. line1 = '';
  632. line2 = '';
  633. line3 = '';
  634. line4 = '';
  635. line5 = '';
  636. line6 = '';
  637. SELECT customer, contact_first, contact_last, address_line1,
  638. address_line2, city, state_province, country, postal_code
  639. FROM CUSTOMER
  640. WHERE cust_no = :cust_no
  641. INTO :customer, :first_name, :last_name, :addr1, :addr2,
  642. :city, :state, :country, :postcode;
  643. IF (customer IS NOT NULL) THEN
  644. line1 = customer;
  645. IF (first_name IS NOT NULL) THEN
  646. line2 = first_name || ' ' || last_name;
  647. ELSE
  648. line2 = last_name;
  649. IF (addr1 IS NOT NULL) THEN
  650. line3 = addr1;
  651. IF (addr2 IS NOT NULL) THEN
  652. line4 = addr2;
  653. IF (country = 'USA') THEN
  654. BEGIN
  655. IF (city IS NOT NULL) THEN
  656. line5 = city || ', ' || state || ' ' || postcode;
  657. ELSE
  658. line5 = state || ' ' || postcode;
  659. END
  660. ELSE
  661. BEGIN
  662. IF (city IS NOT NULL) THEN
  663. line5 = city || ', ' || state;
  664. ELSE
  665. line5 = state;
  666. line6 = country || ' ' || postcode;
  667. END
  668. SUSPEND;
  669. END !!
  670. /*
  671. * Ship a sales order.
  672. * First, check if the order is already shipped, if the customer
  673. * is on hold, or if the customer has an overdue balance.
  674. *
  675. * Parameters:
  676. * purchase order number
  677. * Returns:
  678. * --
  679. *
  680. */
  681. CREATE EXCEPTION order_already_shipped 'Order status is "shipped."' !!
  682. CREATE EXCEPTION customer_on_hold 'This customer is on hold.' !!
  683. CREATE EXCEPTION customer_check 'Overdue balance -- can not ship.' !!
  684. CREATE PROCEDURE ship_order (po_num CHAR(8))
  685. AS
  686. DECLARE VARIABLE ord_stat CHAR(7);
  687. DECLARE VARIABLE hold_stat CHAR(1);
  688. DECLARE VARIABLE cust_no INTEGER;
  689. DECLARE VARIABLE any_po CHAR(8);
  690. BEGIN
  691. SELECT s.order_status, c.on_hold, c.cust_no
  692. FROM sales s, customer c
  693. WHERE po_number = :po_num
  694. AND s.cust_no = c.cust_no
  695. INTO :ord_stat, :hold_stat, :cust_no;
  696. /* This purchase order has been already shipped. */
  697. IF (ord_stat = 'shipped') THEN
  698. BEGIN
  699. EXCEPTION order_already_shipped;
  700. SUSPEND;
  701. END
  702. /* Customer is on hold. */
  703. ELSE IF (hold_stat = '*') THEN
  704. BEGIN
  705. EXCEPTION customer_on_hold;
  706. SUSPEND;
  707. END
  708. /*
  709. * If there is an unpaid balance on orders shipped over 2 months ago,
  710. * put the customer on hold.
  711. */
  712. FOR SELECT po_number
  713. FROM sales
  714. WHERE cust_no = :cust_no
  715. AND order_status = 'shipped'
  716. AND paid = 'n'
  717. AND ship_date < CAST('NOW' AS TIMESTAMP) - 60
  718. INTO :any_po
  719. DO
  720. BEGIN
  721. EXCEPTION customer_check;
  722. UPDATE customer
  723. SET on_hold = '*'
  724. WHERE cust_no = :cust_no;
  725. SUSPEND;
  726. END
  727. /*
  728. * Ship the order.
  729. */
  730. UPDATE sales
  731. SET order_status = 'shipped', ship_date = 'NOW'
  732. WHERE po_number = :po_num;
  733. SUSPEND;
  734. END !!
  735. CREATE PROCEDURE show_langs (code VARCHAR(5), grade SMALLINT, cty VARCHAR(15))
  736. RETURNS (languages VARCHAR(15))
  737. AS
  738. DECLARE VARIABLE i INTEGER;
  739. BEGIN
  740. i = 1;
  741. WHILE (i <= 5) DO
  742. BEGIN
  743. SELECT language_req[:i] FROM joB
  744. WHERE ((job_code = :code) AND (job_grade = :grade) AND (job_country = :cty)
  745. AND (language_req IS NOT NULL))
  746. INTO :languages;
  747. IF (languages = ' ') THEN /* Prints 'NULL' instead of blanks */
  748. languages = 'NULL';
  749. i = i +1;
  750. SUSPEND;
  751. END
  752. END!!
  753. CREATE PROCEDURE all_langs RETURNS
  754. (code VARCHAR(5), grade VARCHAR(5),
  755. country VARCHAR(15), LANG VARCHAR(15)) AS
  756. BEGIN
  757. FOR SELECT job_code, job_grade, job_country FROM job
  758. INTO :code, :grade, :country
  759. DO
  760. BEGIN
  761. FOR SELECT languages FROM show_langs
  762. (:code, :grade, :country) INTO :lang DO
  763. SUSPEND;
  764. /* Put nice separators between rows */
  765. code = '=====';
  766. grade = '=====';
  767. country = '===============';
  768. lang = '==============';
  769. SUSPEND;
  770. END
  771. END!!
  772. SET TERM ; !!
  773. /* Privileges */
  774. GRANT ALL PRIVILEGES ON country TO PUBLIC WITH GRANT OPTION;
  775. GRANT ALL PRIVILEGES ON job TO PUBLIC WITH GRANT OPTION;
  776. GRANT ALL PRIVILEGES ON department TO PUBLIC WITH GRANT OPTION;
  777. GRANT ALL PRIVILEGES ON employee TO PUBLIC WITH GRANT OPTION;
  778. GRANT ALL PRIVILEGES ON phone_list TO PUBLIC WITH GRANT OPTION;
  779. GRANT ALL PRIVILEGES ON project TO PUBLIC WITH GRANT OPTION;
  780. GRANT ALL PRIVILEGES ON employee_project TO PUBLIC WITH GRANT OPTION;
  781. GRANT ALL PRIVILEGES ON proj_dept_budget TO PUBLIC WITH GRANT OPTION;
  782. GRANT ALL PRIVILEGES ON salary_history TO PUBLIC WITH GRANT OPTION;
  783. GRANT ALL PRIVILEGES ON customer TO PUBLIC WITH GRANT OPTION;
  784. GRANT ALL PRIVILEGES ON sales TO PUBLIC WITH GRANT OPTION;
  785. GRANT EXECUTE ON PROCEDURE get_emp_proj TO PUBLIC WITH GRANT OPTION;
  786. GRANT EXECUTE ON PROCEDURE add_emp_proj TO PUBLIC WITH GRANT OPTION;
  787. GRANT EXECUTE ON PROCEDURE sub_tot_budget TO PUBLIC WITH GRANT OPTION;
  788. GRANT EXECUTE ON PROCEDURE delete_employee TO PUBLIC WITH GRANT OPTION;
  789. GRANT EXECUTE ON PROCEDURE dept_budget TO PUBLIC WITH GRANT OPTION;
  790. GRANT EXECUTE ON PROCEDURE org_chart TO PUBLIC WITH GRANT OPTION;
  791. GRANT EXECUTE ON PROCEDURE mail_label TO PUBLIC WITH GRANT OPTION;
  792. GRANT EXECUTE ON PROCEDURE ship_order TO PUBLIC WITH GRANT OPTION;
  793. GRANT EXECUTE ON PROCEDURE show_langs TO PUBLIC WITH GRANT OPTION;
  794. GRANT EXECUTE ON PROCEDURE all_langs TO PUBLIC WITH GRANT OPTION;