GitBucket
4.21.2
Toggle navigation
Snippets
Sign in
Files
Branches
1
Releases
Issues
Pull requests
Labels
Priorities
Milestones
Wiki
Forks
nigel.stanger
/
sqlmarker
Browse code
• Fixed reference to TOAD.
• Added note about SET DEFINE OFF. • Changed all Comments columns to CLOB.
master
1 parent
27c44d5
commit
b7cdf5f3751461f090f184abc2721bbb8d6f47e1
Nigel Stanger
authored
on 27 May 2016
Patch
Showing
2 changed files
BDL/BDL.xml
BDL/BDL_schema.sql
Ignore Space
Show notes
View
BDL/BDL.xml
<?xml version="1.0" standalone="yes"?> <document class="fragment"> <section label="sec:database-info"> <title>System specification and details</title> <p>Better Digital, Ltd. (BDL) is a large U.S.<space />company that produces a wide range of consumer electronics devices such as radios, stereo components, digital clocks, universal remotes, etc., which they sell in bulk to various retailers. The company has branches in several major U.S. cities, and employs about <number>9000</number> staff across six departments: Central Management, Sales <ampersand/> Marketing, Personnel, Manufacturing, Inventory, and Accounts.</p> <p>BDL are currently designing and implementing a new corporate database to be located at the company headquarters in Los Angeles. The requirements analysis phase of the project is complete, and you’ve been brought in as a lead database developer. It’ll be your task to implement an initial prototype of the specification resulting from the requirements analysis phase. An ERD of the proposed database is shown in <hyperlink label="fig-erd"><reference label="fig-erd"/></hyperlink>, and more detailed specifications of the database requirements may be found in the following sections.</p> <figure label="fig-erd" latex-placement="!htb"> <caption>ERD of Better Digital’s database (Information Engineering notation)</caption> <image basename="BDL_IE" location="images" latex-options="width=0.9\columnwidth,keepaspectratio"> <description>ERD of Better Digital’s database (Information Engineering notation)</description> </image> </figure> <section> <title>The <tt>Staff</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Staff_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Surname</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Firstnames</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 150 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Department</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Position</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Monetary, <dollar-sign/><number>1000.00</number><endash/><dollar-sign/><number>99999.99</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>As noted above, BDL has about <number>9000</number> employees. The usual details such as name, address, and phone number will be recorded. The phone number must cater for both (U.S.) landline and mobile numbers.</item> <item>There are six possible departments, as follows: <quote>Central Management</quote>, <quote>Sales <ampersand /> Marketing</quote>, <quote>Personnel</quote>, <quote>Manufacturing</quote>, <quote>Inventory</quote>, and <quote>Accounts</quote>.</item> <item>There are twenty possible employee positions, as follows: <quote>CEO</quote>, <quote>CTO</quote>, <quote>CFO</quote>, <quote>CIO</quote>, <quote>Director</quote>, <quote>President</quote>, <quote>Vice-President</quote>, <quote>Manager</quote>, <quote>Personal Assistant</quote>, <quote>Secretary</quote>, <quote>Technician</quote>, <quote>Researcher</quote>, <quote>Designer</quote>, <quote>Assembler</quote>, <quote>Programmer</quote>, <quote>Contractor</quote>, <quote>Sales Representative</quote>, <quote>Accountant</quote>, <quote>Inventory</quote>, and <quote>Assistant</quote>.</item> <item>Salary values are monthly, and are in U.S.<space /> dollars.</item> </itemised-list> <answer> <code-block> CREATE TABLE Staff ( Staff_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Firstnames VARCHAR2(50) NOT NULL, Phone VARCHAR2(11) NOT NULL, Address VARCHAR2(150) NOT NULL, Department VARCHAR2(18) NOT NULL CONSTRAINT Staff_Department_Invalid CHECK ( Department IN ( 'Central Management', 'Personnel', 'Sales ' || CHR(38) || ' Marketing', 'Manufacturing', 'Inventory', 'Accounts' ) ), Position VARCHAR2(20) NOT NULL CONSTRAINT Staff_POSITION_INVALID CHECK ( Position IN ( 'CEO', 'CTO', 'CFO', 'CIO', 'Director', 'President', 'Vice-President', 'Manager', 'Personal Assistant', 'Secretary', 'Technician', 'Researcher', 'Designer', 'Assembler', 'Programmer', 'Contractor', 'Sales Representative', 'Accountant', 'Inventory', 'Assistant' ) ), Salary NUMBER(7,2) NOT NULL CONSTRAINT Staff_Salary_Range_Invalid CHECK ( Salary BETWEEN 1000 AND 99999.99 ), Comments CLOB, -- CONSTRAINT STAFF_PK PRIMARY KEY ( Staff_ID ) ); </code-block> <p indent="no">The most commmon errors here were either renaming some of the columns, or misspelling the values in the <code>Department</code> and <code>Position</code><space /><code>CHECK</code> constraints. Note the use of the <code>CHR</code> function in “Sales <ampersand /> Marketing” to avoid the issue with ampersand (<ampersand />) characters in SQL Developer. (Alternatively, use <code>SET ESCAPE '\';</code> and change the value to <tt>'Sales <backslash /><ampersand /> Marketing'</tt>; or <code>SET DEFINE OFF;</code> and just use “<ampersand />” directly.) Remember also that <code>BETWEEN</code> is inclusive of the two endpoint values, so the upper value for <code>Salary</code> should be 99999.99, not 100000.</p> </answer> </section> <section label="sec:customer"> <title>The <tt>Customer</tt> entity</title> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Customer</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Customer_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Name</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Person</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="medium"/> <p indent="no">BDL’s customers are retail outlets of various sizes. BDL currently has about <number>400000</number> customers on its books, increasing by about <number>10000</number> per year. The usual details will be recorded for each customer: name, address, phone, and optionally the name of a contact person and an email address. The phone number must cater for full international numbers, as many of BDL’s customers are based outside the U.S.</p> <answer> <code-block> CREATE TABLE Customer ( Customer_ID NUMBER(7), Name VARCHAR2(50) NOT NULL, Contact_Person VARCHAR2(50), Phone VARCHAR2(12) NOT NULL, Address VARCHAR2(200) NOT NULL, Email VARCHAR2(50), Comments CLOB, -- CONSTRAINT Customer_PK PRIMARY KEY ( Customer_ID ) ); </code-block> <p indent="no">The most commmon errors here were again renaming some of the columns, or using far too small a size for the <code>Comments</code> column. 150 characters is about the same as a text message, which doesn’t provide a lot of space for meaningful comments! This is one case where it actually does make sense to just set the length to the maximum possible value (4000 for a <code>VARCHAR2</code>), or just use a <code>CLOB</code>, which for the purposes of this system has effectively infinite length.</p> <p>Phone numbers were another trap. A normal American phone number is ten digits, but since BDL’s customers are actually companies, not people, some may have 800 toll-free numbers, which are always prefixed by “1” for long-distance (like “0” for toll calls in New Zealand), i.e., 1 800 xxx xxx xxxx. So eleven digits is really the minimum size here. (If you’re interested, look up the “North American Numbering Plan” in Wikipedia.)</p> </answer> </section> <section label="sec:supplier"> <title>The <tt>Supplier</tt> entity</title> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Supplier</tt></cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Supplier_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Name</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Person</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see description for <code>Customer</code> entity)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="medium"/> <p indent="no">BDL orders components from a small group (currently thirty-three) of trusted suppliers. Many of these suppliers overlap in the components that they supply, thus enabling BDL to take advantage of special deals, and providing alternative sources for components. BDL normally buys components from the supplier offering the best deal at the time of ordering (pricing data won’t be stored in the database because they change too frequently). The details to be recorded for suppliers are identical to those for customers.</p> <answer> <code-block> CREATE TABLE Supplier ( Supplier_ID NUMBER(7), Name VARCHAR2(50) NOT NULL, Contact_Person VARCHAR2(50), Phone VARCHAR2(12) NOT NULL, Address VARCHAR2(200) NOT NULL, Email VARCHAR2(50), Comments CLOB, -- CONSTRAINT Supplier_PK PRIMARY KEY ( Supplier_ID ) ); </code-block> <p indent="no">This table is essentially identical to Customer, so the same errors tended to apply. Phone numbers are slightly trickier here, because they can be full international numbers. The International Telecommunications Union (ITU) set standards for telecommunications, including phone numbers. They specify the maximum length of a full international phone number to be fifteen digits, including country code, area code and local number (where applicable). An optional “+” can be added at the front, making a total of up to 16 characters However, this doesn’t mean that all international phone numbers are fifteen digits long! New Zealand phone numbers, for example, are between ten and twelve digits depending on whether it’s a landline or a mobile. Twelve digits is probably a reasonable minimum size for the <code>Phone</code> column.</p> </answer> </section> <section> <title>The <tt>Product</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Product_Code</code></cell> <cell>Internally generated 8 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Stock_Count</code></cell> <cell>Number of units in stock, 0<endash/><number>99999</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Restock_Level</code></cell> <cell>Number of units to restock to, 0<endash/><number>99999</number> (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Minimum_Level</code></cell> <cell>Threshold at which restocking occurs (see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>List_Price</code></cell> <cell>Monetary, <dollar-sign/>0.00<endash/><dollar-sign/><number>99999.99</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Assembly_Manual</code></cell> <cell>Assembly instructions in PDF format</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Assembly_Program</code></cell> <cell>Compiled Java class for assembly line</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>BDL currently manufactures <number>16492</number> different products, which are assembled from various components (resistors, capacitors, controller chips, power supplies, cases, etc.). BDL can manufacture products on demand in response to a sale, but they also produce an ongoing supply of the most popular products. These are stored in a warehouse and used to fulfil sales.</item> <item>Popular products have a <quote>restock</quote> and a <quote>minimum</quote> stock level. If the stock count for a product falls below the minimum level, the inventory management application automatically raises an alert to Inventory staff, who then request Manufacturing to make more of the product. Manufacturing then produce enough units to bring the number in stock back up to at least the restock level (the smallest possible production run is fifty units). The minimum level must therefore be smaller than the restock level; it may be zero.</item> <item>The database will contain the assembly instructions for each product, where applicable. The <code>Assembly_Manual</code> column will contain a PDF detailing the assembly procedure for each product in human-readable form. These PDFs will average about 150<thin-space />kB each. The <code>Assembly_Program</code> column will contain a compiled Java class file that can be downloaded from the database and used to control one of BDL’s fifty automated assembly lines. These files will average about 50<thin-space />kB each.</item> <item>Prices are in U.S.<space />dollars.</item> </itemised-list> <answer> <code-block> CREATE TABLE Product ( Product_Code NUMBER(8), Description VARCHAR2(50) NOT NULL, Stock_Count NUMBER(5) NOT NULL CONSTRAINT Product_Stock_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 99999 ), Restock_Level NUMBER(5) CONSTRAINT Product_Restock_Level_Too_Low CHECK ( Restock_Level BETWEEN 0 AND 99999 ), Minimum_Level NUMBER(5), List_Price NUMBER(7,2) NOT NULL CONSTRAINT Product_List_Price_Too_Low CHECK ( List_Price BETWEEN 0 AND 99999.99 ), Assembly_Manual BLOB, Assembly_Program BLOB, -- CONSTRAINT Product_Min_Level_Invalid CHECK ( ( Minimum_Level >= 0 ) AND ( Minimum_Level < Restock_Level ) ), -- CONSTRAINT Product_PK PRIMARY KEY ( Product_Code ) ); </code-block> <p indent="no">The most common error here was simply not including range constraints for the various stock count columns. In particular, many people only checked the maximum value and didn’t bother check that they were zero or more.</p> </answer> </section> <section> <title>The <tt>Component</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Component_Code</code></cell> <cell>Internally generated 8 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Suppliers_Code</code></cell> <cell>Up to 25 character identifier provided by supplier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Stock_Count</code></cell> <cell>Number of units in stock, 0<endash/><number>9999999</number></cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>Components are ordered from suppliers and used to assemble products. BDL currently uses about <number>120000</number> different components. While BDL always has some components in stock, it usually works on a <quote>just-in-time</quote> ordering system, where components are ordered shortly before they are actually required. This means that there will be frequent small orders to suppliers for components.</item> <item>The same component may be used in many different products, and multiple times in the same product.</item> <item>The same component is often provided by more than one supplier. For example, <quote>35 ohm resistor</quote> might be available from thirteen different suppliers, at varying prices (pricing data won’t be stored in the database because they change too frequently). Although it leads to duplication of component descriptions, BDL have decided for practical reasons to individually store details of each component from each supplier (so the <quote>35 ohm resistor</quote> above would appear thirteen times).</item> <item>Since BDL has no control over how suppliers identify their components, different suppliers may sometimes use the same component codes for different components. For example, Western Electronics may use the code <quote>BC882719</quote> for 35 ohm resistors, whereas Eastern Electrical Supplies may use the same code for large red LEDs.</item> </itemised-list> <answer> <code-block> CREATE TABLE Component ( Component_Code NUMBER(8), Suppliers_Code VARCHAR2(25), Description VARCHAR2(100) NOT NULL, Stock_Count NUMBER(7) NOT NULL CONSTRAINT Component_Stk_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 9999999 ), Supplier_ID NUMBER(7) NOT NULL, -- CONSTRAINT Component_PK PRIMARY KEY ( Component_Code ), -- CONSTRAINT Component_FK_To_Supplier FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); </code-block> </answer> </section> <section label="sec:assembly"> <title>The <tt>Assembly</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Quantity</code></cell> <cell>Number of units used of this component, 2–<number>9999</number></cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <paragraph indent="no">Each product can be made from at least two up to hundreds of distinct components. Some components (e.g., transistors or LEDs) occur many times in the same product.</paragraph> <answer> <code-block> CREATE TABLE Assembly ( Product_Code NUMBER(8), Component_Code NUMBER(8), Quantity NUMBER(4) NOT NULL CONSTRAINT Assembly_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- CONSTRAINT Assembly_PK PRIMARY KEY ( Product_Code, Component_Code ), -- CONSTRAINT Assembly_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, CONSTRAINT Assembly_FK_To_Component FOREIGN KEY ( Component_Code ) REFERENCES Component ); </code-block> <p indent="no">It doesn’t make sense to allow zero as a value of <code>Quantity</code>; if there are none of a particular component in a product, then you wouldn’t add an entry to this table anyway!</p> </answer> </section> <section label="sec:sales"> <title>The <tt>Sale<underscore />head</tt> and <tt>Sale<underscore />line</tt> entities</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Sale<underscore />head</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Sale_Num</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Sale_Date</code></cell> <cell>Date and time of sale (cannot be in future)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Status</code></cell> <cell>Current status of sale (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule /> </tabular-body> </tabular> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Sale<underscore />line</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Quantity</code></cell> <cell>Number of units of a product sold, up to <number>9999</number></cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Actual_Price</code></cell> <cell>Unit sale price, <dollar-sign/>0.00<endash/><dollar-sign/><number>99999.99</number></cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>On a typical working day, BDL makes about seven thousand sales. Each sale is typically for some quantity (possibly several thousand) of each of about seven to ten different products. For example, a customer might buy twenty-three remote garage door openers and two burglar alarm systems in the same sale.</item> <item>Products may sell for a different (usually lower) price from that listed (e.g., bulk discounts, cash payments, etc.). Prices are in U.S.<space /> dollars.</item> <item>The status of a sale must be one of the following: <quote>pending</quote>, <quote>in progress</quote>, <quote>cancelled</quote>, <quote>backordered</quote> or <quote>shipped</quote>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Sale_Head ( Sale_Num NUMBER(10), Sale_Date DATE NOT NULL, Status VARCHAR2(11) NOT NULL CONSTRAINT Sale_Head_Status_Invalid CHECK ( Status IN ( 'pending', 'in progress', 'cancelled', 'backordered', 'shipped' ) ), Staff_ID NUMBER(7) NOT NULL, Customer_ID NUMBER(7) NOT NULL, Comments CLOB, -- CONSTRAINT Sale_Head_PK PRIMARY KEY ( Sale_Num ), -- CONSTRAINT Sale_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, CONSTRAINT Sale_Head_FK_To_Customer FOREIGN KEY ( Customer_ID ) REFERENCES Customer ); CREATE TABLE Sale_Line ( Sale_Num NUMBER(10), Product_Code NUMBER(8), Quantity NUMBER(6) NOT NULL CONSTRAINT Sale_Line_Quantity_Too_Low CHECK ( Quantity > 0 ), Actual_Price NUMBER(7,2) NOT NULL CONSTRAINT Sale_Line_Act_Price_Too_Low CHECK ( Actual_Price BETWEEN 0 AND 99999.99 ), -- CONSTRAINT Sale_Line_PK PRIMARY KEY ( Sale_Num, Product_Code ), -- CONSTRAINT Sale_Line_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, CONSTRAINT Sale_Line_FK_To_Sale_Hd FOREIGN KEY ( Sale_Num ) REFERENCES Sale_Head ); </code-block> <p indent="no">It was great to see people using the workaround for checking the <code>Sale_Date</code> isn’t in the future. However, it was very frustrating to also see of them not bothering to explain it! We were quite happy to accept an extra column to store the sale entry date, as long as there was an explanation of why it was being added. (Note that the code above doesn’t include this to save space.)</p> <p>Once again it doesn’t really make sense for <code>Quantity</code> in <code>Sale_Line</code> to be zero (although it does make sense for <code>Actual_Price</code>).</p> </answer> </section> <section label="sec:orders"> <title>The <tt>Order<underscore />head</tt> and <tt>Order<underscore />line</tt> entities</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Order<underscore />head</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Order_Num</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Order_Date</code></cell> <cell>Date and time of order (cannot be in future)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Due_Date</code></cell> <cell>Date that final shipment is due (after <code>Order_Date</code>)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Date_Completed</code></cell> <cell>Date that final shipment is received (after <code>Order_Date</code>)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Status</code></cell> <cell>Current status of order (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule /> </tabular-body> </tabular> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Order<underscore />line</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Qty_Ordered</code></cell> <cell>Number units of a component ordered, up to <number>99999</number></cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Price</code></cell> <cell>Unit price (see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Qty_Received</code></cell> <cell>Number of components received (see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>BDL places an average of about 320 orders to suppliers per working day. Each order is typically for some quantity (possibly tens of thousands) of each of about fifteen to twenty different components.</item> <item>While component pricing data won’t be stored in the database, the unit prices paid for components must still be recorded on the order. Prices are in the range <dollar-sign/>0.00<endash/><dollar-sign/><number>9999.99</number>, and are in U.S.<space /> dollars.</item> <item>Components arrive in shipments from a supplier, which may or may not correspond to the original order (for example, a single shipment might include components from several different orders to that supplier). When a shipment arrives, the Inventory staff need to note on the original order how many of each component they have received, so that they can determine when the order is complete. An order is complete when the number of components received is at least equal to the number of components ordered. This will also enable them to tell when they have received more components than they originally ordered.</item> <item>The status of an order must be one of the following: <quote>in progress</quote> or <quote>complete</quote>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Order_Head ( Order_Num NUMBER(10), Order_Date DATE NOT NULL, Due_Date DATE NOT NULL, Date_Completed DATE, Status VARCHAR2(11) NOT NULL CONSTRAINT Order_Head_Status_Invalid CHECK ( Status IN ( 'complete', 'in progress' ) ), Staff_ID NUMBER(7) NOT NULL, Supplier_ID NUMBER(7) NOT NULL, Comments CLOB, -- CONSTRAINT Order_Head_Due_Date_Invalid CHECK ( Due_Date > Order_Date ), -- CONSTRAINT Order_Head_PK PRIMARY KEY ( Order_Num ), -- CONSTRAINT Order_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, CONSTRAINT Order_Head_FK_To_Supp FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); CREATE TABLE Order_Line ( Order_Num NUMBER(10), Component_Code NUMBER(8), Qty_Ordered NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Ord_Too_Low CHECK ( Qty_Ordered BETWEEN 0 AND 99999 ), Price NUMBER(6,2) NOT NULL CONSTRAINT Order_Line_Price_Too_Low CHECK ( Price BETWEEN 0 AND 9999.99 ), Qty_Received NUMBER(6) NOT NULL, -- CONSTRAINT Order_Line_PK PRIMARY KEY ( Order_Num, Component_Code ), -- CONSTRAINT Order_Line_FK_To_Comp FOREIGN KEY ( Component_Code ) REFERENCES Component, CONSTRAINT Order_Line_FK_To_Ord_Hd FOREIGN KEY ( Order_Num ) REFERENCES Order_Head ); </code-block> </answer> </section> </section> </document>
<?xml version="1.0" standalone="yes"?> <document class="fragment"> <section label="sec:database-info"> <title>System specification and details</title> <p>Better Digital, Ltd. (BDL) is a large U.S.<space />company that produces a wide range of consumer electronics devices such as radios, stereo components, digital clocks, universal remotes, etc., which they sell in bulk to various retailers. The company has branches in several major U.S. cities, and employs about <number>9000</number> staff across six departments: Central Management, Sales <ampersand/> Marketing, Personnel, Manufacturing, Inventory, and Accounts.</p> <p>BDL are currently designing and implementing a new corporate database to be located at the company headquarters in Los Angeles. The requirements analysis phase of the project is complete, and you’ve been brought in as a lead database developer. It’ll be your task to implement an initial prototype of the specification resulting from the requirements analysis phase. An ERD of the proposed database is shown in <hyperlink label="fig-erd"><reference label="fig-erd"/></hyperlink>, and more detailed specifications of the database requirements may be found in the following sections.</p> <figure label="fig-erd" latex-placement="!htb"> <caption>ERD of Better Digital’s database (Information Engineering notation)</caption> <image basename="BDL_IE" location="images" latex-options="width=0.9\columnwidth,keepaspectratio"> <description>ERD of Better Digital’s database (Information Engineering notation)</description> </image> </figure> <section> <title>The <tt>Staff</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Staff_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Surname</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Firstnames</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 150 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Department</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Position</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Monetary, <dollar-sign/><number>1000.00</number><endash/><dollar-sign/><number>99999.99</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>As noted above, BDL has about <number>9000</number> employees. The usual details such as name, address, and phone number will be recorded. The phone number must cater for both (U.S.) landline and mobile numbers.</item> <item>There are six possible departments, as follows: <quote>Central Management</quote>, <quote>Sales <ampersand /> Marketing</quote>, <quote>Personnel</quote>, <quote>Manufacturing</quote>, <quote>Inventory</quote>, and <quote>Accounts</quote>.</item> <item>There are twenty possible employee positions, as follows: <quote>CEO</quote>, <quote>CTO</quote>, <quote>CFO</quote>, <quote>CIO</quote>, <quote>Director</quote>, <quote>President</quote>, <quote>Vice-President</quote>, <quote>Manager</quote>, <quote>Personal Assistant</quote>, <quote>Secretary</quote>, <quote>Technician</quote>, <quote>Researcher</quote>, <quote>Designer</quote>, <quote>Assembler</quote>, <quote>Programmer</quote>, <quote>Contractor</quote>, <quote>Sales Representative</quote>, <quote>Accountant</quote>, <quote>Inventory</quote>, and <quote>Assistant</quote>.</item> <item>Salary values are monthly, and are in U.S.<space /> dollars.</item> </itemised-list> <answer> <code-block> CREATE TABLE Staff ( Staff_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Firstnames VARCHAR2(50) NOT NULL, Phone VARCHAR2(11) NOT NULL, Address VARCHAR2(150) NOT NULL, Department VARCHAR2(18) NOT NULL CONSTRAINT Staff_Department_Invalid CHECK ( Department IN ( 'Central Management', 'Personnel', 'Sales ' || CHR(38) || ' Marketing', 'Manufacturing', 'Inventory', 'Accounts' ) ), Position VARCHAR2(20) NOT NULL CONSTRAINT Staff_POSITION_INVALID CHECK ( Position IN ( 'CEO', 'CTO', 'CFO', 'CIO', 'Director', 'President', 'Vice-President', 'Manager', 'Personal Assistant', 'Secretary', 'Technician', 'Researcher', 'Designer', 'Assembler', 'Programmer', 'Contractor', 'Sales Representative', 'Accountant', 'Inventory', 'Assistant' ) ), Salary NUMBER(7,2) NOT NULL CONSTRAINT Staff_Salary_Range_Invalid CHECK ( Salary BETWEEN 1000 AND 99999.99 ), Comments VARCHAR2(4000), -- CONSTRAINT STAFF_PK PRIMARY KEY ( Staff_ID ) ); </code-block> <p indent="no">The most commmon errors here were either renaming some of the columns, or misspelling the values in the <code>Department</code> and <code>Position</code><space /><code>CHECK</code> constraints. Note the use of the <code>CHR</code> function in “Sales <ampersand /> Marketing” to avoid the issue with ampersand (<ampersand />) characters in TOAD. (Alternatively, use <code>SET ESCAPE '\';</code> and change the value to <tt>'Sales <backslash /><ampersand /> Marketing'</tt>.) Remember also that <code>BETWEEN</code> is inclusive of the two endpoint values, so the upper value for <code>Salary</code> should be 99999.99, not 100000.</p> </answer> </section> <section label="sec:customer"> <title>The <tt>Customer</tt> entity</title> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Customer</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Customer_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Name</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Person</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="medium"/> <p indent="no">BDL’s customers are retail outlets of various sizes. BDL currently has about <number>400000</number> customers on its books, increasing by about <number>10000</number> per year. The usual details will be recorded for each customer: name, address, phone, and optionally the name of a contact person and an email address. The phone number must cater for full international numbers, as many of BDL’s customers are based outside the U.S.</p> <answer> <code-block> CREATE TABLE Customer ( Customer_ID NUMBER(7), Name VARCHAR2(50) NOT NULL, Contact_Person VARCHAR2(50), Phone VARCHAR2(12) NOT NULL, Address VARCHAR2(200) NOT NULL, Email VARCHAR2(50), Comments VARCHAR2(4000), -- CONSTRAINT Customer_PK PRIMARY KEY ( Customer_ID ) ); </code-block> <p indent="no">The most commmon errors here were again renaming some of the columns, or using far too small a size for the <code>Comments</code> column. 150 characters is about the same as a text message, which doesn’t provide a lot of space for meaningful comments! This is one case where it actually does make sense to just set the length to the maximum possible value (4000 for a <code>VARCHAR2</code>), or just use a <code>CLOB</code>, which for the purposes of this system has effectively infinite length.</p> <p>Phone numbers were another trap. A normal American phone number is ten digits, but since BDL’s customers are actually companies, not people, some may have 800 toll-free numbers, which are always prefixed by “1” for long-distance (like “0” for toll calls in New Zealand), i.e., 1 800 xxx xxx xxxx. So eleven digits is really the minimum size here. (If you’re interested, look up the “North American Numbering Plan” in Wikipedia.)</p> </answer> </section> <section label="sec:supplier"> <title>The <tt>Supplier</tt> entity</title> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Supplier</tt></cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Supplier_ID</code></cell> <cell>Internally generated 7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Name</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Person</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Phone</code></cell> <cell>(see description for <code>Customer</code> entity)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="medium"/> <p indent="no">BDL orders components from a small group (currently thirty-three) of trusted suppliers. Many of these suppliers overlap in the components that they supply, thus enabling BDL to take advantage of special deals, and providing alternative sources for components. BDL normally buys components from the supplier offering the best deal at the time of ordering (pricing data won’t be stored in the database because they change too frequently). The details to be recorded for suppliers are identical to those for customers.</p> <answer> <code-block> CREATE TABLE Supplier ( Supplier_ID NUMBER(7), Name VARCHAR2(50) NOT NULL, Contact_Person VARCHAR2(50), Phone VARCHAR2(12) NOT NULL, Address VARCHAR2(200) NOT NULL, Email VARCHAR2(50), Comments VARCHAR2(4000), -- CONSTRAINT Supplier_PK PRIMARY KEY ( Supplier_ID ) ); </code-block> <p indent="no">This table is essentially identical to Customer, so the same errors tended to apply. Phone numbers are slightly trickier here, because they can be full international numbers. The International Telecommunications Union (ITU) set standards for telecommunications, including phone numbers. They specify the maximum length of a full international phone number to be fifteen digits, including country code, area code and local number (where applicable). An optional “+” can be added at the front, making a total of up to 16 characters However, this doesn’t mean that all international phone numbers are fifteen digits long! New Zealand phone numbers, for example, are between ten and twelve digits depending on whether it’s a landline or a mobile. Twelve digits is probably a reasonable minimum size for the <code>Phone</code> column.</p> </answer> </section> <section> <title>The <tt>Product</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Product_Code</code></cell> <cell>Internally generated 8 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Stock_Count</code></cell> <cell>Number of units in stock, 0<endash/><number>99999</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Restock_Level</code></cell> <cell>Number of units to restock to, 0<endash/><number>99999</number> (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Minimum_Level</code></cell> <cell>Threshold at which restocking occurs (see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>List_Price</code></cell> <cell>Monetary, <dollar-sign/>0.00<endash/><dollar-sign/><number>99999.99</number></cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Assembly_Manual</code></cell> <cell>Assembly instructions in PDF format</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Assembly_Program</code></cell> <cell>Compiled Java class for assembly line</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>BDL currently manufactures <number>16492</number> different products, which are assembled from various components (resistors, capacitors, controller chips, power supplies, cases, etc.). BDL can manufacture products on demand in response to a sale, but they also produce an ongoing supply of the most popular products. These are stored in a warehouse and used to fulfil sales.</item> <item>Popular products have a <quote>restock</quote> and a <quote>minimum</quote> stock level. If the stock count for a product falls below the minimum level, the inventory management application automatically raises an alert to Inventory staff, who then request Manufacturing to make more of the product. Manufacturing then produce enough units to bring the number in stock back up to at least the restock level (the smallest possible production run is fifty units). The minimum level must therefore be smaller than the restock level; it may be zero.</item> <item>The database will contain the assembly instructions for each product, where applicable. The <code>Assembly_Manual</code> column will contain a PDF detailing the assembly procedure for each product in human-readable form. These PDFs will average about 150<thin-space />kB each. The <code>Assembly_Program</code> column will contain a compiled Java class file that can be downloaded from the database and used to control one of BDL’s fifty automated assembly lines. These files will average about 50<thin-space />kB each.</item> <item>Prices are in U.S.<space />dollars.</item> </itemised-list> <answer> <code-block> CREATE TABLE Product ( Product_Code NUMBER(8), Description VARCHAR2(50) NOT NULL, Stock_Count NUMBER(5) NOT NULL CONSTRAINT Product_Stock_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 99999 ), Restock_Level NUMBER(5) CONSTRAINT Product_Restock_Level_Too_Low CHECK ( Restock_Level BETWEEN 0 AND 99999 ), Minimum_Level NUMBER(5), List_Price NUMBER(7,2) NOT NULL CONSTRAINT Product_List_Price_Too_Low CHECK ( List_Price BETWEEN 0 AND 99999.99 ), Assembly_Manual BLOB, Assembly_Program BLOB, -- CONSTRAINT Product_Min_Level_Invalid CHECK ( ( Minimum_Level >= 0 ) AND ( Minimum_Level < Restock_Level ) ), -- CONSTRAINT Product_PK PRIMARY KEY ( Product_Code ) ); </code-block> <p indent="no">The most common error here was simply not including range constraints for the various stock count columns. In particular, many people only checked the maximum value and didn’t bother check that they were zero or more.</p> </answer> </section> <section> <title>The <tt>Component</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule/> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule/> <row> <cell><tt><hash/></tt></cell> <cell><code>Component_Code</code></cell> <cell>Internally generated 8 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Suppliers_Code</code></cell> <cell>Up to 25 character identifier provided by supplier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Stock_Count</code></cell> <cell>Number of units in stock, 0<endash/><number>9999999</number></cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>Components are ordered from suppliers and used to assemble products. BDL currently uses about <number>120000</number> different components. While BDL always has some components in stock, it usually works on a <quote>just-in-time</quote> ordering system, where components are ordered shortly before they are actually required. This means that there will be frequent small orders to suppliers for components.</item> <item>The same component may be used in many different products, and multiple times in the same product.</item> <item>The same component is often provided by more than one supplier. For example, <quote>35 ohm resistor</quote> might be available from thirteen different suppliers, at varying prices (pricing data won’t be stored in the database because they change too frequently). Although it leads to duplication of component descriptions, BDL have decided for practical reasons to individually store details of each component from each supplier (so the <quote>35 ohm resistor</quote> above would appear thirteen times).</item> <item>Since BDL has no control over how suppliers identify their components, different suppliers may sometimes use the same component codes for different components. For example, Western Electronics may use the code <quote>BC882719</quote> for 35 ohm resistors, whereas Eastern Electrical Supplies may use the same code for large red LEDs.</item> </itemised-list> <answer> <code-block> CREATE TABLE Component ( Component_Code NUMBER(8), Suppliers_Code VARCHAR2(25), Description VARCHAR2(100) NOT NULL, Stock_Count NUMBER(7) NOT NULL CONSTRAINT Component_Stk_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 9999999 ), Supplier_ID NUMBER(7) NOT NULL, -- CONSTRAINT Component_PK PRIMARY KEY ( Component_Code ), -- CONSTRAINT Component_FK_To_Supplier FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); </code-block> </answer> </section> <section label="sec:assembly"> <title>The <tt>Assembly</tt> entity</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Quantity</code></cell> <cell>Number of units used of this component, 2–<number>9999</number></cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <paragraph indent="no">Each product can be made from at least two up to hundreds of distinct components. Some components (e.g., transistors or LEDs) occur many times in the same product.</paragraph> <answer> <code-block> CREATE TABLE Assembly ( Product_Code NUMBER(8), Component_Code NUMBER(8), Quantity NUMBER(4) NOT NULL CONSTRAINT Assembly_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- CONSTRAINT Assembly_PK PRIMARY KEY ( Product_Code, Component_Code ), -- CONSTRAINT Assembly_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, CONSTRAINT Assembly_FK_To_Component FOREIGN KEY ( Component_Code ) REFERENCES Component ); </code-block> <p indent="no">It doesn’t make sense to allow zero as a value of <code>Quantity</code>; if there are none of a particular component in a product, then you wouldn’t add an entry to this table anyway!</p> </answer> </section> <section label="sec:sales"> <title>The <tt>Sale<underscore />head</tt> and <tt>Sale<underscore />line</tt> entities</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Sale<underscore />head</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Sale_Num</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Sale_Date</code></cell> <cell>Date and time of sale (cannot be in future)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Status</code></cell> <cell>Current status of sale (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule /> </tabular-body> </tabular> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Sale<underscore />line</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Quantity</code></cell> <cell>Number of units of a product sold, up to <number>9999</number></cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Actual_Price</code></cell> <cell>Unit sale price, <dollar-sign/>0.00<endash/><dollar-sign/><number>99999.99</number></cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>On a typical working day, BDL makes about seven thousand sales. Each sale is typically for some quantity (possibly several thousand) of each of about seven to ten different products. For example, a customer might buy twenty-three remote garage door openers and two burglar alarm systems in the same sale.</item> <item>Products may sell for a different (usually lower) price from that listed (e.g., bulk discounts, cash payments, etc.). Prices are in U.S.<space /> dollars.</item> <item>The status of a sale must be one of the following: <quote>pending</quote>, <quote>in progress</quote>, <quote>cancelled</quote>, <quote>backordered</quote> or <quote>shipped</quote>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Sale_Head ( Sale_Num NUMBER(10), Sale_Date DATE NOT NULL, Status VARCHAR2(11) NOT NULL CONSTRAINT Sale_Head_Status_Invalid CHECK ( Status IN ( 'pending', 'in progress', 'cancelled', 'backordered', 'shipped' ) ), Staff_ID NUMBER(7) NOT NULL, Customer_ID NUMBER(7) NOT NULL, Comments VARCHAR2(4000), -- CONSTRAINT Sale_Head_PK PRIMARY KEY ( Sale_Num ), -- CONSTRAINT Sale_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, CONSTRAINT Sale_Head_FK_To_Customer FOREIGN KEY ( Customer_ID ) REFERENCES Customer ); CREATE TABLE Sale_Line ( Sale_Num NUMBER(10), Product_Code NUMBER(8), Quantity NUMBER(6) NOT NULL CONSTRAINT Sale_Line_Quantity_Too_Low CHECK ( Quantity > 0 ), Actual_Price NUMBER(7,2) NOT NULL CONSTRAINT Sale_Line_Act_Price_Too_Low CHECK ( Actual_Price BETWEEN 0 AND 99999.99 ), -- CONSTRAINT Sale_Line_PK PRIMARY KEY ( Sale_Num, Product_Code ), -- CONSTRAINT Sale_Line_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, CONSTRAINT Sale_Line_FK_To_Sale_Hd FOREIGN KEY ( Sale_Num ) REFERENCES Sale_Head ); </code-block> <p indent="no">It was great to see people using the workaround for checking the <code>Sale_Date</code> isn’t in the future. However, it was very frustrating to also see of them not bothering to explain it! We were quite happy to accept an extra column to store the sale entry date, as long as there was an explanation of why it was being added. (Note that the code above doesn’t include this to save space.)</p> <p>Once again it doesn’t really make sense for <code>Quantity</code> in <code>Sale_Line</code> to be zero (although it does make sense for <code>Actual_Price</code>).</p> </answer> </section> <section label="sec:orders"> <title>The <tt>Order<underscore />head</tt> and <tt>Order<underscore />line</tt> entities</title> <tabular border="1"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Order<underscore />head</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt><hash/></tt></cell> <cell><code>Order_Num</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Order_Date</code></cell> <cell>Date and time of order (cannot be in future)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Due_Date</code></cell> <cell>Date that final shipment is due (after <code>Order_Date</code>)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Date_Completed</code></cell> <cell>Date that final shipment is received (after <code>Order_Date</code>)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Status</code></cell> <cell>Current status of order (see below)</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Arbitrary text</cell> </row> <row-rule /> </tabular-body> </tabular> <tabular border="1" align="left"> <tabular-columns> <column align="center" left-border="|" right-border="|"/> <column align="left" right-border="|"/> <column align="left" right-border="|"/> </tabular-columns> <tabular-body> <row> <cell header="yes" columns="3" align="left"><tt>Order<underscore />line</tt></cell> </row> <row-rule /> <row> <cell header="yes"/> <cell header="yes">Column</cell> <cell header="yes">Description</cell> </row> <row-rule /> <row> <cell><tt>*</tt></cell> <cell><code>Qty_Ordered</code></cell> <cell>Number units of a component ordered, up to <number>99999</number></cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Price</code></cell> <cell>Unit price (see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Qty_Received</code></cell> <cell>Number of components received (see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>BDL places an average of about 320 orders to suppliers per working day. Each order is typically for some quantity (possibly tens of thousands) of each of about fifteen to twenty different components.</item> <item>While component pricing data won’t be stored in the database, the unit prices paid for components must still be recorded on the order. Prices are in the range <dollar-sign/>0.00<endash/><dollar-sign/><number>9999.99</number>, and are in U.S.<space /> dollars.</item> <item>Components arrive in shipments from a supplier, which may or may not correspond to the original order (for example, a single shipment might include components from several different orders to that supplier). When a shipment arrives, the Inventory staff need to note on the original order how many of each component they have received, so that they can determine when the order is complete. An order is complete when the number of components received is at least equal to the number of components ordered. This will also enable them to tell when they have received more components than they originally ordered.</item> <item>The status of an order must be one of the following: <quote>in progress</quote> or <quote>complete</quote>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Order_Head ( Order_Num NUMBER(10), Order_Date DATE NOT NULL, Due_Date DATE NOT NULL, Date_Completed DATE, Status VARCHAR2(11) NOT NULL CONSTRAINT Order_Head_Status_Invalid CHECK ( Status IN ( 'complete', 'in progress' ) ), Staff_ID NUMBER(7) NOT NULL, Supplier_ID NUMBER(7) NOT NULL, Comments VARCHAR2(4000), -- CONSTRAINT Order_Head_Due_Date_Invalid CHECK ( Due_Date > Order_Date ), -- CONSTRAINT Order_Head_PK PRIMARY KEY ( Order_Num ), -- CONSTRAINT Order_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, CONSTRAINT Order_Head_FK_To_Supp FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); CREATE TABLE Order_Line ( Order_Num NUMBER(10), Component_Code NUMBER(8), Qty_Ordered NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Ord_Too_Low CHECK ( Qty_Ordered BETWEEN 0 AND 99999 ), Price NUMBER(6,2) NOT NULL CONSTRAINT Order_Line_Price_Too_Low CHECK ( Price BETWEEN 0 AND 9999.99 ), Qty_Received NUMBER(6) NOT NULL, -- CONSTRAINT Order_Line_PK PRIMARY KEY ( Order_Num, Component_Code ), -- CONSTRAINT Order_Line_FK_To_Comp FOREIGN KEY ( Component_Code ) REFERENCES Component, CONSTRAINT Order_Line_FK_To_Ord_Hd FOREIGN KEY ( Order_Num ) REFERENCES Order_Head ); </code-block> </answer> </section> </section> </document>
Ignore Space
Show notes
View
BDL/BDL_schema.sql
-------------------------------------------------------------------------------- -- -- SQL schema definition of the Better Digital, Ltd. (BDL) corporate -- database, as specified in INFO 214 Assignment 1. -- -- Schema written for Oracle11g. -- -------------------------------------------------------------------------------- -- -- NOTE: this script will drop any existing tables automatically so -- that they can be re-created. -- DECLARE TYPE Table_Names_T IS TABLE OF VARCHAR2 ( 32 ) ; Table_Names Table_Names_T := Table_Names_T ( 'ASSEMBLY', 'COMPONENT', 'CUSTOMER', 'ORDER_HEAD', 'ORDER_LINE', 'PRODUCT', 'SALE_HEAD', 'SALE_LINE', 'STAFF', 'SUPPLIER' ) ; Table_Nonexistent EXCEPTION; PRAGMA Exception_Init ( Table_Nonexistent, -942 ) ; BEGIN FOR T IN Table_Names.FIRST..Table_Names.LAST LOOP BEGIN EXECUTE IMMEDIATE 'DROP TABLE ' || Table_Names ( T ) || '' || ' CASCADE CONSTRAINTS'; EXCEPTION -- We only want to suppress exceptions due to the table not existing. That's -- -942: ORA-00942: table or view does not exist -- Other exceptions, such as being unable to drop a table because of locks(!), should not be trapped, so that the user sees an error message. WHEN Table_Nonexistent THEN DBMS_Output.Put_Line ( SQLCODE || ': ' || SQLERRM || ': Ignoring nonexistent table ' || T ) ; -- null; END; END LOOP; END; / -------------------------------------------------------------------------------- -- -- Staff table -- CREATE TABLE Staff ( Staff_ID NUMBER(7), -- Surname VARCHAR2(50) NOT NULL, -- Firstnames VARCHAR2(50) NOT NULL, -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(150) NOT NULL, -- Department VARCHAR2(18) NOT NULL CONSTRAINT Staff_Department_Invalid -- Yes, this should really be a lookup table :) CHECK ( Department IN ( 'Central Management', 'Sales ' || chr(38) || ' Marketing', 'Personnel', 'Manufacturing', 'Inventory', 'Accounts' ) ), -- Position VARCHAR2(20) NOT NULL CONSTRAINT Staff_POSITION_INVALID -- Yes, this should really be a lookup table too :) CHECK ( Position IN ( 'CEO', 'CTO', 'CFO', 'CIO', 'Director', 'President', 'Vice-President', 'Manager', 'Personal Assistant', 'Secretary', 'Technician', 'Researcher', 'Designer', 'Assembler', 'Programmer', 'Contractor', 'Sales Representative', 'Accountant', 'Inventory', 'Assistant' ) ), -- Salary NUMBER(7,2) NOT NULL CONSTRAINT Staff_Salary_Range_Invalid CHECK ( Salary BETWEEN 1000 and 99999.99 ), -- Comments CLOB, -- CONSTRAINT STAFF_PK PRIMARY KEY ( Staff_ID ) ); -------------------------------------------------------------------------------- -- -- Customer table -- CREATE TABLE Customer ( Customer_ID NUMBER(7), -- Name VARCHAR2(50) NOT NULL, -- Contact_Person VARCHAR2(50), -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(200) NOT NULL, -- Email VARCHAR2(50), -- Comments CLOB, -- CONSTRAINT Customer_PK PRIMARY KEY ( Customer_ID ) ); -------------------------------------------------------------------------------- -- -- Supplier table -- CREATE TABLE Supplier ( Supplier_ID NUMBER(7), -- Name VARCHAR2(50) NOT NULL, -- Contact_Person VARCHAR2(50), -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(200) NOT NULL, -- Email VARCHAR2(50), -- Comments CLOB, -- CONSTRAINT Supplier_PK PRIMARY KEY ( Supplier_ID ) ); -------------------------------------------------------------------------------- -- -- Product table -- CREATE TABLE Product ( Product_Code NUMBER(8), -- Description VARCHAR2(50) NOT NULL, -- Stock_Count NUMBER(5) NOT NULL CONSTRAINT Product_Stock_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 99999 ), -- Restock_Level NUMBER(5) CONSTRAINT Product_Restock_Level_Too_Low CHECK ( Restock_Level BETWEEN 0 AND 99999 ), -- Minimum_Level NUMBER(5), -- List_Price NUMBER(7,2) NOT NULL CONSTRAINT Product_List_Price_Too_Low CHECK ( List_Price BETWEEN 0 AND 99999.99 ), -- Assembly_Manual BLOB, -- Assembly_Program BLOB, -- CONSTRAINT Product_Min_Level_Invalid CHECK ( ( Minimum_Level >= 0 ) AND ( Minimum_Level < Restock_Level ) ), -- CONSTRAINT Product_PK PRIMARY KEY ( Product_Code ) ); -------------------------------------------------------------------------------- -- -- Component table -- CREATE TABLE Component ( Component_Code NUMBER(8), -- Suppliers_Code VARCHAR2(25) NOT NULL, -- Description VARCHAR2(100) NOT NULL, -- Stock_Count NUMBER(7) NOT NULL CONSTRAINT Component_Stk_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 9999999 ), -- Supplier_ID NUMBER(7) NOT NULL, -- CONSTRAINT Component_PK PRIMARY KEY ( Component_Code ), -- CONSTRAINT Component_FK_To_Supplier FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); -------------------------------------------------------------------------------- -- -- Assembly table -- CREATE TABLE Assembly ( Product_Code NUMBER(8), -- Component_Code NUMBER(8), -- Quantity NUMBER(4) NOT NULL CONSTRAINT Assembly_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- CONSTRAINT Assembly_PK PRIMARY KEY ( Product_Code, Component_Code ), -- CONSTRAINT Assembly_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, -- CONSTRAINT Assembly_FK_To_Component FOREIGN KEY ( Component_Code ) REFERENCES Component ); -------------------------------------------------------------------------------- -- -- Sale_Head table -- CREATE TABLE Sale_Head ( Sale_Num NUMBER(10), -- Sale_Date DATE NOT NULL, -- Date_Entered DATE DEFAULT SYSDATE NOT NULL, -- Status VARCHAR2(11) NOT NULL CONSTRAINT Sale_Head_Status_Invalid CHECK ( Status IN ( 'pending', 'in progress', 'cancelled', 'backordered', 'shipped' ) ), -- Staff_ID NUMBER(7) NOT NULL, -- Customer_ID NUMBER(7) NOT NULL, -- Comments CLOB, -- CONSTRAINT Sale_Head_Date_In_Future CHECK ( Sale_Date <= Date_Entered ), -- CONSTRAINT Sale_Head_PK PRIMARY KEY ( Sale_Num ), -- CONSTRAINT Sale_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, -- CONSTRAINT Sale_Head_FK_To_Customer FOREIGN KEY ( Customer_ID ) REFERENCES Customer ); -------------------------------------------------------------------------------- -- -- Sale_Line table -- CREATE TABLE Sale_Line ( Sale_Num NUMBER(10), -- Product_Code NUMBER(8), -- Quantity NUMBER(4) NOT NULL CONSTRAINT Sale_Line_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- Actual_Price NUMBER(7,2) NOT NULL CONSTRAINT Sale_Line_Act_Price_Too_Low CHECK ( Actual_Price BETWEEN 0 AND 99999.99 ), -- CONSTRAINT Sale_Line_PK PRIMARY KEY ( Sale_Num, Product_Code ), -- CONSTRAINT Sale_Line_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, -- CONSTRAINT Sale_Line_FK_To_Sale_Hd FOREIGN KEY ( Sale_Num ) REFERENCES Sale_Head ); -------------------------------------------------------------------------------- -- -- Order_Head table -- CREATE TABLE Order_Head ( Order_Num NUMBER(10), -- Order_Date DATE NOT NULL, -- Date_Entered DATE DEFAULT SYSDATE NOT NULL, -- Due_Date DATE NOT NULL, -- Date_Completed DATE, -- Status VARCHAR2(11) NOT NULL CONSTRAINT Order_Head_Status_Invalid CHECK ( Status IN ( 'complete', 'in progress' ) ), -- Staff_ID NUMBER(7) NOT NULL, -- Supplier_ID NUMBER(7) NOT NULL, -- Comments CLOB, -- CONSTRAINT Order_Head_Date_In_Future CHECK ( Order_Date <= Date_Entered ), -- CONSTRAINT Order_Head_Due_Date_Invalid CHECK ( Due_Date > Order_Date ), -- CONSTRAINT Order_Head_Date_Comp_Invalid CHECK ( Date_Completed > Order_Date ), -- CONSTRAINT Order_Head_PK PRIMARY KEY ( Order_Num ), -- CONSTRAINT Order_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, -- CONSTRAINT Order_Head_FK_To_Supp FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); -------------------------------------------------------------------------------- -- -- Order_Line table -- CREATE TABLE Order_Line ( Order_Num NUMBER(10), -- Component_Code NUMBER(8), -- Qty_Ordered NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Ord_Too_Low CHECK ( Qty_Ordered BETWEEN 1 AND 99999 ), -- Price NUMBER(6,2) NOT NULL CONSTRAINT Order_Line_Price_Too_Low CHECK ( Price BETWEEN 0 AND 9999.99 ), -- Qty_Received NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Rec_Too_Low CHECK ( Qty_Received >= 0 ), -- CONSTRAINT Order_Line_PK PRIMARY KEY ( Order_Num, Component_Code ), -- CONSTRAINT Order_Line_FK_To_Comp FOREIGN KEY ( Component_Code ) REFERENCES Component, -- CONSTRAINT Order_Line_FK_To_Ord_Hd FOREIGN KEY ( Order_Num ) REFERENCES Order_Head ); -------------------------------------------------------------------------------- -- -- Here endeth the schema. -- --------------------------------------------------------------------------------
-------------------------------------------------------------------------------- -- -- SQL schema definition of the Better Digital, Ltd. (BDL) corporate -- database, as specified in INFO 214 Assignment 1. -- -- Schema written for Oracle11g. -- -------------------------------------------------------------------------------- -- -- NOTE: this script will drop any existing tables automatically so -- that they can be re-created. -- DECLARE TYPE Table_Names_T IS TABLE OF VARCHAR2 ( 32 ) ; Table_Names Table_Names_T := Table_Names_T ( 'ASSEMBLY', 'COMPONENT', 'CUSTOMER', 'ORDER_HEAD', 'ORDER_LINE', 'PRODUCT', 'SALE_HEAD', 'SALE_LINE', 'STAFF', 'SUPPLIER' ) ; Table_Nonexistent EXCEPTION; PRAGMA Exception_Init ( Table_Nonexistent, -942 ) ; BEGIN FOR T IN Table_Names.FIRST..Table_Names.LAST LOOP BEGIN EXECUTE IMMEDIATE 'DROP TABLE ' || Table_Names ( T ) || '' || ' CASCADE CONSTRAINTS'; EXCEPTION -- We only want to suppress exceptions due to the table not existing. That's -- -942: ORA-00942: table or view does not exist -- Other exceptions, such as being unable to drop a table because of locks(!), should not be trapped, so that the user sees an error message. WHEN Table_Nonexistent THEN DBMS_Output.Put_Line ( SQLCODE || ': ' || SQLERRM || ': Ignoring nonexistent table ' || T ) ; -- null; END; END LOOP; END; / -------------------------------------------------------------------------------- -- -- Staff table -- CREATE TABLE Staff ( Staff_ID NUMBER(7), -- Surname VARCHAR2(50) NOT NULL, -- Firstnames VARCHAR2(50) NOT NULL, -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(150) NOT NULL, -- Department VARCHAR2(18) NOT NULL CONSTRAINT Staff_Department_Invalid -- Yes, this should really be a lookup table :) CHECK ( Department IN ( 'Central Management', 'Sales ' || chr(38) || ' Marketing', 'Personnel', 'Manufacturing', 'Inventory', 'Accounts' ) ), -- Position VARCHAR2(20) NOT NULL CONSTRAINT Staff_POSITION_INVALID -- Yes, this should really be a lookup table too :) CHECK ( Position IN ( 'CEO', 'CTO', 'CFO', 'CIO', 'Director', 'President', 'Vice-President', 'Manager', 'Personal Assistant', 'Secretary', 'Technician', 'Researcher', 'Designer', 'Assembler', 'Programmer', 'Contractor', 'Sales Representative', 'Accountant', 'Inventory', 'Assistant' ) ), -- Salary NUMBER(7,2) NOT NULL CONSTRAINT Staff_Salary_Range_Invalid CHECK ( Salary BETWEEN 1000 and 99999.99 ), -- Comments VARCHAR2(4000), -- CONSTRAINT STAFF_PK PRIMARY KEY ( Staff_ID ) ); -------------------------------------------------------------------------------- -- -- Customer table -- CREATE TABLE Customer ( Customer_ID NUMBER(7), -- Name VARCHAR2(50) NOT NULL, -- Contact_Person VARCHAR2(50), -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(200) NOT NULL, -- Email VARCHAR2(50), -- Comments VARCHAR2(4000), -- CONSTRAINT Customer_PK PRIMARY KEY ( Customer_ID ) ); -------------------------------------------------------------------------------- -- -- Supplier table -- CREATE TABLE Supplier ( Supplier_ID NUMBER(7), -- Name VARCHAR2(50) NOT NULL, -- Contact_Person VARCHAR2(50), -- Phone VARCHAR2(15) NOT NULL, -- Address VARCHAR2(200) NOT NULL, -- Email VARCHAR2(50), -- Comments VARCHAR2(4000), -- CONSTRAINT Supplier_PK PRIMARY KEY ( Supplier_ID ) ); -------------------------------------------------------------------------------- -- -- Product table -- CREATE TABLE Product ( Product_Code NUMBER(8), -- Description VARCHAR2(50) NOT NULL, -- Stock_Count NUMBER(5) NOT NULL CONSTRAINT Product_Stock_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 99999 ), -- Restock_Level NUMBER(5) CONSTRAINT Product_Restock_Level_Too_Low CHECK ( Restock_Level BETWEEN 0 AND 99999 ), -- Minimum_Level NUMBER(5), -- List_Price NUMBER(7,2) NOT NULL CONSTRAINT Product_List_Price_Too_Low CHECK ( List_Price BETWEEN 0 AND 99999.99 ), -- Assembly_Manual BLOB, -- Assembly_Program BLOB, -- CONSTRAINT Product_Min_Level_Invalid CHECK ( ( Minimum_Level >= 0 ) AND ( Minimum_Level < Restock_Level ) ), -- CONSTRAINT Product_PK PRIMARY KEY ( Product_Code ) ); -------------------------------------------------------------------------------- -- -- Component table -- CREATE TABLE Component ( Component_Code NUMBER(8), -- Suppliers_Code VARCHAR2(25) NOT NULL, -- Description VARCHAR2(100) NOT NULL, -- Stock_Count NUMBER(7) NOT NULL CONSTRAINT Component_Stk_Count_Too_Low CHECK ( Stock_Count BETWEEN 0 AND 9999999 ), -- Supplier_ID NUMBER(7) NOT NULL, -- CONSTRAINT Component_PK PRIMARY KEY ( Component_Code ), -- CONSTRAINT Component_FK_To_Supplier FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); -------------------------------------------------------------------------------- -- -- Assembly table -- CREATE TABLE Assembly ( Product_Code NUMBER(8), -- Component_Code NUMBER(8), -- Quantity NUMBER(4) NOT NULL CONSTRAINT Assembly_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- CONSTRAINT Assembly_PK PRIMARY KEY ( Product_Code, Component_Code ), -- CONSTRAINT Assembly_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, -- CONSTRAINT Assembly_FK_To_Component FOREIGN KEY ( Component_Code ) REFERENCES Component ); -------------------------------------------------------------------------------- -- -- Sale_Head table -- CREATE TABLE Sale_Head ( Sale_Num NUMBER(10), -- Sale_Date DATE NOT NULL, -- Date_Entered DATE DEFAULT SYSDATE NOT NULL, -- Status VARCHAR2(11) NOT NULL CONSTRAINT Sale_Head_Status_Invalid CHECK ( Status IN ( 'pending', 'in progress', 'cancelled', 'backordered', 'shipped' ) ), -- Staff_ID NUMBER(7) NOT NULL, -- Customer_ID NUMBER(7) NOT NULL, -- Comments VARCHAR2(4000), -- CONSTRAINT Sale_Head_Date_In_Future CHECK ( Sale_Date <= Date_Entered ), -- CONSTRAINT Sale_Head_PK PRIMARY KEY ( Sale_Num ), -- CONSTRAINT Sale_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, -- CONSTRAINT Sale_Head_FK_To_Customer FOREIGN KEY ( Customer_ID ) REFERENCES Customer ); -------------------------------------------------------------------------------- -- -- Sale_Line table -- CREATE TABLE Sale_Line ( Sale_Num NUMBER(10), -- Product_Code NUMBER(8), -- Quantity NUMBER(4) NOT NULL CONSTRAINT Sale_Line_Quantity_Too_Low CHECK ( Quantity BETWEEN 1 AND 9999 ), -- Actual_Price NUMBER(7,2) NOT NULL CONSTRAINT Sale_Line_Act_Price_Too_Low CHECK ( Actual_Price BETWEEN 0 AND 99999.99 ), -- CONSTRAINT Sale_Line_PK PRIMARY KEY ( Sale_Num, Product_Code ), -- CONSTRAINT Sale_Line_FK_To_Product FOREIGN KEY ( Product_Code ) REFERENCES Product, -- CONSTRAINT Sale_Line_FK_To_Sale_Hd FOREIGN KEY ( Sale_Num ) REFERENCES Sale_Head ); -------------------------------------------------------------------------------- -- -- Order_Head table -- CREATE TABLE Order_Head ( Order_Num NUMBER(10), -- Order_Date DATE NOT NULL, -- Date_Entered DATE DEFAULT SYSDATE NOT NULL, -- Due_Date DATE NOT NULL, -- Date_Completed DATE, -- Status VARCHAR2(11) NOT NULL CONSTRAINT Order_Head_Status_Invalid CHECK ( Status IN ( 'complete', 'in progress' ) ), -- Staff_ID NUMBER(7) NOT NULL, -- Supplier_ID NUMBER(7) NOT NULL, -- Comments VARCHAR2(4000), -- CONSTRAINT Order_Head_Date_In_Future CHECK ( Order_Date <= Date_Entered ), -- CONSTRAINT Order_Head_Due_Date_Invalid CHECK ( Due_Date > Order_Date ), -- CONSTRAINT Order_Head_Date_Comp_Invalid CHECK ( Date_Completed > Order_Date ), -- CONSTRAINT Order_Head_PK PRIMARY KEY ( Order_Num ), -- CONSTRAINT Order_Head_FK_To_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, -- CONSTRAINT Order_Head_FK_To_Supp FOREIGN KEY ( Supplier_ID ) REFERENCES Supplier ); -------------------------------------------------------------------------------- -- -- Order_Line table -- CREATE TABLE Order_Line ( Order_Num NUMBER(10), -- Component_Code NUMBER(8), -- Qty_Ordered NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Ord_Too_Low CHECK ( Qty_Ordered BETWEEN 1 AND 99999 ), -- Price NUMBER(6,2) NOT NULL CONSTRAINT Order_Line_Price_Too_Low CHECK ( Price BETWEEN 0 AND 9999.99 ), -- Qty_Received NUMBER(5) NOT NULL CONSTRAINT Order_Line_Qty_Rec_Too_Low CHECK ( Qty_Received >= 0 ), -- CONSTRAINT Order_Line_PK PRIMARY KEY ( Order_Num, Component_Code ), -- CONSTRAINT Order_Line_FK_To_Comp FOREIGN KEY ( Component_Code ) REFERENCES Component, -- CONSTRAINT Order_Line_FK_To_Ord_Hd FOREIGN KEY ( Order_Num ) REFERENCES Order_Head ); -------------------------------------------------------------------------------- -- -- Here endeth the schema. -- --------------------------------------------------------------------------------
Show line notes below