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
Merge branch 'master' into a1-automarking-test
master
commit
d3b18381a62647924c247fe73ac1b63e752687ee
2 parents
7af0cd1
+
02173da
Nigel Stanger
authored
on 22 Jul 2013
Patch
Showing
3 changed files
BDL.xml
STINK_postgrad.xml
STINK_student_records.xml
Ignore Space
Show notes
View
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. 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 that will be located at the company headquarters in Los Angeles. The requirements analysis phase of the project is complete, and you have been brought in as a lead database developer. It will 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="!hb"> <caption>ERD of Better Digital’s database (Barker notation)</caption> <image basename="BDL_barker" location="images" latex-options="width=0.9\columnwidth,keepaspectratio"> <description>ERD of Better Digital’s database (Barker 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.</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 of trusted suppliers (of which there are currently thirty-three). 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 will not 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, an alert is raised by the inventory management application 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 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 KB each.</item> </itemised-list> <p indent="no">BDL orders components from a small group of trusted suppliers (of which there are currently thirty-three). 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 will not 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 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 will not 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 in the example above, <quote>35 ohm resistor</quote> 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 of this component used, 1–<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) 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.).</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>*</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>Since pricing data will not be stored with the actual component data, the unit prices paid for components must be recorded on the order. Prices are in the range <dollar-sign/>0.00<endash/><dollar-sign/><number>9999.99</number>.</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 (this happens when the number of components received is 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, 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>
<?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. 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 that will be located at the company headquarters in Los Angeles. The requirements analysis phase of the project is almost complete, and you have been brought in as a lead database developer. It will 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="!hb"> <caption>ERD of Better Digital’s database (Barker notation)</caption> <image basename="BDL_barker" location="images"> <description>ERD of Better Digital’s database (Barker 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.</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 of trusted suppliers (of which there are currently thirty-three). 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 will not 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, an alert is raised by the inventory management application 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 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 KB each.</item> </itemised-list> <p indent="no">BDL orders components from a small group of trusted suppliers (of which there are currently thirty-three). 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 will not 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 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 will not 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 in the example above, <quote>35 ohm resistor</quote> 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 of this component used, 1–<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) 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.).</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>*</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>Since pricing data will not be stored with the actual component data, the unit prices paid for components must be recorded on the order. Prices are in the range <dollar-sign/>0.00<endash/><dollar-sign/><number>9999.99</number>.</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 (this happens when the number of components received is 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, 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
STINK_postgrad.xml
<?xml version="1.0" standalone="yes"?> <document class="fragment"> <section label="sec:database-info"> <title>System specification and details</title> <p>The Southern Technical Institute for Natural Knowledge is a medium-sized tertiary education provider, founded in 1982, which teaches papers across many subjects leading to many different qualifications. They began offering postgraduate degrees in 2008, and are in the process of designing and implementing a database to keep track of their postgraduate students. The requirements analysis and conceptual design phases of the project are complete, and you have been brought in as lead database developer. Your task is to verify the soundness of the conceptual specification by implementing an initial prototype based on it. A design-level entity-relationship diagram 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="!hb"> <caption>Design-level ERD of the proposed database (Barker notation)</caption> <image basename="STINK_postgrad_barker" location="images"> <description>Design-level ERD of the proposed database (Barker notation)</description> </image> </figure> <section> <title>The <tt>Degree</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>Abbreviation</code></cell> <cell>Up to 10 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Full_Name</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Degree_Type</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Funding_Limit</code></cell> <cell>Zero or greater</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>The abbreviation is a short string identifying the postgraduate degree, for example, <quote>PhD</quote>, <quote>MSc</quote>, <quote>PGDipCom</quote>.</item> <item>The degree type must be one of the following: <quote>Taught</quote>, <quote>Papers <ampersand/> thesis</quote> or <quote>Thesis only</quote>.</item> <item>The funding limit specifies the maximum number of years that the degree will be funded by the government, for example, four years for a PhD. This may not always be a whole number.</item> </itemised-list> <answer> <p><strong>Degree</strong>{<underline>Abbreviation</underline>, Full<underscore />Name, Degree<underscore />Type, Funding<underscore />Limit}</p> <code-block> CREATE TABLE Degree ( Abbreviation VARCHAR2(10), Full_Name VARCHAR2(100) NOT NULL, Degree_Type VARCHAR2(15) NOT NULL CHECK ( Degree_Type IN ( 'Taught', 'Papers & thesis', 'Thesis only' ) ), Funding_Limit NUMBER(3,1) NOT NULL CHECK ( Funding_Limit >= 0 ) -- PRIMARY KEY (Abbreviation) ); </code-block> <p>Some people added lookup tables for things like degree types. Strictly speaking, this isn<apostrophe />t really part of of the schema transformation (the schema will work fine either with or without lookup tables), but in general there is nothing wrong with doing this, <em>as long as it doesn<apostrophe />t change the specification</em>. Some people did do this correctly, by simply using the existing values (which are already unique) as the primary key of the new lookup table. For example, the <code>Degree_Type</code> table would consist of a single column <code>Degree_Type</code>, which contained the valid values for degree types, and was also the primary key. Other people got carried away and invented unnecessary surrogate keys for their lookup tables, thus completely breaking the specification.</p> </answer> </section> <section> <title>The <tt>Student</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>Student_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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Home_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Home_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>International</code></cell> <cell>Boolean, default false</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="large"/> <p indent="no">Many students are international, so phone numbers must cater for this.</p> <answer> <p><strong>Student</strong>{<underline>Student<underscore />ID</underline>, Surname, Other<underscore />Names, Contact<underscore />Phone, Contact<underscore />Address, Home<underscore />Phone, Home<underscore />Address, Username, International, Degree<underscore />Code); Degree<underscore />Code FK to <strong>Degree</strong>.</p> <code-block> CREATE TABLE Student ( Student_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(15), -- at least 15, maybe more -- for international numbers Contact_Address VARCHAR2(200) NOT NULL, Home_Phone VARCHAR2(15), Home_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL, International CHAR(1) DEFAULT 'F' NOT NULL CHECK ( International IN ( 'T', 'F' ) ), Degree_Code VARCHAR2(10) NOT NULL, -- PRIMARY KEY (Student_ID), FOREIGN KEY (Degree_Code) REFERENCES Degree (Abbreviation) ); </code-block> <p>Remember that <code>ON DELETE CASCADE</code> is not appropriate in all cases! Many people added an <code>ON DELETE CASCADE</code> to the foreign key from <code>Student</code> to <code>Degree</code>, but if you think about how the organisation would work, this doesn<apostrophe />t make any sense. Why should deleting a degree cause all students enrolled in that degree to also be deleted? This is equivalent to expelling the student (actually, worse, since even expelled students probably wouldn<apostrophe />t have their data deleted). It<apostrophe />s much more likely that the affected students would be reassigned to a different degree (or at the very least to a <quote>dummy</quote> placeholder degree until their status is resolved).</p> </answer> </section> <section> <title>The <tt>Enrolment</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>Enrolment_ID</code></cell> <cell>Internally generated 10 digit identifier</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>Year_Enrolled</code></cell> <cell>4 digits</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Grade</code></cell> <cell>(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> <itemised-list> <item>The year of enrolment cannot be earlier than the year in which the Institute started offering postgraduate degrees.</item> <item>For a paper, the grade must be one of the following: <quote>E</quote>, <quote>D</quote>, <quote>C<endash/></quote>, <quote>C</quote>, <quote>C+</quote>, <quote>B<endash/></quote>, <quote>B</quote>, <quote>B+</quote>, <quote>A<endash/></quote>, <quote>A</quote> or <quote>A+</quote>. For a thesis, the grade must be one of the following: <quote>Fail</quote>, <quote>Pass</quote>, <quote>Credit</quote>, <quote>Distinction</quote> or <quote>Incomplete</quote>.</item> </itemised-list> <answer> <p><strong>Enrolment</strong>(<underline>Enrolment<underscore />ID</underline>, Description, Year<underscore />Enrolled, Grade, Comments, Component<underscore />Code, Student<underscore />ID); Component<underscore />Code FK to <strong>Component</strong>, Student<underscore />ID FK to <strong>Student</strong></p> <code-block> CREATE TABLE Enrolment ( Enrolment_ID NUMBER(10), Description VARCHAR2(100) NOT NULL, Year_Enrolled NUMBER(4) NOT NULL CHECK ( Year_Enrolled >= 2008 ), Result VARCHAR2(11) NOT NULL CHECK ( Result IN ( 'E', 'D', 'C-', 'C', 'C+', 'B-', 'B', 'B+', 'A-', 'A', 'A+', 'Fail', 'Pass', 'Credit', 'Distinction', 'Incomplete' ) ) Comments VARCHAR2(4000), -- or CLOB (LONG is deprecated) Student_ID NUMBER(7) NOT NULL, Component_Code CHAR(7) NOT NULL, -- PRIMARY KEY (Enrolment_ID), FOREIGN KEY (Student_ID) REFERENCES Student, FOREIGN KEY (Component_Code) REFERENCES Component ); </code-block> <p><code>ON DELETE CASCADE</code> <em>does</em> make sense for the <code>Student_ID</code> foreign key here (and also for the foreign keys in <code>Staff_Component</code>), because the existence of these data is very tightly linked with the associated data. This is a very good illustration of the point that we need to consider not just structural aspects of a problem when building a database, but also procedural aspects.</p> </answer> </section> <section> <title>The <tt>Component</tt> entity and its subtypes</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"><tt>Component</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>Component_Code</code></cell> <cell>7 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Title</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Points</code></cell> <cell>Integer, default 20 (also see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Period</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Component_Type</code></cell> <cell>(see below)</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>The component code comprises a four-letter subject code (e.g., <quote>INFO</quote>) followed by a three digit course number (e.g., <quote>212</quote>). The course numbers for Diploma, Masters<apostrophe/> and PhD theses are 480, 580 and 980 respectively.</item> <item>The period of a component must be one of the following: <quote>SS</quote> (Summer School), <quote>S1</quote> (Semester One), <quote>S2</quote> (Semester Two), <quote>FY</quote> (Full Year) or <quote>O</quote> (Other). [<strong>Bonus:</strong> thesis courses must always be Other.]</item> <item>The component type must be one of the following: <quote>Doctoral thesis</quote>, <quote>Masters<apostrophe/> thesis</quote>, <quote>Diploma thesis</quote> or <quote>Paper</quote>.</item> <item>Semester and Summer School papers are worth 20 points, while full year papers are worth 40 points. A Diploma thesis is worth 40 points, a Masters<apostrophe /> thesis 120 points and a PhD thesis 360 points.</item> <item>The <tt>Thesis</tt> and <tt>Paper</tt> subtypes have no additional attributes.</item> </itemised-list> <answer> <p><strong>Component</strong>(<underline>Component_Code</underline>, Title, Description, Points, Period, Component<underscore />Type)</p> <code-block> CREATE TABLE Component ( Component_Code CHAR(7), Title VARCHAR2(50) NOT NULL, Description VARCHAR2(200) NOT NULL, Points NUMBER(2) NOT NULL CHECK ( Points IN ( 20, 40, 120, 360 ) ), Period CHAR(2) NOT NULL CHECK ( Period IN ( 'S1', 'S2', 'SS', 'FY', 'O' ) ), Component_Type VARCHAR2(15) NOT NULL CHECK ( Component_Code IN ( 'Doctoral thesis', 'Masters'' thesis', 'Diploma thesis', 'Paper' ) ) -- PRIMARY KEY (Component_Code) ); </code-block> <p>This solution uses the integrated approach for transforming subtypes (i.e., one relation containing all the super- and subtype attributes). The reason for this is that the two <code>Component</code> subtypes provide no additional attributes. Splitting them off as separate (single-attribute) relations therefore seems somewhat pointless (but see the further discussion below).</p> <p>There is one significant consequence of using the integrated approach. If we collapse all the <code>Component</code> super- and subtypes into a single entity, we may also want to collapse the <strong>supervises</strong> and <strong>teaches</strong> many-to-many relationships into a single relationship (although we aren<apostrophe />t required to do so). If we do nothing else at this point, we have eliminated some important information from the schema: namely the type of relationship between staff and components (a subtle but important distinction). We can re-introduce this information by adding a <code>Type</code> attribute to the <code>Staff_Component</code> relation when we resolve the many-to-many relationship. This has been included in the SQL code for the table.</p> <p>Some people stated that the discrete approach (three relations) was the best choice, then gave either no justification at all or simply repeated the advantages of the approach mentioned in lectures, presumably on the theory that <quote>if it was stated in lectures, it <em>must</em> be true</quote>. (It is worth noting that we quite clearly stated in those lectures that you should always consider the context in which subtypes occur when deciding on the best approach to transform them.) This clearly shows that those people had not thought about what the best solution might be <em>for this case</em>, and were instead applying a <quote>one size fits all</quote> mentality, which can be very dangerous. In this case, the discrete approach is perhaps not an ideal solution, as it adds some data redundancy and complicates queries by requiring extra joins.</p> <p>However, you can successfully argue that the Institute might want to add new subtypes in future, which would be difficult to achieve under the integrated approach. This is a perfectly valid solution, <em>as long as you clearly state this assumption</em>. A couple of people did precisely this, and got full marks for the subtype transformation. In other words, the schema presented here is not the only possible solution to this problem.</p> <p>A common error when using the discrete approach was to define all three relations containing the all the <code>Component</code> attributes. However, this defeats the purpose of having a <code>Component</code> supertype relation, as the supertype is supposed to contain the attributes that are shared across all subtypes. Implementing it this way would be little different from the additive approach (which doesn<apostrophe />t really work in this scenario; see below). With three relations, <code>Component</code> should have all the attributes, while <code>Thesis</code> and <code>Paper</code> have only the primary key column (plus a foreign key to <code>Component</code>) and nothing else. Yes, it looks weird, but it works, and the end user never has to see it (logical data independence).</p> <p>As noted above, the integrated approach merges the two many-to-many relationships into one, which means you need some kind of <quote>type</quote> attribute in the intermediate relation. However, as a few observant people noted, you can achieve the same effect by looking up <code>Component_Type</code> in <code>Component</code> (bonus marks were awarded to those who spotted this, although note that this solution would require application developers to join with <code>Component</code> and filter appropriately).</p> <p>The additive approach is definitely inappropriate for this scenario because it would force us to include two foreign keys to <code>Component</code> in <code>Enrolment</code>. Worse, because each enrolment is for a single component, only one of those foreign keys can have a value for any given enrolment. This means that both foreign key columns must allow nulls, which is a significant variation from what the original ERD specified. Also, with this approach it is possible to have two identical components that are both a paper and a thesis at the same time!</p> <p>On a completely different note, most people who implemented the <code>CHECK</code> constraint for <code>Component.Component_Type</code> got it slightly wrong, by checking for <quote>Masters thesis</quote> instead of <quote>Masters<apostrophe /> thesis</quote> (note the apostrophe after <quote>Masters</quote>, and check the code above to see how this is done in SQL). This may seem rather picky, but once again, you have to follow the specification in detail, otherwise you can end up in a situation where the front end supplies what should be a valid value, which is then unexpectedly rejected by the back end!</p> </answer> </section> <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 5 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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Grade</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Monetary, <ge/><dollar-sign/>42<digitsep/>670.00</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>Phone numbers must cater for both local landline and cellular numbers.</item> <item>A staff member<apostrophe/>s grade must be one of the following: <quote>AL</quote> (Assistant Lecturer), <quote>L</quote> (Lecturer), <quote>SL</quote> (Senior Lecturer), <quote>AP</quote> (Associate Professor) or <quote>P</quote> (Professor).</item> </itemised-list> <answer> <p><strong>Staff</strong>(<underline>Staff<underscore />ID</underline>, Surname, Other<underscore />Names, Contact<underscore />Phone, Contact<underscore />Address, Username, Grade, Salary)</p> <code-block> CREATE TABLE Staff ( Staff_ID NUMBER(5), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(10), -- at least 10, maybe more Contact_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL, Grade VARCHAR2(2) NOT NULL CHECK ( Grade IN ( 'AL', 'L', 'SL', 'AP', 'P' ) ), Salary NUMBER(7,2) NOT NULL CHECK ( Salary >= 42670 ), -- PRIMARY KEY (Staff_ID) ); </code-block> <p>We also need to add a relation between <code>Staff</code> and <code>Component</code> to resolve the many-to-many relationship:</p> <p><code><strong>Staff<underscore />Component</strong>(<underline>Staff<underscore />ID, Component<underscore />Code</underline>, Type)</code>; <code>Staff<underscore />ID</code> FK to <code><strong>Staff</strong></code>, <code>Component<underscore />Code</code> FK to <code><strong>Component</strong></code></p> <code-block> CREATE TABLE Staff_Component ( Staff_ID NUMBER(5), Component_Code CHAR(7), Type VARCHAR2(10) NOT NULL CHECK ( Type IN ( 'teaches', 'supervises' ) ), -- PRIMARY KEY (Staff_ID, Component_Code), FOREIGN KEY (Staff_ID) REFERENCES Staff, FOREIGN KEY (Component_Code) REFERENCES Component ); </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>The Southern Technical Institute for Natural Knowledge is a medium-sized tertiary education provider, founded in 1982, which teaches papers across many subjects leading to many different qualifications. They began offering postgraduate degrees in 2008, and are in the process of designing and implementing a database to keep track of their postgraduate students. The requirements analysis and conceptual design phases of the project are complete, and you have been brought in as lead database developer. Your task is to verify the soundness of the conceptual specification by implementing an initial prototype based on it. A design-level entity-relationship diagram 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="!hb"> <caption>Design-level ERD of the proposed database</caption> <image basename="STINK_postgrad" location="images"> <description>Design-level ERD of the proposed database</description> </image> </figure> <section> <title>The <tt>Degree</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>Abbreviation</code></cell> <cell>Up to 10 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Full_Name</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Degree_Type</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Funding_Limit</code></cell> <cell>Zero or greater</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>The abbreviation is a short string identifying the postgraduate degree, for example, <quote>PhD</quote>, <quote>MSc</quote>, <quote>PGDipCom</quote>.</item> <item>The degree type must be one of the following: <quote>Taught</quote>, <quote>Papers <ampersand/> thesis</quote> or <quote>Thesis only</quote>.</item> <item>The funding limit specifies the maximum number of years that the degree will be funded by the government, for example, four years for a PhD. This may not always be a whole number.</item> </itemised-list> <answer> <p><strong>Degree</strong>{<underline>Abbreviation</underline>, Full<underscore />Name, Degree<underscore />Type, Funding<underscore />Limit}</p> <code-block> CREATE TABLE Degree ( Abbreviation VARCHAR2(10), Full_Name VARCHAR2(100) NOT NULL, Degree_Type VARCHAR2(15) NOT NULL CHECK ( Degree_Type IN ( 'Taught', 'Papers & thesis', 'Thesis only' ) ), Funding_Limit NUMBER(3,1) NOT NULL CHECK ( Funding_Limit >= 0 ) -- PRIMARY KEY (Abbreviation) ); </code-block> <p>Some people added lookup tables for things like degree types. Strictly speaking, this isn<apostrophe />t really part of of the schema transformation (the schema will work fine either with or without lookup tables), but in general there is nothing wrong with doing this, <em>as long as it doesn<apostrophe />t change the specification</em>. Some people did do this correctly, by simply using the existing values (which are already unique) as the primary key of the new lookup table. For example, the <code>Degree_Type</code> table would consist of a single column <code>Degree_Type</code>, which contained the valid values for degree types, and was also the primary key. Other people got carried away and invented unnecessary surrogate keys for their lookup tables, thus completely breaking the specification.</p> </answer> </section> <section> <title>The <tt>Student</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>Student_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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Home_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Home_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>International</code></cell> <cell>Boolean, default false</cell> </row> <row-rule/> </tabular-body> </tabular> <vskip size="large"/> <p indent="no">Many students are international, so phone numbers must cater for this.</p> <answer> <p><strong>Student</strong>{<underline>Student<underscore />ID</underline>, Surname, Other<underscore />Names, Contact<underscore />Phone, Contact<underscore />Address, Home<underscore />Phone, Home<underscore />Address, Username, International, Degree<underscore />Code); Degree<underscore />Code FK to <strong>Degree</strong>.</p> <code-block> CREATE TABLE Student ( Student_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(15), -- at least 15, maybe more -- for international numbers Contact_Address VARCHAR2(200) NOT NULL, Home_Phone VARCHAR2(15), Home_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL, International CHAR(1) DEFAULT 'F' NOT NULL CHECK ( International IN ( 'T', 'F' ) ), Degree_Code VARCHAR2(10) NOT NULL, -- PRIMARY KEY (Student_ID), FOREIGN KEY (Degree_Code) REFERENCES Degree (Abbreviation) ); </code-block> <p>Remember that <code>ON DELETE CASCADE</code> is not appropriate in all cases! Many people added an <code>ON DELETE CASCADE</code> to the foreign key from <code>Student</code> to <code>Degree</code>, but if you think about how the organisation would work, this doesn<apostrophe />t make any sense. Why should deleting a degree cause all students enrolled in that degree to also be deleted? This is equivalent to expelling the student (actually, worse, since even expelled students probably wouldn<apostrophe />t have their data deleted). It<apostrophe />s much more likely that the affected students would be reassigned to a different degree (or at the very least to a <quote>dummy</quote> placeholder degree until their status is resolved).</p> </answer> </section> <section> <title>The <tt>Enrolment</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>Enrolment_ID</code></cell> <cell>Internally generated 10 digit identifier</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>Year_Enrolled</code></cell> <cell>4 digits</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Grade</code></cell> <cell>(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> <itemised-list> <item>The year of enrolment cannot be earlier than the year in which the Institute started offering postgraduate degrees.</item> <item>For a paper, the grade must be one of the following: <quote>E</quote>, <quote>D</quote>, <quote>C<endash/></quote>, <quote>C</quote>, <quote>C+</quote>, <quote>B<endash/></quote>, <quote>B</quote>, <quote>B+</quote>, <quote>A<endash/></quote>, <quote>A</quote> or <quote>A+</quote>. For a thesis, the grade must be one of the following: <quote>Fail</quote>, <quote>Pass</quote>, <quote>Credit</quote>, <quote>Distinction</quote> or <quote>Incomplete</quote>.</item> </itemised-list> <answer> <p><strong>Enrolment</strong>(<underline>Enrolment<underscore />ID</underline>, Description, Year<underscore />Enrolled, Grade, Comments, Component<underscore />Code, Student<underscore />ID); Component<underscore />Code FK to <strong>Component</strong>, Student<underscore />ID FK to <strong>Student</strong></p> <code-block> CREATE TABLE Enrolment ( Enrolment_ID NUMBER(10), Description VARCHAR2(100) NOT NULL, Year_Enrolled NUMBER(4) NOT NULL CHECK ( Year_Enrolled >= 2008 ), Result VARCHAR2(11) NOT NULL CHECK ( Result IN ( 'E', 'D', 'C-', 'C', 'C+', 'B-', 'B', 'B+', 'A-', 'A', 'A+', 'Fail', 'Pass', 'Credit', 'Distinction', 'Incomplete' ) ) Comments VARCHAR2(4000), -- or CLOB (LONG is deprecated) Student_ID NUMBER(7) NOT NULL, Component_Code CHAR(7) NOT NULL, -- PRIMARY KEY (Enrolment_ID), FOREIGN KEY (Student_ID) REFERENCES Student, FOREIGN KEY (Component_Code) REFERENCES Component ); </code-block> <p><code>ON DELETE CASCADE</code> <em>does</em> make sense for the <code>Student_ID</code> foreign key here (and also for the foreign keys in <code>Staff_Component</code>), because the existence of these data is very tightly linked with the associated data. This is a very good illustration of the point that we need to consider not just structural aspects of a problem when building a database, but also procedural aspects.</p> </answer> </section> <section> <title>The <tt>Component</tt> entity and its subtypes</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"><tt>Component</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>Component_Code</code></cell> <cell>7 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Title</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Points</code></cell> <cell>Integer, default 20 (also see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Period</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Component_Type</code></cell> <cell>(see below)</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>The component code comprises a four-letter subject code (e.g., <quote>INFO</quote>) followed by a three digit course number (e.g., <quote>212</quote>). The course numbers for Diploma, Masters<apostrophe/> and PhD theses are 480, 580 and 980 respectively.</item> <item>The period of a component must be one of the following: <quote>SS</quote> (Summer School), <quote>S1</quote> (Semester One), <quote>S2</quote> (Semester Two), <quote>FY</quote> (Full Year) or <quote>O</quote> (Other). [<strong>Bonus:</strong> thesis courses must always be Other.]</item> <item>The component type must be one of the following: <quote>Doctoral thesis</quote>, <quote>Masters<apostrophe/> thesis</quote>, <quote>Diploma thesis</quote> or <quote>Paper</quote>.</item> <item>Semester and Summer School papers are worth 20 points, while full year papers are worth 40 points. A Diploma thesis is worth 40 points, a Masters<apostrophe /> thesis 120 points and a PhD thesis 360 points.</item> <item>The <tt>Thesis</tt> and <tt>Paper</tt> subtypes have no additional attributes.</item> </itemised-list> <answer> <p><strong>Component</strong>(<underline>Component_Code</underline>, Title, Description, Points, Period, Component<underscore />Type)</p> <code-block> CREATE TABLE Component ( Component_Code CHAR(7), Title VARCHAR2(50) NOT NULL, Description VARCHAR2(200) NOT NULL, Points NUMBER(2) NOT NULL CHECK ( Points IN ( 20, 40, 120, 360 ) ), Period CHAR(2) NOT NULL CHECK ( Period IN ( 'S1', 'S2', 'SS', 'FY', 'O' ) ), Component_Type VARCHAR2(15) NOT NULL CHECK ( Component_Code IN ( 'Doctoral thesis', 'Masters'' thesis', 'Diploma thesis', 'Paper' ) ) -- PRIMARY KEY (Component_Code) ); </code-block> <p>This solution uses the integrated approach for transforming subtypes (i.e., one relation containing all the super- and subtype attributes). The reason for this is that the two <code>Component</code> subtypes provide no additional attributes. Splitting them off as separate (single-attribute) relations therefore seems somewhat pointless (but see the further discussion below).</p> <p>There is one significant consequence of using the integrated approach. If we collapse all the <code>Component</code> super- and subtypes into a single entity, we may also want to collapse the <strong>supervises</strong> and <strong>teaches</strong> many-to-many relationships into a single relationship (although we aren<apostrophe />t required to do so). If we do nothing else at this point, we have eliminated some important information from the schema: namely the type of relationship between staff and components (a subtle but important distinction). We can re-introduce this information by adding a <code>Type</code> attribute to the <code>Staff_Component</code> relation when we resolve the many-to-many relationship. This has been included in the SQL code for the table.</p> <p>Some people stated that the discrete approach (three relations) was the best choice, then gave either no justification at all or simply repeated the advantages of the approach mentioned in lectures, presumably on the theory that <quote>if it was stated in lectures, it <em>must</em> be true</quote>. (It is worth noting that we quite clearly stated in those lectures that you should always consider the context in which subtypes occur when deciding on the best approach to transform them.) This clearly shows that those people had not thought about what the best solution might be <em>for this case</em>, and were instead applying a <quote>one size fits all</quote> mentality, which can be very dangerous. In this case, the discrete approach is perhaps not an ideal solution, as it adds some data redundancy and complicates queries by requiring extra joins.</p> <p>However, you can successfully argue that the Institute might want to add new subtypes in future, which would be difficult to achieve under the integrated approach. This is a perfectly valid solution, <em>as long as you clearly state this assumption</em>. A couple of people did precisely this, and got full marks for the subtype transformation. In other words, the schema presented here is not the only possible solution to this problem.</p> <p>A common error when using the discrete approach was to define all three relations containing the all the <code>Component</code> attributes. However, this defeats the purpose of having a <code>Component</code> supertype relation, as the supertype is supposed to contain the attributes that are shared across all subtypes. Implementing it this way would be little different from the additive approach (which doesn<apostrophe />t really work in this scenario; see below). With three relations, <code>Component</code> should have all the attributes, while <code>Thesis</code> and <code>Paper</code> have only the primary key column (plus a foreign key to <code>Component</code>) and nothing else. Yes, it looks weird, but it works, and the end user never has to see it (logical data independence).</p> <p>As noted above, the integrated approach merges the two many-to-many relationships into one, which means you need some kind of <quote>type</quote> attribute in the intermediate relation. However, as a few observant people noted, you can achieve the same effect by looking up <code>Component_Type</code> in <code>Component</code> (bonus marks were awarded to those who spotted this, although note that this solution would require application developers to join with <code>Component</code> and filter appropriately).</p> <p>The additive approach is definitely inappropriate for this scenario because it would force us to include two foreign keys to <code>Component</code> in <code>Enrolment</code>. Worse, because each enrolment is for a single component, only one of those foreign keys can have a value for any given enrolment. This means that both foreign key columns must allow nulls, which is a significant variation from what the original ERD specified. Also, with this approach it is possible to have two identical components that are both a paper and a thesis at the same time!</p> <p>On a completely different note, most people who implemented the <code>CHECK</code> constraint for <code>Component.Component_Type</code> got it slightly wrong, by checking for <quote>Masters thesis</quote> instead of <quote>Masters<apostrophe /> thesis</quote> (note the apostrophe after <quote>Masters</quote>, and check the code above to see how this is done in SQL). This may seem rather picky, but once again, you have to follow the specification in detail, otherwise you can end up in a situation where the front end supplies what should be a valid value, which is then unexpectedly rejected by the back end!</p> </answer> </section> <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 5 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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Grade</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Monetary, <ge/><dollar-sign/>42<digitsep/>670.00</cell> </row> <row-rule/> </tabular-body> </tabular> <itemised-list> <item>Phone numbers must cater for both local landline and cellular numbers.</item> <item>A staff member<apostrophe/>s grade must be one of the following: <quote>AL</quote> (Assistant Lecturer), <quote>L</quote> (Lecturer), <quote>SL</quote> (Senior Lecturer), <quote>AP</quote> (Associate Professor) or <quote>P</quote> (Professor).</item> </itemised-list> <answer> <p><strong>Staff</strong>(<underline>Staff<underscore />ID</underline>, Surname, Other<underscore />Names, Contact<underscore />Phone, Contact<underscore />Address, Username, Grade, Salary)</p> <code-block> CREATE TABLE Staff ( Staff_ID NUMBER(5), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(10), -- at least 10, maybe more Contact_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL, Grade VARCHAR2(2) NOT NULL CHECK ( Grade IN ( 'AL', 'L', 'SL', 'AP', 'P' ) ), Salary NUMBER(7,2) NOT NULL CHECK ( Salary >= 42670 ), -- PRIMARY KEY (Staff_ID) ); </code-block> <p>We also need to add a relation between <code>Staff</code> and <code>Component</code> to resolve the many-to-many relationship:</p> <p><strong>Staff<underscore />Component</strong>(<underline>Staff<underscore />ID, Component<underscore />Code</underline>, Type)</code>; <code>Staff<underscore />ID</code> FK to <code><strong>Staff</strong></code>, <code>Component<underscore />Code</code> FK to <code><strong>Component</strong></p> <code-block> CREATE TABLE Staff_Component ( Staff_ID NUMBER(5), Component_Code CHAR(7), Type VARCHAR2(10) NOT NULL CHECK ( Type IN ( 'teaches', 'supervises' ) ), -- PRIMARY KEY (Staff_ID, Component_Code), FOREIGN KEY (Staff_ID) REFERENCES Staff, FOREIGN KEY (Component_Code) REFERENCES Component ); </code-block> </answer> </section> </section> </document>
Ignore Space
Show notes
View
STINK_student_records.xml
<?xml version="1.0" standalone="yes"?> <document class="fragment"> <section label="sec:database-info"> <title>System specification and details</title> <p>The Southern Technical Institute for Natural Knowledge is a medium-sized tertiary education provider (founded in 1982) that teaches papers across many subjects, which lead to several different qualifications. They are currently in the process of designing and implementing a new student records database. The requirements analysis phase of the project is complete, and you have been brought in as lead database developer. It will be your task to implement an initial prototype of the database 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="!hb"> <caption>ERD of the proposed database (Barker notation)</caption> <image basename="STINK_student_records_barker" location="images"> <description>ERD of the proposed database (Barker notation)</description> </image> </figure> <section label="entity:qualification"> <title>The <tt>Qualification</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>Abbreviation</code></cell> <cell>Up to 10 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Full_Name</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Type</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>The abbreviation is a short string that identifies the qualification, e.g., “BCom”, “PGDipCApSc” (these are not the only possible values).</item> <item>The qualification type must be one of the following: “Degree”, “Diploma” or “Certificate”.</item> </itemised-list> <answer> <code-block> CREATE TABLE Qualification ( Abbreviation VARCHAR2(10), Full_Name VARCHAR2(100) NOT NULL, Type VARCHAR2(11) NOT NULL CONSTRAINT Qualification_Type_Valid CHECK ( Type IN ( 'Degree', 'Diploma', 'Certificate' ) ), -- CONSTRAINT Qualification_PK PRIMARY KEY ( Abbreviation ) ); </code-block> <p indent="no">If we wanted to allow for additional qualification types in future, we could create a separate <code>Qualification_Type</code> lookup table, with a single column <code>Type</code>. We could then replace the <code>CHECK</code> constraint <code>Qualification_Type_Valid</code> with a foreign key to the lookup table. If we use the existing values, this can even be done without breaking the specification.</p> </answer> </section> <section label="entity:paper"> <title>The <tt>Paper</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>Paper_Code</code></cell> <cell>7 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Title</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 500 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Points</code></cell> <cell>Whole number 0–36, default 18</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Period</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item>The paper code comprises a four-letter subject code (e.g., “INFO”) followed by a three digit course number (e.g., “214”).</item> <item>The period must be one of the following: “SS”, “S1”, “S2” or “FY” (representing Summer School, Semester One, Semester Two and Full Year, respectively).</item> </itemised-list> <answer> <code-block> CREATE TABLE Paper ( Paper_Code CHAR(7), Title VARCHAR2(50) NOT NULL, Description VARCHAR2(500) NOT NULL, Points NUMBER(2) DEFAULT 18 NOT NULL CONSTRAINT Paper_Points_Range CHECK ( Points BETWEEN 0 AND 36 ), Period CHAR(2) NOT NULL CONSTRAINT Paper_Period_Valid CHECK ( Period IN ( 'S1', 'S2', 'SS', 'FY' ) ), -- CONSTRAINT Paper_PK PRIMARY KEY ( Paper_Code ) ); </code-block> </answer> </section> <section label="entity:schedule"> <title>The <tt>Schedule</tt> entity</title> <p>The <tt>Schedule</tt> entity exists only to associate <tt>Qualification</tt> with <tt>Paper</tt> and thus has no additional attributes beyond its primary key attributes.</p> <answer> <code-block> CREATE TABLE Schedule ( Abbreviation VARCHAR2(10), Paper_Code CHAR(7), -- CONSTRAINT Schedule_PK PRIMARY KEY ( Abbreviation, Paper_Code ), CONSTRAINT Schedule_FK_to_Qualification FOREIGN KEY ( Abbreviation ) REFERENCES Qualification, CONSTRAINT Schedule_FK_to_Paper FOREIGN KEY ( Paper_Code ) REFERENCES Paper ); </code-block> </answer> </section> <section label="entity:people"> <title>The <tt>Person</tt>, <tt>Staff</tt> and <tt>Student</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"><tt>Person</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>Person_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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 10 characters</cell> </row> <row-rule /> <row> <cell columns="3" /> </row> <row> <cell header="yes" columns="3"><tt>Staff</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>Staff_ID</code></cell> <cell>7 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Rank</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Money, <ge /><dollar-sign /><number>40450.00</number></cell> </row> <row-rule /> <row> <cell columns="3" /> </row> <row> <cell header="yes" columns="3"><tt>Student</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>Student_ID</code></cell> <cell>7 digit identifier</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Home_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Home_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>International</code></cell> <cell>True/false, default false</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item><tt>Staff</tt> and <tt>Student</tt> are subtypes of <tt>Person</tt>, and thus share primary key values.</item> <item>Contact phone numbers must cater for full New Zealand landline and mobile numbers. Students’ home phone numbers must cater for full international numbers, as many students are from overseas.</item> <item>A staff member’s rank must be one of the following: “T”, “AL”, “L”, “SL”, “AP” or “P” (representing Tutor, Assistant Lecturer, Lecturer, Senior Lecturer, Associate Professor and Professor, respectively). Salaries for senior positions exceed <dollar-sign /><number>100000</number>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Person ( Person_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(11), -- at least 11, maybe more Contact_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL CONSTRAINT Person_Username_Unique UNIQUE, -- bonus marks! -- CONSTRAINT Person_PK PRIMARY KEY ( Person_ID ) ); CREATE TABLE Staff ( Staff_ID NUMBER(7), Rank VARCHAR2(2) NOT NULL CONSTRAINT Staff Rank_Valid CHECK ( Rank IN ( 'AL', 'L', 'SL', 'AP', 'P' ) ), Salary NUMBER(8,2) NOT NULL CONSTRAINT Staff_Salary_Range CHECK ( Salary >= 40450 ), -- CONSTRAINT Staff_PK PRIMARY KEY ( Staff_ID ), CONSTRAINT Staff_FK_to_Person FOREIGN KEY ( Staff_ID ) REFERENCES Person ( Person_ID ) ); CREATE TABLE Student ( Student_ID NUMBER(7), Home_Phone VARCHAR2(15), -- ITU Recommendation E.164 Home_Address VARCHAR2(200) NOT NULL, International CHAR(1) DEFAULT 'F' NOT NULL CONSTRAINT Student_International_Valid CHECK ( International IN ( 'T', 'F' ) ), Supervisor_ID NUMBER(7), -- optional -- CONSTRAINT Student_PK PRIMARY KEY (Student_ID), CONSTRAINT Student_FK_to_Person FOREIGN KEY (Student_ID) REFERENCES Person (Person_ID), CONSTRAINT Student_FK_to_Staff FOREIGN KEY (Supervisor_ID) REFERENCES Staff (Staff_ID) ); </code-block> <p>It’s important when implementing “boolean” style columns such as <code>International</code> in <code>Student</code> and <code>Release</code> in <code>Assessment</code> that you are consistent in the values that you use across all such columns (more precisely, all such columns should have the same domain). Quite a few people did something like implement one column as <code>'T', 'F'</code> and the other as <code>'True', 'False'</code>, or even more subtle, <code>'t', 'f'</code> (remembering that SQL is case sensitive). Using inconsistent domains for columns that should have the same domain could lead to subtle bugs later on.</p> <p>This of course is really a consequence of not having a proper <code>BOOLEAN</code> data type in SQL. However, one person did discover—possibly inadvertently, given that it isn’t mentioned anywhere in the documentation—that <OracleServer /> now supports the use of the <code>BOOLEAN</code> data type in <code>CREATE TABLE</code>! This certainly wasn’t possible in older versions, where <code>BOOLEAN</code> was available in PL/SQL only.</p> </answer> </section> <section label="entity:teach"> <title>The <tt>Teach</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>7 digit identifier</cell> </row> <row> <cell><tt><hash /></tt></cell> <cell><code>Paper_Code</code></cell> <cell>7 characters</cell> </row> <row> <cell><tt><hash /></tt></cell> <cell><code>Year_Taught</code></cell> <cell>4 digits</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Role</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item>The teaching year cannot be earlier than the year that the Institute was founded. (Technically it should also not be in the future, but this is surprisingly difficult to check in <OracleServer />! You are welcome to try, but please ensure that you complete the rest of the assignment <em>first</em>.)</item> <item>The role must be one of the following: “Coordinator”, “Lecturer” or “Tutor”.</item> </itemised-list> <answer> <code-block> CREATE TABLE Teach ( Staff_ID NUMBER(7), Paper_Code CHAR(7), Year_Taught NUMBER(4), CONSTRAINT Teach_Year_Taught_Range CHECK ( Year_Taught >= 1982 ), Role VARCHAR2(11) NOT NULL CONSTRAINT Teach_Role_Valid CHECK ( Role IN ( 'Coordinator', 'Lecturer', 'Tutor' ) ), -- CONSTRAINT Teach_PK PRIMARY KEY ( Staff_ID, Paper_Code, Year_Taught ), CONSTRAINT Teach_FK_to_Staff FOREIGN KEY ( Staff_ID ) REFERENCES Staff, CONSTRAINT Teach_FK_to_Paper FOREIGN KEY ( Paper_Code ) REFERENCES Paper ); </code-block> </answer> </section> <section label="entity:enrolment"> <title>The <tt>Enrolment</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>Enrolment_ID</code></cell> <cell>Internally generated 10 digit identifier</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>Year_Enrolled</code></cell> <cell>4 digits</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Comments</code></cell> <cell>Text (see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item>The enrolment year cannot be earlier than the year that the Institute was founded (nor in the future—see the note above under the <hyperlink label="entity:teach"><tt>Teach</tt><space />entity</hyperlink>).</item> <item>Comments are used to record details of any issues relating to the enrolment, e.g., a detailed explanation of the reasons for waiving a prerequisite, or a description of how a timetable clash is to be resolved.</item> </itemised-list> <answer> <code-block> CREATE TABLE Enrolment ( Enrolment_ID NUMBER(10), Description VARCHAR2(100) NOT NULL, Year_Enrolled NUMBER(4) NOT NULL CONSTRAINT Enrolment_Year_Enrolled_Range CHECK (Year_Enrolled >= 1982), Comments VARCHAR2(4000), -- or CLOB Student_ID NUMBER(7) NOT NULL, Paper_Code CHAR(7) NOT NULL, -- CONSTRAINT Enrolment_PK PRIMARY KEY ( Enrolment_ID ), CONSTRAINT Enrolment_FK_to_Student FOREIGN KEY ( Student_ID ) REFERENCES Student, CONSTRAINT Enrolment_FK_to_Paper FOREIGN KEY ( Paper_Code ) REFERENCES Paper ); </code-block> <p indent="no">A surprising number of people appear to have missed the statement of when the Institute was founded in the first paragraph of the specification!</p> <p>Another very common error was to set the size of the <code>Comments</code> column to a relatively small number, like 200. Think about how much you can say in that many characters (one and a bit text messages), then consider what kinds of things you might want to enter into a general comments column. We deducted marks for anything smaller than 500 characters. When you have no idea of how much you’re going to get, it’s much better to go large than to go small!</p> </answer> </section> <section label="entity:assessment"> <title>The <tt>Assessment</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>Assessment_ID</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Assessment_Year</code></cell> <cell>4 digits</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>Description</code></cell> <cell>Up to 500 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Type</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Release</code></cell> <cell>True/false, default false</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Weight</code></cell> <cell>0–100, no decimal places</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Maximum_Mark</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item>A new set of assessments is created for each year that a paper is offered. The year cannot be earlier than the year that the Institute was founded (nor in the future—see the note above under the <hyperlink label="entity:teach"><tt>Teach</tt><space />entity</hyperlink>).</item> <item>The assessment type must be one of the following: “A”, “P”, “T” or “X” (representing assignment, presentation, test and exam, respectively).</item> <item>The <code>Maximum_Mark</code> attribute stores the maximum possible raw mark for the assessment (e.g., 30), while the <code>Weight</code> attribute stores the percentage weight of this assessment for the paper as a whole (e.g., 10<percent-sign />). If <code>Maximum_Mark</code> is not specified, then front-end applications should use <code>Weight</code> for both.</item> <item>The <code>Release</code> attribute controls whether or not the marks for this assessment are accessible by students.</item> </itemised-list> <answer> <code-block> CREATE TABLE Assessment ( Assessment_ID NUMBER(10), Assessment_Year NUMBER(4) NOT NULL CONSTRAINT Assessment_Year_Range CHECK ( Assessment_Year >= 1982 ), Name VARCHAR2(50) NOT NULL, Description VARCHAR2(500), Type CHAR(1) NOT NULL CONSTRAINT Assessment_Type_Valid CHECK ( Type IN ( 'A', 'P', 'T', 'X' ) ), Release CHAR(1) DEFAULT 'F' NOT NULL CONSTRAINT Assessment_Release_Valid CHECK ( Release IN ( 'T', 'F' ) ), Weight NUMBER(3) NOT NULL CONSTRAINT Assessment_Weight_Range CHECK ( Weight BETWEEN 0 AND 100 ), Maximum_Mark NUMBER(3), Paper_Code CHAR(7) NOT NULL, -- CONSTRAINT Assessment_PK PRIMARY KEY ( Assessment_ID ), CONSTRAINT Assessment_FK_to_Paper FOREIGN KEY ( Paper_Code ) REFERENCES Paper ); </code-block> </answer> </section> <section label="entity:result"> <title>The <tt>Result</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>Assessment_ID</code></cell> <cell>10 digit identifier</cell> </row> <row> <cell><tt><hash /></tt></cell> <cell><code>Enrolment_ID</code></cell> <cell>10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Raw_Mark</code></cell> <cell>3 digits plus 1 decimal place (i.e., 000.0)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Weighted_Mark</code></cell> <cell>Floating point</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Percentage_Mark</code></cell> <cell>0–100, 2 decimal places</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="medium" /> <itemised-list> <item>The <code>Raw_Mark</code> attribute stores the raw mark awarded for an assessment. Its value should be between zero and the value of <code>Assessment.Maximum_Mark</code> (note that only the lower bound is required for this assignment—bonus marks if you can also implement the upper bound).</item> <item>The value of the <code>Weighted_Mark</code> attribute is calculated by the formula: <line-break /> <code>Raw_Mark</code> / <code>Assessment.Maximum_Mark</code><space /> <times /><space /> <code>Assessment.Weight</code>.</item> <item>The value of the <code>Percentage_Mark</code> attribute is calculated by the formula: <line-break /> <code>Raw_Mark</code> / <code>Assessment.Maximum_Mark</code><space /> <times /> 100.</item> <item>Note that the calculations for <code>Weighted_Mark</code> and <code>Percentage_Mark</code> are <emph>not</emph> constraints and should not be implemented as such! You may attempt to implement these calculations if you feel confident in your ability to do so, but please ensure that you complete the rest of the assignment <em>first</em>.</item> </itemised-list> <answer> <code-block> CREATE TABLE Result ( Assessment_ID NUMBER(10), Enrolment_ID NUMBER(10), Raw_Mark NUMBER(4,1) NOT NULL, Weighted_Mark NUMBER NOT NULL, Percentage_Mark NUMBER(5,2) NOT NULL CONSTRAINT Result_Percentage_Mark_Range CHECK (Percentage_Mark BETWEEN 0 AND 100), -- CONSTRAINT Result_PK PRIMARY KEY ( Assessment_ID, Enrolment_ID ), CONSTRAINT Result_FK_to_Assessment FOREIGN KEY ( Assessment_ID ) REFERENCES Assessment, CONSTRAINT Result_FK_to_Enrolment FOREIGN KEY ( Enrolment_ID ) REFERENCES Enrolment ); </code-block> <p indent="no">A lot of people got the sizes of the various <code>NUMBER</code> columns incorrect. Remember that the number of decimal places is <em>included</em> in the total number of digits, not <em>in addition to</em>.</p> <p>We also accepted <code>FLOAT</code> and <code>BINARY_FLOAT</code> for <code>Weighted_Mark</code>. Anything with a fixed number of decimal places was marked down, as this is a <em>fixed</em> point number, not a floating point number.</p> </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>The Southern Technical Institute for Natural Knowledge is a medium-sized tertiary education provider (founded in 1982) that teaches papers across many subjects, which lead to several different qualifications. They are currently in the process of designing and implementing a new student records database. The requirements analysis and conceptual design phases of the project are complete, and you have been brought in as lead database developer. It will be your task to implement an initial prototype of the conceptual specification. A design-level entity-relationship diagram 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. <strong>Reminder:</strong> In the tables that follow, <quote><tt><hash /></tt></quote> indicates the unique identifier, <quote><tt>*</tt></quote> indicates that a value is required, and <quote><tt>o</tt></quote> indicates that a value is not required.</p> <figure label="fig:erd" latex-placement="!hb"> <caption>Design-level ERD of the proposed database</caption> <image basename="STINK_student_records" location="images"> <description>Design-level ERD of the proposed database</description> </image> </figure> <section> <title>The <tt>Qualification</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>Abbreviation</code></cell> <cell>Up to 10 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Full_Name</code></cell> <cell>Up to 100 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Type</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>The abbreviation is a short string that identifies the qualification, e.g., <quote>BCom</quote>, <quote>PGDipCApSc</quote> (these are not the only possible values).</item> <item>The qualification type must be one of the following: <quote>Degree</quote>, <quote>Diploma</quote> or <quote>Certificate</quote>.</item> </itemised-list> <answer> <p indent="no"><strong>Qualification</strong><left-brace /><underline>Abbreviation</underline>, Full<underscore />Name, Type<right-brace /></p> <code-block> CREATE TABLE Qualification ( Abbreviation VARCHAR2(10), Full_Name VARCHAR2(100) NOT NULL, Type VARCHAR2(11) NOT NULL CONSTRAINT Qualification_Type_Valid CHECK (Type IN ('Degree', 'Diploma', 'Certificate')), -- CONSTRAINT Qualification_PK PRIMARY KEY (Abbreviation) ); </code-block> <p indent="no">If we wanted to allow for additional qualification types in future, we could create a separate <code>Qualification_Type</code> lookup table, with a single column <code>Type</code>. We could then replace the <code>CHECK</code> constraint <code>Qualification_Type_Valid</code> with a foreign key to the lookup table. </p> </answer> </section> <section> <title>The <tt>Paper</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>Paper_Code</code></cell> <cell>7 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Title</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Description</code></cell> <cell>Up to 500 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Points</code></cell> <cell>Integer 0<endash />36, default 18</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Period</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <vskip size="large" /> <p indent="no">The period of a paper must be one of the following: <quote>SS</quote> (Summer School), <quote>S1</quote> (Semester One), <quote>S2</quote> (Semester Two) or <quote>FY</quote> (Full Year).</p> <answer> <p indent="no"><strong>Paper</strong><left-brace /><underline>Paper<underscore />Code</underline>, Title, Description, Points, Period<right-brace /></p> <code-block> CREATE TABLE Paper ( Paper_Code CHAR(7), Title VARCHAR2(50) NOT NULL, Description VARCHAR2(500) NOT NULL, Points NUMBER(2) DEFAULT 18 NOT NULL CONSTRAINT Paper_Points_Range CHECK (Points BETWEEN 0 AND 36), Period CHAR(2) NOT NULL CONSTRAINT Paper_Period_Valid CHECK (Period IN ('S1', 'S2', 'SS', 'FY')), -- CONSTRAINT Paper_PK PRIMARY KEY (Paper_Code) ); </code-block> <p indent="no">We also need to add an associative entity between <strong>Paper</strong> and <strong>Qualification</strong> in order to resolve the many-to-many relationship:</p> <vskip size="small" /> <p indent="no"><strong>Schedule</strong><left-brace/><underline>Abbreviation, Paper<underscore/>Code</underline><right-brace/>; Abbreviation FK to <strong>Qualification</strong>, Paper<underscore/>Code FK to <strong>Paper</strong></p> <code-block> CREATE TABLE Schedule ( Abbreviation VARCHAR2(10), Paper_Code CHAR(7), -- CONSTRAINT Schedule_PK PRIMARY KEY (Abbreviation, Paper_Code), CONSTRAINT Schedule_FK_to_Qualification FOREIGN KEY (Abbreviation) REFERENCES Qualification, CONSTRAINT Schedule_FK_to_Paper FOREIGN KEY (Paper_Code) REFERENCES Paper ); </code-block> </answer> </section> <section> <title>The <tt>Person</tt> entity and its subtypes</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"><tt>Person</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>Person_ID</code></cell> <cell>Internally generated 7 digit identifier (see below)</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>Other_Names</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Contact_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Contact_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Username</code></cell> <cell>Up to 10 characters</cell> </row> <row-rule /> <row> <cell columns="3" /> </row> <row> <cell header="yes" columns="3"><tt>Staff</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>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Rank</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Salary</code></cell> <cell>Monetary, <ge /><dollar-sign />35<digitsep />450.00</cell> </row> <row-rule /> <row> <cell columns="3" /> </row> <row> <cell header="yes" columns="3"><tt>Student</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>Email</code></cell> <cell>Up to 50 characters</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Home_Phone</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Home_Address</code></cell> <cell>Up to 200 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>International</code></cell> <cell>True/false, default false</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>You are not required to automatically generate the value of the <code>Person_ID</code> attribute, but bonus marks will be awarded if you are able to do so. (This also applies to the <code>Enrolment_ID</code> and <code>Assessment_ID</code> attributes below.)</item> <item>Phone numbers must cater for full international numbers, as many students are from overseas.</item> <item>A staff member<apostrophe />s rank must be one of the following: <quote>AL</quote> (Assistant Lecturer), <quote>L</quote> (Lecturer), <quote>SL</quote> (Senior Lecturer), <quote>AP</quote> (Associate Professor) or <quote>P</quote> (Professor).</item> </itemised-list> <answer> <p indent="no"><strong>Person</strong><left-brace /><underline>Person<underscore />ID</underline>, Surname, Other<underscore />Names, Contact<underscore />Phone, Contact<underscore />Address, Username<right-brace /></p> <vskip size="small" /> <p indent="no"><strong>Staff</strong><left-brace /><underline>Staff<underscore />ID</underline>, Email, Rank, Salary<right-brace />; Staff<underscore />ID FK to <strong>Person</strong></p> <vskip size="small" /> <p indent="no"><strong>Staff</strong><left-brace /><underline>Student<underscore />ID</underline>, Email, Home<underscore />Phone, Home<underscore />Address, International, Supervisor<underscore />ID<right-brace />; Student<underscore />ID FK to <strong>Person</strong>, Supervisor<underscore />ID FK to <strong>Staff</strong></p> <code-block> CREATE TABLE Person ( Person_ID NUMBER(7), Surname VARCHAR2(50) NOT NULL, Other_Names VARCHAR2(50) NOT NULL, Contact_Phone VARCHAR2(12), -- at least 12, maybe more Contact_Address VARCHAR2(200) NOT NULL, Username VARCHAR2(50) NOT NULL CONSTRAINT Person_Username_Unique UNIQUE, -- bonus marks! -- CONSTRAINT Person_PK PRIMARY KEY (Person_ID) ); CREATE TABLE Staff ( Staff_ID NUMBER(7), Email VARCHAR2(50) NOT NULL, Rank VARCHAR2(2) NOT NULL CONSTRAINT Staff Rank_Valid CHECK (Rank IN ('AL', 'L', 'SL', 'AP', 'P')), Salary NUMBER(7,2) NOT NULL CONSTRAINT Staff_Salary_Range CHECK (Salary >= 35450), -- CONSTRAINT Staff_PK PRIMARY KEY (Staff_ID), CONSTRAINT Staff_FK_to_Person FOREIGN KEY (Staff_ID) REFERENCES Person (Person_ID) ); CREATE TABLE Student ( Student_ID NUMBER(7), Email VARCHAR2(50) NOT NULL, Home_Phone VARCHAR2(12), Home_Address VARCHAR2(200) NOT NULL, International CHAR(1) DEFAULT 'F' NOT NULL CONSTRAINT Student_International_Valid CHECK (International IN ('T', 'F')), Supervisor_ID NUMBER(7), -- optional -- CONSTRAINT Student_PK PRIMARY KEY (Student_ID), CONSTRAINT Student_FK_to_Person FOREIGN KEY (Student_ID) REFERENCES Person (Person_ID), CONSTRAINT Student_FK_to_Staff FOREIGN KEY (Supervisor_ID) REFERENCES Staff (Staff_ID) ); </code-block> <p indent="no">This solution uses the discrete approach for transforming subtypes. The additive approach is also feasible (i.e., place the <strong>Person</strong> attributes into both <strong>Staff</strong> and <strong>Student</strong>, and eliminate <strong>Person</strong> entirely). We accepted either approach, but note that the discrete approach has one distinct advantage over the additive approach in this scenario. Consider what happens when someone is both a staff member and a student: we end up duplicating all the <quote>person</quote> data across both tables. This doesn<apostrophe />t occur with the discrete approach. People who didn<apostrophe />t discuss this aspect lost marks.</p> <p>For those who implemented the additive approach, we marked the <quote>person</quote> attributes in <strong>Staff</strong> and <strong>Student</strong> as if they were a separate <strong>Person</strong> entity.</p> <p>The integrated approach was definitely <em>not</em> suitable due to the supervision relationship between <strong>Staff</strong> and <strong>Student</strong> (which, incidentally, many people missed completely), and the mandatory attributes that exist in both <strong>Staff</strong> and <strong>Student</strong>.</p> <p>We also need to add an associative entity between <strong>Paper</strong> and <strong>Staff</strong> in order to resolve the many-to-many relationship:</p> <vskip size="small" /> <p indent="no"><strong>Teach</strong><left-brace /><underline>Staff<underscore />ID, Paper<underscore />Code</underline><right-brace />; Staff<underscore />ID FK to <strong>Staff</strong>, Paper<underscore />Code FK to <strong>Paper</strong></p> <code-block> CREATE TABLE Teach ( Staff_ID NUMBER(7), Paper_Code CHAR(7), -- CONSTRAINT Teach_PK PRIMARY KEY (Staff_ID, Paper_Code), CONSTRAINT Teach_FK_to_Staff FOREIGN KEY (Staff_ID) REFERENCES Staff, CONSTRAINT Teach_FK_to_Paper FOREIGN KEY (Paper_Code) REFERENCES Paper ); </code-block> <p>It<apostrophe />s important when implementing <quote>boolean</quote> style columns such as <code>International</code> in <code>Student</code> and <code>Visible</code> in <code>Assessment</code> that you are consistent in the values that you use across all such columns (more precisely, all such columns should have the same domain). Quite a few people did something like implement one column as <code>'T', 'F'</code> and the other as <code>'True', 'False'</code>, or even more subtle, <code>'t', 'f'</code> (remembering that SQL is case sensitive). Using inconsistent domains for columns that should have the same domain could lead to subtle bugs later on.</p> <p>This of course is really a consequence of not having a proper <code>BOOLEAN</code> data type in SQL. However, one person did discover<emdash />possibly inadvertently, given that it isn<apostrophe />t mentioned anywhere in the documentation<emdash />that <OracleServer /> now supports the use of the <code>BOOLEAN</code> data type in <code>CREATE TABLE</code>! This certainly wasn<apostrophe />t possible in older versions, where <code>BOOLEAN</code> was available in PL/SQL only.</p> </answer> </section> <newpage /> <section> <title>The <tt>Enrolment</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>Enrolment_ID</code></cell> <cell>Internally generated 10 digit identifier</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>Year_Enrolled</code></cell> <cell>4 digits</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="large" /> <p indent="no">The year of enrolment cannot be earlier than the year in which the Institute was founded. (Technically it should also not be in the future, but we cannot check this in <OracleServer />.)</p> <answer> <p indent="no"><strong>Enrolment</strong>(<underline>Enrolment<underscore />ID</underline>, Description, Year<underscore />Enrolled, Comments, Paper<underscore />Code, Student<underscore />ID); Paper<underscore />Code FK to <strong>Paper</strong>, Student<underscore />ID FK to <strong>Student</strong></p> <code-block> CREATE TABLE Enrolment ( Enrolment_ID NUMBER(10), Description VARCHAR2(100) NOT NULL, Year_Enrolled NUMBER(4) NOT NULL CONSTRAINT Enrolment_Year_Enrolled_Range CHECK (Year_Enrolled >= 1982), Comments VARCHAR2(4000), -- or CLOB Student_ID NUMBER(7) NOT NULL, Paper_Code CHAR(7) NOT NULL, -- CONSTRAINT Enrolment_PK PRIMARY KEY (Enrolment_ID), CONSTRAINT Enrolment_FK_to_Student FOREIGN KEY (Student_ID) REFERENCES Student, CONSTRAINT Enrolment_FK_to_Paper FOREIGN KEY (Paper_Code) REFERENCES Paper ); </code-block> <p indent="no">A surprising number of people appear to have missed the statement of when the Institute was founded in the first paragraph of the specification!</p> <p>Another very common error was to set the size of the <code>Comments</code> column to a relatively small number, like 200. Think about how much you can say in that many characters (one and a bit text messages), then consider what kinds of things you might want to enter into a general comments column. We deducted marks for anything smaller than 500 characters. When you have no idea of how much you<apostrophe />re going to get, it<apostrophe />s much better to go large than to go small!</p> </answer> </section> <section> <title>The <tt>Assessment</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>Assessment_ID</code></cell> <cell>Internally generated 10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Assessment_Year</code></cell> <cell>4 digits</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>Description</code></cell> <cell>Up to 500 characters</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Type</code></cell> <cell>(see below)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Visible</code></cell> <cell>True/false, default false</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Weight</code></cell> <cell>0<endash />100, no decimal places</cell> </row> <row> <cell><tt>o</tt></cell> <cell><code>Maximum_Mark</code></cell> <cell>(see below)</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>A new set of assessments is created for each year that a paper is offered. The year cannot be earlier than the year in which the Institute was founded. (Technically it should also not be in the future, but we cannot check this in <OracleServer />.)</item> <item>The assessment type must be one of the following: <quote>A</quote> (assignment), <quote>T</quote> (test) or <quote>X</quote> (exam).</item> <item>The <code>Maximum_Mark</code> attribute stores the maximum possible raw mark for the assessment (e.g., 30), while the <code>Weight</code> attribute stores the percentage weight of this assessment for the paper as a whole (e.g., 10<percent-sign />). If <code>Maximum_Mark</code> is not specified, then applications should use <code>Weight</code> for both.</item> <item>The <code>Visible</code> attribute controls whether or not the marks for this assessment are publicly accessible.</item> </itemised-list> <answer> <p indent="no"><strong>Assessment</strong>(<underline>Assessment<underscore />ID</underline>, Assessment<underscore />Year, Name, Description, Type, Visible, Weight, Maximum<underscore />Mark, Paper<underscore />Code); Paper<underscore />Code FK to <strong>Paper</strong></p> <code-block> CREATE TABLE Assessment ( Assessment_ID NUMBER(10), Assessment_Year NUMBER(4) NOT NULL CONSTRAINT Assessment_Year_Range CHECK (Assessment_Year >= 1982), Name VARCHAR2(50) NOT NULL, Description VARCHAR2(500), Type CHAR(1) NOT NULL CONSTRAINT Assessment_Type_Valid CHECK (Type IN ('A', 'T', 'X')), Visible CHAR(1) DEFAULT 'F' NOT NULL CONSTRAINT Assessment_Visible_Valid CHECK (Visible IN ('T', 'F')), Weight NUMBER(3) NOT NULL CONSTRAINT Assessment_Weight_Range CHECK (Weight BETWEEN 0 AND 100), Maximum_Mark NUMBER(3), Paper_Code CHAR(7) NOT NULL, -- CONSTRAINT Assessment_PK PRIMARY KEY (Assessment_ID), CONSTRAINT Assessment_FK_to_Paper FOREIGN KEY (Paper_Code) REFERENCES Paper ); </code-block> </answer> </section> <newpage /> <section> <title>The <tt>Result</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>Assessment_ID</code></cell> <cell>10 digit identifier</cell> </row> <row> <cell><tt><hash /></tt></cell> <cell><code>Enrolment_ID</code></cell> <cell>10 digit identifier</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Raw_Mark</code></cell> <cell>3 digits plus 1 decimal place (i.e., 000.0)</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Weighted_Mark</code></cell> <cell>Floating point</cell> </row> <row> <cell><tt>*</tt></cell> <cell><code>Percentage_Mark</code></cell> <cell>0<endash />100, 2 decimal places</cell> </row> <row-rule /> </tabular-body> </tabular> <itemised-list> <item>The <code>Raw_Mark</code> attribute stores the raw mark awarded for an assessment. Its value should be between zero and the value of <code>Assessment.Maximum_Mark</code> (note that only the former is required for this assignment<emdash />bonus marks if you can also achieve the latter).</item> <item>The value of the <code>Weighted_Mark</code> attribute is calculated by the formula: <line-break /> <code>Raw_Mark</code> / <code>Assessment.Maximum_Mark</code><space /> <times /><space /> <code>Assessment.Weight</code>.</item> <item>The value of the <code>Percentage_Mark</code> attribute is calculated by the formula: <line-break /> <code>Raw_Mark</code> / <code>Assessment.Maximum_Mark</code><space /> <times /> 100.</item> <item>Note that the two calculations above are <emph>not</emph> constraints and should not be implemented as such. You may attempt to implement these calculations if you feel confident in your ability to do so, but please ensure that you complete the rest of the assignment <em>first</em>.</item> </itemised-list> <answer> <p indent="no"><strong>Result</strong>(<underline>Assessment<underscore />ID, Enrolment<underscore />ID</underline>, Raw<underscore />Mark, Weighted<underscore />Mark, Percentage<underscore />Mark); Assessment<underscore />ID FK to <strong>Assessment</strong>, Enrolment<underscore />ID FK to <strong>Enrolment</strong></p> <code-block> CREATE TABLE Result ( Assessment_ID NUMBER(10), Enrolment_ID NUMBER(10), Raw_Mark NUMBER(4,1) NOT NULL, Weighted_Mark NUMBER NOT NULL, Percentage_Mark NUMBER(5,2) NOT NULL CONSTRAINT Result_Percentage_Mark_Range CHECK (Percentage_Mark BETWEEN 0 AND 100), -- CONSTRAINT Result_PK PRIMARY KEY (Assessment_ID, Enrolment_ID), CONSTRAINT Result_FK_to_Assessment FOREIGN KEY (Assessment_ID) REFERENCES Assessment, CONSTRAINT Result_FK_to_Enrolment FOREIGN KEY (Enrolment_ID) REFERENCES Enrolment ); </code-block> <p indent="no">A lot of people got the sizes of the various <code>NUMBER</code> columns incorrect. Remember that the number of decimal places is <em>included</em> in the total number of digits, not <em>in addition to</em>.</p> <p>We also accepted <code>FLOAT</code> and <code>BINARY_FLOAT</code> for <code>Weighted_Mark</code>. Anything with a fixed number of decimal places was marked down, as this is a <em>fixed</em> point number, not a floating point number.</p> </answer> </section> </section> </document>
Show line notes below