Newer
Older
sqlmarker / STINK_student_records / 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><![CDATA[
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>
				
				<p>Remember also that SQL string comparison is case sensitive, so it’s important to get the values in the <code>CHECK</code> constraint for <code>Type</code> correct and apply them consistently.</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><![CDATA[
CREATE TABLE Paper
( Paper_Code        CHAR(7)
    CONSTRAINT Paper_Code_Valid
      CHECK ( REGEXP_LIKE( Paper_Code, '[A-Z]{4}[0-9]{3}' ) ),
  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">As with <code>Qualification.Type</code>, we could create a separate lookup table for <code>Period</code>. This table could even store additional information about the period, such as its full name, start and end dates, etc.</p>
				
				<p>There are several ways that we could write the regular expression for the paper code. The expression above could be shortened even further by replacing the <code>[0-9]</code> with <code>\d</code>, which means “any digit 0–9”.</p>
			
			</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><![CDATA[
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>
				
				<p indent="no">The most common problems here were omitting either the primary key or the foreign keys. Note also that there’s no need to repeat constraints on, e.g., <code>Paper_Code</code>, because the foreign key already forces the value to be one that exists in <code>Paper</code> anyway.</p>
			
			</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 Associate Professors and Professors usually exceed <dollar-sign /><number>100000</number>.</item>
				
			</itemised-list>

			<answer>
			
				<code-block><![CDATA[
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,
  Email             VARCHAR2(50)    NOT NULL,
  Username          VARCHAR2(10)    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 ( 'T', '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
);

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,
  CONSTRAINT Student_FK_to_Staff
    FOREIGN KEY ( Supervisor_ID ) REFERENCES Staff
);]]>
				</code-block>
			
				<p indent="no">The subtype hierarchy seemed to confuse a few people. The most common example of this was, e.g., including both <code>Person_ID</code> and <code>Staff_ID</code> in <code>Staff</code>. This is unnecessary because they should be the same value anyway, and a column can appear in both the primary key and a foreign key at the same time. Also make sure that the foreign keys are referring to the correct tables as specified in the ERD (e.g., <code>Supervisor_ID</code> should reference <code>Staff</code>, not <code>Person</code>).</p>
				
				<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’re consistent in the values that you use across all such columns (more precisely, all such columns should have the same domain). 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 string comparsion is case sensitive). Using inconsistent domains for columns that should have the same domain could lead to subtle bugs later on.</p>
				
				<p>A few people implemented something like <code>'T', 'F', 't', 'f'</code> on the seemingly reasonable theory that it was more “flexible”. (One person even included <code>'Y', 'N', 'y', 'n', '0', 1'</code>!) This kind of “flexibility” usually causes more problems than it solves, unfortunately. The main problem is that it’s now harder to write queries to find all the (for example) “true” values: we either have to test for all the possible permutations of “true”, or we have convert everything to the same format before comparing. Either way it's a pain to implement, and easy to get wrong. Keep things as simple as possible! You’ll thank yourself later.</p>
				
				<p>This of course is really a consequence of not having a proper <code>BOOLEAN</code> data type in SQL. There was a period where <OracleServer /> release 1 could create columns of type <code>BOOLEAN</code>, but this must have been unintentional, as it was never documented, and it no longer works as of <OracleServer /> release 2. The only place you can use <code>BOOLEAN</code> in <OracleServer /> is in its built-in database programming language, PL/SQL. The inconsistency of implementation of a Boolean data type across various DBMSs means that it’s generally safer to use the approach above if portability is important.</p>
				
				<p>Once again, we could use a lookup table for <code>Staff.Rank</code>.</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><![CDATA[
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>
				
				<p indent="no">A surprising number of people appear to have missed the statement of the year that the Institute was founded in the first paragraph of the specification! Again, <code>Role</code> could be constrained using a lookup table.</p>

			</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><![CDATA[
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 common error (especially amongst those who didn’t use the schema checker) 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, maybe 30 words), 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><![CDATA[
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)
    CONSTRAINT Assessment_Maximum_Mark_Range
      CHECK ( Maximum_Mark >= 0 ),  -- bonus marks!
  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>
				
				<p indent="no"><code>Type</code> could be constrained by a lookup table.</p>
				
			</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><![CDATA[
CREATE TABLE Result
( Assessment_ID     NUMBER(10),
  Enrolment_ID      NUMBER(10),
  Raw_Mark          NUMBER(4,1)     NOT NULL
    CONSTRAINT Result_Raw_Mark_Range CHECK ( Raw_Mark >= 0 ),
  Weighted_Mark     NUMBER          NOT NULL
    CONSTRAINT Result_Weighted_Mark_Range
      CHECK ( Weighted_Mark >= 0 ), -- bonus marks!
  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">Quite a few 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>, <code>DOUBLE</code> (although it’s really overkill), <code>BINARY_FLOAT</code> and <code>BINARY_DOUBLE</code> for <code>Weighted_Mark</code>. Anything with a fixed length or number of decimal places was marked down, as this is a <em>fixed</em> point number, not a floating point number. The whole point (!) is that the precision and decimal places should adjust to what’s required at the time.</p>
				
				<p>As a couple of students discovered, <OracleServer /> now supports <em>virtual columns</em> that are computed by a formula, which opens the possibility of automatically computing the values of <code>Weighted_Mark</code> and <code>Percentage_Mark</code>. Unfortunately, virtual columns expressions can’t refer to columns in other tables, so the only way we can achieve this is to duplicate the <code>Maximum_Mark</code> and <code>Weight</code> columns from <code>Assessment</code> into <code>Result</code>. This could actually be useful in practice, however, as would enable us to vary the weight and maximum mark on a per-submission basis (perhaps to cater for students who were unable to complete the entire assignment due to unusual circumstances). We could use a trigger that runs before an <code>INSERT</code> on <code>Result</code> to copy across the “default” values from <code>Assessment</code>. <code>Result</code> could then look something like this:</p>
				
				<code-block><![CDATA[
  ...
  Weight            NUMBER(3)       NOT NULL
    CONSTRAINT Result_Weight_Range CHECK ( Weight BETWEEN 0 AND 100 ),
  Maximum_Mark      NUMBER(3)
    CONSTRAINT Result_Maximum_Mark_Range CHECK ( Maximum_Mark >= 0 ),
  Raw_Mark          NUMBER(4,1)     NOT NULL
    CONSTRAINT Result_Raw_Mark_Range CHECK ( Raw_Mark >= 0 ),
  Weighted_Mark     NUMBER 
    GENERATED ALWAYS AS ( Raw_Mark / Maximum_Mark * Weight ),
  Percentage_Mark   NUMBER(5,2)
    GENERATED ALWAYS AS ( Raw_Mark / Maximum_Mark * 100 ),
  ...
]]>
				</code-block>
				
			</answer>
			
		</section>
	
	</section>

</document>