├── Amazon ER Diagram.png ├── CS6360.003-Team3-amazon.pdf ├── Final-Project.docx ├── README.md └── amazon_db_system.sql /Amazon ER Diagram.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/anshul1004/AmazonDatabaseDesign/29b1ce93f46a1533cc357faa6bb61c3d4b90bd98/Amazon ER Diagram.png -------------------------------------------------------------------------------- /CS6360.003-Team3-amazon.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/anshul1004/AmazonDatabaseDesign/29b1ce93f46a1533cc357faa6bb61c3d4b90bd98/CS6360.003-Team3-amazon.pdf -------------------------------------------------------------------------------- /Final-Project.docx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/anshul1004/AmazonDatabaseDesign/29b1ce93f46a1533cc357faa6bb61c3d4b90bd98/Final-Project.docx -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # AmazonDatabaseDesign 2 | 3 | In this project, amazon e-commerce database design is implemented in Oracle SQL, using relevant stored procedures and triggers. 4 | For detailed problem statement, please refer "Final-Project.docx". 5 | For detailed project report, please refer "CS6360.003-Team3-amazon.pdf". 6 | -------------------------------------------------------------------------------- /amazon_db_system.sql: -------------------------------------------------------------------------------- 1 | -- ============================================= 2 | -- Authors: Ashwani K Kashyap, Anshul Pardhi, Gunjan Agicha 3 | -- Create date: 11/27/2019 4 | -- Description: Amazon database design, consisting of required tables, constraints, procedures and triggers 5 | -- ============================================= 6 | 7 | CREATE TABLE amz_user ( 8 | email VARCHAR(255) PRIMARY KEY, 9 | fname VARCHAR(255) NOT NULL, 10 | lname VARCHAR(255), 11 | password VARCHAR(30) NOT NULL, 12 | user_type NUMBER(1) NOT NULL 13 | ); 14 | 15 | CREATE TABLE contact_detail ( 16 | user_id VARCHAR(255) NOT NULL, 17 | address_id INTEGER PRIMARY KEY, 18 | street1 VARCHAR(255) NOT NULL, 19 | street2 VARCHAR(255), 20 | city VARCHAR(50) NOT NULL, 21 | state VARCHAR(50) NOT NULL, 22 | country VARCHAR(50) NOT NULL, 23 | zipcode NUMBER(5) NOT NULL, 24 | phone VARCHAR(20) NOT NULL, 25 | is_default NUMBER(1) DEFAULT 0 26 | ); 27 | 28 | CREATE TABLE card_info ( 29 | card_id INTEGER PRIMARY KEY, 30 | card_number NUMBER(16) NOT NULL, 31 | expiry_date DATE NOT NULL, 32 | cvv NUMBER(3) NOT NULL, 33 | buyer_id VARCHAR(255) NOT NULL, 34 | is_default NUMBER(1) 35 | ); 36 | 37 | CREATE TABLE buyer ( 38 | buyer_id VARCHAR(255) PRIMARY KEY, 39 | is_prime NUMBER(1) DEFAULT 0, 40 | prime_expiry_date DATE 41 | ); 42 | 43 | CREATE TABLE seller ( 44 | seller_id VARCHAR(255) PRIMARY KEY, 45 | company_name VARCHAR(255) NOT NULL, 46 | url VARCHAR(255), 47 | description VARCHAR(255), 48 | average_rating NUMBER(2, 1) DEFAULT 2.5, 49 | rating_count NUMBER DEFAULT 0 50 | ); 51 | 52 | CREATE TABLE category ( 53 | category_id INTEGER PRIMARY KEY, 54 | category_name VARCHAR(255) NOT NULL 55 | ); 56 | 57 | CREATE TABLE product ( 58 | product_id INTEGER PRIMARY KEY, 59 | name VARCHAR(255) NOT NULL, 60 | seller_id VARCHAR(255) NOT NULL, 61 | price NUMBER(10, 2) NOT NULL, 62 | rating NUMBER(2, 1), 63 | review_count INTEGER, 64 | category_id INTEGER, 65 | description VARCHAR(255), 66 | discount_percent NUMBER(4, 2), 67 | available_units INTEGER, 68 | color VARCHAR(30), 69 | in_stock NUMBER(1), 70 | weight NUMBER(10, 2), 71 | carrier_id INTEGER 72 | ); 73 | 74 | CREATE TABLE product_image ( 75 | product_id INTEGER, 76 | image_url VARCHAR(255), 77 | PRIMARY KEY ( product_id, 78 | image_url ) 79 | ); 80 | 81 | CREATE TABLE shopping_cart ( 82 | buyer_id VARCHAR(255), 83 | date_added DATE 84 | ); 85 | 86 | CREATE TABLE product_shoppingcart ( 87 | product_id INTEGER, 88 | buyer_id VARCHAR(255), 89 | PRIMARY KEY ( product_id, 90 | buyer_id ) 91 | ); 92 | 93 | CREATE TABLE wish_list ( 94 | buyer_id VARCHAR(255), 95 | date_added DATE 96 | ); 97 | 98 | CREATE TABLE product_wishlist ( 99 | product_id INTEGER, 100 | buyer_id VARCHAR(255), 101 | PRIMARY KEY ( product_id, 102 | buyer_id ) 103 | ); 104 | 105 | CREATE TABLE amz_order ( 106 | order_id INTEGER PRIMARY KEY, 107 | buyer_id VARCHAR(255) NOT NULL, 108 | card_id INTEGER NOT NULL, 109 | total_price NUMBER(10, 2), 110 | order_date DATE, 111 | tax NUMBER(4, 2) DEFAULT 10, 112 | shipping_price NUMBER(4, 2) DEFAULT 10, 113 | delivery_address_id INTEGER, 114 | delivery_date DATE, 115 | order_status CHAR(1) NOT NULL, 116 | quantity INTEGER NOT NULL 117 | ); 118 | 119 | CREATE TABLE order_product ( 120 | order_id INTEGER, 121 | product_id INTEGER, 122 | PRIMARY KEY ( order_id, 123 | product_id ) 124 | ); 125 | 126 | CREATE TABLE review ( 127 | review_id INTEGER PRIMARY KEY, 128 | product_id INTEGER NOT NULL, 129 | buyer_id VARCHAR(255) NOT NULL, 130 | review VARCHAR(1000), 131 | rating NUMBER(2, 1), 132 | review_date DATE 133 | ); 134 | 135 | CREATE TABLE review_image ( 136 | review_id INTEGER, 137 | image_url VARCHAR(255), 138 | PRIMARY KEY ( review_id, 139 | image_url ) 140 | ); 141 | 142 | CREATE TABLE carrier ( 143 | carrier_id INTEGER PRIMARY KEY, 144 | carrier_name VARCHAR(255) NOT NULL, 145 | carrier_phone NUMBER(10) NOT NULL, 146 | carrier_email VARCHAR(255) NOT NULL 147 | ); 148 | 149 | ALTER TABLE contact_detail 150 | ADD CONSTRAINT contact_detail_user_id_fk FOREIGN KEY ( user_id ) 151 | REFERENCES amz_user ( email ) 152 | ON DELETE CASCADE; 153 | 154 | ALTER TABLE card_info 155 | ADD CONSTRAINT card_info_buyer_id_fk FOREIGN KEY ( buyer_id ) 156 | REFERENCES buyer ( buyer_id ) 157 | ON DELETE CASCADE; 158 | 159 | ALTER TABLE product 160 | ADD CONSTRAINT product_seller_id_fk FOREIGN KEY ( seller_id ) 161 | REFERENCES seller ( seller_id ) 162 | ON DELETE CASCADE; 163 | 164 | ALTER TABLE product 165 | ADD CONSTRAINT product_category_id_fk FOREIGN KEY ( category_id ) 166 | REFERENCES category ( category_id ) 167 | ON DELETE CASCADE; 168 | 169 | ALTER TABLE product 170 | ADD CONSTRAINT product_carrier_id_fk FOREIGN KEY ( carrier_id ) 171 | REFERENCES carrier ( carrier_id ) 172 | ON DELETE CASCADE; 173 | 174 | ALTER TABLE product_image 175 | ADD CONSTRAINT product_image_product_id_fk FOREIGN KEY ( product_id ) 176 | REFERENCES product ( product_id ) 177 | ON DELETE CASCADE; 178 | 179 | ALTER TABLE shopping_cart 180 | ADD CONSTRAINT shopping_cart_buyer_id_fk FOREIGN KEY ( buyer_id ) 181 | REFERENCES buyer ( buyer_id ) 182 | ON DELETE CASCADE; 183 | 184 | ALTER TABLE product_shoppingcart 185 | ADD CONSTRAINT product_sc_buyer_id_fk FOREIGN KEY ( buyer_id ) 186 | REFERENCES buyer ( buyer_id ) 187 | ON DELETE CASCADE; 188 | 189 | ALTER TABLE product_shoppingcart 190 | ADD CONSTRAINT product_sc_product_id_fk FOREIGN KEY ( product_id ) 191 | REFERENCES product ( product_id ) 192 | ON DELETE CASCADE; 193 | 194 | ALTER TABLE wish_list 195 | ADD CONSTRAINT wishlist_buyer_id_fk FOREIGN KEY ( buyer_id ) 196 | REFERENCES buyer ( buyer_id ) 197 | ON DELETE CASCADE; 198 | 199 | ALTER TABLE product_wishlist 200 | ADD CONSTRAINT product_wishlist_product_id_fk FOREIGN KEY ( product_id ) 201 | REFERENCES product ( product_id ) 202 | ON DELETE CASCADE; 203 | 204 | ALTER TABLE product_wishlist 205 | ADD CONSTRAINT product_wishlist_buyer_id_fk FOREIGN KEY ( buyer_id ) 206 | REFERENCES buyer ( buyer_id ) 207 | ON DELETE CASCADE; 208 | 209 | ALTER TABLE amz_order 210 | ADD CONSTRAINT order_buyer_id_fk FOREIGN KEY ( buyer_id ) 211 | REFERENCES buyer ( buyer_id ) 212 | ON DELETE CASCADE; 213 | 214 | ALTER TABLE amz_order 215 | ADD CONSTRAINT order_card_id_fk FOREIGN KEY ( card_id ) 216 | REFERENCES card_info ( card_id ) 217 | ON DELETE CASCADE; 218 | 219 | ALTER TABLE amz_order 220 | ADD CONSTRAINT order_delivery_address_id_fk FOREIGN KEY ( delivery_address_id ) 221 | REFERENCES contact_detail ( address_id ) 222 | ON DELETE CASCADE; 223 | 224 | ALTER TABLE order_product 225 | ADD CONSTRAINT order_product_order_id_fk FOREIGN KEY ( order_id ) 226 | REFERENCES amz_order ( order_id ) 227 | ON DELETE CASCADE; 228 | 229 | ALTER TABLE order_product 230 | ADD CONSTRAINT order_product_product_id_fk FOREIGN KEY ( product_id ) 231 | REFERENCES product ( product_id ) 232 | ON DELETE CASCADE; 233 | 234 | ALTER TABLE review 235 | ADD CONSTRAINT review_product_id_fk FOREIGN KEY ( product_id ) 236 | REFERENCES product ( product_id ) 237 | ON DELETE CASCADE; 238 | 239 | ALTER TABLE review 240 | ADD CONSTRAINT review_buyer_id_fk FOREIGN KEY ( buyer_id ) 241 | REFERENCES buyer ( buyer_id ) 242 | ON DELETE CASCADE; 243 | 244 | ALTER TABLE review_image 245 | ADD CONSTRAINT review_image_review_id_fk FOREIGN KEY ( review_id ) 246 | REFERENCES review ( review_id ) 247 | ON DELETE CASCADE; 248 | 249 | CREATE OR REPLACE PROCEDURE register_buyer ( 250 | email IN VARCHAR, 251 | fname IN VARCHAR, 252 | lname IN VARCHAR, 253 | password IN VARCHAR 254 | ) AS 255 | BEGIN 256 | INSERT INTO amz_user VALUES ( 257 | email, 258 | fname, 259 | lname, 260 | password, 261 | 0 262 | ); 263 | 264 | INSERT INTO buyer VALUES ( 265 | email, 266 | 0, 267 | NULL 268 | ); 269 | 270 | END register_buyer; 271 | 272 | -------------------------------------------------------------------------------------------- 273 | 274 | CREATE OR REPLACE PROCEDURE register_seller ( 275 | email IN VARCHAR, 276 | fname IN VARCHAR, 277 | lname IN VARCHAR, 278 | password IN VARCHAR, 279 | company_name IN VARCHAR, 280 | url IN VARCHAR, 281 | description_var IN VARCHAR 282 | ) AS 283 | BEGIN 284 | INSERT INTO amz_user VALUES ( 285 | email, 286 | fname, 287 | lname, 288 | password, 289 | 1 290 | ); 291 | 292 | INSERT INTO seller VALUES ( 293 | email, 294 | company_name, 295 | url, 296 | description_var, 297 | 2.5, 298 | 0 299 | ); 300 | 301 | END register_seller; 302 | 303 | --------------------------------------------------------------------------------------------- 304 | 305 | CREATE OR REPLACE PROCEDURE add_contact_details ( 306 | user_id IN VARCHAR, 307 | address_id IN INTEGER, 308 | street1 IN VARCHAR, 309 | street2 IN VARCHAR, 310 | city IN VARCHAR, 311 | state IN VARCHAR, 312 | country IN VARCHAR, 313 | zipcode IN NUMBER, 314 | phone IN VARCHAR 315 | ) AS 316 | BEGIN 317 | INSERT INTO contact_detail VALUES ( 318 | user_id, 319 | address_id, 320 | street1, 321 | street2, 322 | city, 323 | state, 324 | country, 325 | zipcode, 326 | phone, 327 | 0 328 | ); 329 | 330 | END add_contact_details; 331 | 332 | -------------------------------------------------------------------------------------------- 333 | 334 | CREATE OR REPLACE PROCEDURE set_default_contact_details ( 335 | contact_id IN INTEGER, 336 | buyer_id IN VARCHAR 337 | ) AS 338 | BEGIN 339 | UPDATE contact_detail 340 | SET 341 | is_default = 1 342 | WHERE 343 | user_id = buyer_id 344 | AND address_id = contact_id; 345 | 346 | END set_default_contact_details; 347 | 348 | -------------------------------------------------------------------------------------------- 349 | 350 | CREATE OR REPLACE PROCEDURE add_card_info ( 351 | buyer_id IN VARCHAR, 352 | card_id IN INTEGER, 353 | card_number IN NUMBER, 354 | expiry_date IN DATE, 355 | cvv IN NUMBER 356 | ) AS 357 | BEGIN 358 | INSERT INTO card_info VALUES ( 359 | card_id, 360 | card_number, 361 | expiry_date, 362 | cvv, 363 | buyer_id, 364 | 0 365 | ); 366 | 367 | END add_card_info; 368 | 369 | -------------------------------------------------------------------------------------------- 370 | 371 | CREATE OR REPLACE PROCEDURE set_default_card_info ( 372 | card_id_var IN INTEGER, 373 | buyer_id_var IN VARCHAR 374 | ) AS 375 | BEGIN 376 | UPDATE card_info 377 | SET 378 | is_default = 1 379 | WHERE 380 | buyer_id = buyer_id_var 381 | AND card_id = card_id_var; 382 | 383 | END set_default_card_info; 384 | 385 | -------------------------------------------------------------------------------------------- 386 | 387 | CREATE OR REPLACE PROCEDURE add_product ( 388 | product_id IN INTEGER, 389 | name IN VARCHAR, 390 | seller_id IN VARCHAR, 391 | price IN NUMBER, 392 | category_id IN INTEGER, 393 | description IN VARCHAR, 394 | available_units IN INTEGER, 395 | color IN VARCHAR, 396 | weight IN NUMBER, 397 | carrier_id IN INTEGER, 398 | image_url IN VARCHAR 399 | ) AS 400 | BEGIN 401 | INSERT INTO product VALUES ( 402 | product_id, 403 | name, 404 | seller_id, 405 | price, 406 | 0, 407 | 0, 408 | category_id, 409 | description, 410 | 0, 411 | available_units, 412 | color, 413 | 1, 414 | weight, 415 | carrier_id 416 | ); 417 | 418 | INSERT INTO product_image VALUES ( 419 | product_id, 420 | image_url 421 | ); 422 | 423 | END add_product; 424 | 425 | -------------------------------------------------------------------------------------------- 426 | 427 | CREATE OR REPLACE PROCEDURE add_to_shopping_cart ( 428 | buyer_id IN VARCHAR, 429 | product_id IN INTEGER 430 | ) AS 431 | BEGIN 432 | INSERT INTO shopping_cart VALUES ( 433 | buyer_id, 434 | sysdate 435 | ); 436 | 437 | INSERT INTO product_shoppingcart VALUES ( 438 | product_id, 439 | buyer_id 440 | ); 441 | 442 | END add_to_shopping_cart; 443 | 444 | -------------------------------------------------------------------------------------------- 445 | 446 | CREATE OR REPLACE PROCEDURE add_to_wish_list ( 447 | buyer_id IN VARCHAR, 448 | product_id IN INTEGER 449 | ) AS 450 | BEGIN 451 | INSERT INTO wish_list VALUES ( 452 | buyer_id, 453 | sysdate 454 | ); 455 | 456 | INSERT INTO product_wishlist VALUES ( 457 | product_id, 458 | buyer_id 459 | ); 460 | 461 | END add_to_wish_list; 462 | 463 | -------------------------------------------------------------------------------------------- 464 | 465 | CREATE OR REPLACE PROCEDURE give_review ( 466 | review_id IN NUMBER, 467 | product_id IN INTEGER, 468 | buyer_id IN VARCHAR, 469 | review IN VARCHAR, 470 | rating IN NUMBER, 471 | image_url IN VARCHAR 472 | ) AS 473 | BEGIN 474 | INSERT INTO review VALUES ( 475 | review_id, 476 | product_id, 477 | buyer_id, 478 | review, 479 | rating, 480 | sysdate 481 | ); 482 | 483 | INSERT INTO review_image VALUES ( 484 | review_id, 485 | image_url 486 | ); 487 | 488 | END give_review; 489 | 490 | -------------------------------------------------------------------------------------------- 491 | 492 | CREATE OR REPLACE TRIGGER update_product_rating AFTER 493 | INSERT ON review 494 | FOR EACH ROW 495 | DECLARE 496 | new_rating NUMBER(2, 1); 497 | review_count_old INTEGER; 498 | BEGIN 499 | SELECT 500 | review_count 501 | INTO review_count_old 502 | FROM 503 | product 504 | WHERE 505 | product_id = :new.product_id; 506 | 507 | new_rating := :new.rating; 508 | UPDATE product 509 | SET 510 | rating = ( ( rating * review_count_old ) + new_rating ) / ( review_count_old + 1 ), 511 | review_count = review_count_old + 1 512 | WHERE 513 | product_id = :new.product_id; 514 | 515 | END; 516 | 517 | -------------------------------------------------------------------------------------------- 518 | 519 | CREATE OR REPLACE TRIGGER update_seller_rating AFTER 520 | INSERT OR UPDATE OF rating ON review 521 | FOR EACH ROW 522 | DECLARE 523 | new_rating NUMBER(2, 1); 524 | seller_id_to_update VARCHAR(255); 525 | BEGIN 526 | new_rating := :new.rating; 527 | SELECT 528 | seller_id 529 | INTO seller_id_to_update 530 | FROM 531 | product 532 | WHERE 533 | product_id = :new.product_id; 534 | 535 | UPDATE seller 536 | SET 537 | average_rating = ( ( average_rating * rating_count ) + new_rating ) / ( rating_count + 1 ), 538 | rating_count = rating_count + 1 539 | WHERE 540 | seller_id = seller_id_to_update; 541 | 542 | END; 543 | 544 | -------------------------------------------------------------------------------------------- 545 | 546 | CREATE OR REPLACE PROCEDURE update_membership ( 547 | buyer_id_input IN VARCHAR 548 | ) AS 549 | BEGIN 550 | UPDATE buyer 551 | SET 552 | is_prime = 1, 553 | prime_expiry_date = add_months(DATE '2019-11-28', 12) 554 | WHERE 555 | buyer_id = buyer_id_input; 556 | 557 | END update_membership; 558 | 559 | -------------------------------------------------------------------------------------------- 560 | 561 | CREATE OR REPLACE PROCEDURE cancel_membership ( 562 | buyer_id_input IN VARCHAR 563 | ) AS 564 | BEGIN 565 | UPDATE buyer 566 | SET 567 | is_prime = 0, 568 | prime_expiry_date = NULL 569 | WHERE 570 | buyer_id = buyer_id_input; 571 | 572 | END cancel_membership; 573 | 574 | -------------------------------------------------------------------------------------------- 575 | 576 | CREATE OR REPLACE PROCEDURE place_order ( 577 | order_id IN INTEGER, 578 | buyer_id_var IN VARCHAR 579 | ) AS 580 | 581 | card_id_var INTEGER; 582 | address_id_var INTEGER; 583 | total_price_var NUMBER := 0; 584 | curr_price_var NUMBER; 585 | total_qty_var NUMBER := 0; 586 | available_units_var NUMBER(1); 587 | shipping_price_var NUMBER := 10; 588 | is_prime_var NUMBER := 0; 589 | CURSOR products_cur IS 590 | SELECT 591 | product_id 592 | FROM 593 | product_shoppingcart 594 | WHERE 595 | buyer_id = buyer_id_var; 596 | 597 | product_id_var INTEGER; 598 | BEGIN 599 | OPEN products_cur; 600 | LOOP 601 | FETCH products_cur INTO product_id_var; 602 | EXIT WHEN products_cur%notfound; 603 | SELECT 604 | price, 605 | available_units 606 | INTO 607 | curr_price_var, 608 | available_units_var 609 | FROM 610 | product 611 | WHERE 612 | product_id = product_id_var; 613 | 614 | IF available_units_var > 0 THEN 615 | total_price_var := ( total_price_var + curr_price_var ); 616 | total_qty_var := total_qty_var + 1; 617 | INSERT INTO order_product VALUES ( 618 | order_id, 619 | product_id_var 620 | ); 621 | 622 | END IF; 623 | 624 | -- DELETE FROM product_shoppingcart 625 | -- WHERE product_id = product_id_var AND buyer_id = buyer_id_var; 626 | 627 | END LOOP; 628 | 629 | CLOSE products_cur; 630 | SELECT 631 | is_prime 632 | INTO is_prime_var 633 | FROM 634 | buyer 635 | WHERE 636 | buyer_id = buyer_id_var; 637 | 638 | IF is_prime_var = 1 THEN 639 | shipping_price_var := 0; 640 | END IF; 641 | SELECT 642 | card_id 643 | INTO card_id_var 644 | FROM 645 | card_info 646 | WHERE 647 | buyer_id = buyer_id_var 648 | AND is_default = 1; 649 | 650 | SELECT 651 | address_id 652 | INTO address_id_var 653 | FROM 654 | contact_detail 655 | WHERE 656 | user_id = buyer_id_var 657 | AND is_default = 1; 658 | 659 | total_price_var := total_price_var + shipping_price_var + 10; 660 | INSERT INTO amz_order VALUES ( 661 | order_id, 662 | buyer_id_var, 663 | card_id_var, 664 | total_price_var, 665 | sysdate, 666 | 10, 667 | shipping_price_var, 668 | address_id_var, 669 | add_months(DATE '2019-11-28', 1), 670 | 'c', 671 | total_qty_var 672 | ); 673 | 674 | END place_order; 675 | 676 | -------------------------------------------------------------------------------------------- 677 | 678 | CREATE OR REPLACE PROCEDURE populate_product_categories AS 679 | BEGIN 680 | INSERT INTO category VALUES ( 681 | 1, 682 | 'Electronics' 683 | ); 684 | 685 | INSERT INTO category VALUES ( 686 | 2, 687 | 'Books' 688 | ); 689 | 690 | INSERT INTO category VALUES ( 691 | 3, 692 | 'Clothing' 693 | ); 694 | 695 | END populate_product_categories; 696 | 697 | -------------------------------------------------------------------------------------------- 698 | 699 | CREATE OR REPLACE PROCEDURE populate_carriers AS 700 | BEGIN 701 | INSERT INTO carrier VALUES ( 702 | 1, 703 | 'DHL', 704 | 1234567890, 705 | 'DHL@gmail.com' 706 | ); 707 | 708 | INSERT INTO carrier VALUES ( 709 | 2, 710 | 'Fedex', 711 | 1234567890, 712 | 'Fedex@gmail.com' 713 | ); 714 | 715 | INSERT INTO carrier VALUES ( 716 | 3, 717 | 'UPS', 718 | 1234567890, 719 | 'UPS@gmail.com' 720 | ); 721 | 722 | END populate_carriers; 723 | 724 | -------------------------------------------------------------------------------------------- 725 | 726 | CREATE OR REPLACE TRIGGER update_available_units AFTER 727 | INSERT ON amz_order 728 | FOR EACH ROW 729 | DECLARE 730 | product_id_var INTEGER; 731 | available_units_var INTEGER; 732 | CURSOR products_cur IS 733 | SELECT 734 | product_id 735 | FROM 736 | order_product 737 | WHERE 738 | order_id = :new.order_id; 739 | 740 | BEGIN 741 | OPEN products_cur; 742 | LOOP 743 | FETCH products_cur INTO product_id_var; 744 | EXIT WHEN products_cur%notfound; 745 | SELECT 746 | available_units 747 | INTO available_units_var 748 | FROM 749 | product 750 | WHERE 751 | product_id = product_id_var; 752 | 753 | IF available_units_var >= 2 THEN 754 | UPDATE product 755 | SET 756 | available_units = available_units - 1 757 | WHERE 758 | product_id = product_id_var; 759 | 760 | ELSIF available_units_var = 1 THEN 761 | UPDATE product 762 | SET 763 | available_units = available_units - 1, 764 | in_stock = 0 765 | WHERE 766 | product_id = product_id_var; 767 | 768 | END IF; 769 | 770 | END LOOP; 771 | 772 | CLOSE products_cur; 773 | END; 774 | 775 | CREATE OR REPLACE TRIGGER remove_items_from_cart AFTER 776 | INSERT ON amz_order 777 | FOR EACH ROW 778 | DECLARE BEGIN 779 | DELETE FROM shopping_cart 780 | WHERE 781 | buyer_id = :new.buyer_id; 782 | 783 | DELETE FROM product_shoppingcart 784 | WHERE 785 | buyer_id = :new.buyer_id; 786 | 787 | END; 788 | 789 | BEGIN 790 | register_buyer('anshulpardhi@gmail.com', 'anshul', 'pardhi', 'abcd123'); 791 | register_buyer('ashwanikashyap@gmail.com', 'ashwani', 'kashyap', 'abcd123'); 792 | register_buyer('gunjanagicha@gmail.com', 'gunjan', 'agicha', 'abcd123'); 793 | END; 794 | 795 | BEGIN 796 | register_seller('kushagradar@gmail.com', 'kushagra', 'dar', 'abcd123', 'kushagra Co and Co', 797 | 'www.kusharga.com', 'company of shoes'); 798 | register_seller('ruchisingh@gmail.com', 'ruchi', 'singh', 'abcd123', 'ruchi Co and Co', 799 | 'www.ruchi.com', 'company of metals'); 800 | register_seller('anantprakash@gmail.com', 'anant', 'prakash', 'abcd123', 'anant Co and Co', 801 | 'www.anant.com', 'company of iphones'); 802 | END; 803 | 804 | BEGIN 805 | update_contact_details('anshulpardhi@gmail.com', 1, '7825 McCallum Blvd', 'Apt 007', 'Dallas', 806 | 'Texas', 'USA', 75252, 8888888888); 807 | 808 | update_contact_details('gunjanagicha@gmail.com', 2, '7825 McCallum Blvd', 'Apt 1702', 'Dallas', 809 | 'Texas', 'USA', 75252, 8888888888); 810 | 811 | update_contact_details('gunjanagicha@gmail.com', 3, '7825 McCallum Blvd', 'Apt 1702', 'Dallas', 812 | 'Texas', 'USA', 75252, 4692309274); 813 | 814 | set_default_contact_details(3, 'gunjanagicha@gmail.com'); 815 | set_default_contact_details(1, 'anshulpardhi@gmail.com'); 816 | END; 817 | 818 | BEGIN 819 | add_card_info('gunjanagicha@gmail.com', 1, 1234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 820 | 666); 821 | add_card_info('gunjanagicha@gmail.com', 2, 0234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 822 | 777); 823 | add_card_info('anshulpardhi@gmail.com', 3, 0234123412341234, TO_DATE('2023-12-09', 'YYYY-MM-DD'), 824 | 777); 825 | set_default_card_info(1, 'gunjanagicha@gmail.com'); 826 | set_default_card_info(3, 'anshulpardhi@gmail.com'); 827 | END; 828 | 829 | BEGIN 830 | populate_product_categories(); 831 | populate_carriers(); 832 | END; 833 | 834 | BEGIN 835 | add_product(1, 'OnePlus 7', 'kushagradar@gmail.com', 400, 1, 836 | 'Best Phone', 2, 'Blue', 2, 2, 837 | 'bit.ly/sfdf4fg'); 838 | 839 | add_product(2, 'Harry Potter', 'kushagradar@gmail.com', 15, 2, 840 | 'Best Book', 5, 'Black', 8, 2, 841 | 'bit.ly/sfdf4fg'); 842 | 843 | add_product(3, 'Nike Shoes', 'anantprakash@gmail.com', 50, 3, 844 | 'Best shoes', 2, 'yellow', 5, 1, 845 | 'bit.ly/sfdf4fg'); 846 | 847 | add_product(4, 'I phone', 'anantprakash@gmail.com', 500, 1, 848 | 'Better than android', 3, 'Black', 2, 3, 849 | 'bit.ly/sfdf4fg'); 850 | 851 | add_product(5, 'Metal Detector', 'ruchisingh@gmail.com', 20, 1, 852 | 'Best metal detector', 4, 'Grey', 12, 2, 853 | 'bit.ly/sfdf4fg'); 854 | 855 | END; 856 | 857 | BEGIN 858 | add_to_wish_list('anshulpardhi@gmail.com', 1); 859 | add_to_wish_list('anshulpardhi@gmail.com', 4); 860 | add_to_wish_list('anshulpardhi@gmail.com', 3); 861 | add_to_wish_list('gunjanagicha@gmail.com', 2); 862 | END; 863 | 864 | BEGIN 865 | add_to_shopping_cart('anshulpardhi@gmail.com', 1); 866 | add_to_shopping_cart('anshulpardhi@gmail.com', 3); 867 | add_to_shopping_cart('gunjanagicha@gmail.com', 2); 868 | add_to_shopping_cart('gunjanagicha@gmail.com', 1); 869 | END; 870 | 871 | BEGIN 872 | update_membership('gunjanagicha@gmail.com'); 873 | END; 874 | 875 | BEGIN 876 | place_order(1, 'gunjanagicha@gmail.com'); 877 | END; 878 | 879 | BEGIN 880 | place_order(2, 'anshulpardhi@gmail.com'); 881 | END; 882 | 883 | BEGIN 884 | give_review(1, 1, 'anshulpardhi@gmail.com', 'cool phone with great camera', 5, 885 | 'www.my_image.com'); 886 | give_review(2, 3, 'anshulpardhi@gmail.com', 'good running shoes', 3, 887 | 'www.my_image.com'); 888 | END; 889 | 890 | BEGIN 891 | give_review(3, 2, 'gunjanagicha@gmail.com', 'nice book', 3.5, 892 | 'www.my_image.com'); 893 | END; 894 | 895 | BEGIN 896 | give_review(4, 1, 'gunjanagicha@gmail.com', 'okay phone', 3, 897 | 'www.my_image.com'); 898 | END; 899 | 900 | BEGIN 901 | give_review(5, 5, 'gunjanagicha@gmail.com', 'doesnt work', 1, 902 | 'www.my_image.com'); 903 | END; 904 | 905 | BEGIN 906 | give_review(6, 5, 'gunjanagicha@gmail.com', 'doesnt work at all', 0, 907 | 'www.my_image.com'); 908 | END; --------------------------------------------------------------------------------