intlddl.sql 25 KB

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