├── Amazon ER.png ├── Relational Tables.jpeg ├── amazon_db_system.sql └── readme.md /Amazon ER.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Ashwanikumarkashyap/amazon-database-system-plsql/4a77feb1b25cdecd0fdc727666c9f237186624e3/Amazon ER.png -------------------------------------------------------------------------------- /Relational Tables.jpeg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Ashwanikumarkashyap/amazon-database-system-plsql/4a77feb1b25cdecd0fdc727666c9f237186624e3/Relational Tables.jpeg -------------------------------------------------------------------------------- /amazon_db_system.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE amz_user ( 2 | email VARCHAR(255) PRIMARY KEY, 3 | fname VARCHAR(255) NOT NULL, 4 | lname VARCHAR(255), 5 | password VARCHAR(30) NOT NULL, 6 | user_type NUMBER(1) NOT NULL 7 | ); 8 | 9 | CREATE TABLE contact_detail ( 10 | user_id VARCHAR(255) NOT NULL, 11 | address_id INTEGER PRIMARY KEY, 12 | street1 VARCHAR(255) NOT NULL, 13 | street2 VARCHAR(255), 14 | city VARCHAR(50) NOT NULL, 15 | state VARCHAR(50) NOT NULL, 16 | country VARCHAR(50) NOT NULL, 17 | zipcode NUMBER(5) NOT NULL, 18 | phone VARCHAR(20) NOT NULL, 19 | is_default NUMBER(1) DEFAULT 0 20 | ); 21 | 22 | CREATE TABLE card_info ( 23 | card_id INTEGER PRIMARY KEY, 24 | card_number NUMBER(16) NOT NULL, 25 | expiry_date DATE NOT NULL, 26 | cvv NUMBER(3) NOT NULL, 27 | buyer_id VARCHAR(255) NOT NULL, 28 | is_default NUMBER(1) 29 | ); 30 | 31 | CREATE TABLE buyer ( 32 | buyer_id VARCHAR(255) PRIMARY KEY, 33 | is_prime NUMBER(1) DEFAULT 0, 34 | prime_expiry_date DATE 35 | ); 36 | 37 | CREATE TABLE seller ( 38 | seller_id VARCHAR(255) PRIMARY KEY, 39 | company_name VARCHAR(255) NOT NULL, 40 | url VARCHAR(255), 41 | description VARCHAR(255), 42 | average_rating NUMBER(2, 1) DEFAULT 2.5, 43 | rating_count NUMBER DEFAULT 0 44 | ); 45 | 46 | CREATE TABLE category ( 47 | category_id INTEGER PRIMARY KEY, 48 | category_name VARCHAR(255) NOT NULL 49 | ); 50 | 51 | CREATE TABLE product ( 52 | product_id INTEGER PRIMARY KEY, 53 | name VARCHAR(255) NOT NULL, 54 | seller_id VARCHAR(255) NOT NULL, 55 | price NUMBER(10, 2) NOT NULL, 56 | rating NUMBER(2, 1), 57 | review_count INTEGER, 58 | category_id INTEGER, 59 | description VARCHAR(255), 60 | discount_percent NUMBER(4, 2), 61 | available_units INTEGER, 62 | color VARCHAR(30), 63 | in_stock NUMBER(1), 64 | weight NUMBER(10, 2), 65 | carrier_id INTEGER 66 | ); 67 | 68 | CREATE TABLE product_image ( 69 | product_id INTEGER, 70 | image_url VARCHAR(255), 71 | PRIMARY KEY ( product_id, 72 | image_url ) 73 | ); 74 | 75 | CREATE TABLE shopping_cart ( 76 | buyer_id VARCHAR(255), 77 | date_added DATE 78 | ); 79 | 80 | CREATE TABLE product_shoppingcart ( 81 | product_id INTEGER, 82 | buyer_id VARCHAR(255), 83 | PRIMARY KEY ( product_id, 84 | buyer_id ) 85 | ); 86 | 87 | CREATE TABLE wish_list ( 88 | buyer_id VARCHAR(255), 89 | date_added DATE 90 | ); 91 | 92 | CREATE TABLE product_wishlist ( 93 | product_id INTEGER, 94 | buyer_id VARCHAR(255), 95 | PRIMARY KEY ( product_id, 96 | buyer_id ) 97 | ); 98 | 99 | CREATE TABLE amz_order ( 100 | order_id INTEGER PRIMARY KEY, 101 | buyer_id VARCHAR(255) NOT NULL, 102 | card_id INTEGER NOT NULL, 103 | total_price NUMBER(10, 2), 104 | order_date DATE, 105 | tax NUMBER(4, 2) DEFAULT 10, 106 | shipping_price NUMBER(4, 2) DEFAULT 10, 107 | delivery_address_id INTEGER, 108 | delivery_date DATE, 109 | order_status CHAR(1) NOT NULL, 110 | quantity INTEGER NOT NULL 111 | ); 112 | 113 | CREATE TABLE order_product ( 114 | order_id INTEGER, 115 | product_id INTEGER, 116 | PRIMARY KEY ( order_id, 117 | product_id ) 118 | ); 119 | 120 | CREATE TABLE review ( 121 | review_id INTEGER PRIMARY KEY, 122 | product_id INTEGER NOT NULL, 123 | buyer_id VARCHAR(255) NOT NULL, 124 | review VARCHAR(1000), 125 | rating NUMBER(2, 1), 126 | review_date DATE 127 | ); 128 | 129 | CREATE TABLE review_image ( 130 | review_id INTEGER, 131 | image_url VARCHAR(255), 132 | PRIMARY KEY ( review_id, 133 | image_url ) 134 | ); 135 | 136 | CREATE TABLE carrier ( 137 | carrier_id INTEGER PRIMARY KEY, 138 | carrier_name VARCHAR(255) NOT NULL, 139 | carrier_phone NUMBER(10) NOT NULL, 140 | carrier_email VARCHAR(255) NOT NULL 141 | ); 142 | 143 | ALTER TABLE contact_detail 144 | ADD CONSTRAINT contact_detail_user_id_fk FOREIGN KEY ( user_id ) 145 | REFERENCES amz_user ( email ) 146 | ON DELETE CASCADE; 147 | 148 | ALTER TABLE card_info 149 | ADD CONSTRAINT card_info_buyer_id_fk FOREIGN KEY ( buyer_id ) 150 | REFERENCES buyer ( buyer_id ) 151 | ON DELETE CASCADE; 152 | 153 | ALTER TABLE product 154 | ADD CONSTRAINT product_seller_id_fk FOREIGN KEY ( seller_id ) 155 | REFERENCES seller ( seller_id ) 156 | ON DELETE CASCADE; 157 | 158 | ALTER TABLE product 159 | ADD CONSTRAINT product_category_id_fk FOREIGN KEY ( category_id ) 160 | REFERENCES category ( category_id ) 161 | ON DELETE CASCADE; 162 | 163 | ALTER TABLE product 164 | ADD CONSTRAINT product_carrier_id_fk FOREIGN KEY ( carrier_id ) 165 | REFERENCES carrier ( carrier_id ) 166 | ON DELETE CASCADE; 167 | 168 | ALTER TABLE product_image 169 | ADD CONSTRAINT product_image_product_id_fk FOREIGN KEY ( product_id ) 170 | REFERENCES product ( product_id ) 171 | ON DELETE CASCADE; 172 | 173 | ALTER TABLE shopping_cart 174 | ADD CONSTRAINT shopping_cart_buyer_id_fk FOREIGN KEY ( buyer_id ) 175 | REFERENCES buyer ( buyer_id ) 176 | ON DELETE CASCADE; 177 | 178 | ALTER TABLE product_shoppingcart 179 | ADD CONSTRAINT product_sc_buyer_id_fk FOREIGN KEY ( buyer_id ) 180 | REFERENCES buyer ( buyer_id ) 181 | ON DELETE CASCADE; 182 | 183 | ALTER TABLE product_shoppingcart 184 | ADD CONSTRAINT product_sc_product_id_fk FOREIGN KEY ( product_id ) 185 | REFERENCES product ( product_id ) 186 | ON DELETE CASCADE; 187 | 188 | ALTER TABLE wish_list 189 | ADD CONSTRAINT wishlist_buyer_id_fk FOREIGN KEY ( buyer_id ) 190 | REFERENCES buyer ( buyer_id ) 191 | ON DELETE CASCADE; 192 | 193 | ALTER TABLE product_wishlist 194 | ADD CONSTRAINT product_wishlist_product_id_fk FOREIGN KEY ( product_id ) 195 | REFERENCES product ( product_id ) 196 | ON DELETE CASCADE; 197 | 198 | ALTER TABLE product_wishlist 199 | ADD CONSTRAINT product_wishlist_buyer_id_fk FOREIGN KEY ( buyer_id ) 200 | REFERENCES buyer ( buyer_id ) 201 | ON DELETE CASCADE; 202 | 203 | ALTER TABLE amz_order 204 | ADD CONSTRAINT order_buyer_id_fk FOREIGN KEY ( buyer_id ) 205 | REFERENCES buyer ( buyer_id ) 206 | ON DELETE CASCADE; 207 | 208 | ALTER TABLE amz_order 209 | ADD CONSTRAINT order_card_id_fk FOREIGN KEY ( card_id ) 210 | REFERENCES card_info ( card_id ) 211 | ON DELETE CASCADE; 212 | 213 | ALTER TABLE amz_order 214 | ADD CONSTRAINT order_delivery_address_id_fk FOREIGN KEY ( delivery_address_id ) 215 | REFERENCES contact_detail ( address_id ) 216 | ON DELETE CASCADE; 217 | 218 | ALTER TABLE order_product 219 | ADD CONSTRAINT order_product_order_id_fk FOREIGN KEY ( order_id ) 220 | REFERENCES amz_order ( order_id ) 221 | ON DELETE CASCADE; 222 | 223 | ALTER TABLE order_product 224 | ADD CONSTRAINT order_product_product_id_fk FOREIGN KEY ( product_id ) 225 | REFERENCES product ( product_id ) 226 | ON DELETE CASCADE; 227 | 228 | ALTER TABLE review 229 | ADD CONSTRAINT review_product_id_fk FOREIGN KEY ( product_id ) 230 | REFERENCES product ( product_id ) 231 | ON DELETE CASCADE; 232 | 233 | ALTER TABLE review 234 | ADD CONSTRAINT review_buyer_id_fk FOREIGN KEY ( buyer_id ) 235 | REFERENCES buyer ( buyer_id ) 236 | ON DELETE CASCADE; 237 | 238 | ALTER TABLE review_image 239 | ADD CONSTRAINT review_image_review_id_fk FOREIGN KEY ( review_id ) 240 | REFERENCES review ( review_id ) 241 | ON DELETE CASCADE; 242 | 243 | CREATE OR REPLACE PROCEDURE register_buyer ( 244 | email IN VARCHAR, 245 | fname IN VARCHAR, 246 | lname IN VARCHAR, 247 | password IN VARCHAR 248 | ) AS 249 | BEGIN 250 | INSERT INTO amz_user VALUES ( 251 | email, 252 | fname, 253 | lname, 254 | password, 255 | 0 256 | ); 257 | 258 | INSERT INTO buyer VALUES ( 259 | email, 260 | 0, 261 | NULL 262 | ); 263 | 264 | END register_buyer; 265 | 266 | -------------------------------------------------------------------------------------------- 267 | 268 | CREATE OR REPLACE PROCEDURE register_seller ( 269 | email IN VARCHAR, 270 | fname IN VARCHAR, 271 | lname IN VARCHAR, 272 | password IN VARCHAR, 273 | company_name IN VARCHAR, 274 | url IN VARCHAR, 275 | description_var IN VARCHAR 276 | ) AS 277 | BEGIN 278 | INSERT INTO amz_user VALUES ( 279 | email, 280 | fname, 281 | lname, 282 | password, 283 | 1 284 | ); 285 | 286 | INSERT INTO seller VALUES ( 287 | email, 288 | company_name, 289 | url, 290 | description_var, 291 | 2.5, 292 | 0 293 | ); 294 | 295 | END register_seller; 296 | 297 | --------------------------------------------------------------------------------------------- 298 | 299 | CREATE OR REPLACE PROCEDURE add_contact_details ( 300 | user_id IN VARCHAR, 301 | address_id IN INTEGER, 302 | street1 IN VARCHAR, 303 | street2 IN VARCHAR, 304 | city IN VARCHAR, 305 | state IN VARCHAR, 306 | country IN VARCHAR, 307 | zipcode IN NUMBER, 308 | phone IN VARCHAR 309 | ) AS 310 | BEGIN 311 | INSERT INTO contact_detail VALUES ( 312 | user_id, 313 | address_id, 314 | street1, 315 | street2, 316 | city, 317 | state, 318 | country, 319 | zipcode, 320 | phone, 321 | 0 322 | ); 323 | 324 | END add_contact_details; 325 | 326 | -------------------------------------------------------------------------------------------- 327 | 328 | CREATE OR REPLACE PROCEDURE set_default_contact_details ( 329 | contact_id IN INTEGER, 330 | buyer_id IN VARCHAR 331 | ) AS 332 | BEGIN 333 | UPDATE contact_detail 334 | SET 335 | is_default = 1 336 | WHERE 337 | user_id = buyer_id 338 | AND address_id = contact_id; 339 | 340 | END set_default_contact_details; 341 | 342 | -------------------------------------------------------------------------------------------- 343 | 344 | CREATE OR REPLACE PROCEDURE add_card_info ( 345 | buyer_id IN VARCHAR, 346 | card_id IN INTEGER, 347 | card_number IN NUMBER, 348 | expiry_date IN DATE, 349 | cvv IN NUMBER 350 | ) AS 351 | BEGIN 352 | INSERT INTO card_info VALUES ( 353 | card_id, 354 | card_number, 355 | expiry_date, 356 | cvv, 357 | buyer_id, 358 | 0 359 | ); 360 | 361 | END add_card_info; 362 | 363 | -------------------------------------------------------------------------------------------- 364 | 365 | CREATE OR REPLACE PROCEDURE set_default_card_info ( 366 | card_id_var IN INTEGER, 367 | buyer_id_var IN VARCHAR 368 | ) AS 369 | BEGIN 370 | UPDATE card_info 371 | SET 372 | is_default = 1 373 | WHERE 374 | buyer_id = buyer_id_var 375 | AND card_id = card_id_var; 376 | 377 | END set_default_card_info; 378 | 379 | -------------------------------------------------------------------------------------------- 380 | 381 | CREATE OR REPLACE PROCEDURE add_product ( 382 | product_id IN INTEGER, 383 | name IN VARCHAR, 384 | seller_id IN VARCHAR, 385 | price IN NUMBER, 386 | category_id IN INTEGER, 387 | description IN VARCHAR, 388 | available_units IN INTEGER, 389 | color IN VARCHAR, 390 | weight IN NUMBER, 391 | carrier_id IN INTEGER, 392 | image_url IN VARCHAR 393 | ) AS 394 | BEGIN 395 | INSERT INTO product VALUES ( 396 | product_id, 397 | name, 398 | seller_id, 399 | price, 400 | 0, 401 | 0, 402 | category_id, 403 | description, 404 | 0, 405 | available_units, 406 | color, 407 | 1, 408 | weight, 409 | carrier_id 410 | ); 411 | 412 | INSERT INTO product_image VALUES ( 413 | product_id, 414 | image_url 415 | ); 416 | 417 | END add_product; 418 | 419 | -------------------------------------------------------------------------------------------- 420 | 421 | CREATE OR REPLACE PROCEDURE add_to_shopping_cart ( 422 | buyer_id IN VARCHAR, 423 | product_id IN INTEGER 424 | ) AS 425 | BEGIN 426 | INSERT INTO shopping_cart VALUES ( 427 | buyer_id, 428 | sysdate 429 | ); 430 | 431 | INSERT INTO product_shoppingcart VALUES ( 432 | product_id, 433 | buyer_id 434 | ); 435 | 436 | END add_to_shopping_cart; 437 | 438 | -------------------------------------------------------------------------------------------- 439 | 440 | CREATE OR REPLACE PROCEDURE add_to_wish_list ( 441 | buyer_id IN VARCHAR, 442 | product_id IN INTEGER 443 | ) AS 444 | BEGIN 445 | INSERT INTO wish_list VALUES ( 446 | buyer_id, 447 | sysdate 448 | ); 449 | 450 | INSERT INTO product_wishlist VALUES ( 451 | product_id, 452 | buyer_id 453 | ); 454 | 455 | END add_to_wish_list; 456 | 457 | -------------------------------------------------------------------------------------------- 458 | 459 | CREATE OR REPLACE PROCEDURE give_review ( 460 | review_id IN NUMBER, 461 | product_id IN INTEGER, 462 | buyer_id IN VARCHAR, 463 | review IN VARCHAR, 464 | rating IN NUMBER, 465 | image_url IN VARCHAR 466 | ) AS 467 | BEGIN 468 | INSERT INTO review VALUES ( 469 | review_id, 470 | product_id, 471 | buyer_id, 472 | review, 473 | rating, 474 | sysdate 475 | ); 476 | 477 | INSERT INTO review_image VALUES ( 478 | review_id, 479 | image_url 480 | ); 481 | 482 | END give_review; 483 | 484 | -------------------------------------------------------------------------------------------- 485 | 486 | CREATE OR REPLACE TRIGGER update_product_rating AFTER 487 | INSERT ON review 488 | FOR EACH ROW 489 | DECLARE 490 | new_rating NUMBER(2, 1); 491 | review_count_old INTEGER; 492 | BEGIN 493 | SELECT 494 | review_count 495 | INTO review_count_old 496 | FROM 497 | product 498 | WHERE 499 | product_id = :new.product_id; 500 | 501 | new_rating := :new.rating; 502 | UPDATE product 503 | SET 504 | rating = ( ( rating * review_count_old ) + new_rating ) / ( review_count_old + 1 ), 505 | review_count = review_count_old + 1 506 | WHERE 507 | product_id = :new.product_id; 508 | 509 | END; 510 | 511 | -------------------------------------------------------------------------------------------- 512 | 513 | CREATE OR REPLACE TRIGGER update_seller_rating AFTER 514 | INSERT OR UPDATE OF rating ON review 515 | FOR EACH ROW 516 | DECLARE 517 | new_rating NUMBER(2, 1); 518 | seller_id_to_update VARCHAR(255); 519 | BEGIN 520 | new_rating := :new.rating; 521 | SELECT 522 | seller_id 523 | INTO seller_id_to_update 524 | FROM 525 | product 526 | WHERE 527 | product_id = :new.product_id; 528 | 529 | UPDATE seller 530 | SET 531 | average_rating = ( ( average_rating * rating_count ) + new_rating ) / ( rating_count + 1 ), 532 | rating_count = rating_count + 1 533 | WHERE 534 | seller_id = seller_id_to_update; 535 | 536 | END; 537 | 538 | -------------------------------------------------------------------------------------------- 539 | 540 | CREATE OR REPLACE PROCEDURE update_membership ( 541 | buyer_id_input IN VARCHAR 542 | ) AS 543 | BEGIN 544 | UPDATE buyer 545 | SET 546 | is_prime = 1, 547 | prime_expiry_date = add_months(DATE '2019-11-28', 12) 548 | WHERE 549 | buyer_id = buyer_id_input; 550 | 551 | END update_membership; 552 | 553 | -------------------------------------------------------------------------------------------- 554 | 555 | CREATE OR REPLACE PROCEDURE cancel_membership ( 556 | buyer_id_input IN VARCHAR 557 | ) AS 558 | BEGIN 559 | UPDATE buyer 560 | SET 561 | is_prime = 0, 562 | prime_expiry_date = NULL 563 | WHERE 564 | buyer_id = buyer_id_input; 565 | 566 | END cancel_membership; 567 | 568 | -------------------------------------------------------------------------------------------- 569 | 570 | CREATE OR REPLACE PROCEDURE place_order ( 571 | order_id IN INTEGER, 572 | buyer_id_var IN VARCHAR 573 | ) AS 574 | 575 | card_id_var INTEGER; 576 | address_id_var INTEGER; 577 | total_price_var NUMBER := 0; 578 | curr_price_var NUMBER; 579 | total_qty_var NUMBER := 0; 580 | available_units_var NUMBER(1); 581 | shipping_price_var NUMBER := 10; 582 | is_prime_var NUMBER := 0; 583 | CURSOR products_cur IS 584 | SELECT 585 | product_id 586 | FROM 587 | product_shoppingcart 588 | WHERE 589 | buyer_id = buyer_id_var; 590 | 591 | product_id_var INTEGER; 592 | BEGIN 593 | OPEN products_cur; 594 | LOOP 595 | FETCH products_cur INTO product_id_var; 596 | EXIT WHEN products_cur%notfound; 597 | SELECT 598 | price, 599 | available_units 600 | INTO 601 | curr_price_var, 602 | available_units_var 603 | FROM 604 | product 605 | WHERE 606 | product_id = product_id_var; 607 | 608 | IF available_units_var > 0 THEN 609 | total_price_var := ( total_price_var + curr_price_var ); 610 | total_qty_var := total_qty_var + 1; 611 | INSERT INTO order_product VALUES ( 612 | order_id, 613 | product_id_var 614 | ); 615 | 616 | END IF; 617 | 618 | -- DELETE FROM product_shoppingcart 619 | -- WHERE product_id = product_id_var AND buyer_id = buyer_id_var; 620 | 621 | END LOOP; 622 | 623 | CLOSE products_cur; 624 | SELECT 625 | is_prime 626 | INTO is_prime_var 627 | FROM 628 | buyer 629 | WHERE 630 | buyer_id = buyer_id_var; 631 | 632 | IF is_prime_var = 1 THEN 633 | shipping_price_var := 0; 634 | END IF; 635 | SELECT 636 | card_id 637 | INTO card_id_var 638 | FROM 639 | card_info 640 | WHERE 641 | buyer_id = buyer_id_var 642 | AND is_default = 1; 643 | 644 | SELECT 645 | address_id 646 | INTO address_id_var 647 | FROM 648 | contact_detail 649 | WHERE 650 | user_id = buyer_id_var 651 | AND is_default = 1; 652 | 653 | total_price_var := total_price_var + shipping_price_var + 10; 654 | INSERT INTO amz_order VALUES ( 655 | order_id, 656 | buyer_id_var, 657 | card_id_var, 658 | total_price_var, 659 | sysdate, 660 | 10, 661 | shipping_price_var, 662 | address_id_var, 663 | add_months(DATE '2019-11-28', 1), 664 | 'c', 665 | total_qty_var 666 | ); 667 | 668 | END place_order; 669 | 670 | -------------------------------------------------------------------------------------------- 671 | 672 | CREATE OR REPLACE PROCEDURE populate_product_categories AS 673 | BEGIN 674 | INSERT INTO category VALUES ( 675 | 1, 676 | 'Electronics' 677 | ); 678 | 679 | INSERT INTO category VALUES ( 680 | 2, 681 | 'Books' 682 | ); 683 | 684 | INSERT INTO category VALUES ( 685 | 3, 686 | 'Clothing' 687 | ); 688 | 689 | END populate_product_categories; 690 | 691 | -------------------------------------------------------------------------------------------- 692 | 693 | CREATE OR REPLACE PROCEDURE populate_carriers AS 694 | BEGIN 695 | INSERT INTO carrier VALUES ( 696 | 1, 697 | 'DHL', 698 | 1234567890, 699 | 'DHL@gmail.com' 700 | ); 701 | 702 | INSERT INTO carrier VALUES ( 703 | 2, 704 | 'Fedex', 705 | 1234567890, 706 | 'Fedex@gmail.com' 707 | ); 708 | 709 | INSERT INTO carrier VALUES ( 710 | 3, 711 | 'UPS', 712 | 1234567890, 713 | 'UPS@gmail.com' 714 | ); 715 | 716 | END populate_carriers; 717 | 718 | -------------------------------------------------------------------------------------------- 719 | 720 | CREATE OR REPLACE TRIGGER update_available_units AFTER 721 | INSERT ON amz_order 722 | FOR EACH ROW 723 | DECLARE 724 | product_id_var INTEGER; 725 | available_units_var INTEGER; 726 | CURSOR products_cur IS 727 | SELECT 728 | product_id 729 | FROM 730 | order_product 731 | WHERE 732 | order_id = :new.order_id; 733 | 734 | BEGIN 735 | OPEN products_cur; 736 | LOOP 737 | FETCH products_cur INTO product_id_var; 738 | EXIT WHEN products_cur%notfound; 739 | SELECT 740 | available_units 741 | INTO available_units_var 742 | FROM 743 | product 744 | WHERE 745 | product_id = product_id_var; 746 | 747 | IF available_units_var >= 2 THEN 748 | UPDATE product 749 | SET 750 | available_units = available_units - 1 751 | WHERE 752 | product_id = product_id_var; 753 | 754 | ELSIF available_units_var = 1 THEN 755 | UPDATE product 756 | SET 757 | available_units = available_units - 1, 758 | in_stock = 0 759 | WHERE 760 | product_id = product_id_var; 761 | 762 | END IF; 763 | 764 | END LOOP; 765 | 766 | CLOSE products_cur; 767 | END; 768 | 769 | CREATE OR REPLACE TRIGGER remove_items_from_cart AFTER 770 | INSERT ON amz_order 771 | FOR EACH ROW 772 | DECLARE BEGIN 773 | DELETE FROM shopping_cart 774 | WHERE 775 | buyer_id = :new.buyer_id; 776 | 777 | DELETE FROM product_shoppingcart 778 | WHERE 779 | buyer_id = :new.buyer_id; 780 | 781 | END; 782 | 783 | BEGIN 784 | register_buyer('anshulpardhi@gmail.com', 'anshul', 'pardhi', 'abcd123'); 785 | register_buyer('ashwanikashyap@gmail.com', 'ashwani', 'kashyap', 'abcd123'); 786 | register_buyer('gunjanagicha@gmail.com', 'gunjan', 'agicha', 'abcd123'); 787 | END; 788 | 789 | BEGIN 790 | register_seller('kushagradar@gmail.com', 'kushagra', 'dar', 'abcd123', 'kushagra Co and Co', 791 | 'www.kusharga.com', 'company of shoes'); 792 | register_seller('ruchisingh@gmail.com', 'ruchi', 'singh', 'abcd123', 'ruchi Co and Co', 793 | 'www.ruchi.com', 'company of metals'); 794 | register_seller('anantprakash@gmail.com', 'anant', 'prakash', 'abcd123', 'anant Co and Co', 795 | 'www.anant.com', 'company of iphones'); 796 | END; 797 | 798 | BEGIN 799 | update_contact_details('anshulpardhi@gmail.com', 1, '7825 McCallum Blvd', 'Apt 007', 'Dallas', 800 | 'Texas', 'USA', 75252, 8888888888); 801 | 802 | update_contact_details('gunjanagicha@gmail.com', 2, '7825 McCallum Blvd', 'Apt 1702', 'Dallas', 803 | 'Texas', 'USA', 75252, 8888888888); 804 | 805 | update_contact_details('gunjanagicha@gmail.com', 3, '7825 McCallum Blvd', 'Apt 1702', 'Dallas', 806 | 'Texas', 'USA', 75252, 4692309274); 807 | 808 | set_default_contact_details(3, 'gunjanagicha@gmail.com'); 809 | set_default_contact_details(1, 'anshulpardhi@gmail.com'); 810 | END; 811 | 812 | BEGIN 813 | add_card_info('gunjanagicha@gmail.com', 1, 1234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 814 | 666); 815 | add_card_info('gunjanagicha@gmail.com', 2, 0234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 816 | 777); 817 | add_card_info('anshulpardhi@gmail.com', 3, 0234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 818 | 777); 819 | set_default_card_info(1, 'gunjanagicha@gmail.com'); 820 | set_default_card_info(3, 'anshulpardhi@gmail.com'); 821 | END; 822 | 823 | BEGIN 824 | populate_product_categories(); 825 | populate_carriers(); 826 | END; 827 | 828 | BEGIN 829 | add_product(1, 'OnePlus 7', 'kushagradar@gmail.com', 400, 1, 830 | 'Best Phone', 2, 'Blue', 2, 2, 831 | 'bit.ly/sfdf4fg'); 832 | 833 | add_product(2, 'Harry Potter', 'kushagradar@gmail.com', 15, 2, 834 | 'Best Book', 5, 'Black', 8, 2, 835 | 'bit.ly/sfdf4fg'); 836 | 837 | add_product(3, 'Nike Shoes', 'anantprakash@gmail.com', 50, 3, 838 | 'Best shoes', 2, 'yellow', 5, 1, 839 | 'bit.ly/sfdf4fg'); 840 | 841 | add_product(4, 'I phone', 'anantprakash@gmail.com', 500, 1, 842 | 'Better than android', 3, 'Black', 2, 3, 843 | 'bit.ly/sfdf4fg'); 844 | 845 | add_product(5, 'Metal Detector', 'ruchisingh@gmail.com', 20, 1, 846 | 'Best metal detector', 4, 'Grey', 12, 2, 847 | 'bit.ly/sfdf4fg'); 848 | 849 | END; 850 | 851 | BEGIN 852 | add_to_wish_list('anshulpardhi@gmail.com', 1); 853 | add_to_wish_list('anshulpardhi@gmail.com', 4); 854 | add_to_wish_list('anshulpardhi@gmail.com', 3); 855 | add_to_wish_list('gunjanagicha@gmail.com', 2); 856 | END; 857 | 858 | BEGIN 859 | add_to_shopping_cart('anshulpardhi@gmail.com', 1); 860 | add_to_shopping_cart('anshulpardhi@gmail.com', 3); 861 | add_to_shopping_cart('gunjanagicha@gmail.com', 2); 862 | add_to_shopping_cart('gunjanagicha@gmail.com', 1); 863 | END; 864 | 865 | BEGIN 866 | update_membership('gunjanagicha@gmail.com'); 867 | END; 868 | 869 | BEGIN 870 | place_order(1, 'gunjanagicha@gmail.com'); 871 | END; 872 | 873 | BEGIN 874 | place_order(2, 'anshulpardhi@gmail.com'); 875 | END; 876 | 877 | BEGIN 878 | give_review(1, 1, 'anshulpardhi@gmail.com', 'cool phone with great camera', 5, 879 | 'www.my_image.com'); 880 | give_review(2, 3, 'anshulpardhi@gmail.com', 'good running shoes', 3, 881 | 'www.my_image.com'); 882 | END; 883 | 884 | BEGIN 885 | give_review(3, 2, 'gunjanagicha@gmail.com', 'nice book', 3.5, 886 | 'www.my_image.com'); 887 | END; 888 | 889 | BEGIN 890 | give_review(4, 1, 'gunjanagicha@gmail.com', 'okay phone', 3, 891 | 'www.my_image.com'); 892 | END; 893 | 894 | BEGIN 895 | give_review(5, 5, 'gunjanagicha@gmail.com', 'doesnt work', 1, 896 | 'www.my_image.com'); 897 | END; 898 | 899 | BEGIN 900 | give_review(6, 5, 'gunjanagicha@gmail.com', 'doesnt work at all', 0, 901 | 'www.my_image.com'); 902 | END; -------------------------------------------------------------------------------- /readme.md: -------------------------------------------------------------------------------- 1 | # E-Commerse Database System - PLSQL and EER Model 2 | 3 | The project implements the **Amazon's e-commerce database system** which fulfils all the functional requirements for an e-commerce website. The database is created by designing the **Extended Entity Relation (EER)** model of Amazon as an E-commerce website. EER is then converted to **relational tables** using the set of well defined rules and after applying the **normalisation techniques**. Project utilizes **PLSQL** and it's **stored procedures, triggeres and cursors** to create tables and maintain the consistency within the relational database. The database system fulfils the following functional requirements - 4 | 5 | **1. A user can register** – A user can be a buyer or a seller. 6 | 7 | **2. A user can place order** - each order contains multiple products. 8 | 9 | **3. A seller can add products** - this contains the details of a product. 10 | 11 | **4. A buyer can give review** - a user can write reviews about a product. 12 | 13 | **5. A user can add products to a Wishlist** - user can store the products which they like but not yet ready to buy. 14 | 15 | **6. A user can add products to a shopping cart** - users add to the shopping cart the products they want to buy. 16 | 17 | **7. Product can be of multiple category** - it defines the category of a product like clothing, electronics etc. 18 | 19 | **8. Product can be carried by different carrier** - the shipping service through which a product can be shipped. 20 | 21 | **9. A user can have multiple address and contact details** - users address and phone number saved in the account. 22 | 23 | **10. A user can have multiple Card info** - users saved card in the account 24 | 25 | **11. A buyer can add images to its review** - each review can have images associated with it. 26 | 27 | **12. A seller can add images to its product** - each product can have multiple images associated with it, so taken in separate table. 28 | 29 | ## ENTITIES AND RELATIONSHIPS 30 | 31 | **1. User-contact\_details:** each user can have multiple contact details saved, while each contact detail will have only 1 user linked. Thus, cardinality is 1: N 32 | 33 | **2. Buyer-card\_info:** each buyer can have many cards, while each card is associated with 1 buyer. Thus, cardinality is 1: N 34 | 35 | **3. Buyer-order:** buyer places order. A buyer can place many orders, while each order is linked with only 1 buyer. Thus, cardinality is 1: N 36 | 37 | **4. Order-product:** each order can contain many products, and each product can come in many orders. Thus, cardinality is M: N 38 | 39 | **5. Seller-product:** seller sells products. Each seller can sell many products, while each product has only 1 seller. Thus, cardinality is 1: N 40 | 41 | **6. Buyer-reviews:** buyer can write a review. Each buyer can write multiple reviews, while each review has only 1 buyer. Thus, cardinality is 1: N 42 | 43 | **7. Review-products:** each review is for 1 product while each product can have many reviews. Thus, cardinality is 1: N 44 | 45 | **8. Buyer-wishlist:** each buyer can have only 1 Wishlist, and each Wishlist has 1 buyer. Thus, cardinality is 1:1. 46 | 47 | **9. Buyer- shopping cart:** each buyer has only 1 shopping cart while each shopping cart is associated with 1 buyer. Thus, cardinality is 1:1. 48 | 49 | **10. Wishlist-product:** each Wishlist contains many products, and each product can be in many wish lists. Thus, cardinality is N:M 50 | 51 | **11. Shopping\_cart-product:** each cart contains many products, and each product can be in many carts. Thus, cardinality is N:M 52 | 53 | **12. Product-category:** each product has only 1 category while each category has many products. Thus, cardinality is 1: N 54 | 55 | **13. Product-carrier:** each product is shipped by 1 carrier, while each carrier ships many products. 56 | 57 | **14. Review-review\_images:** each review has many review images while each review image is linked with 1 review. Thus, cardinality is 1: N 58 | 59 | **15. Product-product\_images:** each product has many product images while each product image is linked with 1 product. Thus, cardinality is 1: N 60 | 61 | **16. Order-card\_info:** each order has a card linked with it, while each card can be used for many orders. Thus, cardinality is 1: N 62 | 63 | **17. Order-contact details:** each order has 1 contact detail (address, phone), while each contact detail is linked with multiple orders. Thus, cardinality is 1: N 64 | 65 | - Number 1:1 relationship = 2 66 | - Number of N: M relationships = 3 67 | - Number of 1: N relationships = 12 68 | - Total Relationships = 17 69 | 70 | ## RELATIONAL SCHEMA 71 | 72 | To map ER diagram into a relational schema, we considered the following mapping rules. 73 | 74 | For each 1: 1 binary relationship, in the total participation entity add the primary key of the other entity as the foreign key. 75 | For 1: N binary relationship, add to the entity on the N side the primary key of the other entity as the foreign key. 76 | For M: N binary relationship, make a new entity with foreign key as the primary key of the two participating entities. Their combination forms the new primary key. 77 | 78 | - In buyer table we have user\_id as foreign key. 79 | - In seller table we have user\_id as foreign key. 80 | - In product table we have seller\_id, carrier\_id and category\_id as foreign keys. 81 | - In order table we have buyer\_id as foreign key. 82 | - In card\_info we have buyer\_id as foreign key. 83 | - In reviews we have buyer\_id, product\_id as foreign keys. 84 | - In wishlist we have buyer\_id as foreign key. 85 | - In shopping cart we have buyer\_id as foreign key. 86 | - In contact\_details we have user\_id as foreign key. 87 | - In review\_images we have review\_id as foreign key. 88 | - In product\_images we have product\_id as foreign key. 89 | - We make a new table name product\_wishlist which as product\_id and wishlist\_id as foreign key. 90 | - We make a new table name product\_shopping\_cart which as product\_id and buyer\_id as foreign key. 91 | - We make a new table name product\_order which as product\_id and order\_id as foreign key. 92 | 93 | 94 | ## SIGNIFICANT PROCEDURES 95 | 96 | **1. Register buyer:** invoked by buyer responsible for 97 | - registering user given email, fname, lname and password. 98 | - registering the buyer itself setting its prime membership as false by default and 99 | prime member expiry date as Null. 100 | 101 | **2. Register seller** has 2 responsibilities 102 | - registering user given email, fname, lname and password. 103 | - registering the seller itself given company name, url, description, setting its average rating as 2.5 default. 104 | 105 | **3. Place order:** Given a buyer id, place order is responsible for the following – 106 | - To iterate over the shopping cart of a particular buyer and remove each item from buyers cart. 107 | - While removing each product, sum up the price of each product to the total price for the order. 108 | - If the user is a prime user, do not include shipping charges for that order. 109 | - Fetch the default address set by the buyer from the list of addresses for that buyer from the contact\_details tables. 110 | - Fetch the default card details set by the buyer from the list of card details for that buyer from the card\_info table. 111 | - To make sure not to include certain products from the shopping car in the order table who's available unity is zero (in\_stock bit is set to 0). 112 | - To add an entry in the order table, containing details of the invoice (total price, total quantity of products in order, tax, shipping charge, card\_details used for the order, delivery contact details used for the order) 113 | - To invokes a trigger responsible for updating the available\_units of each product being bought in that order. 114 | 115 | **4. Give review:** A buyer can add a review by providing product\_id, buyer\_id, review, rating, and image\_url (if any). It adds a review in the review table and image of it in the image table. After execution It invokes two triggers. 116 | - update\_product\_rating 117 | - updte\_seller\_rating. 118 | 119 | **5. Add\_contact\_details:** adds details about address and the users number. A user can add multiple contact details and can set a single to contact\_details to be used by default. 120 | 121 | **6. Add\_card\_info:** add cards information like card number, expiry\_date etc. A user can add mupltiple card details and can set a single to card\_info to be used by default. 122 | 123 | **7. Add\_prodcut:** adds a product sold a by a seller. It also asks for the image URL if any, A seller can upload multiple images for a product. 124 | 125 | **8. Add\_to\_shopping\_cart:** adds a product in the shopping cart for a buyer, given the buyer Id 126 | 127 | **9. Add\_to\_wishlist:** adds a product to the wishlist of a buyer, given the buyer id. 128 | 129 | **10. Update\_membership:** update users prime membership information. 130 | 131 | **11. Cancel\_membership:** cancel users prime membership 132 | 133 | **12. Populate\_product\_categories:** adds all the available categories of product in it 134 | 135 | **13. Populate\_carrier\_categories:** adds all the available carrier serviced responsible for delivering products. 136 | 137 | 138 | ## IMPORTANT TRIGGERS 139 | 140 | **1. Update available units:** 141 | - Trigger is invoked whenever a user places an order. Update available unitsis responsible for updating the value of available units for each product in the product table that is being ordered by a buyer. 142 | - The procedures iterate over all the entries of order\_product table for a specific order and iteratively updates each products quantity in the product table. 143 | - If the quantity reaches 0, the product is marked as out of stock, setting its in\_stock value as 0. 144 | 145 | **2. Update\_product\_rating:** 146 | - It is responsible for updating the rating of a product every time a buyer gives a review by averaging the earlier rating with this buyers rating. 147 | - It also updates the count of rating given for that particular product. 148 | 149 | **3. Update\_seller\_rating** 150 | - It is responsible for updating the rating of a seller every time a buyer gives a review to a product by averaging the earlier rating with this buyers rating. 151 | 152 | **4. Remove\_products\_from\_cart** 153 | - After placing an order by a buyer, the trigger is responsible for removing all the ordered products from the shopping cart of that particular buyer. 154 | --------------------------------------------------------------------------------