Entering content frame

Background documentation Explanation of the Database Objects in HOTELDB_COMPLETE Locate the document in its SAP Library structure

After you execute the SQL statements for data definition in HOTELDB_COMPLETE, the HOTEL schema contains the tables city, customer, hotel, room, reservation, employee, and other database objects. The tables were filled with data using the INSERT statements.

Tables

CITY

Each row in this table contains the following information: zip, name of the city, abbreviation of the name of the state where the city is located.

CREATE TABLE city
(zip       CHAR(5)  PRIMARY KEY CONSTRAINT zip_cons CHECK
                  SUBSTR(zip,1,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,2,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,3,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,4,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,5,1) BETWEEN '0' AND '9',
 
name      CHAR(20) NOT NULL,
 state     CHAR(2)  NOT NULL)

The zip column contains the primary key.

The zip_cons constraint ensures that the only numbers between 0 and 9 can be entered for the zip code.

The city name (name) and state abbreviation (state) columns cannot contain NULL values.

CUSTOMER

Each row in this table contains the following customer information: a number that uniquely identifies the customer, the title used for correspondence with the customer, the customer’s first and last name, and the customer’s address consisting of the zip code, street, and house number.

CREATE TABLE customer
(cno        FIXED(4) PRIMARY KEY CONSTRAINT cno_cons CHECK cno > 0,
 title      CHAR(7) CONSTRAINT title_cons CHECK title IN ('Mr', 'Mrs', 'Company'),
 firstname  CHAR(10),
 name       CHAR(10) NOT NULL,
 zip        CHAR(5) CONSTRAINT zip_cons CHECK
                  SUBSTR(zip,1,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,2,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,3,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,4,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,5,1) BETWEEN '0' AND '9',
 address    CHAR(25) NOT NULL,
FOREIGN KEY customer_zip_in_city (zip) REFERENCES city ON DELETE RESTRICT)

The cno column contains the primary key.

The cno_cons constraint ensures that a customer number greater than zero is selected.

The title_cons constraint ensures that Mr, Mrs, or Company is selected as the title.

NULL values cannot be entered in the name and address columns.

The zip_cons constraint ensures that the only numbers between 0 and 9 can be entered for the zip code.

The zip column contains the foreign key. The keywords ON DELETE RESTRICT cause a warning to be displayed when a row in the CITY table is deleted if the CUSTOMER table contains a row that matches the zip code of the row to be deleted.

HOTEL

Each row in this table contains the following hotel information: a number that uniquely identifies the hotel, the hotel name and address (zip code, street, and house number), and information about the hotel.

CREATE TABLE hotel
(hno     FIXED(4) PRIMARY KEY CONSTRAINT hno_cons CHECK hno > 0,
 name    CHAR(15) NOT NULL,
 zip     CHAR(5) CONSTRAINT zip_cons CHECK
                  SUBSTR(zip,1,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,2,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,3,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,4,1) BETWEEN '0' AND '9' AND
                  SUBSTR(zip,5,1) BETWEEN '0' AND '9',
 address CHAR(25) NOT NULL,
 info    LONG,
FOREIGN KEY hotel_zip_in_city (zip) REFERENCES city ON DELETE RESTRICT)

The hno column contains the primary key.

The hno_cons constraint ensures that a hotel number greater than zero is selected.

NULL values cannot be entered in the name and address columns.

The zip_cons constraint ensures that the only numbers between 0 and 9 can be entered for the zip code.

The zip column contains the foreign key. The keywords ON DELETE RESTRICT cause a warning to be displayed when a row in the CITY table is deleted if the HOTEL table contains a row that matches the zip code of the row to be deleted. In this case, the row is not deleted.

ROOM

Each row in this table contains the following room information: a number that uniquely identifies the hotel where the room is located, the room type (single, double, suite), the number of vacant rooms, and the price per room.

CREATE TABLE room
(hno       FIXED(4) CONSTRAINT hno_cons CHECK hno > 0,
 type      CHAR(6)  CONSTRAINT type_cons CHECK type IN ('single','double','suite'), PRIMARY KEY (hno,type),
 free      FIXED(3,0) CONSTRAINT free_cons CHECK free >= 0,
 price     FIXED(6,2) CONSTRAINT price_cons CHECK price BETWEEN 0.00 AND 5000.00,
FOREIGN KEY room_hno_in_hotel (hno) REFERENCES hotel ON DELETE CASCADE)

The hno and type columns form the primary key.

The hno_cons constraint ensures that a hotel number greater than zero is selected.

The type_cons constraint ensures that single, double, or suite is selected as the room type.

The free_cons constraint ensures that the selected number of vacant rooms is greater than zero.

The price_cons constraint ensures that the selected room price is between 0 and 5000.

The hno column contains the foreign key. When rows are deleted in the HOTEL table, the keywords ON DELETE CASCADE cause the rows in the ROOM table that contain matching hotel numbers to be deleted at the same time.

RESERVATION

Each row in this table contains the following reservation information: a number that uniquely identifies the reservation, a number that uniquely identifies the customer, a number that uniquely identifies the hotel, the room type (single, double, suite), the date of arrival, and the date of departure.

CREATE TABLE reservation
(rno       FIXED(4) PRIMARY KEY CONSTRAINT rno_cons CHECK rno > 0,
 cno       FIXED(4) CONSTRAINT cno_cons CHECK cno > 0,
 hno       FIXED(4) CONSTRAINT hno_cons CHECK hno > 0,
 type      CHAR(6) CONSTRAINT type_cons CHECK type IN ('single','double','suite'),
 arrival   DATE     NOT NULL,
 departure DATE     NOT NULL, CONSTRAINT staying CHECK departure > arrival,
FOREIGN KEY reservation_cno_in_customer (cno) REFERENCES customer ON DELETE CASCADE
FOREIGN KEY reservation_info_in_room (hno,type) REFERENCES room ON DELETE CASCADE)

The rno column contains the primary key.

The rno_cons constraint ensures that a reservation number greater than zero is selected.

The cno_cons constraint ensures that a customer number greater than zero is selected.

The hno_cons constraint ensures that a hotel number greater than zero is selected.

The type_cons constraint ensures that single, double, or suite is selected as the room type.

NULL values cannot be entered in the arrival and departure columns.

The staying constraint ensures that the selected departure date is after the arrival date.

The cno column contains the foreign key. When rows are deleted in the CUSTOMER table, the keywords ON DELETE CASCADE cause the rows in the RESERVATION table that contain matching customer numbers to be deleted at the same time.

The hno and type columns form a foreign key. When rows are deleted in the ROOM table, the keywords ON DELETE CASCADE cause the rows in the RESERVATION table that contain matching hotel numbers and room type to be deleted at the same time.

EMPLOYEE

Each row in this table contains the following employee information: a number that uniquely identifies the hotel, a number that uniquely identifies the employee, the title used in correspondence, the first and last name of the employee, and a number that assigns the employee to a superior.

CREATE TABLE employee
(hno         FIXED(4),
 eno         FIXED(4), PRIMARY KEY (hno,eno),
 title       CHAR(7)  CONSTRAINT title_cons CHECK title IN ('Mr','Mrs'),
 firstname   CHAR(10),
 name        CHAR(10) NOT NULL,
 manager_eno FIXED(4),
FOREIGN KEY employee_hno_in_hotel (hno) REFERENCES hotel ON DELETE CASCADE)

The hno and eno columns form the primary key.

The title_cons constraint ensures that Mr or Mrs is selected as the title.

NULL values cannot be entered in the name column.

The hno column contains the foreign key. When rows are deleted in the HOTEL table, the keywords ON DELETE CASCADE cause the rows in the EMPLOYEE table that contain matching hotel numbers to be deleted at the same time.

 

Leaving content frame