| 1 | = Normalization and improvement of database schema |
| 2 | Due to the complexity of the restaurant management system and the large number of attributes tied to different logical responsibilities, it is not feasible to normalize all data in a single relation. Instead, normalization is applied to functional modules individually, based on the logical responsibilities within the system. |
| 3 | The system is divided into three major functional domains: |
| 4 | 1. Reservation Management – comprising: Reservation, FrontStaff and Customer |
| 5 | 2. Shifts Management – comprising: Manager, Shift, Assignment, and Employee |
| 6 | 3. Order Management – comprising: Employee, TabOrder, OnlineOrder, Payment, Table, Customer, OrderItem, Product, Inventory, and Category |
| 7 | |
| 8 | |
| 9 | |
| 10 | == Reservation Management |
| 11 | ||= user_id =||= email =||= city =||= street =||= phone_number =||= password =||= net_salary =||= gross_salary =||= staffRole_id =||= name =||= stay_length =||= creation_timestamp =||= datetime =||= number_of_people =||= reservation_id =||= customer_id =||= c_email =||= c_street =||= c_city =||= c_phone_num =||= c_password =|| |
| 12 | || 1 || test@hotmail.com || Strumica || Mladinska 3 || 70003005 || password1 || 30000 || 40000 || 1 || Server || NULL || 15.7.2025 10:33 || 15.7.2025 20:00 || 4 || 1 || 2 || test2@hotmail.com || Marsal Tito 10 || Strumica || 70001002 || password2 || |
| 13 | || 1 || test@hotmail.com || Strumica || Mladinska 3 || 70003005 || password1 || 30000 || 40000 || 1 || Server || NULL || 16.7.2025 10:33 || 17.7.2025 20:00 || 6 || 2 || 2 || test2@hotmail.com || Marsal Tito 10 || Strumica || 70001002 || password2 || |
| 14 | || 5 || test5@hotmail.com || Strumica || Mladinska 12 3 || 70005005 || password1 || 20000 || 37000 || 4 || Hostess || NULL || 18.7.2025 10:33 || 18.7.2025 20:00 || 6 || 3 || 2 || test2@hotmail.com || Marsal Tito 10 || Strumica || 70001002 || password2 || |
| 15 | || 5 || test5@hotmail.com || Strumica || Mladinska 12 3 || 70005005 || password1 || 20000 || 37000 || 4 || Hostess || NULL || 18.7.2025 10:33 || 18.7.2025 21:00 || 6 || 4 || 3 || test3@hotmail.com || Mladinska 5 || Strumica || 70003003 || password2 || |
| 16 | |
| 17 | R = {e_id, e_email,e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, staffRole_id, name, stay_length, creation_timestamp, datetime, number_of_people, reservation_id, customer_id, c_email, c_street, c_city, c_phone_number,c_password} |
| 18 | |
| 19 | Functional Dependencies: |
| 20 | - e_id → e_email, e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, staffRole_id |
| 21 | - staffRole_id → name |
| 22 | - reservation_id → e_id, stay_length, creation_timestamp, datetime, number_of_people, customer_id |
| 23 | - customer_id → c_email, c_street, c_city, c_phone_number, c_password |
| 24 | |
| 25 | Left only: reservation_id |
| 26 | |
| 27 | Left and right: e_id, staffRole_id, customer_id |
| 28 | |
| 29 | Right only: e_email, e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, name, stay_length, creation_timestamp, datetime, number_of_people, c_email, c_street, c_city, c_phone_number, c_password |
| 30 | |
| 31 | {reservation_id}* = R => reservation_id is the primary key |
| 32 | |
| 33 | We can see that 1NF and 2NF are satisfied due to having atomic attributes and a single primary key, but BNCF is not satisfied due to transitive dependencies. |
| 34 | |
| 35 | Decomposition: |
| 36 | Step 1: Decompose R by e_id |
| 37 | |
| 38 | {e_id}* = { e_email, e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, staffRole_id, name} |
| 39 | |
| 40 | R1 = {e_id, e_email, e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, staffRole_id, name} |
| 41 | |
| 42 | R2 = {e_id, stay_length, creation_timestamp, datetime, number_of_people, reservation_id, customer_id, c_email, c_street, c_city, c_phone_number,c_password} |
| 43 | |
| 44 | Step 2: Decompose R1 by staffRole_id |
| 45 | {staffRole_id}*= {staffRole_id, name} |
| 46 | |
| 47 | R3 = {staffRole_id, name} |
| 48 | |
| 49 | R4 = {e_id, e_email, e_city, e_street, e_phone_number, e_password, net_salary, gross_salary, tip_precent, staffRole_id} |
| 50 | |
| 51 | Step 3: Decompose R2 by customer_id |
| 52 | {customer_id}* = {c_email, c_street, c_city, c_phone_number, c_password} |
| 53 | |
| 54 | R5 = {customer_id, c_email, c_street, c_city, c_phone_number, c_password} |
| 55 | |
| 56 | R6 = {reservation_id, e_id, stay_length, creation_timestamp, datetime, number_of_people, customer_id} |
| 57 | |
| 58 | Final BCNF Relations: |
| 59 | - R3(StaffRole), R4(FrontStaff), R5(Customer), R6(Reservation) |
| 60 | |
| 61 | == Shift Management |
| 62 | |
| 63 | For manager I will use m, for employee e. |
| 64 | |
| 65 | R = {m_id,m_email,m_city,m_street, m_phone_number, m_password, m_net_salary, m_gross_salary,e_id,e_email,e_city,e_street, e_phone_number, e_password, e_net_salary, e_gross_salary , shift_id, date, start, end, assignment_id, clock_in_time, clock_out_time, is_assigned} |
| 66 | |
| 67 | Functional Dependencies: |
| 68 | - e_id → e_email, e_city, e_street, e_phone_number, e_password, e_net_salary, e_gross_salary |
| 69 | - m_id → m_email, m_city, m_street, m_phone_number, m_password, m_net_salary, m_gross_salary |
| 70 | - shift_id → date, start, end, m_id |
| 71 | - assignment_id → shift_id, e_id, clock_in_time, clock_out_time, is_assigned |
| 72 | |
| 73 | Left only: assignment_id |
| 74 | |
| 75 | Left and right: e_id, m_id, shift_id |
| 76 | |
| 77 | Right only: m_email,m_city,m_street, m_phone_number, m_password, m_net_salary, m_gross_salary, e_email, e_city, e_street, e_phone_number, e_password, e_net_salary, e_gross_salary , date, start, end, clock_in_time, clock_out_time, is_assigned |
| 78 | |
| 79 | {assignment_id}* = R => assignment_id is the primary key |
| 80 | |
| 81 | We can see that 1NF and 2NF are satisfied due to having atomic attributes and a single primary key, but BNCF is not satisfied due to transitive dependencies. |
| 82 | |
| 83 | Decomposition: |
| 84 | |
| 85 | Step 1: Decompose R by shift_id |
| 86 | {shift_id}* = {shift_id, date, start, end, m_id,m_email,m_city,m_street, m_phone_number, m_password, m_net_salary, m_gross_salary} |
| 87 | |
| 88 | R1 = {shift_id, date, start, end, m_id,m_email,m_city,m_street, m_phone_number, m_password, m_net_salary, m_gross_salary} |
| 89 | |
| 90 | R2 = {shift_id, e_id, e_email,e_city,e_street, e_phone_number, e_password, e_net_salary, e_gross_salary, assignment_id, clock_in_time, clock_out_time, is_assigned} |
| 91 | |
| 92 | Step 2: Decompose R1 by m_id |
| 93 | {m_id}*= {m_id,m_email,m_city,m_street, m_phone_number, m_password, m_net_salary, m_gross_salary} |
| 94 | |
| 95 | R3 = {m_id, m_email, m_city, m_street, m_phone_number, m_password, m_net_salary, m_gross_salary} |
| 96 | |
| 97 | R4 = {m_id, shift_id, date, start, end} |
| 98 | |
| 99 | Step 3: Decompose R2 by e_id |
| 100 | {e_id}* = {e_id, e_email,e_city,e_street, e_phone_number, e_password, e_net_salary, e_gross_salary} |
| 101 | |
| 102 | R5 = {e_id, e_email,e_city,e_street, e_phone_number, e_password, e_net_salary, e_gross_salary} |
| 103 | |
| 104 | R6 = {e_id, shift_id, assignment_id, clock_in_time, clock_out_time, is_assigned} |
| 105 | |
| 106 | Final BCNF Relations: |
| 107 | - R3(Manager), R4(Shifts), R5(Employees), R6(Assigments) |
| 108 | |
| 109 | == Order Management |
| 110 | I will refer to order as o, orderItem as oi, customer as c, payment as p, product as pr,category as ca,inventory as i |
| 111 | |
| 112 | R = {order_id, employee_id, o_timestamp, o_status, seat_capacity, table_number, delivery_address, tip_amount, p_id, p_timestamp, payment_type, amount, oi_id, oi_timestamp, oi_is_processed, oi_price, oi_quantity, pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id, ca_name, ca_is_available, i_quantity, i_restock_level} |
| 113 | |
| 114 | Functional Dependencies: |
| 115 | |
| 116 | - order_id -> employee_id, o_timestamp, o_status |
| 117 | - order_id -> table_number |
| 118 | - order_id -> delivery_address, customer_id |
| 119 | - table_number -> seat_capacity |
| 120 | - p_id -> p_timestamp, payment_type, amount, tip_amount, order_id |
| 121 | - oi_id -> oi_timestamp, oi_is_processed, oi_price, pr_id, order_id, oi_quantity |
| 122 | - pr_id -> pr_description, tax_class, pr_price, pr_name, manage_inventory, i_quantity, i_restock_level, ca_id |
| 123 | - manage_inventory -> i_quantity, i_restock_level |
| 124 | - ca_id -> ca_name, ca_is_available |
| 125 | |
| 126 | There isn’t one attribute that is a candidate for primary key so BCNF is violated. |
| 127 | |
| 128 | Step 1: Decompose R by Order_id |
| 129 | |
| 130 | {order_id}* = {employee_id, o_timestamp, o_status, table_number, seat_capacity delivery_address, customer_id} |
| 131 | |
| 132 | R1 = {order_id, employee_id, o_timestamp, o_status, table_number, seat_capacity delivery_address, customer_id} |
| 133 | |
| 134 | R2 = {order_id, tip_amount, p_id, p_timestamp, payment_type, amount, oi_id, oi_timestamp, oi_is_processed, oi_price, oi_quantity, pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id, ca_name, ca_is_available, i_quantity, i_restock_level} |
| 135 | |
| 136 | Step 2: Decompose R1 by table_number |
| 137 | |
| 138 | {table_number}*= {table_number, seat_capacity} |
| 139 | |
| 140 | R3={table_number,seat_capacity} |
| 141 | |
| 142 | R4= {order_id, employee_id, o_timestamp, o_status, table_number, delivery_address, customer_id} |
| 143 | |
| 144 | Due to the issue that when there is a TabOrder the delivery_address and customer_id will always be NULL values and when there is an OnlineOrder table_number will always have NULL value we split R4 into |
| 145 | |
| 146 | R5= {order_id, employee_id, o_timestamp, o_status} |
| 147 | |
| 148 | R6= {order_id, table_number} |
| 149 | |
| 150 | R7= {order_id, delivery_address, customer_id} |
| 151 | |
| 152 | Step3: Decompose R2 by p_id |
| 153 | |
| 154 | {p_id}I* = { order_id, tip_amount, p_id, p_timestamp, payment_type, amount} |
| 155 | |
| 156 | R8 = {order_id, tip_amount, p_id, p_timestamp, payment_type, amount} |
| 157 | |
| 158 | Because we have order_id in R8 we don’t need to keep p_id in R9. |
| 159 | |
| 160 | R9 = {order_id, oi_id, oi_timestamp, oi_is_processed, oi_price, oi_quantity, pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id, ca_name, ca_is_available, i_quantity, i_restock_level |
| 161 | |
| 162 | Step 4: Decompose R9 by pr_id |
| 163 | {pr_id}* = {pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id, ca_name, ca_is_available, i_quantity, i_restock_level} |
| 164 | |
| 165 | R10 = {pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id, ca_name, ca_is_available, i_quantity, i_restock_level} |
| 166 | R11 = { order_id, oi_id, oi_timestamp, oi_is_processed, oi_price, oi_quantity, pr_id} – OrderItems |
| 167 | Step 5: Decompose R10 by ca_id |
| 168 | {ca_id}* = {ca_id, ca_name, ca_is_available} |
| 169 | |
| 170 | R12= {ca_id, ca_name, ca_is_available} |
| 171 | |
| 172 | R13 = {pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id,i_quantity,i_restock_level} |
| 173 | |
| 174 | Step 6: Decompose Inventory from R13 |
| 175 | |
| 176 | {i_quantity, i_restock_level} are functionally dependent on pr_id only when manage_inventory is true. If manage_inventory is false it leads to NULL values in our table so we decompose R13 to |
| 177 | |
| 178 | R14 = {pr_id, pr_description, tax_class, pr_price, pr_name, manage_inventory, ca_id} |
| 179 | |
| 180 | And |
| 181 | |
| 182 | R15= {pr_id, i_quantity,i_restock_level} |
| 183 | |
| 184 | Final BCNF Realtions: |
| 185 | R3(Tables), R5(Orders), R6(TabOrders), R7(OnlineOrders), R8(Payments), R11(OrderItems), R14(Products), R15(Inventory) |
| 186 | |
| 187 | == Conclusion |
| 188 | Ultimately, the process of normalization validated our initial design. The final tables derived through formal decomposition were a perfect match for the original tables represented in the ER diagram, confirming the correctness of the schema. |