├── LICENSE ├── PostgreSQL └── sampledb │ └── v1 │ ├── README.md │ ├── data │ └── csv │ │ ├── mlb_data.csv │ │ ├── name_data.csv │ │ ├── nfl_data.csv │ │ ├── nfl_stadium_data.csv │ │ ├── seat_type.csv │ │ ├── sport_division.csv │ │ ├── sport_league.csv │ │ ├── sport_location.csv │ │ └── sport_type.csv │ ├── install-postgresql.sql │ ├── schema │ ├── create-constraint.sql │ ├── create-index.sql │ ├── create-table.sql │ ├── create-view.sql │ ├── foreign-keys.sql │ └── functions │ │ ├── esubstr.sql │ │ ├── generatemlbseason.sql │ │ ├── generatenflseason.sql │ │ ├── generateseats.sql │ │ ├── generatesporttickets.sql │ │ ├── generateticketactivity.sql │ │ ├── generatetickets.sql │ │ ├── generatetransferactivity.sql │ │ ├── loadmlbplayers.sql │ │ ├── loadmlbteams.sql │ │ ├── loadnflplayers.sql │ │ ├── loadnflteams.sql │ │ ├── selltickets.sql │ │ ├── set_mlb_team_home_field.sql │ │ ├── setnflhomefield.sql │ │ └── transferticket.sql │ └── user │ └── create-user.sql ├── README.md ├── exercises ├── mysql-shard-consolidation │ ├── README.md │ ├── create-shards.sql │ └── schema │ │ ├── export_shard_data.sql │ │ ├── generate_ticket_activity.sql │ │ ├── load_person.sql │ │ ├── load_sporting_event_ticket.sql │ │ ├── unload_person.sql │ │ └── unload_sporting_event_ticket.sql └── oracle-to-postgres │ └── README.md ├── images ├── mongo_sampledb.png ├── mongo_sampledb_doc.png ├── sampledb.jpg ├── shardConsolidationAlternative.png ├── shardConsolidationFinal.png ├── shardConsolidationStageOne.png ├── shardedERD.jpg └── unconsolidatedShards.png ├── mongodb └── sampledb │ └── v1 │ ├── README.md │ ├── config │ └── mongodb-org-3.4.repo │ ├── data │ ├── mlb_data.sql │ ├── name_data.sql │ ├── nfl_data.sql │ └── nfl_stadium_data.sql │ ├── install_ruby.sh │ ├── install_sampledb.sh │ ├── schema │ ├── generate_sporting_events.rb │ ├── generate_tickets.rb │ ├── load_mlb_data.rb │ ├── load_name_data.rb │ ├── load_nfl_data.rb │ ├── load_nfl_stadium_data.rb │ ├── load_person.rb │ ├── load_sport.rb │ ├── load_sport_location.rb │ └── load_sports_teams.rb │ ├── scripts │ ├── list_mlb_data.rb │ ├── list_mlb_teams.rb │ ├── list_name_data.rb │ ├── list_nfl_data.rb │ ├── list_nfl_stadium_data.rb │ ├── list_nfl_teams.rb │ ├── list_sport_locations.rb │ ├── list_sport_locations_with_seats.rb │ ├── list_sporting_events.rb │ ├── list_sports.rb │ └── list_teams.rb │ └── user │ └── create_dms_user.js ├── mysql └── sampledb │ └── v1 │ ├── README.md │ ├── data │ ├── mlb_data.sql │ ├── name_data.sql │ ├── nfl_data.sql │ └── nfl_stadium_data.sql │ ├── install-rds.sql │ ├── remove-sampledb.sql │ ├── schema │ ├── create_dms_sample.sql │ ├── generate_mlb_season.sql │ ├── generate_nfl_season.sql │ ├── generate_sport_tickets.sql │ ├── generate_ticket_activity.sql │ ├── generate_tickets.sql │ ├── generate_transfer_activity.sql │ ├── install_dms_sample_data.sql │ ├── load_base_data.sql │ ├── mlb_data.tab │ ├── name_data.tab │ ├── nfl_data.tab │ ├── nfl_stadium_data.tab │ ├── person.tab │ ├── player.tab │ ├── seat.tab │ ├── seat_type.tab │ ├── sell_tickets.sql │ ├── set_mlb_team_home_field.sql │ ├── set_nfl_team_home_field.sql │ ├── sport_division.tab │ ├── sport_league.tab │ ├── sport_location.tab │ ├── sport_team.tab │ ├── sport_type.tab │ ├── sporting_event.tab │ ├── sporting_event_info.vw │ ├── sporting_event_ticket.tab │ ├── sporting_event_ticket_info.vw │ ├── ticket_purchase_hist.tab │ └── transfer_tickets.sql │ └── user │ ├── create_dms_user.sql │ └── dms_user_privileges.sql ├── oracle └── sampledb │ └── v1 │ ├── README.md │ ├── data │ ├── README.txt │ ├── master.csv │ ├── players_2013-12-12.csv │ └── random_names.csv │ ├── install-onprem.sql │ ├── install-rds.sql │ ├── remove-sampledb.sql │ ├── schema │ ├── README.txt │ ├── dim_player │ ├── dim_sport_team │ ├── dim_sporting_event │ ├── dms_sample_dw.ddl │ ├── dms_sample_dw.pdf │ ├── generate_mlb_season.sql │ ├── generate_nfl_season.sql │ ├── generate_tickets.pls │ ├── install_dms_sample_data.sql │ ├── load_base_data.sql │ ├── mlb_data.sql │ ├── mlb_data.tab │ ├── name_data.sql │ ├── name_data.tab │ ├── nfl_data.sql │ ├── nfl_data.tab │ ├── nfl_stadium_data.sql │ ├── nfl_stadium_data.tab │ ├── person.tab │ ├── player.tab │ ├── public_synonyms.sql │ ├── seat.tab │ ├── seat_type.tab │ ├── set_mlb_team_home_field.sql │ ├── set_nfl_team_home_field.sql │ ├── sport_division.tab │ ├── sport_league.tab │ ├── sport_location.tab │ ├── sport_team.tab │ ├── sport_type.tab │ ├── sporting_event.tab │ ├── sporting_event_info.vw │ ├── sporting_event_ticket.tab │ ├── ticket_info.vw │ ├── ticket_management.pkg │ └── ticket_purchase_hist.tab │ └── user │ ├── README.txt │ ├── create_dms_sample.sql │ ├── create_dms_user.sql │ ├── dms_sample_dms_user_grants.sql │ ├── dms_sample_privileges.sql │ ├── dms_sample_privileges_onprem.sql │ ├── dms_user_privileges.sql │ ├── dms_user_privileges_onprem.sql │ └── dms_user_sct_privileges.sql ├── sampledb.pdf └── sqlserver └── sampledb └── v1 ├── README.md ├── data ├── master.csv ├── players_2013-12-12.csv └── random_names.csv ├── install-onprem.sql ├── remove-sampledb.sql ├── schema ├── create_dms_sample.sql ├── generateTicketActivity.sql ├── generateTransferActivity.sql ├── generate_mlb_season.sql ├── generate_nfl_season.sql ├── generate_tickets.sql ├── getNewId.vw ├── load_mlb_tickets.sql ├── load_nfl_tickets.sql ├── mlb_data.sql ├── mlb_data.tab ├── name_data.sql ├── name_data.tab ├── nfl_data.sql ├── nfl_data.tab ├── nfl_stadium_data.sql ├── nfl_stadium_data.tab ├── person.tab ├── player.tab ├── rand_int.sql ├── seat.tab ├── seat_type.tab ├── sellTickets.sql ├── set_mlb_team_home_field.sql ├── set_nfl_team_home_field.sql ├── sport_division.tab ├── sport_league.tab ├── sport_location.tab ├── sport_team.tab ├── sport_type.tab ├── sporting_event.tab ├── sporting_event_info.vw ├── sporting_event_ticket.tab ├── ticket_info.vw ├── ticket_purchase_hist.tab └── transferTicket.sql ├── show_server.sql ├── system ├── dms_sample_backup.sql └── enable_replication.sql └── user └── create_dms_user.sql /PostgreSQL/sampledb/v1/data/csv/nfl_stadium_data.csv: -------------------------------------------------------------------------------- 1 | 2 | Los Angeles Memorial Coliseum,93607,"Los Angeles, California",Natural grass,Open,Los Angeles Rams,1923,31 3 | MetLife Stadium,82500,"East Rutherford, New Jersey",UBU Speed Series S5-M Synthetic Turf,Open,New York Giants,2010,32 4 | MetLife Stadium,82500,"East Rutherford, New Jersey",UBU Speed Series S5-M Synthetic Turf,Open,New York Jets,2010,32 5 | FedExField,82000,"Landover, Maryland",Latitude 36 Bermuda Grass,Open,Washington Redskins,1997,34 6 | Lambeau Field,81435,"Green Bay, Wisconsin",Hybrid Grass-Synthetic,Open,Green Bay Packers,1957,35 7 | AT&T Stadium,80000,"Arlington, Texas",Matrix RealGrass artificial turf,Retractable,Dallas Cowboys,2009,36 8 | Arrowhead Stadium,76416,"Kansas City, Missouri",Latitude 36 Bermuda Grass,Open,Kansas City Chiefs,1972,37 9 | Sports Authority Field at Mile High,76125,"Denver, Colorado",Kentucky Bluegrass,Open,Denver Broncos,2001,38 10 | Bank of America Stadium,75419,"Charlotte, North Carolina",Voyager Bermuda Grass,Open,Carolina Panthers,1996,39 11 | Mercedes-Benz Superdome,73000,"New Orleans, Louisiana",UBU Turf (artificial),Fixed,New Orleans Saints,1975,40 12 | NRG Stadium,72220,"Houston, Texas",AstroTurf GameDay Grass 3D,Retractable,Houston Texans,2002,41 13 | New Era Field,71870,"Orchard Park, New York",A-Turf Titan 50 (artificial),Open,Buffalo Bills,1973,42 14 | Georgia Dome,71250,"Atlanta, Georgia",FieldTurf Classic HD,Fixed,Atlanta Falcons,1992,43 15 | M&T Bank Stadium,71008,"Baltimore, Maryland",Latitude 36 Bermuda Grass,Open,Baltimore Ravens,1998,44 16 | Qualcomm Stadium,70561,"San Diego, California",Bandera Bermuda Grass,Open,San Diego Chargers,1967,45 17 | Lincoln Financial Field,69596,"Philadelphia, Pennsylvania",Desso GrassMaster,Open,Philadelphia Eagles,2003,46 18 | Nissan Stadium,69143,"Nashville, Tennessee",TifSport Bermuda Grass,Open,Tennessee Titans,1999,47 19 | Levi's Stadium,68500,"Santa Clara, California",Tifway II Bermuda Grass / Perennial Ryegrass mixture,Open,San Francisco 49ers,2014,48 20 | Heinz Field,68400,"Pittsburgh, Pennsylvania",Kentucky Bluegrass,Open,Pittsburgh Steelers,2001,49 21 | CenturyLink Field,68000,"Seattle, Washington",FieldTurf Revolution,Open,Seattle Seahawks,2002,50 22 | FirstEnergy Stadium,67431,"Cleveland, Ohio",Kentucky Bluegrass,Open,Cleveland Browns,1999,51 23 | EverBank Field,67246,"Jacksonville, Florida",Tifway 419 Bermuda Grass,Open,Jacksonville Jaguars,1995,52 24 | Lucas Oil Stadium,67000,"Indianapolis, Indiana",FieldTurf Classic HD,Retractable,Indianapolis Colts,2008,53 25 | Gillette Stadium,66829,"Foxborough, Massachusetts",FieldTurf Revolution,Open,New England Patriots,2002,54 26 | U.S. Bank Stadium,66200,"Minneapolis, Minnesota",UBU Speed Series S5-M Synthetic Turf,Fixed,Minnesota Vikings,2016,55 27 | Raymond James Stadium,65890,"Tampa, Florida",Tifway 419 Bermuda Grass,Open,Tampa Bay Buccaneers,1998,56 28 | Paul Brown Stadium,65515,"Cincinnati, Ohio",UBU Speed Series S5-M Synthetic Turf,Open,Cincinnati Bengals,2000,57 29 | Hard Rock Stadium,65326,"Miami Gardens, Florida",Platinum TE Paspalum,Open,Miami Dolphins,1987,58 30 | Ford Field,65000,"Detroit, Michigan",FieldTurf Classic HD,Fixed,Detroit Lions,2002,59 31 | University of Phoenix Stadium,63400,"Glendale, Arizona",Tifway 419 Bermuda Grass,Retractable,Arizona Cardinals,2006,60 32 | Soldier Field,61500,"Chicago, Illinois",Kentucky Bluegrass,Open,Chicago Bears,1924,61 33 | Oakland Alameda Coliseum,56063,"Oakland, California",Tifway II Bermuda Grass,Open,Oakland Raiders,1966,62 34 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/data/csv/seat_type.csv: -------------------------------------------------------------------------------- 1 | 2 | luxury,"Excellent seats - box seats, behind the plate, etc. etc.",1 3 | obstructed,"Pretty crappy, partially obstructed seats",5 4 | premium,"Really good seats - first level, mid field, etc. etc.",2 5 | standard,Standard seats - not super awesome but pretty good,3 6 | standing,"Really? That's not a seat at all now, is it?",10 7 | sub-standard,"End zone, nose bleed, etc.",4 8 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/data/csv/sport_division.csv: -------------------------------------------------------------------------------- 1 | 2 | baseball,MLB,AL Central,American League Central,American League Central 3 | baseball,MLB,AL East,American League East,American League East 4 | baseball,MLB,AL West,American League West,American League West 5 | baseball,MLB,NL Central,National League Central,National League Central 6 | baseball,MLB,NL East,National League East,National League East 7 | baseball,MLB,NL West,National League West,National League West 8 | football,NFL,AFC East,American Football Conference East,American Football Conference East 9 | football,NFL,AFC North,American Football Conference North,American Football Conference North 10 | football,NFL,AFC South,American Football Conference South,American Football Conference South 11 | football,NFL,AFC West,American Football Conference West,American Football Conference West 12 | football,NFL,NFC East,National Football Conference East,National Football Conference East 13 | football,NFL,NFC North,National Football Conference North,National Football Conference North 14 | football,NFL,NFC South,National Football Conference South,National Football Conference South 15 | football,NFL,NFC West,National Football Conference West,National Football Conference West 16 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/data/csv/sport_league.csv: -------------------------------------------------------------------------------- 1 | 2 | baseball,MLB,Major League Baseball,Professional baseball league in North America. 3 | football,NFL,National Footbal League,Professional football league in North America. 4 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/data/csv/sport_location.csv: -------------------------------------------------------------------------------- 1 | 2 | 1,Angel Stadium,Anaheim California,45483,2,45 3 | 2,AT&T Park,San Francisco California,41915,2,41 4 | 3,Busch Stadium,St Louis Missouri,43975,2,43 5 | 4,Chase Field,Phoenix Arizona,48519,2,48 6 | 5,Citi Field,Queens New York,41922,2,41 7 | 6,Citizens Bank Park,Philadelphia Pennsylvania,43651,2,43 8 | 7,Comercia Park,Detroit Michigan,41297,2,41 9 | 8,Coors Field,Denver Colorado,50398,3,50 10 | 9,Dodger Stadium,Los Angeles California,56000,3,56 11 | 10,Fenway Park,Boston Massachusetts,37949,2,37 12 | 11,GLobe Life Park,Arlington Texas,48114,2,48 13 | 12,Great American Ball Park,Cincinnati Ohio,42319,2,42 14 | 13,Kauffman Stadium,Kansas City Missouri,37903,2,37 15 | 14,Martins Park,Miami Florida,36742,2,36 16 | 15,Miller Park,Milwaukee Wisconsin,41900,2,41 17 | 16,Minute Maid Park,Houston Texas,41676,2,41 18 | 17,Nationals Park,Washington D.C.,41313,2,41 19 | 18,Oakland Coliseum,Oakland California,35067,2,35 20 | 19,Camden Yards,Baltimore Maryland,45971,2,45 21 | 20,Petco Park,San Diego California,40162,2,40 22 | 21,PNC Park,Pittsburgh Pennsylvania,38362,2,38 23 | 22,Progressive Field,Cleveland Ohio,35225,2,35 24 | 23,Rogers Centre,Toronto Ontario,49282,2,49 25 | 24,Safeco Field,Seattle Washington,47963,2,47 26 | 25,Target Field,Minneapolis Minnesota,38871,2,38 27 | 26,Tropicana Field,St. Petersburg Florida,31042,2,31 28 | 27,Turner Field,Atlanta Georgia,49586,2,49 29 | 28,US Cellular Field,Chicago Illinois,40615,2,40 30 | 29,Wrigley Field,Chicago Illinois,41268,2,41 31 | 30,Yankee Stadium,Bronx New York,49642,2,49 32 | 31,Los Angeles Memorial Coliseum,"Los Angeles, California",93607,3,93 33 | 32,MetLife Stadium,"East Rutherford, New Jersey",82500,3,82 34 | 33,MetLife Stadium,"East Rutherford, New Jersey",82500,3,82 35 | 34,FedExField,"Landover, Maryland",82000,3,82 36 | 35,Lambeau Field,"Green Bay, Wisconsin",81435,3,81 37 | 36,AT&T Stadium,"Arlington, Texas",80000,3,80 38 | 37,Arrowhead Stadium,"Kansas City, Missouri",76416,3,76 39 | 38,Sports Authority Field at Mile High,"Denver, Colorado",76125,3,76 40 | 39,Bank of America Stadium,"Charlotte, North Carolina",75419,3,75 41 | 40,Mercedes-Benz Superdome,"New Orleans, Louisiana",73000,2,73 42 | 41,NRG Stadium,"Houston, Texas",72220,2,72 43 | 42,New Era Field,"Orchard Park, New York",71870,2,71 44 | 43,Georgia Dome,"Atlanta, Georgia",71250,2,71 45 | 44,M&T Bank Stadium,"Baltimore, Maryland",71008,2,71 46 | 45,Qualcomm Stadium,"San Diego, California",70561,2,70 47 | 46,Lincoln Financial Field,"Philadelphia, Pennsylvania",69596,2,69 48 | 47,Nissan Stadium,"Nashville, Tennessee",69143,2,69 49 | 48,Levi's Stadium,"Santa Clara, California",68500,2,68 50 | 49,Heinz Field,"Pittsburgh, Pennsylvania",68400,2,68 51 | 50,CenturyLink Field,"Seattle, Washington",68000,2,68 52 | 51,FirstEnergy Stadium,"Cleveland, Ohio",67431,2,67 53 | 52,EverBank Field,"Jacksonville, Florida",67246,2,67 54 | 53,Lucas Oil Stadium,"Indianapolis, Indiana",67000,2,67 55 | 54,Gillette Stadium,"Foxborough, Massachusetts",66829,2,66 56 | 55,U.S. Bank Stadium,"Minneapolis, Minnesota",66200,2,66 57 | 56,Raymond James Stadium,"Tampa, Florida",65890,2,65 58 | 57,Paul Brown Stadium,"Cincinnati, Ohio",65515,2,65 59 | 58,Hard Rock Stadium,"Miami Gardens, Florida",65326,2,65 60 | 59,Ford Field,"Detroit, Michigan",65000,2,65 61 | 60,University of Phoenix Stadium,"Glendale, Arizona",63400,2,63 62 | 61,Soldier Field,"Chicago, Illinois",61500,2,61 63 | 62,Oakland Alameda Coliseum,"Oakland, California",56063,2,56 64 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/data/csv/sport_type.csv: -------------------------------------------------------------------------------- 1 | 2 | baseball,"A sport with 9 players, bats, and balls - what could possibly go wrong?" 3 | football,Teams of 11 players attempt to move an oblong ball 100 yards while beating the snot out of each other. 4 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/install-postgresql.sql: -------------------------------------------------------------------------------- 1 | -- Sample PostgreSQL database for Database Migration Service testing 2 | 3 | -- Creating schema and tables 4 | select null as "Setting appropriate search path"; 5 | set search_path = dms_sample; 6 | select null as "Creating the tables"; 7 | \i ./schema/create-table.sql 8 | select null as "Creating required indexes"; 9 | \i ./schema/create-index.sql 10 | select null as "Creating dms_user user:"; 11 | \i ./user/create-user.sql 12 | 13 | -- Copying base data 14 | select null as "Copying base data into tables"; 15 | \copy mlb_data from './data/csv/mlb_data.csv' DELIMITER ',' CSV HEADER; 16 | \copy name_data from './data/csv/name_data.csv' DELIMITER ',' CSV HEADER; 17 | \copy nfl_data from './data/csv/nfl_data.csv' DELIMITER ',' CSV HEADER; 18 | \copy nfl_stadium_data from './data/csv/nfl_stadium_data.csv' DELIMITER ',' CSV HEADER; 19 | \copy seat_type from './data/csv/seat_type.csv' DELIMITER ',' CSV HEADER; 20 | \copy sport_location from './data/csv/sport_location.csv' DELIMITER ',' CSV HEADER; 21 | \copy sport_division from './data/csv/sport_division.csv' DELIMITER ',' CSV HEADER; 22 | \copy sport_league from './data/csv/sport_league.csv' DELIMITER ',' CSV HEADER; 23 | INSERT /*+ APPEND */ INTO person(id, full_name, last_name, first_name) 24 | SELECT row_number() OVER() as rownum 25 | ,first.name || ' ' || last.name 26 | ,last.name 27 | ,first.name 28 | FROM name_data first, name_data last 29 | WHERE first.name_type != 'LAST' 30 | AND last.name_type = 'LAST'; 31 | 32 | -- loading NFL and MLB teams 33 | select null as "Loading NFL and MLB teams"; 34 | \i ./schema/functions/loadmlbteams.sql 35 | \i ./schema/functions/loadnflteams.sql 36 | select loadmlbteams(); 37 | select loadnflteams(); 38 | \i ./schema/functions/set_mlb_team_home_field.sql 39 | \i ./schema/functions/setnflhomefield.sql 40 | select setnflteamhomefield(); 41 | 42 | -- generating seats 43 | select null as "Generating game seats"; 44 | \i ./schema/functions/esubstr.sql 45 | \i ./schema/functions/generateseats.sql 46 | select generateseats(); 47 | select generateseats(); 48 | select generateseats(); 49 | select generateseats(); 50 | 51 | -- loading mlb and nfl players 52 | select null as "Creating players"; 53 | \i ./schema/functions/loadmlbplayers.sql 54 | \i ./schema/functions/loadnflplayers.sql 55 | select loadmlbplayers(); 56 | select loadnflplayers(); 57 | 58 | -- generating mlb and nfl seasons 59 | select null as "Creating the MLB and NFL seasons"; 60 | \i ./schema/functions/generatemlbseason.sql 61 | select generatemlbseason(); 62 | \i ./schema/functions/generatenflseason.sql 63 | select generatenflseason(); 64 | 65 | -- generating tickets for game events 66 | select null as "Generating game tickets for MLB and NFL"; 67 | \i ./schema/functions/generatesporttickets.sql 68 | -- generating football and baseball tickets 69 | select generatesporttickets('football'); 70 | select generatesporttickets('baseball'); 71 | 72 | -- Sell tickets and generating ticket activities 73 | select null as "Creating functions to sell and transfer tickets"; 74 | \i ./schema/functions/generateticketactivity.sql 75 | -- generating some initial ticket purchases 76 | select generateticketactivity(5000); 77 | 78 | -- Generating transfer activity procedures and views 79 | \i ./schema/functions/transferticket.sql 80 | \i ./schema/functions/generatetransferactivity.sql 81 | select generatetransferactivity(1000); 82 | 83 | -- adding Foreign Keys 84 | \i ./schema/foreign-keys.sql 85 | 86 | -- creating required views 87 | \i ./schema/create-view.sql 88 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/create-index.sql: -------------------------------------------------------------------------------- 1 | CREATE INDEX seat_sport_location_idx 2 | ON dms_sample.seat 3 | USING BTREE (sport_location_id ASC); 4 | 5 | 6 | 7 | CREATE INDEX se_start_date_fcn 8 | ON dms_sample.sporting_event 9 | USING BTREE (DATE(start_date_time) ASC); 10 | 11 | 12 | 13 | CREATE INDEX set_ev_id_tkholder_id_idx 14 | ON dms_sample.sporting_event_ticket 15 | USING BTREE (sporting_event_id ASC, ticketholder_id ASC); 16 | 17 | 18 | 19 | CREATE INDEX set_seat_idx 20 | ON dms_sample.sporting_event_ticket 21 | USING BTREE (sport_location_id ASC, seat_level ASC, seat_section ASC, seat_row ASC, seat ASC); 22 | 23 | 24 | 25 | CREATE INDEX set_sporting_event_idx 26 | ON dms_sample.sporting_event_ticket 27 | USING BTREE (sporting_event_id ASC); 28 | 29 | 30 | 31 | CREATE INDEX set_ticketholder_idx 32 | ON dms_sample.sporting_event_ticket 33 | USING BTREE (ticketholder_id ASC); 34 | 35 | 36 | 37 | CREATE UNIQUE INDEX sport_team_u 38 | ON dms_sample.sport_team 39 | USING BTREE (sport_type_name ASC, sport_league_short_name ASC, name ASC); 40 | 41 | 42 | 43 | CREATE INDEX tph_purch_by_id 44 | ON dms_sample.ticket_purchase_hist 45 | USING BTREE (purchased_by_id ASC); 46 | 47 | 48 | 49 | CREATE INDEX tph_trans_from_id 50 | ON dms_sample.ticket_purchase_hist 51 | USING BTREE (transferred_from_id ASC); 52 | 53 | 54 | 55 | -- ------------ Write CREATE-CONSTRAINT-stage scripts ----------- 56 | 57 | ALTER TABLE dms_sample.name_data 58 | ADD CONSTRAINT name_data_pk PRIMARY KEY (name_type, name); 59 | 60 | 61 | 62 | ALTER TABLE dms_sample.person 63 | ADD CONSTRAINT person_pk PRIMARY KEY (id); 64 | 65 | 66 | 67 | ALTER TABLE dms_sample.player 68 | ADD CONSTRAINT player_pk PRIMARY KEY (id); 69 | 70 | 71 | 72 | --ALTER TABLE dms_sample.seat 73 | --ADD CONSTRAINT seat_pk PRIMARY KEY (sport_location_id, seat_level, seat_section, seat_row, seat); 74 | 75 | 76 | 77 | ALTER TABLE dms_sample.seat_type 78 | ADD CONSTRAINT st_seat_type_pk PRIMARY KEY (name); 79 | 80 | 81 | 82 | ALTER TABLE dms_sample.sporting_event 83 | ADD CONSTRAINT chk_sold_out CHECK (sold_out IN (0, 1)); 84 | 85 | 86 | 87 | ALTER TABLE dms_sample.sporting_event 88 | ADD CONSTRAINT sporting_event_pk PRIMARY KEY (id); 89 | 90 | 91 | 92 | ALTER TABLE dms_sample.sporting_event_ticket 93 | ADD CONSTRAINT sporting_event_ticket_pk PRIMARY KEY (id); 94 | 95 | 96 | 97 | ALTER TABLE dms_sample.sport_division 98 | ADD CONSTRAINT sport_division_pk PRIMARY KEY (sport_type_name, sport_league_short_name, short_name); 99 | 100 | 101 | 102 | ALTER TABLE dms_sample.sport_league 103 | ADD CONSTRAINT sport_league_pk PRIMARY KEY (short_name); 104 | 105 | 106 | 107 | ALTER TABLE dms_sample.sport_location 108 | ADD CONSTRAINT sport_location_pk PRIMARY KEY (id); 109 | 110 | 111 | 112 | ALTER TABLE dms_sample.sport_team 113 | ADD CONSTRAINT sport_team_pk PRIMARY KEY (id); 114 | 115 | 116 | 117 | ALTER TABLE dms_sample.sport_type 118 | ADD CONSTRAINT sport_type_pk PRIMARY KEY (name); 119 | 120 | 121 | 122 | ALTER TABLE dms_sample.ticket_purchase_hist 123 | ADD CONSTRAINT ticket_purchase_hist_pk PRIMARY KEY (sporting_event_ticket_id, purchased_by_id, transaction_date_time); 124 | 125 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/create-view.sql: -------------------------------------------------------------------------------- 1 | create or replace view sporting_event_info as 2 | select e.id as event_id 3 | , e.sport_type_name as sport 4 | , e.start_date_time as event_date_time 5 | , h.name as home_team 6 | , a.name as away_team 7 | , l.name as location 8 | , l.city as city 9 | from sporting_event e, sport_team h, sport_team a, sport_location l 10 | where e.home_team_id = h.id 11 | and e.away_team_id = a.id 12 | and e.location_id = l.id; 13 | 14 | 15 | create or replace view sporting_event_ticket_info as 16 | select t.id as ticket_id 17 | ,e.event_id 18 | ,e.sport 19 | ,e.event_date_time 20 | ,e.home_team 21 | ,e.away_team 22 | ,e.location 23 | ,e.city 24 | ,t.seat_level 25 | ,t.seat_section 26 | ,t.seat_row 27 | ,t.seat 28 | ,t.ticket_price 29 | ,p.full_name as ticketholder 30 | from sporting_event_info e 31 | , sporting_event_ticket t 32 | , person p 33 | where t.sporting_event_id = e.event_id 34 | and t.ticketholder_id = p.id; 35 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/esubstr.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION esubstr( 2 | str character varying, 3 | pos integer, 4 | cnt integer) 5 | RETURNS character varying AS 6 | $BODY$ 7 | declare 8 | len int; 9 | begin 10 | if str is null or pos is null or cnt is null then 11 | return null; 12 | elsif cnt <= 0 or pos = 0 then 13 | return ''; 14 | elsif pos > 0 then 15 | return substr(str, pos, cnt); 16 | elsif pos < 0 then 17 | len := length(str); 18 | return substr(str, len+pos+1, cnt); 19 | end if; 20 | end; 21 | $BODY$ 22 | LANGUAGE plpgsql; 23 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/generatesporttickets.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.generatesporttickets(IN par_p_sport VARCHAR, OUT p_refcur refcursor) 2 | AS 3 | $BODY$ 4 | DECLARE 5 | var_v_event_id BIGINT; 6 | var_all_done varchar(10) DEFAULT FALSE; 7 | event_cur2 CURSOR FOR 8 | SELECT 9 | id 10 | FROM dms_sample.sporting_event 11 | WHERE LOWER(sport_type_name) = LOWER(par_p_sport); 12 | BEGIN 13 | OPEN p_refcur FOR 14 | SELECT 15 | par_p_sport; 16 | OPEN event_cur2; 17 | 18 | <> 19 | LOOP 20 | FETCH event_cur2 INTO var_v_event_id; 21 | 22 | IF NOT FOUND THEN 23 | CLOSE event_cur2; 24 | EXIT event_loop; 25 | END IF; 26 | 27 | WITH event_list AS ( 28 | SELECT 29 | id AS var_v_e_id, 30 | location_id AS var_v_loc_id 31 | FROM dms_sample.sporting_event 32 | WHERE id = var_v_event_id 33 | ), 34 | constants AS ( 35 | SELECT 36 | ROUND(((RANDOM() * (50::NUMERIC - 30::NUMERIC)) + 30::NUMERIC)::NUMERIC, (2)::INT)::NUMERIC(6, 2) 37 | AS var_v_standard_price 38 | ) 39 | INSERT INTO dms_sample.sporting_event_ticket ( 40 | sporting_event_id, 41 | sport_location_id, 42 | seat_level, 43 | seat_section, 44 | seat_row, 45 | seat, 46 | ticket_price 47 | ) 48 | SELECT 49 | sporting_event.id, 50 | seat.sport_location_id, 51 | seat.seat_level, 52 | seat.seat_section, 53 | seat.seat_row, 54 | seat.seat, 55 | (CASE 56 | WHEN LOWER(seat.seat_type) = LOWER('luxury'::VARCHAR(15)) 57 | THEN 3::NUMERIC * var_v_standard_price::NUMERIC 58 | WHEN LOWER(seat.seat_type) = LOWER('premium'::VARCHAR(15)) 59 | THEN 2::NUMERIC * var_v_standard_price::NUMERIC 60 | WHEN LOWER(seat.seat_type) = LOWER('standard'::VARCHAR(15)) 61 | THEN var_v_standard_price 62 | WHEN LOWER(seat.seat_type) = LOWER('sub-standard'::VARCHAR(15)) 63 | THEN 0.8::NUMERIC * var_v_standard_price::NUMERIC 64 | WHEN LOWER(seat.seat_type) = LOWER('obstructed'::VARCHAR(15)) 65 | THEN 0.5::NUMERIC * var_v_standard_price::NUMERIC 66 | WHEN LOWER(seat.seat_type) = LOWER('standing'::VARCHAR(15)) 67 | THEN 0.5::NUMERIC * var_v_standard_price::NUMERIC 68 | END) AS ticket_price 69 | FROM constants, event_list, dms_sample.sporting_event, dms_sample.seat 70 | WHERE sporting_event.location_id = seat.sport_location_id 71 | AND sporting_event.id = var_v_e_id; 72 | 73 | END LOOP; 74 | END; 75 | $BODY$ 76 | LANGUAGE plpgsql; 77 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/generateticketactivity.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.generateticketactivity(IN par_max_transactions INTEGER DEFAULT 10) 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | min_person_id INTEGER; 7 | max_person_id INTEGER; 8 | rand_person_id INTEGER; 9 | min_event_id INTEGER; 10 | max_event_id INTEGER; 11 | rand_event_id INTEGER; 12 | tick_quantity INTEGER; 13 | var_current_txn INTEGER DEFAULT 0; 14 | 15 | 16 | BEGIN 17 | min_person_id := (select MIN(id) FROM dms_sample.person); 18 | max_person_id := (select MAX(id) FROM dms_sample.person); 19 | min_event_id := (select MIN(sporting_event_id) FROM dms_sample.sporting_event_ticket); 20 | max_event_id := (select MAX(sporting_event_id) FROM dms_sample.sporting_event_ticket); 21 | 22 | WHILE var_current_txn < par_max_transactions LOOP 23 | rand_person_id := floor(random()*(max_person_id-min_person_id+min_person_id))+min_person_id; 24 | rand_event_id := floor(random()*(max_event_id-min_event_id+min_event_id))+min_event_id; 25 | tick_quantity := floor(random()*(10000-2000+2000))+2000; 26 | 27 | WITH ticket_list AS ( 28 | SELECT 29 | id AS var_v_ticket_id, 30 | seat_level AS var_v_seat_level, 31 | seat_section AS var_v_seat_section, 32 | seat_row AS var_v_seat_row 33 | FROM dms_sample.sporting_event_ticket 34 | WHERE sporting_event_id = rand_event_id 35 | ORDER BY seat_level NULLS FIRST, 36 | LOWER(seat_section) NULLS FIRST, 37 | LOWER(seat_row) NULLS FIRST 38 | LIMIT tick_quantity 39 | ), 40 | ticket_holder_list AS ( 41 | UPDATE dms_sample.sporting_event_ticket 42 | SET ticketholder_id = rand_person_id 43 | FROM ticket_list 44 | WHERE id = var_v_ticket_id 45 | RETURNING id, 46 | ticketholder_id, 47 | ticket_price 48 | ) 49 | INSERT INTO dms_sample.ticket_purchase_hist ( 50 | sporting_event_ticket_id, 51 | purchased_by_id, 52 | transaction_date_time, 53 | purchase_price) 54 | SELECT 55 | id, 56 | ticketholder_id, 57 | clock_timestamp()::TIMESTAMP, 58 | ticket_price 59 | FROM ticket_holder_list; 60 | 61 | var_current_txn := (var_current_txn + 1)::INT; 62 | END LOOP; 63 | END; 64 | $BODY$ 65 | LANGUAGE plpgsql; 66 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/generatetickets.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.generatetickets(IN par_p_event_id BIGINT) 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_v_e_id BIGINT; 7 | var_v_loc_id INTEGER; 8 | var_v_standard_price NUMERIC(6, 2); 9 | var_all_done VARCHAR(10) DEFAULT FALSE; 10 | event_cur CURSOR FOR 11 | SELECT 12 | id, location_id 13 | FROM dms_sample.sporting_event 14 | WHERE id = par_p_event_id; 15 | BEGIN 16 | var_v_standard_price := ROUND(((RANDOM() * (50::NUMERIC - 30::NUMERIC)) + 30::NUMERIC)::NUMERIC, (2)::INT)::NUMERIC(6, 2); 17 | OPEN event_cur; 18 | 19 | <> 20 | LOOP 21 | FETCH event_cur INTO var_v_e_id, var_v_loc_id; 22 | 23 | IF NOT FOUND THEN 24 | CLOSE event_cur; 25 | EXIT ticket_loop; 26 | END IF; 27 | INSERT INTO dms_sample.sporting_event_ticket (sporting_event_id, sport_location_id, seat_level, seat_section, seat_row, seat, ticket_price) 28 | SELECT 29 | sporting_event.id, seat.sport_location_id, seat.seat_level, seat.seat_section, seat.seat_row, seat.seat, (CASE 30 | WHEN LOWER(seat.seat_type) = LOWER('luxury'::VARCHAR(15)) THEN 3::NUMERIC * var_v_standard_price::NUMERIC 31 | WHEN LOWER(seat.seat_type) = LOWER('premium'::VARCHAR(15)) THEN 2::NUMERIC * var_v_standard_price::NUMERIC 32 | WHEN LOWER(seat.seat_type) = LOWER('standard'::VARCHAR(15)) THEN var_v_standard_price 33 | WHEN LOWER(seat.seat_type) = LOWER('sub-standard'::VARCHAR(15)) THEN 0.8::NUMERIC * var_v_standard_price::NUMERIC 34 | WHEN LOWER(seat.seat_type) = LOWER('obstructed'::VARCHAR(15)) THEN 0.5::NUMERIC * var_v_standard_price::NUMERIC 35 | WHEN LOWER(seat.seat_type) = LOWER('standing'::VARCHAR(15)) THEN 0.5::NUMERIC * var_v_standard_price::NUMERIC 36 | END) AS ticket_price 37 | FROM dms_sample.sporting_event, dms_sample.seat 38 | WHERE sporting_event.location_id = seat.sport_location_id AND sporting_event.id = var_v_e_id; 39 | END LOOP; 40 | END; 41 | $BODY$ 42 | LANGUAGE plpgsql; 43 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/generatetransferactivity.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.generatetransferactivity(IN par_max_transactions NUMERIC) 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_txn_count NUMERIC(10, 0) DEFAULT 0; 7 | var_min_tik_id NUMERIC(20, 0); 8 | var_max_tik_id NUMERIC(20, 0); 9 | var_tik_id NUMERIC(20, 0); 10 | var_max_p_id NUMERIC(10, 0); 11 | var_min_p_id NUMERIC(10, 0); 12 | var_person_id NUMERIC(10, 0); 13 | var_rand_p_max NUMERIC(10, 0); 14 | var_rand_max NUMERIC(20, 0); 15 | var_xfer_all NUMERIC(1, 0) DEFAULT 1; 16 | var_price NUMERIC(10, 4); 17 | var_price_multiplier NUMERIC(18, 0) DEFAULT 1; 18 | BEGIN 19 | SELECT 20 | MIN(sporting_event_ticket_id), MAX(sporting_event_ticket_id) 21 | INTO var_min_tik_id, var_max_tik_id 22 | FROM dms_sample.ticket_purchase_hist; 23 | SELECT 24 | MIN(id), MAX(id) 25 | INTO var_min_p_id, var_max_p_id 26 | FROM dms_sample.person; 27 | 28 | WHILE var_txn_count < par_max_transactions LOOP 29 | /* find a random upper bound for ticket and person ids */ 30 | var_rand_max := floor(random()*(var_max_tik_id-var_min_tik_id+var_min_tik_id))+var_min_tik_id; 31 | var_rand_p_max := floor(random()*(var_max_p_id-var_min_p_id+var_min_p_id))+var_min_p_id; 32 | SELECT 33 | MAX(sporting_event_ticket_id) 34 | INTO var_tik_id 35 | FROM dms_sample.ticket_purchase_hist 36 | WHERE sporting_event_ticket_id <= var_rand_max; 37 | SELECT 38 | MAX(id) 39 | INTO var_person_id 40 | FROM dms_sample.person 41 | WHERE id <= var_rand_p_max 42 | /* 80% of the time transfer all tickets, 20% of the time don't */; 43 | 44 | IF ((floor(random()*(5-1+1))+1) = 5) THEN 45 | var_xfer_all := 0; 46 | END IF 47 | /* 30% of the time change the price by up to 20% in either direction */; 48 | 49 | IF ((floor(random()*(3-1+1))+1) = 1) THEN 50 | var_price_multiplier := CAST ((floor(random()*(12-8+8))+8) AS NUMERIC(18, 0)) / 10; 51 | END IF; 52 | SELECT 53 | var_price_multiplier * ticket_price 54 | INTO var_price 55 | FROM dms_sample.sporting_event_ticket 56 | WHERE id = var_tik_id; 57 | PERFORM dms_sample.transferticket(var_tik_id, var_person_id, var_xfer_all, var_price) 58 | /* reset some variables */; 59 | var_txn_count := (var_txn_count + 1)::INT; 60 | var_xfer_all := 1; 61 | var_price_multiplier := 1; 62 | END LOOP; 63 | EXCEPTION 64 | WHEN OTHERS THEN 65 | RAISE NOTICE '%', ('Sorry, no tickets are available for transfer.'); 66 | END; 67 | $BODY$ 68 | LANGUAGE plpgsql; 69 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/loadmlbplayers.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.loadmlbplayers() 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_v_sport_team_id INTEGER; 7 | var_v_last_name VARCHAR(30); 8 | var_v_first_name VARCHAR(30); 9 | var_v_full_name VARCHAR(30); 10 | var_v_team_name VARCHAR(60); 11 | var_done VARCHAR(10) DEFAULT FALSE; 12 | mlb_players CURSOR FOR 13 | SELECT DISTINCT 14 | CASE LOWER(LTRIM(RTRIM(mlb_team_long::VARCHAR)::VARCHAR)) 15 | WHEN LOWER('Anaheim Angels') THEN 'Los Angeles Angels' 16 | ELSE LTRIM(RTRIM(mlb_team_long::VARCHAR)::VARCHAR) 17 | END AS mlb_team_long, LTRIM(RTRIM(mlb_name::VARCHAR)::VARCHAR) AS name, esubstr(LTRIM(RTRIM(mlb_name::VARCHAR)::VARCHAR)::VARCHAR, 1::INT, POSITION(' '::VARCHAR IN mlb_name::VARCHAR)::INT) AS t_name, esubstr(LTRIM(RTRIM(mlb_name::VARCHAR)::VARCHAR)::VARCHAR, POSITION(' '::VARCHAR IN mlb_name::VARCHAR)::INT, LENGTH(mlb_name::VARCHAR)::INT) AS f_name 18 | FROM dms_sample.mlb_data; 19 | BEGIN 20 | OPEN mlb_players; 21 | 22 | <> 23 | LOOP 24 | FETCH FROM mlb_players INTO var_v_team_name, var_v_last_name, var_v_first_name, var_v_full_name; 25 | 26 | IF NOT FOUND THEN 27 | EXIT read_loop; 28 | END IF; 29 | SELECT 30 | id::INTEGER 31 | INTO var_v_sport_team_id 32 | FROM dms_sample.sport_team 33 | WHERE LOWER(sport_type_name) = LOWER('baseball'::VARCHAR(15)) AND LOWER(sport_league_short_name) = LOWER('MLB'::VARCHAR(10)) AND LOWER(name) = LOWER(var_v_team_name::VARCHAR(30)); 34 | INSERT INTO dms_sample.player (sport_team_id, last_name, first_name, full_name) 35 | VALUES (var_v_sport_team_id, var_v_last_name, var_v_first_name, var_v_full_name); 36 | END LOOP; 37 | CLOSE mlb_players; 38 | END; 39 | $BODY$ 40 | LANGUAGE plpgsql; 41 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/loadmlbteams.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.loadmlbteams() 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | v_div DMS_SAMPLE.SPORT_DIVISION.short_name%TYPE; 7 | mlb_teams CURSOR FOR 8 | SELECT DISTINCT 9 | CASE TRIM(mlb_team) 10 | WHEN 'AAA' THEN 'LAA' 11 | ELSE mlb_team 12 | END AS a_name, 13 | CASE TRIM(mlb_team_long) 14 | WHEN 'Anaheim Angels' THEN 'Los Angeles Angels' 15 | ELSE mlb_team_long 16 | END AS l_name 17 | FROM dms_sample.mlb_data; 18 | BEGIN 19 | FOR trec IN mlb_teams LOOP 20 | CASE 21 | WHEN trec.a_name IN ('BAL', 'BOS', 'TOR', 'TB', 'NYY') THEN 22 | v_div := 'AL East'; 23 | WHEN trec.a_name IN ('CLE', 'DET', 'KC', 'CWS', 'MIN') THEN 24 | v_div := 'AL Central'; 25 | WHEN trec.a_name IN ('TEX', 'SEA', 'HOU', 'OAK', 'LAA') THEN 26 | v_div := 'AL West'; 27 | WHEN trec.a_name IN ('WSH', 'MIA', 'NYM', 'PHI', 'ATL') THEN 28 | v_div := 'NL East'; 29 | WHEN trec.a_name IN ('CHC', 'STL', 'PIT', 'MIL', 'CIN') THEN 30 | v_div := 'NL Central'; 31 | WHEN trec.a_name IN ('COL', 'SD', 'LAD', 'SF', 'ARI') THEN 32 | v_div := 'NL West'; 33 | END CASE; 34 | INSERT INTO dms_sample.sport_team (name, abbreviated_name, sport_type_name, sport_league_short_name, sport_division_short_name) 35 | VALUES (trec.l_name, trec.a_name, 'baseball', 'MLB', v_div); 36 | END LOOP; 37 | END; 38 | $BODY$ 39 | LANGUAGE plpgsql; 40 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/loadnflplayers.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.loadnflplayers() 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_v_team VARCHAR(10); 7 | var_v_name VARCHAR(60); 8 | var_v_l_name VARCHAR(30); 9 | var_v_f_name VARCHAR(30); 10 | var_v_sport_team_id INTEGER; 11 | var_done VARCHAR(10) DEFAULT FALSE; 12 | nfl_players CURSOR FOR 13 | SELECT 14 | team, name, esubstr(RTRIM(LTRIM(name::VARCHAR)::VARCHAR)::VARCHAR, 1::INT, POSITION(','::VARCHAR IN name::VARCHAR) - 1::NUMERIC::INT) AS l_name, RTRIM(LTRIM(esubstr(RTRIM(LTRIM(name::VARCHAR)::VARCHAR)::VARCHAR, POSITION(','::VARCHAR IN name::VARCHAR) + 1::NUMERIC::INT, LENGTH(name::VARCHAR)::INT)::VARCHAR)::VARCHAR) AS f_name 15 | FROM dms_sample.nfl_data; 16 | BEGIN 17 | OPEN nfl_players; 18 | 19 | <> 20 | LOOP 21 | FETCH FROM nfl_players INTO var_v_team, var_v_name, var_v_l_name, var_v_f_name; 22 | 23 | IF NOT FOUND THEN 24 | EXIT read_loop; 25 | END IF; 26 | SELECT 27 | id::INTEGER 28 | INTO var_v_sport_team_id 29 | FROM dms_sample.sport_team 30 | WHERE LOWER(sport_type_name) = LOWER('football'::VARCHAR(15)) AND LOWER(sport_league_short_name) = LOWER('NFL'::VARCHAR(10)) AND LOWER(abbreviated_name) = LOWER(var_v_team); 31 | INSERT INTO dms_sample.player (sport_team_id, last_name, first_name, full_name) 32 | VALUES (var_v_sport_team_id, var_v_l_name, var_v_f_name, var_v_name); 33 | END LOOP; 34 | CLOSE nfl_players; 35 | END; 36 | $BODY$ 37 | LANGUAGE plpgsql; 38 | 39 | CREATE OR REPLACE FUNCTION dms_sample.esubstr( 40 | str character varying, 41 | pos integer) 42 | RETURNS character varying AS 43 | $BODY$ 44 | declare 45 | len int; 46 | begin 47 | if str is null or pos is null then 48 | return null; 49 | elsif pos = 0 then 50 | return ''; 51 | elsif pos > 0 then 52 | return substr(str, pos); 53 | elsif pos < 0 then 54 | len := length(str); 55 | return substr(str, len+pos+1); 56 | end if; 57 | end; 58 | $BODY$ 59 | LANGUAGE plpgsql VOLATILE 60 | COST 100; 61 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/selltickets.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.selltickets(IN par_p_person_id INTEGER, IN par_p_event_id INTEGER, IN par_p_quantity INTEGER) 2 | RETURNS VOID 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_v_ticket_id BIGINT; 7 | var_v_seat_level VARCHAR(50); 8 | var_v_seat_section VARCHAR(15); 9 | var_v_seat_row VARCHAR(10); 10 | var_v_tickets_sold INTEGER DEFAULT 0; 11 | var_v_time_of_sale TIMESTAMP WITHOUT TIME ZONE; 12 | var_all_done VARCHAR(50) DEFAULT FALSE; 13 | t_cur CURSOR FOR 14 | SELECT 15 | id, seat_level, seat_section, seat_row 16 | FROM dms_sample.sporting_event_ticket 17 | WHERE sporting_event_id = par_p_event_id 18 | ORDER BY seat_level NULLS FIRST, LOWER(seat_section) NULLS FIRST, LOWER(seat_row) NULLS FIRST; 19 | BEGIN 20 | var_v_time_of_sale := (clock_timestamp()::TIMESTAMP)::TIMESTAMP WITHOUT TIME ZONE; 21 | OPEN t_cur; 22 | 23 | <> 24 | LOOP 25 | FETCH t_cur INTO var_v_ticket_id, var_v_seat_level, var_v_seat_section, var_v_seat_row; 26 | UPDATE dms_sample.sporting_event_ticket 27 | SET ticketholder_id = par_p_person_id 28 | WHERE id = var_v_ticket_id; 29 | INSERT INTO dms_sample.ticket_purchase_hist (sporting_event_ticket_id, purchased_by_id, transaction_date_time, purchase_price) 30 | SELECT 31 | id, ticketholder_id, var_v_time_of_sale, ticket_price 32 | FROM dms_sample.sporting_event_ticket 33 | WHERE id = var_v_ticket_id; 34 | var_v_tickets_sold := (var_v_tickets_sold::NUMERIC + 1::NUMERIC)::SMALLINT; 35 | 36 | IF var_v_tickets_sold = par_p_quantity THEN 37 | CLOSE t_cur; 38 | 39 | EXIT tik_loop; 40 | END IF; 41 | END LOOP; 42 | END; 43 | $BODY$ 44 | LANGUAGE plpgsql; 45 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/setnflhomefield.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.setnflteamhomefield() 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_v_sport_location_id INTEGER; 7 | var_v_team VARCHAR(40); 8 | var_v_loc VARCHAR(40); 9 | var_done VARCHAR(40) DEFAULT FALSE; 10 | nsd_cur CURSOR FOR 11 | SELECT 12 | sport_location_id, team, location 13 | FROM dms_sample.nfl_stadium_data; 14 | BEGIN 15 | OPEN nsd_cur; 16 | 17 | <> 18 | LOOP 19 | FETCH FROM nsd_cur INTO var_v_sport_location_id, var_v_team, var_v_loc; 20 | 21 | IF NOT FOUND THEN 22 | EXIT read_loop; 23 | END IF; 24 | UPDATE dms_sample.sport_team AS s 25 | SET home_field_id = var_v_sport_location_id::SMALLINT 26 | WHERE LOWER(s.name) = LOWER(var_v_team::VARCHAR(30)) AND LOWER(s.sport_league_short_name) = LOWER('NFL'::VARCHAR(10)) AND LOWER(s.sport_type_name) = LOWER('football'::VARCHAR(15)); 27 | END LOOP; 28 | CLOSE nsd_cur; 29 | END; 30 | $BODY$ 31 | LANGUAGE plpgsql; 32 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/schema/functions/transferticket.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION dms_sample.transferticket(IN par_ticket_id NUMERIC, IN par_new_ticketholder_id NUMERIC, IN par_transfer_all NUMERIC DEFAULT 0, IN par_price NUMERIC DEFAULT NULL) 2 | RETURNS void 3 | AS 4 | $BODY$ 5 | DECLARE 6 | var_last_txn_date TIMESTAMP WITHOUT TIME ZONE; 7 | var_old_ticketholder_id NUMERIC(10, 0); 8 | var_sporting_event_ticket_id NUMERIC(20, 0); 9 | var_purchase_price NUMERIC(10, 4); 10 | var_xfer_cur refcursor; 11 | BEGIN 12 | SELECT 13 | MAX(h.transaction_date_time), t.ticketholder_id 14 | INTO var_last_txn_date, var_old_ticketholder_id 15 | FROM dms_sample.ticket_purchase_hist AS h, dms_sample.sporting_event_ticket AS t 16 | WHERE t.id = par_ticket_id AND h.purchased_by_id = t.ticketholder_id AND ((h.sporting_event_ticket_id = par_ticket_id) OR (par_transfer_all = 1)) 17 | GROUP BY t.ticketholder_id; 18 | OPEN var_xfer_cur FOR 19 | SELECT 20 | sporting_event_ticket_id, purchase_price 21 | FROM dms_sample.ticket_purchase_hist 22 | WHERE purchased_by_id = var_old_ticketholder_id AND transaction_date_time = var_last_txn_date; 23 | FETCH var_xfer_cur INTO var_sporting_event_ticket_id, var_purchase_price; 24 | 25 | WHILE (CASE FOUND::INT 26 | WHEN 0 THEN - 1 27 | ELSE 0 28 | END) = 0 LOOP 29 | /* update the sporting event ticket with the new owner */ 30 | UPDATE dms_sample.sporting_event_ticket 31 | SET ticketholder_id = par_new_ticketholder_id 32 | WHERE id = var_sporting_event_ticket_id 33 | /* record the transaction */; 34 | INSERT INTO dms_sample.ticket_purchase_hist (sporting_event_ticket_id, purchased_by_id, transferred_from_id, transaction_date_time, purchase_price) 35 | VALUES (var_sporting_event_ticket_id, par_new_ticketholder_id, var_old_ticketholder_id, CURRENT_TIMESTAMP(3), COALESCE(par_price, var_purchase_price)); 36 | FETCH var_xfer_cur INTO var_sporting_event_ticket_id, var_purchase_price; 37 | END LOOP; 38 | CLOSE var_xfer_cur 39 | ; 40 | END; 41 | $BODY$ 42 | LANGUAGE plpgsql; 43 | -------------------------------------------------------------------------------- /PostgreSQL/sampledb/v1/user/create-user.sql: -------------------------------------------------------------------------------- 1 | DROP USER IF EXISTS dms_user; 2 | CREATE USER dms_user WITH PASSWORD 'dms_user'; 3 | GRANT ALL PRIVILEGES ON SCHEMA dms_sample TO dms_user; 4 | GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA dms_sample TO dms_user; 5 | GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA dms_sample TO dms_user; 6 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # aws-database-migration-samples 2 | A set of sample database and associated items to allow customers to among other things follow along with published database migration recipes. 3 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/export_shard_data.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ## unload the data to /tmp by default 18 | use dms_sample 19 | source ./shard/unload_person.sql 20 | source ./shard/unload_sporting_event_ticket.sql 21 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/generate_ticket_activity.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | ---------------------------------------------- 16 | -- create procedure to generate ticket activity 17 | ----------------------------------------------- 18 | DELIMITER $$ 19 | 20 | DROP PROCEDURE IF EXISTS generateTicketActivity $$ 21 | 22 | CREATE PROCEDURE generateTicketActivity(IN p_max_transactions INT, IN p_delay_in_seconds REAL(5,2)) 23 | BEGIN 24 | DECLARE v_min_person_id INT; 25 | DECLARE v_max_person_id INT; 26 | DECLARE v_min_row INT; 27 | DECLARE v_max_row INT; 28 | DECLARE v_target_row INT; 29 | DECLARE v_event_id BIGINT; 30 | DECLARE v_target_person_id INT; 31 | DECLARE v_person_id INT; 32 | DECLARE v_quantity INT; 33 | DECLARE v_current_txn INT DEFAULT 0; 34 | DECLARE v_reset_events INT DEFAULT 1; 35 | DECLARE v_max_transactions INT; 36 | DECLARE v_delay_message VARCHAR(100); 37 | DECLARE v_delay REAL(5,2); 38 | 39 | SET v_delay = COALESCE(p_delay_in_seconds,0.25); 40 | 41 | drop temporary table if exists v_open_events; 42 | create temporary table v_open_events(rownum INT NOT NULL AUTO_INCREMENT, id BIGINT, constraint v_pk primary key(rownum)) engine=memory; 43 | 44 | /* get the range of person ids. */ 45 | SELECT MIN(id), MAX(id) into v_min_person_id, v_max_person_id from person; 46 | 47 | SET v_max_transactions = COALESCE(p_max_transactions,1000); 48 | 49 | WHILE v_current_txn < v_max_transactions DO 50 | IF v_reset_events = 1 THEN 51 | DELETE FROM v_open_events; 52 | INSERT INTO v_open_events(id) SELECT distinct sporting_event_id FROM sporting_event_ticket; 53 | SELECT MIN(rownum), MAX(rownum) INTO v_min_row, v_max_row FROM v_open_events; 54 | SET v_reset_events = 0; 55 | END IF; 56 | 57 | SET v_target_row = ROUND((RAND() * (v_max_row - v_min_row)) + v_min_row); 58 | SELECT id INTO v_event_id FROM v_open_events WHERE rownum = v_target_row; 59 | 60 | SET v_target_person_id = ROUND((RAND()*(v_max_person_id - v_min_person_id)) + v_min_person_id); 61 | SELECT MIN(id) INTO v_person_id FROM person WHERE id > v_target_person_id -1; 62 | 63 | SET v_quantity = ROUND((RAND() * (6 - 1)) + 1); 64 | 65 | /* The following will sell tickets. If tickets aren't available, there should be exception processing to reload the events table. 66 | That processing hasn't been written yet (for the mysql examples.) 67 | */ 68 | 69 | call sellTickets(v_person_id, v_event_id, v_quantity); 70 | 71 | SET v_current_txn = v_current_txn +1; 72 | 73 | SET v_delay_message = (SELECT sleep(v_delay) ); 74 | 75 | END WHILE; 76 | drop temporary table if exists v_open_events; 77 | END; 78 | $$ 79 | 80 | DELIMITER ; 81 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/load_person.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | LOAD DATA INFILE '/tmp/person.csv' INTO TABLE person 17 | FIELDS TERMINATED BY ',' 18 | OPTIONALLY ENCLOSED BY '"' 19 | ESCAPED BY '\\\\' 20 | LINES TERMINATED BY '\\n' ; 21 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/load_sporting_event_ticket.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | LOAD DATA INFILE '/tmp/sporting_event_ticket.csv' INTO TABLE sporting_event_ticket 17 | FIELDS TERMINATED BY ',' 18 | OPTIONALLY ENCLOSED BY '"' 19 | ESCAPED BY '\\\\' 20 | LINES TERMINATED BY '\\n' ; 21 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/unload_person.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | SELECT * FROM person INTO OUTFILE '/tmp/person.csv' 17 | FIELDS TERMINATED BY ',' 18 | OPTIONALLY ENCLOSED BY '"' 19 | ESCAPED BY '\\\\' 20 | LINES TERMINATED BY '\\n' ; 21 | 22 | -------------------------------------------------------------------------------- /exercises/mysql-shard-consolidation/schema/unload_sporting_event_ticket.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | SELECT * FROM sporting_event_ticket INTO OUTFILE '/tmp/sporting_event_ticket.csv' 17 | FIELDS TERMINATED BY ',' 18 | OPTIONALLY ENCLOSED BY '"' 19 | ESCAPED BY '\\\\' 20 | LINES TERMINATED BY '\\n' ; 21 | 22 | -------------------------------------------------------------------------------- /images/mongo_sampledb.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/mongo_sampledb.png -------------------------------------------------------------------------------- /images/mongo_sampledb_doc.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/mongo_sampledb_doc.png -------------------------------------------------------------------------------- /images/sampledb.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/sampledb.jpg -------------------------------------------------------------------------------- /images/shardConsolidationAlternative.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/shardConsolidationAlternative.png -------------------------------------------------------------------------------- /images/shardConsolidationFinal.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/shardConsolidationFinal.png -------------------------------------------------------------------------------- /images/shardConsolidationStageOne.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/shardConsolidationStageOne.png -------------------------------------------------------------------------------- /images/shardedERD.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/shardedERD.jpg -------------------------------------------------------------------------------- /images/unconsolidatedShards.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/images/unconsolidatedShards.png -------------------------------------------------------------------------------- /mongodb/sampledb/v1/config/mongodb-org-3.4.repo: -------------------------------------------------------------------------------- 1 | [mongodb-org-3.4] 2 | name=MongoDB Repository 3 | baseurl=https://repo.mongodb.org/yum/amazon/2013.03/mongodb-org/3.4/x86_64/ 4 | gpgcheck=1 5 | enabled=1 6 | gpgkey=https://www.mongodb.org/static/pgp/server-3.4.asc 7 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/install_ruby.sh: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | sudo yum update ruby 18 | sudo yum install -y gcc 19 | sudo yum install -y rubygems 20 | sudo yum install -y ruby-devel 21 | sudo gem update --system 22 | sudo gem install mongo 23 | sudo gem install bson_ext 24 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/install_sampledb.sh: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | mkdir ./log 18 | ./schema/load_mlb_data.rb 19 | ./schema/load_nfl_data.rb 20 | ./schema/load_name_data.rb 21 | ./schema/load_nfl_stadium_data.rb 22 | ./schema/load_sport.rb 23 | ./schema/load_sport_location.rb 24 | ./schema/load_sports_teams.rb 25 | ./schema/generate_sporting_events.rb 26 | ./schema/generate_tickets.rb 27 | ./schema/load_person.rb 28 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_mlb_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_mlb_data.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | # Load data from the file 32 | fname = ARGV.first || './data/mlb_data.sql' 33 | 34 | puts "loading MLB data from: " + fname 35 | 36 | cols = [] 37 | vals = [] 38 | players = [] 39 | 40 | File.open(fname).each_with_index do |r,idx| 41 | 42 | # Get the attributes 43 | if idx == 0 44 | col_list = r.slice(0, r.rindex(') values (')) # remove insert statement 45 | col_list.slice!('Insert into mlb_data (') 46 | cols = col_list.split(',').map{ |c| c.downcase.to_sym } 47 | end 48 | 49 | # Get the values 50 | unless r.chomp.empty? 51 | r = r.slice(r.rindex('values (') +8, r.length).strip.chomp(');') 52 | 53 | vals = r.split(',') 54 | 55 | player = {} 56 | cols.each_with_index do |c,i| 57 | player[c] = vals[i].sub(/'/,'').chomp("'") # remove quotes 58 | end 59 | 60 | players << player # Add to hash 61 | end 62 | end 63 | 64 | # Load Mongo collection 65 | mlb_data = db[:mlb_data] 66 | result = mlb_data.drop 67 | result = mlb_data.insert_many(players) 68 | puts "inserted: " + result.inserted_count.to_s + " mlb player records" 69 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_name_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_name_data.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | # Load data from the file 32 | fname = ARGV.first || './data/name_data.sql' 33 | 34 | puts "loading name data from: " + fname 35 | 36 | name_hash = {} 37 | File.open(fname).each_with_index do |r,idx| 38 | 39 | unless r.chomp.empty? 40 | r = r.slice(r.rindex('values (') +8, r.length).strip.chomp(');') 41 | 42 | vals = r.split(',').map{ |v| v.sub(/'/,'').chomp("'") } 43 | vals = vals.map{ |v| v == vals[0] ? v.to_sym : v } 44 | 45 | if name_hash[vals[0]] 46 | name_hash[vals[0]] << vals[1] 47 | else 48 | name_hash[vals[0]] = [vals[1]] 49 | end 50 | 51 | end 52 | end 53 | 54 | # Load Mongo collection 55 | name_data = db[:name_data] 56 | result = name_data.drop 57 | result = name_data.insert_one(name_hash) 58 | puts "inserted: " + result.n.to_s + " name records" 59 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_nfl_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_nfl_data.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | # Load data from the file 32 | fname = ARGV.first || './data/nfl_data.sql' 33 | 34 | puts "loading NFL data from: " + fname 35 | 36 | cols = [] 37 | vals = [] 38 | players = [] 39 | 40 | File.open(fname).each_with_index do |r,idx| 41 | 42 | # Get the attributes 43 | if idx == 0 44 | col_list = r.slice(0, r.rindex(') values (')) # remove insert statement 45 | col_list.slice!('Insert into nfl_data (') 46 | cols = col_list.split(',').map{ |c| c.to_sym } 47 | end 48 | 49 | # Get the values 50 | unless r.chomp.empty? 51 | r = r.slice(r.rindex('values (') +8, r.length).strip.chomp(');') 52 | r = r.sub(/'/,'').gsub(/','/,'~').gsub(/,'/,'~').gsub(/',/,'~').gsub(/,null/,'~null').chomp("'") 53 | 54 | vals = r.split("~") 55 | 56 | player = {} 57 | cols.each_with_index do |c,i| 58 | player[c] = vals[i] 59 | end 60 | 61 | # reformat player name 62 | player[:name] = player[:name].split(',')[1] + " " + player[:name].split(',')[0] 63 | player[:name] = player[:name].strip 64 | players << player # Add to hash 65 | end 66 | end 67 | 68 | # Load Mongo collection 69 | nfl_data = db[:nfl_data] 70 | result = nfl_data.drop 71 | result = nfl_data.insert_many(players) 72 | puts "inserted: " + result.inserted_count.to_s + " nfl player records" 73 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_nfl_stadium_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_nfl_stadium_data.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | # Load data from the file 32 | fname = ARGV.first || './data/nfl_stadium_data.sql' 33 | 34 | puts "loading NFL stadium data from: " + fname 35 | 36 | cols = [] 37 | vals = [] 38 | stadiums = [] 39 | 40 | File.open(fname).each_with_index do |r,idx| 41 | 42 | # Get the attributes 43 | if idx == 0 44 | col_list = r.slice(0, r.rindex(') values (')) # remove insert statement 45 | col_list.slice!('Insert into nfl_stadium_data (') 46 | cols = col_list.split(',').map{ |c| c.to_sym } 47 | end 48 | 49 | # Get the values 50 | unless r.chomp.empty? 51 | r = r.slice(r.rindex('values (') +8, r.length).strip.chomp(');') 52 | r = r.sub(/'/,'').gsub(/\'\'/,'').gsub(/','/,'~').gsub(/,'/,'~').gsub(/',/,'~').gsub(/,null/,'~null').chomp("'") 53 | 54 | vals = r.split('~') 55 | 56 | stadium = {} 57 | cols.each_with_index do |c,i| 58 | stadium[c] = vals[i] 59 | end 60 | 61 | stadium[:seating_capacity] = stadium[:seating_capacity].to_i 62 | stadium[:sport_location_id] = stadium[:sport_location_id].to_i 63 | 64 | stadiums << stadium # Add to hash 65 | end 66 | end 67 | 68 | 69 | # Load Mongo collection 70 | nfl_stadium_data = db[:nfl_stadium_data] 71 | result = nfl_stadium_data.drop 72 | result = nfl_stadium_data.insert_many(stadiums) 73 | puts "inserted: " + result.inserted_count.to_s + " nfl stadium records" 74 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_person.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_person.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | person = db[:person] 32 | person.drop() 33 | 34 | name_data = db[:name_data] 35 | names = name_data.find.first 36 | male_firsts = names[:MALE_FIRST] 37 | female_firsts = names[:FEMALE_FIRST] 38 | lasts = names[:LAST] 39 | 40 | id = 0 41 | 42 | lasts.each_slice(10) do |l_slice| 43 | people = [] # initialize the array 44 | 45 | l_slice.each do |l| 46 | male_firsts.each do |m| 47 | id += 1 48 | people << {:id => id, :first_name => m, :last_name => l, :full_name => m + " " + l} 49 | end 50 | 51 | female_firsts.each do |f| 52 | id += 1 53 | people << {:id => id, :first_name => f, :last_name => l, :full_name => f + " " + l} 54 | end 55 | end 56 | 57 | # Insert the array after shuffleing the names around 58 | result = person.insert_many(people.shuffle) 59 | puts "inserted: " + result.inserted_count.to_s + " people" 60 | end 61 | 62 | 63 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/schema/load_sport.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | 4 | # 5 | # Copyright 2017 Amazon.com 6 | # 7 | # Licensed under the Apache License, Version 2.0 (the "License"); 8 | # you may not use this file except in compliance with the License. 9 | # You may obtain a copy of the License at 10 | # 11 | # http://www.apache.org/licenses/LICENSE-2.0 12 | # 13 | # Unless required by applicable law or agreed to in writing, software 14 | # distributed under the License is distributed on an "AS IS" BASIS, 15 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 16 | # See the License for the specific language governing permissions and 17 | # limitations under the License. 18 | 19 | 20 | 21 | require 'rubygems' # not necessary for Ruby 1.9 22 | require 'mongo' 23 | 24 | port = ARGV.first || '27017' 25 | 26 | # Connect to db. Located here to make it easy to change port etc... 27 | db = Mongo::Client.new([ '127.0.0.1:' + port ], :database => 'dms_sample') 28 | Mongo::Logger.logger = ::Logger.new('./log/load_sport.log') 29 | Mongo::Logger.logger.level = ::Logger::INFO 30 | 31 | bb = {:name => "baseball", :description => "A sport with 9 players, bats, and balls - what could possibly go wrong?", 32 | :league => "MLB", :league_name => "Major League Baseball"} 33 | 34 | fb = {:name => "football", :description => "Teams of 11 players attempt to move an oblong ball 100 yards while beating the snot out of each other.", 35 | :league => "NFL", :league_name => "National Football League"} 36 | 37 | bb[:divisions] = [ 38 | {:name => "AL East", :description => "American League East"}, 39 | {:name => "AL Central", :description => "American League Central"}, 40 | {:name => "AL West", :description => "American League West"}, 41 | {:name => "NL East", :description => "National League East"}, 42 | {:name => "NL Central", :description => "National League Central"}, 43 | {:name => "NL West", :description => "National League West"} 44 | ] 45 | 46 | fb[:divisions] = [ 47 | {:name => "AFC East", :description => "American Football Conference East"}, 48 | {:name => "AFC West", :description => "American Football Conference West"}, 49 | {:name => "AFC North", :description => "American Football Conference North"}, 50 | {:name => "AFC South", :description => "American Football Conference South"}, 51 | {:name => "NFC East", :description => "National Football Conference East"}, 52 | {:name => "NFC West", :description => "National Football Conference West"}, 53 | {:name => "NFC North", :description => "National Football Conference North"}, 54 | {:name => "NFC South", :description => "National Football Conference South"} 55 | ] 56 | 57 | sports = [] 58 | 59 | sports << fb 60 | sports << bb 61 | 62 | sport_tab = db[:sport] 63 | result = sport_tab.drop 64 | result = sport_tab.insert_many(sports) 65 | puts "inserted: " + result.inserted_count.to_s + " sport records" 66 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_mlb_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | mlb_data = db[:mlb_data] 27 | mlb_data.find.each do |player| 28 | player.each_key do |k| 29 | puts k + " => " + player[k] 30 | end 31 | end 32 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_mlb_teams.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport_team = db[:sport_team] 27 | 28 | sport_team.find({sport: 'baseball'}).each do |t| 29 | t.each_key do |k| 30 | puts k + " => " + t[k].to_s 31 | end 32 | end 33 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_name_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | name_data = db[:name_data] 27 | names = name_data.find.first 28 | 29 | names.keys.each do |k| 30 | puts k + ":" 31 | puts names[k] 32 | end 33 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_nfl_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | nfl_data = db[:nfl_data] 27 | nfl_data.find.each do |player| 28 | player.each_key do |k| 29 | puts k + " => " + player[k] 30 | end 31 | end 32 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_nfl_stadium_data.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | nfl_stadium_data = db[:nfl_stadium_data] 27 | nfl_stadium_data.find.each do |stadium| 28 | stadium.each_key do |k| 29 | puts k + " => " + stadium[k].to_s 30 | end 31 | end 32 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_nfl_teams.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport_team = db[:sport_team] 27 | 28 | sport_team.find({sport: 'football'}).each do |t| 29 | t.each_key do |k| 30 | puts k + " => " + t[k].to_s 31 | end 32 | end 33 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_sport_locations.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport_location = db[:sport_location] 27 | 28 | tot_locations = 0 29 | sport_location.find.each do |t| 30 | tot_locations += 1 31 | t.each_key do |k| 32 | unless k == 'seats' 33 | puts k + " => " + t[k].to_s 34 | end 35 | end 36 | end 37 | 38 | puts "Total Locations: " + tot_locations.to_s 39 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_sport_locations_with_seats.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport_location = db[:sport_location] 27 | 28 | sport_location.find.each do |t| 29 | t.each_key do |k| 30 | puts k + " => " + t[k].to_s 31 | end 32 | end 33 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_sporting_events.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sporting_events = db[:sporting_event] 27 | sporting_events.find.sort({sport: 1,home_team_name: 1, event_date: 1, away_team_name: 1}).each do |ev| 28 | puts ev[:sport] + " " + ev[:home_team_name] + " " + ev[:away_team_name] + " " + ev[:event_date].to_s 29 | end 30 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_sports.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport = db[:sport] 27 | sport.find.each do |s| 28 | puts s[:name] + " " + s[:league] + " " + s[:league_name] 29 | puts " Divisions: " 30 | s[:divisions].each do |d| 31 | puts " " + d[:name] + " " + d[:description] 32 | end 33 | end 34 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/scripts/list_teams.rb: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env ruby 2 | 3 | # 4 | # Copyright 2017 Amazon.com 5 | # 6 | # Licensed under the Apache License, Version 2.0 (the "License"); 7 | # you may not use this file except in compliance with the License. 8 | # You may obtain a copy of the License at 9 | # 10 | # http://www.apache.org/licenses/LICENSE-2.0 11 | # 12 | # Unless required by applicable law or agreed to in writing, software 13 | # distributed under the License is distributed on an "AS IS" BASIS, 14 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 15 | # See the License for the specific language governing permissions and 16 | # limitations under the License. 17 | 18 | 19 | 20 | require 'rubygems' # not necessary for Ruby 1.9 21 | require 'mongo' 22 | 23 | # Connect to db. Located here to make it easy to change port etc... 24 | db = Mongo::Client.new([ '127.0.0.1:27017' ], :database => 'dms_sample') 25 | 26 | sport_team = db[:sport_team] 27 | 28 | sport_team.find.each do |t| 29 | t.each_key do |k| 30 | puts k + " => " + t[k].to_s 31 | end 32 | end 33 | -------------------------------------------------------------------------------- /mongodb/sampledb/v1/user/create_dms_user.js: -------------------------------------------------------------------------------- 1 | use dms_sample 2 | db.createUser({ 3 | user: 'dms_user', 4 | pwd: 'dms_user', 5 | roles: [{ role: 'readWrite', db:'dms_sample'}] 6 | }) 7 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/data/mlb_data.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/mysql/sampledb/v1/data/mlb_data.sql -------------------------------------------------------------------------------- /mysql/sampledb/v1/install-rds.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | ############################ 17 | # 18 | # The dms_sample database contains the objects and data 19 | # for the sample database. 20 | # 21 | ############################# 22 | 23 | source ./schema/create_dms_sample.sql 24 | 25 | ############################# 26 | # 27 | # The dms_user script creates the user dms_user with 28 | # the password dms_user. It is recommended you change 29 | # the password for dms_user. 30 | # 31 | # dms_user should have all the privileges required to 32 | # use the Database Migration Service and Schema Conversion 33 | # Tool against the dms_sample database. 34 | # 35 | ############################# 36 | 37 | source ./user/create_dms_user.sql 38 | source ./user/dms_user_privileges.sql 39 | 40 | 41 | ############################# 42 | # RDS Specific commands 43 | ############################# 44 | call mysql.rds_set_configuration('binlog retention hours',8); 45 | 46 | 47 | ############################ 48 | # 49 | # install the objects in the dms_sample database 50 | # 51 | ############################# 52 | use dms_sample; 53 | source ./schema/load_base_data.sql 54 | source ./schema/install_dms_sample_data.sql 55 | 56 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/remove-sampledb.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | drop database dms_sample; 18 | drop user dms_user; 19 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/create_dms_sample.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create database if not exists dms_sample; 18 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/generate_sport_tickets.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ####################### 18 | # create procedure to generate MLB tickets 19 | ####################### 20 | DELIMITER $$ 21 | 22 | DROP PROCEDURE IF EXISTS generateSportTickets $$ 23 | 24 | create procedure generateSportTickets(IN p_sport VARCHAR(15) ) 25 | BEGIN 26 | DECLARE v_event_id BIGINT; 27 | DECLARE all_done INT DEFAULT FALSE; 28 | 29 | DECLARE event_cur CURSOR FOR 30 | SELECT id 31 | FROM sporting_event 32 | WHERE sport_type_name = p_sport; 33 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET all_done = TRUE; 34 | 35 | select p_sport; 36 | 37 | OPEN event_cur; 38 | event_loop: LOOP 39 | FETCH event_cur INTO v_event_id; 40 | 41 | IF all_done THEN 42 | CLOSE event_cur; 43 | LEAVE event_loop; 44 | END IF; 45 | 46 | CALL generateTickets(v_event_id); 47 | END LOOP; 48 | 49 | END; 50 | $$ 51 | DELIMITER ; 52 | 53 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/generate_ticket_activity.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ####################### 18 | # create procedure to generate ticket activity 19 | ####################### 20 | DELIMITER $$ 21 | 22 | DROP PROCEDURE IF EXISTS generateTicketActivity $$ 23 | 24 | CREATE PROCEDURE generateTicketActivity(IN p_max_transactions INT, IN p_delay_in_seconds REAL(5,2)) 25 | BEGIN 26 | DECLARE v_min_person_id INT; 27 | DECLARE v_max_person_id INT; 28 | DECLARE v_min_row INT; 29 | DECLARE v_max_row INT; 30 | DECLARE v_target_row INT; 31 | DECLARE v_event_id BIGINT; 32 | DECLARE v_target_person_id INT; 33 | DECLARE v_person_id INT; 34 | DECLARE v_quantity INT; 35 | DECLARE v_current_txn INT DEFAULT 0; 36 | DECLARE v_reset_events INT DEFAULT 1; 37 | DECLARE v_max_transactions INT; 38 | DECLARE v_delay_message VARCHAR(100); 39 | DECLARE v_delay REAL(5,2); 40 | 41 | SET v_delay = COALESCE(p_delay_in_seconds,0.25); 42 | 43 | drop temporary table if exists v_open_events; 44 | create temporary table v_open_events(rownum INT NOT NULL AUTO_INCREMENT, id BIGINT, constraint v_pk primary key(rownum)) engine=memory; 45 | 46 | /* get the range of person ids. */ 47 | SELECT MIN(id), MAX(id) into v_min_person_id, v_max_person_id from person; 48 | 49 | SET v_max_transactions = COALESCE(p_max_transactions,1000); 50 | 51 | WHILE v_current_txn < v_max_transactions DO 52 | IF v_reset_events = 1 THEN 53 | DELETE FROM v_open_events; 54 | INSERT INTO v_open_events(id) SELECT id FROM sporting_event WHERE sold_out <> 1 ORDER BY start_date; 55 | SELECT MIN(rownum), MAX(rownum) INTO v_min_row, v_max_row FROM v_open_events; 56 | SET v_reset_events = 0; 57 | END IF; 58 | 59 | SET v_target_row = ROUND((RAND() * (v_max_row - v_min_row)) + v_min_row); 60 | SELECT id INTO v_event_id FROM v_open_events WHERE rownum = v_target_row; 61 | 62 | SET v_target_person_id = ROUND((RAND()*(v_max_person_id - v_min_person_id)) + v_min_person_id); 63 | SELECT MIN(id) INTO v_person_id FROM person WHERE id > v_target_person_id -1; 64 | 65 | SET v_quantity = ROUND((RAND() * (6 - 1)) + 1); 66 | 67 | /* The following will sell tickets. If tickets aren't available, there should be exception processing to reload the events table. 68 | That processing hasn't been written yet (for the mysql examples.) 69 | */ 70 | 71 | call sellTickets(v_person_id, v_event_id, v_quantity); 72 | 73 | SET v_current_txn = v_current_txn +1; 74 | 75 | SET v_delay_message = (SELECT sleep(v_delay) ); 76 | 77 | END WHILE; 78 | drop temporary table if exists v_open_events; 79 | END; 80 | $$ 81 | 82 | DELIMITER ; 83 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/generate_tickets.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ####################### 18 | # create procedure to generate tickets 19 | ####################### 20 | DELIMITER $$ 21 | 22 | DROP PROCEDURE IF EXISTS generateTickets $$ 23 | 24 | create procedure generateTickets(IN p_event_id BIGINT) 25 | BEGIN 26 | DECLARE v_e_id BIGINT; 27 | DECLARE v_loc_id INT; 28 | DECLARE v_standard_price DECIMAL(6,2); 29 | DECLARE all_done INT DEFAULT FALSE; 30 | 31 | DECLARE event_cur CURSOR FOR 32 | SELECT id, location_id 33 | FROM sporting_event 34 | WHERE id = p_event_id; 35 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET all_done = TRUE; 36 | 37 | 38 | /* randomly generated standard price between 30 and 50 dollars */ 39 | SET v_standard_price = ROUND((RAND() * (50-30))+30,2); 40 | 41 | OPEN event_cur; 42 | ticket_loop: LOOP 43 | 44 | FETCH event_cur INTO v_e_id, v_loc_id; 45 | IF all_done THEN 46 | CLOSE event_cur; 47 | LEAVE ticket_loop; 48 | END IF; 49 | 50 | INSERT INTO sporting_event_ticket(sporting_event_id,sport_location_id,seat_level,seat_section,seat_row,seat,ticket_price) 51 | SELECT sporting_event.id 52 | ,seat.sport_location_id 53 | ,seat.seat_level 54 | ,seat.seat_section 55 | ,seat.seat_row 56 | ,seat.seat 57 | ,(CASE 58 | WHEN seat.seat_type = 'luxury' THEN 3*v_standard_price 59 | WHEN seat.seat_type = 'premium' THEN 2*v_standard_price 60 | WHEN seat.seat_type = 'standard' THEN v_standard_price 61 | WHEN seat.seat_type = 'sub-standard' THEN 0.8*v_standard_price 62 | WHEN seat.seat_type = 'obstructed' THEN 0.5*v_standard_price 63 | WHEN seat.seat_type = 'standing' THEN 0.5*v_standard_price 64 | END ) ticket_price 65 | FROM sporting_event 66 | ,seat 67 | WHERE sporting_event.location_id = seat.sport_location_id 68 | AND sporting_event.id = v_e_id; 69 | 70 | END LOOP; 71 | 72 | END; 73 | $$ 74 | 75 | DELIMITER ; 76 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/generate_transfer_activity.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ####################### 18 | # create procedure to generate ticket activity 19 | ####################### 20 | DELIMITER $$ 21 | 22 | DROP PROCEDURE IF EXISTS generateTransferActivity $$ 23 | 24 | CREATE PROCEDURE generateTransferActivity(p_max_transactions INT, p_delay_in_seconds DECIMAL(5,2)) 25 | BEGIN 26 | DECLARE v_txn_count INT DEFAULT 0; 27 | DECLARE v_min_tik_id BIGINT; 28 | DECLARE v_max_tik_id BIGINT; 29 | DECLARE v_tik_id BIGINT; 30 | DECLARE v_max_p_id INT; 31 | DECLARE v_min_p_id INT; 32 | DECLARE v_person_id INT; 33 | DECLARE v_rand_p_max INT; 34 | DECLARE v_rand_max BIGINT; 35 | DECLARE v_xfer_all TINYINT DEFAULT 1; 36 | DECLARE v_price DECIMAL(6,2); 37 | DECLARE v_price_multiplier DECIMAL(4,2) DEFAULT 1.0; 38 | DECLARE v_max_transactions INT; 39 | DECLARE v_delay_message VARCHAR(100); 40 | DECLARE v_delay REAL(5,2); 41 | 42 | SET v_delay = COALESCE(p_delay_in_seconds,0.25); 43 | 44 | /* get max and min ticket ids */ 45 | SELECT min(sporting_event_ticket_id), max(sporting_event_ticket_id) INTO v_min_tik_id, v_max_tik_id FROM ticket_purchase_hist; 46 | 47 | /* get max and min person ids */ 48 | SELECT min(id), max(id) INTO v_min_p_id, v_max_p_id FROM person; 49 | 50 | select concat('max t: ',v_max_tik_id,' min t: ', v_min_tik_id, 'max p: ',v_max_p_id,' min p: ', v_min_p_id); 51 | 52 | SET v_max_transactions = COALESCE(p_max_transactions,10); 53 | 54 | WHILE v_txn_count < v_max_transactions DO 55 | /* find a random upper bound for ticket and person ids */ 56 | SET v_rand_max = ROUND((RAND() * (v_max_tik_id - v_min_tik_id)) + v_min_tik_id); 57 | SET v_rand_p_max = ROUND((RAND() * (v_max_p_id - v_min_p_id)) + v_min_p_id); 58 | 59 | SELECT MAX(sporting_event_ticket_id) INTO v_tik_id 60 | FROM ticket_purchase_hist 61 | WHERE sporting_event_ticket_id <= v_rand_max; 62 | 63 | SELECT MAX(id) INTO v_person_id FROM person WHERE id <= v_rand_p_max; 64 | 65 | /* 80% of the time transfer all tickets, 20% of the time don't */ 66 | 67 | IF ( ROUND((RAND() *(5-1)) +1 ) = 5 ) THEN 68 | SET v_xfer_all = 0; 69 | END IF; 70 | 71 | /* 30% of the time change the price by up to 20% in either direction */ 72 | IF ( ROUND((RAND() * (3-1) +1)) = 1) THEN 73 | SET v_price_multiplier = ROUND((RAND()*(12-8)) +8)/10; 74 | END IF; 75 | 76 | SELECT v_price_multiplier*ticket_price INTO v_price 77 | FROM sporting_event_ticket 78 | WHERE id = v_tik_id; 79 | 80 | select CONCAT('Ticket to transfer: ', v_tik_id, ' Transfer to person id: ' , v_person_id, ' All tickets?: ',v_xfer_all, ' price: ', v_price); 81 | 82 | call transferTicket(v_tik_id, v_person_id, v_xfer_all, v_price); 83 | 84 | /* reset some variables */ 85 | SET v_txn_count = v_txn_count + 1; 86 | SET v_xfer_all = 1; 87 | SET v_price_multiplier = 1; 88 | SET v_delay_message = (SELECT sleep(v_delay) ); 89 | 90 | END WHILE; 91 | END; 92 | $$ 93 | 94 | DELIMITER ; 95 | 96 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/load_base_data.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ############################### 18 | # 19 | # The following scripts load raw data used to generate the 20 | # sample database 21 | # 22 | ############################### 23 | use dms_sample 24 | source ./schema/mlb_data.tab 25 | source ./data/mlb_data.sql 26 | commit; 27 | source ./schema/name_data.tab 28 | source ./data/name_data.sql 29 | commit; 30 | source ./schema/nfl_data.tab 31 | source ./data/nfl_data.sql 32 | commit; 33 | source schema/nfl_stadium_data.tab 34 | source ./data/nfl_stadium_data.sql 35 | commit; 36 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/mlb_data.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create table mlb_data(mlb_id MEDIUMINT, 18 | mlb_name VARCHAR(30), 19 | mlb_pos VARCHAR(30), 20 | mlb_team VARCHAR(30), 21 | mlb_team_long VARCHAR(30), 22 | bats VARCHAR(30), 23 | throws VARCHAR(30), 24 | birth_year VARCHAR(30), 25 | bp_id SMALLINT, 26 | bref_id VARCHAR(30), 27 | bref_name VARCHAR(30), 28 | cbs_id VARCHAR(30), 29 | cbs_name VARCHAR(30), 30 | cbs_pos VARCHAR(30), 31 | espn_id SMALLINT, 32 | espn_name VARCHAR(30), 33 | espn_pos VARCHAR(30), 34 | fg_id VARCHAR(30), 35 | fg_name VARCHAR(30), 36 | lahman_id VARCHAR(30), 37 | nfbc_id SMALLINT, 38 | nfbc_name VARCHAR(30), 39 | nfbc_pos VARCHAR(30), 40 | retro_id VARCHAR(30), 41 | retro_name VARCHAR(30), 42 | debut VARCHAR(30), 43 | yahoo_id MEDIUMINT, 44 | yahoo_name VARCHAR(30), 45 | yahoo_pos VARCHAR(30), 46 | mlb_depth VARCHAR(30)); 47 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/name_data.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create table name_data( 18 | name_type VARCHAR(15) NOT NULL, 19 | name VARCHAR(45) NOT NULL, 20 | constraint name_data_pk primary key(name_type, name) 21 | ); 22 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/nfl_data.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create table nfl_data( 18 | Position varchar(5), 19 | player_number SMALLINT, 20 | Name varchar(40), 21 | status varchar(10), 22 | stat1 varchar(10), 23 | stat1_val varchar(10), 24 | stat2 varchar(10), 25 | stat2_val varchar(10), 26 | stat3 varchar(10), 27 | stat3_val varchar(10), 28 | stat4 varchar(10), 29 | stat4_val varchar(10), 30 | team varchar(10) 31 | ); 32 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/nfl_stadium_data.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create table nfl_stadium_data( 18 | stadium varchar(60), 19 | seating_capacity MEDIUMINT, 20 | location varchar(40), 21 | surface varchar(80), 22 | roof varchar(30), 23 | team varchar(40), 24 | opened varchar(10), 25 | sport_location_id SMALLINT 26 | ); 27 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/person.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | create table if not exists person 19 | (ID MEDIUMINT NOT NULL AUTO_INCREMENT, 20 | full_name varchar(60) NOT NULL, 21 | last_name varchar(30), 22 | first_name varchar(30), 23 | constraint person_pk primary key(id) 24 | ); 25 | 26 | INSERT INTO person(full_name, last_name, first_name) 27 | SELECT CONCAT(first.name, ' ', last.name) 28 | ,last.name 29 | ,first.name 30 | FROM name_data first, name_data last 31 | WHERE first.name_type != 'LAST' 32 | AND last.name_type = 'LAST'; 33 | 34 | 35 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/seat_type.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | 19 | create table if not exists seat_type 20 | (name varchar(15) NOT NULL, 21 | description varchar(120), 22 | relative_quality TINYINT, 23 | constraint st_seat_type_pk primary key(name) 24 | ); 25 | 26 | insert into seat_type(name,description,relative_quality) 27 | values('luxury','Excellent seats - box seats, behind the plate, etc. etc.',1); 28 | insert into seat_type(name,description,relative_quality) 29 | values('premium','Really good seats - first level, mid field, etc. etc.',2); 30 | insert into seat_type(name,description,relative_quality) 31 | values('standard','Standard seats - not super awesome but pretty good',3); 32 | insert into seat_type(name,description,relative_quality) 33 | values('sub-standard','End zone, nose bleed, etc.',4); 34 | insert into seat_type(name,description,relative_quality) 35 | values('obstructed','Pretty crappy, partially obstructed seats',5); 36 | insert into seat_type(name,description,relative_quality) 37 | values('standing','Really? That''s not a seat at all now, is it?',10); 38 | 39 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sell_tickets.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | ####################### 18 | # create procedure to sell tickets 19 | ####################### 20 | DELIMITER $$ 21 | 22 | DROP PROCEDURE IF EXISTS sellTickets $$ 23 | 24 | CREATE PROCEDURE sellTickets(IN p_person_id MEDIUMINT, IN p_event_id BIGINT, IN p_quantity SMALLINT ) 25 | BEGIN 26 | DECLARE v_ticket_id BIGINT; 27 | DECLARE v_seat_level INT; 28 | DECLARE v_seat_section varchar(15); 29 | DECLARE v_seat_row varchar(10); 30 | DECLARE v_tickets_sold SMALLINT DEFAULT 0; 31 | DECLARE v_time_of_sale DATETIME; 32 | DECLARE all_done INT DEFAULT FALSE; 33 | 34 | DECLARE t_cur CURSOR FOR 35 | SELECT id, seat_level, seat_section, seat_row 36 | FROM sporting_event_ticket 37 | WHERE sporting_event_id = p_event_id 38 | ORDER BY seat_level, seat_section, seat_row; 39 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET all_done = TRUE; 40 | 41 | SET v_time_of_sale = current_timestamp(); 42 | 43 | OPEN t_cur; 44 | tik_loop: LOOP 45 | START TRANSACTION; 46 | FETCH t_cur INTO v_ticket_id, v_seat_level, v_seat_section, v_seat_row; 47 | 48 | IF all_done THEN 49 | CLOSE t_cur; 50 | ROLLBACK; 51 | SELECT CONCAT('Sorry, unable to find ', p_quantity,' tickets for that event.'); 52 | LEAVE tik_loop; 53 | END IF; 54 | 55 | UPDATE sporting_event_ticket 56 | SET ticketholder_id = p_person_id 57 | WHERE id = v_ticket_id; 58 | 59 | INSERT INTO ticket_purchase_hist(sporting_event_ticket_id, purchased_by_id, transaction_date_time, purchase_price) 60 | SELECT id, ticketholder_id, v_time_of_sale,ticket_price 61 | FROM sporting_event_ticket 62 | WHERE id = v_ticket_id; 63 | 64 | SET v_tickets_sold = v_tickets_sold +1; 65 | 66 | IF v_tickets_sold = p_quantity THEN 67 | COMMIT; 68 | CLOSE t_cur; 69 | SELECT CONCAT('Congratulations! You''ve just purchased ',p_quantity,' tickets.'); 70 | LEAVE tik_loop; 71 | END IF; 72 | END LOOP; 73 | END; 74 | $$ 75 | 76 | DELIMITER ; 77 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/set_nfl_team_home_field.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | 19 | ####################### 20 | # create procedure to set nfl team home field 21 | ####################### 22 | DELIMITER $$ 23 | 24 | DROP PROCEDURE IF EXISTS setNFLTeamHomeField $$ 25 | 26 | CREATE PROCEDURE setNFLTeamHomeField() 27 | BEGIN 28 | DECLARE v_sport_location_id INT; 29 | DECLARE v_team VARCHAR(40); 30 | DECLARE v_loc VARCHAR(40); 31 | 32 | DECLARE done INT DEFAULT FALSE; 33 | 34 | DECLARE nsd_cur CURSOR FOR SELECT sport_location_id, team, location FROM nfl_stadium_data; 35 | 36 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; 37 | 38 | OPEN nsd_cur; 39 | read_loop: LOOP 40 | FETCH NEXT FROM nsd_cur INTO v_sport_location_id, v_team, v_loc; 41 | IF done THEN 42 | LEAVE read_loop; 43 | END IF; 44 | 45 | UPDATE sport_team s 46 | SET s.home_field_id = v_sport_location_id 47 | WHERE s.name = v_team 48 | AND s.sport_league_short_name = 'NFL' 49 | AND s.sport_type_name = 'football'; 50 | 51 | END LOOP; 52 | 53 | CLOSE nsd_cur; 54 | END; 55 | $$ 56 | 57 | DELIMITER ; 58 | 59 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sport_league.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | create table if not exists sport_league 19 | (sport_type_name varchar(15) NOT NULL, 20 | short_name varchar(10) NOT NULL, 21 | long_name varchar(60) NOT NULL, 22 | description varchar(120), 23 | constraint sport_league_pk primary key(short_name), 24 | constraint sl_sport_type_fk foreign key(sport_type_name) references sport_type(name) 25 | ); 26 | 27 | insert into sport_league(sport_type_name,short_name,long_name,description) 28 | values('baseball','MLB','Major League Baseball','Professional baseball league in North America.'); 29 | 30 | insert into sport_league(sport_type_name,short_name,long_name,description) 31 | values('football','NFL','National Footbal League','Professional football league in North America.'); 32 | 33 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sport_type.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | 19 | create table if not exists sport_type 20 | (name varchar(15) NOT NULL, 21 | description varchar(120), 22 | constraint sport_type_pk primary key(name) 23 | ); 24 | 25 | insert into sport_type(name,description) 26 | values('baseball','A sport with 9 players, bats, and balls - what could possibly go wrong?'); 27 | 28 | insert into sport_type(name,description) 29 | values('football','Teams of 11 players attempt to move an oblong ball 100 yards while beating the snot out of each other.'); 30 | 31 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sporting_event.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | create table if not exists sporting_event 19 | (id BIGINT NOT NULL AUTO_INCREMENT, 20 | sport_type_name VARCHAR(15) NOT NULL, 21 | home_team_id MEDIUMINT NOT NULL, 22 | away_team_id MEDIUMINT NOT NULL, 23 | location_id SMALLINT NOT NULL, 24 | start_date_time DATETIME NOT NULL, 25 | start_date DATE NOT NULL, 26 | sold_out BOOLEAN DEFAULT FALSE NOT NULL, 27 | constraint sporting_event_pk primary key(id), 28 | constraint se_sport_type_fk foreign key(sport_type_name) references sport_type(name), 29 | constraint se_home_team_id_fk foreign key(home_team_id) references sport_team(id), 30 | constraint se_away_team_id_fk foreign key(away_team_id) references sport_team(id), 31 | constraint se_location_id_fk foreign key(location_id) references sport_location(id) 32 | ); 33 | 34 | create index se_start_date on sporting_event(start_date); 35 | 36 | 37 | 38 | 39 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sporting_event_info.vw: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | drop view if exists sporting_event_info; 19 | 20 | create view sporting_event_info as 21 | select e.id as event_id 22 | , e.sport_type_name sport 23 | , e.start_date_time event_date_time 24 | , h.name home_team 25 | , a.name away_team 26 | , l.name location 27 | , l.city city 28 | from sporting_event e, sport_team h, sport_team a, sport_location l 29 | where e.home_team_id = h.id 30 | and e.away_team_id = a.id 31 | and e.location_id = l.id; 32 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sporting_event_ticket.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | create table sporting_event_ticket 18 | ( id BIGINT NOT NULL AUTO_INCREMENT, 19 | sporting_event_id BIGINT NOT NULL, 20 | sport_location_id SMALLINT NOT NULL, 21 | seat_level SMALLINT NOT NULL, 22 | seat_section VARCHAR(15) NOT NULL, 23 | seat_row VARCHAR(10) NOT NULL, 24 | seat VARCHAR(10) NOT NULL, 25 | ticketholder_id MEDIUMINT, 26 | ticket_price DECIMAL(6,2) NOT NULL, 27 | constraint sporting_event_ticket_pk primary key(id), 28 | constraint set_sporting_event_fk foreign key(sporting_event_id) references sporting_event(id), 29 | constraint set_person_id foreign key(ticketholder_id) references person(id), 30 | constraint set_seat_fk foreign key(sport_location_id,seat_level,seat_section,seat_row, seat) references seat(sport_location_id,seat_level,seat_section,seat_row,seat) 31 | ); 32 | 33 | 34 | create index set_sporting_event_idx on sporting_event_ticket(sporting_event_id); 35 | 36 | create index set_seat_idx on sporting_event_ticket(sport_location_id,seat_level,seat_section,seat_row,seat); 37 | 38 | create index set_ticketholder_idx on sporting_event_ticket(ticketholder_id); 39 | 40 | create index set_ev_id_tkholder_id_idx on sporting_event_ticket(sporting_event_id,ticketholder_id); -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/sporting_event_ticket_info.vw: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | drop view if exists sporting_event_ticket_info; 19 | 20 | create view sporting_event_ticket_info as 21 | select t.id as ticket_id 22 | ,e.event_id 23 | ,e.sport 24 | ,e.event_date_time 25 | ,e.home_team 26 | ,e.away_team 27 | ,e.location 28 | ,e.city 29 | ,t.seat_level 30 | ,t.seat_section 31 | ,t.seat_row 32 | ,t.seat 33 | ,t.ticket_price 34 | ,p.full_name as ticketholder 35 | from sporting_event_ticket t 36 | JOIN sporting_event_info e ON t.sporting_event_id = e.event_id 37 | LEFT OUTER JOIN person p ON t.ticketholder_id = p.id; 38 | 39 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/ticket_purchase_hist.tab: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | create table if not exists ticket_purchase_hist 19 | ( sporting_event_ticket_id BIGINT NOT NUll 20 | ,purchased_by_id MEDIUMINT NOT NULL 21 | ,transaction_date_time DATETIME NOT NULL 22 | ,transferred_from_id MEDIUMINT 23 | ,purchase_price DECIMAL(6,2) NOT NULL 24 | ,constraint ticket_purchase_hist_pk primary key(sporting_event_ticket_id, purchased_by_id, transaction_date_time) 25 | ,constraint tph_sport_event_tik_id foreign key(sporting_event_ticket_id) references sporting_event_ticket(id) 26 | ,constraint tph_ticketholder_id foreign key(purchased_by_id) references person(id) 27 | ,constraint tph_transfer_from_id foreign key(transferred_from_id) references person(id) 28 | ); 29 | 30 | create index tph_purch_by_id on ticket_purchase_hist(purchased_by_id); 31 | create index tph_trans_from_id on ticket_purchase_hist(transferred_from_id); 32 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/schema/transfer_tickets.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | 18 | 19 | ####################### 20 | # create procedure to transfer tickets 21 | ####################### 22 | DELIMITER $$ 23 | 24 | DROP PROCEDURE IF EXISTS transferTicket $$ 25 | 26 | 27 | CREATE PROCEDURE transferTicket(p_ticket_id BIGINT, p_new_ticketholder_id MEDIUMINT, p_transfer_all TINYINT, p_price DECIMAL(6,2)) 28 | BEGIN 29 | DECLARE v_last_txn_date DATETIME; 30 | DECLARE v_old_ticketholder_id MEDIUMINT; 31 | DECLARE v_sporting_event_ticket_id BIGINT; 32 | DECLARE v_purchase_price DECIMAL(6,2); 33 | DECLARE v_time_of_purchase TIMESTAMP; 34 | DECLARE all_done INT DEFAULT FALSE; 35 | 36 | /* get all tickets purchased at the same time for that event by that ticketholder */ 37 | 38 | DECLARE xfer_cur CURSOR FOR 39 | SELECT sporting_event_ticket_id, purchase_price 40 | FROM ticket_purchase_hist 41 | WHERE purchased_by_id = v_old_ticketholder_id 42 | AND transaction_date_time = v_last_txn_date 43 | AND ((sporting_event_ticket_id = p_ticket_id) OR (p_transfer_all = TRUE) ); 44 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET all_done = TRUE; 45 | 46 | /* get the latest record of purchase for this particular tickeholder for that event 47 | note they could have purchsed, sold and repurchased the ticket 48 | */ 49 | 50 | SELECT max(h.transaction_date_time), t.ticketholder_id 51 | INTO v_last_txn_date, v_old_ticketholder_id 52 | FROM ticket_purchase_hist h 53 | ,sporting_event_ticket t 54 | WHERE t.id = p_ticket_id 55 | AND h.purchased_by_id = t.ticketholder_id 56 | GROUP BY t.ticketholder_id; 57 | 58 | select p_transfer_all; 59 | 60 | SET v_time_of_purchase = current_timestamp(); 61 | 62 | OPEN xfer_cur; 63 | xfer_loop: LOOP 64 | FETCH xfer_cur INTO v_sporting_event_ticket_id, v_purchase_price; 65 | 66 | IF all_done THEN 67 | CLOSE xfer_cur; 68 | LEAVE xfer_loop; 69 | END IF; 70 | 71 | /* update the sporting event ticket with the new owner */ 72 | UPDATE sporting_event_ticket 73 | SET ticketholder_id = p_new_ticketholder_id 74 | WHERE id = v_sporting_event_ticket_id; 75 | 76 | /* record the transaction */ 77 | INSERT INTO ticket_purchase_hist(sporting_event_ticket_id, purchased_by_id, transferred_from_id, transaction_date_time, purchase_price) 78 | VALUES(v_sporting_event_ticket_id, p_new_ticketholder_id, v_old_ticketholder_id, v_time_of_purchase,COALESCE( p_price,v_purchase_price)); 79 | 80 | SELECT CONCAT('Ticket id: ', v_sporting_event_ticket_id, ' Original price: ', v_purchase_price, ' Old Ticketholder: ',v_old_ticketholder_id,' Txn Date: ', v_last_txn_date); 81 | 82 | END LOOP; 83 | END; 84 | 85 | $$ 86 | 87 | DELIMITER ; 88 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/user/create_dms_user.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | 17 | CREATE USER 'dms_user'@'%' IDENTIFIED BY 'dms_user'; 18 | 19 | 20 | -------------------------------------------------------------------------------- /mysql/sampledb/v1/user/dms_user_privileges.sql: -------------------------------------------------------------------------------- 1 | # 2 | # Copyright 2017 Amazon.com 3 | # 4 | # Licensed under the Apache License, Version 2.0 (the "License"); 5 | # you may not use this file except in compliance with the License. 6 | # You may obtain a copy of the License at 7 | # 8 | # http://www.apache.org/licenses/LICENSE-2.0 9 | # 10 | # Unless required by applicable law or agreed to in writing, software 11 | # distributed under the License is distributed on an "AS IS" BASIS, 12 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | # See the License for the specific language governing permissions and 14 | # limitations under the License. 15 | 16 | GRANT ALL PRIVILEGES ON dms_sample.* TO 'dms_user'@'%' IDENTIFIED BY 'dms_user'; 17 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/data/README.txt: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------- 2 | Amazon DMS Sample Database for Oracle: version 1.0 3 | -------------------------------------------------------- 4 | Files in this directory contain base data and are for reference only 5 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/data/master.csv: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/oracle/sampledb/v1/data/master.csv -------------------------------------------------------------------------------- /oracle/sampledb/v1/install-onprem.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Allow 45 minutes for installation (depending on the size of the host) 3 | -- 4 | 5 | -------------------------------------------------------- 6 | -- 7 | -- !!! log in as a user with DBA privilege (master user in RDS) 8 | -- 9 | -------------------------------------------------------- 10 | 11 | -- Spool to output 12 | spool install-rds.out 13 | 14 | 15 | -------------------------------------------------------- 16 | -- 17 | -- The dms_sample user/schema contains the objects and data 18 | -- for this database. 19 | -- 20 | -- The following script creates the user dms_sample/dms_sample 21 | -- it is recommended that you change the password 22 | -- after creating the account. 23 | -- 24 | --------------------------------------------------------- 25 | 26 | @user/create_dms_sample.sql 27 | 28 | 29 | --------------------------------------------------------- 30 | -- In order to capture changes supplemental logging is required 31 | -- The following commands turn on supplemental logging and increase 32 | -- archive retention (RDS) 33 | --------------------------------------------------------- 34 | 35 | --------------------------------------------------------- 36 | -- If your source is NOT on RDS: 37 | --------------------------------------------------------- 38 | ALTER DATABASE ADD SUPPLEMENTAL LOG DATA; 39 | ALTER DATABASE ADD SUPPLEMENTAL LOG DATA (PRIMARY KEY) COLUMNS; 40 | 41 | 42 | 43 | -------------------------------------------------------- 44 | -- 45 | -- In general, it's a good idea to create and use an 46 | -- account other than the account that owns the schema 47 | -- objects for the migration. The following creates the 48 | -- user dms_user/dms_user which can be used to migrate 49 | -- the objects contained in the dms_sample account. 50 | -- It is recommended that you change the password 51 | -- after creating the account. 52 | --------------------------------------------------------- 53 | @user/create_dms_user.sql 54 | @user/dms_user_privileges_onprem.sql 55 | 56 | -------------------------------------------------------- 57 | -- 58 | -- If you want the dms_user to use the Schema Conversion 59 | -- Tool (SCT) you will need to give them the following privileges 60 | -- 61 | -------------------------------------------------------- 62 | @user/dms_user_sct_privileges.sql 63 | 64 | 65 | 66 | -------------------------------------------------------- 67 | -- 68 | -- !!! log in as the user DMS_SAMPLE 69 | -- 70 | --------------------------------------------------------- 71 | -- run the following scripts: 72 | alter session set current_schema = dms_sample; 73 | @schema/load_base_data.sql 74 | @schema/install_dms_sample_data.sql 75 | 76 | 77 | -- stop spooling 78 | spool off 79 | 80 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/install-rds.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | -- 18 | -- Allow 45 minutes for installation (depending on the size of the host) 19 | -- 20 | 21 | -------------------------------------------------------- 22 | -- 23 | -- !!! log in as a user with DBA privilege (master user in RDS) 24 | -- 25 | -------------------------------------------------------- 26 | 27 | -- Spool to output 28 | spool install-rds.out 29 | 30 | 31 | -------------------------------------------------------- 32 | -- 33 | -- The dms_sample user/schema contains the objects and data 34 | -- for this database. 35 | -- 36 | -- The following script creates the user dms_sample/dms_sample 37 | -- it is recommended that you change the password 38 | -- after creating the account. 39 | -- 40 | --------------------------------------------------------- 41 | 42 | @user/create_dms_sample.sql 43 | 44 | 45 | --------------------------------------------------------- 46 | -- In order to capture changes supplemental logging is required 47 | -- The following commands turn on supplemental logging and increase 48 | -- archive retention (RDS) 49 | --------------------------------------------------------- 50 | 51 | 52 | --------------------------------------------------------- 53 | -- RDS Specific commands 54 | --------------------------------------------------------- 55 | exec rdsadmin.rdsadmin_util.alter_supplemental_logging('ADD'); 56 | exec rdsadmin.rdsadmin_util.alter_supplemental_logging('ADD','PRIMARY KEY'); 57 | exec rdsadmin.rdsadmin_util.set_configuration('archivelog retention hours',8); 58 | 59 | 60 | -------------------------------------------------------- 61 | -- 62 | -- In general, it's a good idea to create and use an 63 | -- account other than the account that owns the schema 64 | -- objects for the migration. The following creates the 65 | -- user dms_user/dms_user which can be used to migrate 66 | -- the objects contained in the dms_sample account. 67 | -- It is recommended that you change the password 68 | -- after creating the account. 69 | --------------------------------------------------------- 70 | @user/create_dms_user.sql 71 | @user/dms_user_privileges.sql 72 | 73 | -------------------------------------------------------- 74 | -- 75 | -- If you want the dms_user to use the Schema Conversion 76 | -- Tool (SCT) you will need to give them the following privileges 77 | -- 78 | -------------------------------------------------------- 79 | @user/dms_user_sct_privileges.sql 80 | 81 | 82 | 83 | -------------------------------------------------------- 84 | -- 85 | -- install the objects in the dms_sample schema 86 | -- 87 | --------------------------------------------------------- 88 | alter session set current_schema = dms_sample; 89 | @schema/load_base_data.sql 90 | @schema/install_dms_sample_data.sql 91 | 92 | 93 | 94 | -- stop spooling output 95 | 96 | spool off 97 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/remove-sampledb.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | --------------------------------------------------------------------- 18 | -- Run the following as a DBA to remove the sample db 19 | --------------------------------------------------------------------- 20 | 21 | drop user dms_user cascade; 22 | drop user dms_sample cascade; 23 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/README.txt: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | Files contained in this directory are used to create the dms_sample schema 3 | objects. More details regarding these objects are located in the main 4 | README.txt file in the root directory. 5 | ------------------------------------- 6 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/dms_sample_dw.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/oracle/sampledb/v1/schema/dms_sample_dw.pdf -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/generate_mlb_season.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | delete from sporting_event where sport_type_name = 'baseball'; 18 | 19 | DECLARE 20 | sport_type_name sport_type.name%TYPE; 21 | event_date DATE; 22 | 23 | date_offset NUMBER := 0; 24 | 25 | CURSOR team1 IS 26 | SELECT id, home_field_id from sport_team 27 | WHERE sport_league_short_name = 'MLB' 28 | AND sport_type_name = 'baseball' 29 | order by id; 30 | 31 | CURSOR team2(IN_ID IN NUMBER) IS 32 | SELECT id, home_field_id from sport_team 33 | WHERE ID > IN_ID 34 | AND sport_league_short_name = 'MLB' 35 | AND sport_type_name = 'baseball' 36 | ORDER BY ID; 37 | 38 | CURSOR team3(IN_ID IN NUMBER) IS 39 | SELECT id, home_field_id from sport_team 40 | WHERE ID < IN_ID 41 | AND sport_league_short_name = 'MLB' 42 | AND sport_type_name = 'baseball' 43 | ORDER BY ID; 44 | 45 | BEGIN 46 | select name into sport_type_name from sport_type where LOWER(name) = 'baseball'; 47 | 48 | --- every team plays every other team twice, each has home field advantage once 49 | 50 | FOR hrec IN team1 LOOP 51 | event_date := NEXT_DAY(TO_DATE('31-MAR-' || TO_CHAR(SYSDATE,'YYYY'),'DD-MON-YYYY'),'saturday') + 7*date_offset; 52 | FOR arec IN team2(hrec.id) LOOP 53 | event_date := event_date + TRUNC(dbms_random.value(12,19))/24; 54 | INSERT INTO sporting_event(sport_type_name, home_team_id, away_team_id, location_id,start_date_time) 55 | VALUES(sport_type_name, hrec.id, arec.id, hrec.home_field_id, event_date); 56 | 57 | event_date := TRUNC(event_date) +7; 58 | END LOOP; 59 | 60 | event_date := TRUNC(NEXT_DAY(EVENT_DATE,'wednesday')); 61 | 62 | FOR h2_rec in team3(hrec.id) LOOP 63 | event_date := (event_date - 7) + TRUNC(dbms_random.value(12,19))/24; 64 | INSERT INTO sporting_event(sport_Type_name, home_team_id, away_team_id, location_id, start_date_time) 65 | VALUES(sport_type_name, hrec.id, h2_rec.id, hrec.home_field_id, event_date); 66 | END LOOP; 67 | 68 | date_offset := date_offset +1; 69 | END LOOP; 70 | END; 71 | / 72 | 73 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/generate_tickets.pls: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | create or replace procedure generate_tickets(P_event_id IN NUMBER) as 19 | CURSOR event_cur(P_ID NUMBER) IS 20 | SELECT id,location_id 21 | FROM sporting_event 22 | WHERE ID = P_ID; 23 | 24 | standard_price NUMBER(6,2); 25 | 26 | BEGIN 27 | standard_price := DBMS_RANDOM.VALUE(30,50); 28 | 29 | FOR event_rec IN event_cur(P_event_id) LOOP 30 | INSERT /*+ APPEND */ INTO sporting_event_ticket(id,sporting_event_id,sport_location_id,seat_level,seat_section,seat_row,seat,ticket_price) 31 | SELECT sporting_event_ticket_seq.nextval 32 | ,sporting_event.id 33 | ,seat.sport_location_id 34 | ,seat.seat_level 35 | ,seat.seat_section 36 | ,seat.seat_row 37 | ,seat.seat 38 | ,(CASE 39 | WHEN seat.seat_type = 'luxury' THEN 3*standard_price 40 | WHEN seat.seat_type = 'premium' THEN 2*standard_price 41 | WHEN seat.seat_type = 'standard' THEN standard_price 42 | WHEN seat.seat_type = 'sub-standard' THEN 0.8*standard_price 43 | WHEN seat.seat_type = 'obstructed' THEN 0.5*standard_price 44 | WHEN seat.seat_type = 'standing' THEN 0.5*standard_price 45 | END ) ticket_price 46 | FROM sporting_event 47 | ,seat 48 | WHERE sporting_event.location_id = seat.sport_location_id 49 | AND sporting_event.id = event_rec.id; 50 | END LOOP; 51 | END; 52 | / 53 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/load_base_data.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | -------------------------------------------------------------- 18 | -- 19 | -- The following scripts load raw data used to generate the 20 | -- sample database 21 | -- 22 | -------------------------------------------------------------- 23 | 24 | @schema/mlb_data.tab 25 | @schema/mlb_data.sql 26 | commit; 27 | @schema/name_data.tab 28 | @schema/name_data.sql 29 | commit; 30 | @schema/nfl_data.tab 31 | @schema/nfl_data.sql 32 | commit; 33 | @schema/nfl_stadium_data.tab 34 | @schema/nfl_stadium_data.sql 35 | commit; 36 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/mlb_data.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/oracle/sampledb/v1/schema/mlb_data.sql -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/mlb_data.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table mlb_data(mlb_id NUMBER, 18 | mlb_name VARCHAR2(30), 19 | mlb_pos VARCHAR2(30), 20 | mlb_team VARCHAR2(30), 21 | mlb_team_long VARCHAR2(30), 22 | bats VARCHAR2(30), 23 | throws VARCHAR2(30), 24 | birth_year VARCHAR2(30), 25 | bp_id NUMBER, 26 | bref_id VARCHAR2(30), 27 | bref_name VARCHAR2(30), 28 | cbs_id VARCHAR2(30), 29 | cbs_name VARCHAR2(30), 30 | cbs_pos VARCHAR2(30), 31 | espn_id NUMBER, 32 | espn_name VARCHAR2(30), 33 | espn_pos VARCHAR2(30), 34 | fg_id VARCHAR2(30), 35 | fg_name VARCHAR2(30), 36 | lahman_id VARCHAR2(30), 37 | nfbc_id NUMBER, 38 | nfbc_name VARCHAR2(30), 39 | nfbc_pos VARCHAR2(30), 40 | retro_id VARCHAR2(30), 41 | retro_name VARCHAR2(30), 42 | debut VARCHAR2(30), 43 | yahoo_id NUMBER, 44 | yahoo_name VARCHAR2(30), 45 | yahoo_pos VARCHAR2(30), 46 | mlb_depth VARCHAR2(30)) 47 | / 48 | 49 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/name_data.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table name_data( 18 | name_type VARCHAR2(15) NOT NULL, 19 | name VARCHAR2(45) NOT NULL, 20 | constraint name_data_pk primary key(name_type, name) 21 | ); 22 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/nfl_data.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table nfl_data( 18 | Position varchar2(5), 19 | player_number NUMBER(3), 20 | Name varchar2(40), 21 | status varchar2(10), 22 | stat1 varchar2(10), 23 | stat1_val varchar2(10), 24 | stat2 varchar2(10), 25 | stat2_val varchar2(10), 26 | stat3 varchar2(10), 27 | stat3_val varchar2(10), 28 | stat4 varchar2(10), 29 | stat4_val varchar2(10), 30 | team varchar2(10) 31 | ); 32 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/nfl_stadium_data.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table nfl_stadium_data( 18 | stadium varchar2(60), 19 | seating_capacity NUMBER, 20 | location varchar2(40), 21 | surface varchar2(80), 22 | roof varchar2(30), 23 | team varchar2(40), 24 | opened varchar2(10), 25 | sport_location_id NUMBER 26 | ); 27 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/person.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table person 18 | (id NUMBER NOT NULL, 19 | full_name varchar2(60) NOT NULL, 20 | last_name varchar2(30), 21 | first_name varchar2(30), 22 | constraint person_pk primary key(id) 23 | ); 24 | 25 | 26 | -- Load person data from the name_data table 27 | -- Note: We want the id to be sequential so 28 | -- we don't have a sequence for this one 29 | -- instead we'll use rownum 30 | 31 | INSERT /*+ APPEND */ INTO person(id, full_name, last_name, first_name) 32 | SELECT rownum 33 | ,first.name || ' ' || last.name 34 | ,last.name 35 | ,first.name 36 | FROM name_data first, name_data last 37 | WHERE first.name_type != 'LAST' 38 | AND last.name_type = 'LAST'; 39 | 40 | commit; 41 | 42 | 43 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/player.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create sequence player_seq 18 | start with 1 increment by 10 cache 20; 19 | 20 | create table player 21 | (id number NOT NULL, 22 | sport_team_id NUMBER NOT NULL 23 | constraint sport_team_fk references sport_team(id), 24 | last_name VARCHAR2(30), 25 | first_name varchar2(30), 26 | full_name varchar2(30), 27 | constraint player_pk primary key(id) 28 | ); 29 | 30 | CREATE or replace TRIGGER player_id_trg 31 | BEFORE INSERT ON player 32 | FOR EACH ROW 33 | DECLARE 34 | BEGIN 35 | IF( :new.id IS NULL ) 36 | THEN 37 | :new.id := player_seq.nextval; 38 | END IF; 39 | END; 40 | / 41 | 42 | 43 | 44 | -- Load MLB Data 45 | CREATE or replace PROCEDURE loadMLBPlayers AS 46 | t_id NUMBER; 47 | 48 | CURSOR mlb_players IS 49 | select distinct 50 | decode(TRIM(mlb_team_long),'Anaheim Angels', 'Los Angeles Angels',mlb_team_long) t_name 51 | ,TRIM(mlb_name) name 52 | ,substr(TRIM(mlb_name),1,instr(mlb_name,' ')) l_name 53 | ,substr(TRIM(mlb_name),instr(mlb_name,' ')) f_name 54 | from mlb_data; 55 | 56 | BEGIN 57 | FOR trec IN mlb_players LOOP 58 | SELECT id INTO t_id FROM sport_team 59 | WHERE sport_type_name = 'baseball' 60 | AND sport_league_short_name = 'MLB' 61 | AND name = trec.t_name; 62 | 63 | insert into player(sport_team_id, last_name, first_name, full_name) 64 | values(t_id, trec.l_name, trec.f_name, trec.name); 65 | END LOOP; 66 | END; 67 | / 68 | 69 | CREATE or replace PROCEDURE loadNFLPlayers AS 70 | t_id NUMBER; 71 | 72 | CURSOR nfl_players IS 73 | SELECT team 74 | ,name 75 | ,RTRIM(TRIM(SUBSTR(TRIM(name),1,instr(name,','))),',') l_name 76 | ,TRIM(LTRIM(TRIM(SUBSTR(TRIM(name),instr(name,','))),',')) f_name 77 | FROM nfl_data; 78 | BEGIN 79 | FOR prec IN nfl_players LOOP 80 | SELECT id INTO t_id FROM sport_team 81 | WHERE sport_type_name = 'football' 82 | AND sport_league_short_name = 'NFL' 83 | AND abbreviated_name = prec.team; 84 | 85 | insert into player(sport_team_id, last_name, first_name, full_name) 86 | values(t_id, prec.l_name, prec.f_name, prec.name); 87 | 88 | END LOOP; 89 | END; 90 | / 91 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/public_synonyms.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create or replace public synonym PERSON for DMS_SAMPLE.PERSON; 18 | create or replace public synonym PLAYER for DMS_SAMPLE.PLAYER; 19 | create or replace public synonym SEAT for DMS_SAMPLE.SEAT; 20 | create or replace public synonym SEAT_TYPE for DMS_SAMPLE.SEAT_TYPE; 21 | create or replace public synonym SPORTING_EVENT for DMS_SAMPLE.SPORTING_EVENT; 22 | create or replace public synonym SPORTING_EVENT_TICKET for DMS_SAMPLE.SPORTING_EVENT_TICKET; 23 | create or replace public synonym SPORT_DIVISION for DMS_SAMPLE.SPORT_DIVISION; 24 | create or replace public synonym SPORT_LEAGUE for DMS_SAMPLE.SPORT_LEAGUE; 25 | create or replace public synonym SPORT_LOCATION for DMS_SAMPLE.SPORT_LOCATION; 26 | create or replace public synonym SPORT_TEAM for DMS_SAMPLE.SPORT_TEAM; 27 | create or replace public synonym SPORT_TYPE for DMS_SAMPLE.SPORT_TYPE; 28 | create or replace public synonym TICKET_PURCHASE_HIST for DMS_SAMPLE.TICKET_PURCHASE_HIST; 29 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/seat_type.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table seat_type 18 | (name varchar2(15) NOT NULL, 19 | description varchar2(120), 20 | relative_quality NUMBER(2), 21 | constraint st_seat_type_pk primary key(name) 22 | ); 23 | 24 | insert into seat_type(name,description,relative_quality) 25 | values('luxury','Excellent seats - box seats, behind the plate, etc. etc.',1); 26 | insert into seat_type(name,description,relative_quality) 27 | values('premium','Really good seats - first level, mid field, etc. etc.',2); 28 | insert into seat_type(name,description,relative_quality) 29 | values('standard','Standard seats - not super awesome but pretty good',3); 30 | insert into seat_type(name,description,relative_quality) 31 | values('sub-standard','End zone, nose bleed, etc.',4); 32 | insert into seat_type(name,description,relative_quality) 33 | values('obstructed','Pretty crappy, partially obstructed seats',5); 34 | insert into seat_type(name,description,relative_quality) 35 | values('standing','Really? That''s not a seat at all now, is it?',10); 36 | 37 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/set_nfl_team_home_field.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | --- Must be run after teams are created and after sporting locations are created 18 | 19 | --------------------------------- 20 | -- Football Teams 21 | --------------------------------- 22 | DECLARE 23 | CURSOR nsd_cur IS 24 | SELECT sport_location_id, team 25 | FROM nfl_stadium_data; 26 | BEGIN 27 | FOR nrec IN nsd_cur LOOP 28 | UPDATE sport_team s 29 | SET s.home_field_id = nrec.sport_location_id 30 | WHERE s.name = nrec.team 31 | AND s.sport_league_short_name = 'NFL' 32 | AND s.sport_type_name = 'football'; 33 | END LOOP; 34 | END; 35 | / 36 | 37 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/sport_league.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table sport_league 18 | (sport_type_name varchar2(15) NOT NULL 19 | constraint sl_sport_type_fk references sport_type(name), 20 | short_name varchar2(10) NOT NULL, 21 | long_name varchar2(60) NOT NULL, 22 | description varchar2(120), 23 | constraint sport_league_pk primary key(short_name) 24 | ); 25 | 26 | insert into sport_league(sport_type_name,short_name,long_name,description) 27 | values('baseball','MLB','Major League Baseball','Professional baseball league in North America.'); 28 | 29 | insert into sport_league(sport_type_name,short_name,long_name,description) 30 | values('football','NFL','National Footbal League','Professional football league in North America.'); 31 | 32 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/sport_type.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table sport_type 18 | (name varchar2(15) NOT NULL, 19 | description varchar2(120), 20 | constraint sport_type_pk primary key(name) 21 | ); 22 | 23 | insert into sport_type(name,description) 24 | values('baseball','A sport with 9 players, bats, and balls - what could possibly go wrong?'); 25 | 26 | insert into sport_type(name,description) 27 | values('football','Teams of 11 players attempt to move an oblong ball 100 yards while beating the snot out of each other.'); 28 | 29 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/sporting_event.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create sequence sporting_event_seq 18 | start with 1 increment by 10 cache 20; 19 | 20 | create table sporting_event 21 | (id NUMBER NOT NULL, 22 | sport_type_name VARCHAR2(15) NOT NULL 23 | constraint se_sport_type_fk references sport_type(name), 24 | home_team_id NUMBER NOT NULL 25 | constraint se_home_team_id_fk references sport_team(id), 26 | away_team_id NUMBER NOT NULL 27 | constraint se_away_team_id_fk references sport_team(id), 28 | location_id NUMBER NOT NULL 29 | constraint se_location_id_fk references sport_location(id), 30 | start_date_time DATE NOT NULL, 31 | sold_out NUMBER(1) DEFAULT 0 NOT NULL, 32 | constraint chk_sold_out CHECK (sold_out IN (0,1)), 33 | constraint sporting_event_pk primary key(id) 34 | ); 35 | 36 | CREATE TRIGGER sporting_event_id_trg 37 | BEFORE INSERT ON sporting_event 38 | FOR EACH ROW 39 | DECLARE 40 | BEGIN 41 | IF( :new.id IS NULL ) 42 | THEN 43 | :new.id := sporting_event_seq.nextval; 44 | END IF; 45 | END; 46 | / 47 | 48 | 49 | create index se_start_date_fcn on sporting_event(TRUNC(start_date_time)); 50 | 51 | 52 | 53 | 54 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/sporting_event_info.vw: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create or replace view sporting_event_info as 18 | select e.id as event_id 19 | , e.sport_type_name sport 20 | , e.start_date_time event_date_time 21 | , h.name home_team 22 | , a.name away_team 23 | , l.name location 24 | , l.city city 25 | from sporting_event e, sport_team h, sport_team a, sport_location l 26 | where e.home_team_id = h.id 27 | and e.away_team_id = a.id 28 | and e.location_id = l.id 29 | / 30 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/sporting_event_ticket.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create sequence sporting_event_ticket_seq 18 | start with 1 increment by 10 cache 100; 19 | 20 | create table sporting_event_ticket 21 | ( id NUMBER NOT NULL, 22 | sporting_event_id NUMBER NOT NULL 23 | constraint set_sporting_event_fk references sporting_event(id), 24 | sport_location_id NUMBER NOT NULL, 25 | seat_level NUMBER(1) NOT NULL, 26 | seat_section VARCHAR(15) NOT NULL, 27 | seat_row VARCHAR2(10) NOT NULL, 28 | seat VARCHAR2(10) NOT NULL, 29 | ticketholder_id NUMBER 30 | constraint set_person_id references person(id), 31 | ticket_price NUMBER(8,2) NOT NULL, 32 | constraint set_seat_fk foreign key (sport_location_id,seat_level,seat_section,seat_row, seat) 33 | references seat(sport_location_id,seat_level,seat_section,seat_row,seat), 34 | constraint sporting_event_ticket_pk primary key(id) 35 | ); 36 | 37 | 38 | create index set_sporting_event_idx on sporting_event_ticket(sporting_event_id); 39 | 40 | create index set_seat_idx on sporting_event_ticket(sport_location_id,seat_level,seat_section,seat_row,seat); 41 | 42 | create index set_ticketholder_idx on sporting_event_ticket(ticketholder_id); 43 | 44 | create index set_ev_id_tkholder_id_idx on sporting_event_ticket(sporting_event_id,ticketholder_id,''); -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/ticket_info.vw: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create or replace view sporting_event_ticket_info as 18 | select t.id as ticket_id 19 | ,e.event_id 20 | ,e.sport 21 | ,e.event_date_time 22 | ,e.home_team 23 | ,e.away_team 24 | ,e.location 25 | ,e.city 26 | ,t.seat_level 27 | ,t.seat_section 28 | ,t.seat_row 29 | ,t.seat 30 | ,t.ticket_price 31 | ,p.full_name as ticketholder 32 | from sporting_event_info e 33 | , sporting_event_ticket t 34 | , person p 35 | where t.sporting_event_id = e.event_id 36 | and t.ticketholder_id = p.id (+) 37 | / 38 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/schema/ticket_purchase_hist.tab: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | create table ticket_purchase_hist 18 | ( sporting_event_ticket_id NUMBER NOT NUll 19 | constraint tph_sport_event_tic_id references sporting_event_ticket(id) 20 | ,purchased_by_id NUMBER NOT NULL 21 | constraint tph_ticketholder_id references person(id) 22 | ,transaction_date_time DATE NOT NULL 23 | ,transferred_from_id NUMBER 24 | constraint tph_transfer_from_id references person(id) 25 | ,purchase_price NUMBER(8,2) NOT NULL 26 | ,constraint ticket_purchase_hist_pk primary key(sporting_event_ticket_id, purchased_by_id, transaction_date_time) 27 | ); 28 | 29 | create index tph_purch_by_id on ticket_purchase_hist(purchased_by_id); 30 | create index tph_trans_from_id on ticket_purchase_hist(transferred_from_id); 31 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/README.txt: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- File in this directory are used to create and manage user accounts 3 | ------------------------------ 4 | 5 | -- The following files create the user dms_user and grant the privileges 6 | -- necessary to access the data from DMS or the SCT 7 | 8 | create_dms_user.sql 9 | dms_user_privileges.sql 10 | dms_user_sct_privileges.sql 11 | 12 | -- The following files create the user dms_sample and grant the privileges 13 | -- necessary to create the objects that make up this sample database. 14 | -- Additionally dms_sample_dms_user_grants.sql grants privileges 15 | -- necessary to access these objects to the user dms_user 16 | 17 | create_dms_sample.sql 18 | dms_sample_dms_user_grants.sql 19 | dms_sample_privileges.sql 20 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/create_dms_sample.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | -------------------------------------------------------- 19 | -- 20 | -- Create the user dms_sample 21 | -- 22 | -------------------------------------------------------- 23 | create user dms_sample identified by dms_sample; 24 | grant CREATE SESSION to dms_sample; 25 | grant resource to dms_sample; 26 | grant create table to dms_sample; 27 | grant create sequence to dms_sample; 28 | grant create procedure to dms_sample; 29 | grant create trigger to dms_sample; 30 | grant create view to dms_sample; 31 | grant create synonym to dms_sample; 32 | grant create public synonym to dms_sample; 33 | grant drop public synonym to dms_sample; 34 | grant execute on dbms_lock to dms_sample; 35 | 36 | alter user dms_sample default tablespace users; 37 | alter user dms_sample quota unlimited on users; 38 | 39 | alter user dms_sample temporary tablespace temp; 40 | 41 | -------------------------------------------------------- 42 | -- 43 | -- required for the schema conversion tool 44 | -- 45 | -------------------------------------------------------- 46 | grant select_catalog_role to dms_sample; 47 | grant select any dictionary to dms_sample; 48 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/create_dms_user.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | --------------------------------------------------------- 19 | -- 20 | -- The following creates a user dms_user to which 21 | -- we will grant all privileges necessary to use DMS to migrate 22 | -- tables and data from the dms_sample schema 23 | -- 24 | --------------------------------------------------------- 25 | 26 | create user dms_user identified by dms_user; 27 | 28 | grant CREATE SESSION to dms_user; 29 | grant connect to dms_user; 30 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_sample_dms_user_grants.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | DECLARE 19 | CURSOR tabcur IS 20 | SELECT table_name 21 | FROM user_tables; 22 | BEGIN 23 | FOR trec IN tabcur LOOP 24 | EXECUTE IMMEDIATE 'grant select on dms_sample.' || trec.table_name || ' to DMS_USER'; 25 | EXECUTE IMMEDIATE 'grant alter on dms_sample.' || trec.table_name || ' to DMS_USER'; 26 | 27 | END LOOP; 28 | END; 29 | / 30 | 31 | 32 | 33 | /*grant execute on ticketManagement to dms_user; 34 | create or replace public synonym ticketmanagement for dms_sample.ticketmanagement; 35 | */ 36 | 37 | create or replace public synonym ticket_management for dms_sample.ticketManagement; 38 | grant execute on ticket_management to dms_user; 39 | 40 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_sample_privileges.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | grant SELECT ANY TRANSACTION to dms_sample; 19 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$ARCHIVED_LOG','DMS_SAMPLE'); 20 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOG','DMS_SAMPLE'); 21 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGFILE','DMS_SAMPLE'); 22 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$DATABASE','DMS_SAMPLE'); 23 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$THREAD','DMS_SAMPLE'); 24 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$PARAMETER','DMS_SAMPLE'); 25 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$NLS_PARAMETERS','DMS_SAMPLE'); 26 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$TIMEZONE_NAMES','DMS_SAMPLE'); 27 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$TRANSACTION','DMS_SAMPLE'); 28 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_OBJECTS','DMS_SAMPLE'); 29 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_TABLES','DMS_SAMPLE'); 30 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_REGISTRY','DMS_SAMPLE'); 31 | exec rdsadmin.rdsadmin_util.grant_sys_object('OBJ$','DMS_SAMPLE'); 32 | grant SELECT on ALL_INDEXES to dms_sample; 33 | grant SELECT on ALL_OBJECTS to dms_sample; 34 | grant SELECT on ALL_TABLES to dms_sample; 35 | grant SELECT on ALL_USERS to dms_sample; 36 | grant SELECT on ALL_CATALOG to dms_sample; 37 | grant SELECT on ALL_CONSTRAINTS to dms_sample; 38 | grant SELECT on ALL_CONS_COLUMNS to dms_sample; 39 | grant SELECT on ALL_TAB_COLS to dms_sample; 40 | grant SELECT on ALL_IND_COLUMNS to dms_sample; 41 | grant SELECT on ALL_LOG_GROUPS to dms_sample; 42 | 43 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_TABLESPACES','DMS_SAMPLE'); 44 | grant SELECT on ALL_TAB_PARTITIONS to dms_sample; 45 | exec rdsadmin.rdsadmin_util.grant_sys_object('ALL_ENCRYPTED_COLUMNS','DMS_SAMPLE'); 46 | grant SELECT on ALL_VIEWS to dms_sample; 47 | 48 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBMS_LOGMNR','DMS_SAMPLE'); 49 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGMNR_LOGS','DMS_SAMPLE'); 50 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGMNR_CONTENTS','DMS_SAMPLE'); 51 | grant logmining to dms_sample; 52 | 53 | 54 | 55 | 56 | 57 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_sample_privileges_onprem.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | grant SELECT ANY TRANSACTION to dms_sample; 19 | grant select on sys.V_$ARCHIVED_LOG to dms_sample; 20 | grant select on sys.V_$LOG to dms_sample; 21 | grant select on sys.V_$LOGFILE to dms_sample; 22 | grant select on sys.V_$DATABASE to dms_sample; 23 | grant select on sys.V_$THREAD to dms_sample; 24 | grant select on sys.V_$PARAMETER to dms_sample; 25 | grant select on sys.V_$NLS_PARAMETERS to dms_sample; 26 | grant select on sys.V_$TIMEZONE_NAMES to dms_sample; 27 | grant select on sys.V_$TRANSACTION to dms_sample; 28 | grant select on sys.DBA_OBJECTS to dms_sample; 29 | grant select on sys.DBA_REGISTRY to dms_sample; 30 | grant select on sys.OBJ$ to dms_sample; 31 | grant select on sys.DBA_TABLESPACES to dms_sample; 32 | grant select on sys.ALL_ENCRYPTED_COLUMNS to dms_sample; 33 | grant select on sys.DBMS_LOGMNR to dms_sample; 34 | grant select on sys.V_$LOGMNR_LOGS to dms_sample; 35 | grant execute on sys.DBMS_LOGMNR to dms_sample; 36 | grant SELECT on ALL_INDEXES to dms_sample; 37 | grant SELECT on ALL_OBJECTS to dms_sample; 38 | grant SELECT on ALL_TABLES to dms_sample; 39 | grant SELECT on ALL_USERS to dms_sample; 40 | grant SELECT on ALL_CATALOG to dms_sample; 41 | grant SELECT on ALL_CONSTRAINTS to dms_sample; 42 | grant SELECT on ALL_CONS_COLUMNS to dms_sample; 43 | grant SELECT on ALL_TAB_COLS to dms_sample; 44 | grant SELECT on ALL_IND_COLUMNS to dms_sample; 45 | grant SELECT on ALL_LOG_GROUPS to dms_sample; 46 | 47 | grant SELECT on ALL_TAB_PARTITIONS to dms_sample; 48 | grant SELECT on ALL_VIEWS to dms_sample; 49 | 50 | grant logmining to dms_sample; 51 | 52 | 53 | 54 | 55 | 56 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_user_privileges.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | --------------------------------------------------------- 19 | -- 20 | -- The following grants all privileges necessary for 21 | -- the user dms_user to use DMS to migrate 22 | -- tables and data from the dms_sample schema 23 | -- 24 | --------------------------------------------------------- 25 | #grant SELECT ANY TRANSACTION to dms_user; 26 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$ARCHIVED_LOG','DMS_USER'); 27 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOG','DMS_USER'); 28 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGFILE','DMS_USER'); 29 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$DATABASE','DMS_USER'); 30 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$THREAD','DMS_USER'); 31 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$PARAMETER','DMS_USER'); 32 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$NLS_PARAMETERS','DMS_USER'); 33 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$TIMEZONE_NAMES','DMS_USER'); 34 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$TRANSACTION','DMS_USER'); 35 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_OBJECTS','DMS_USER'); 36 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_REGISTRY','DMS_USER'); 37 | exec rdsadmin.rdsadmin_util.grant_sys_object('OBJ$','DMS_USER'); 38 | grant SELECT on ALL_INDEXES to dms_user; 39 | grant SELECT on ALL_OBJECTS to dms_user; 40 | grant SELECT on ALL_TABLES to dms_user; 41 | grant SELECT on ALL_USERS to dms_user; 42 | grant SELECT on ALL_CATALOG to dms_user; 43 | grant SELECT on ALL_CONSTRAINTS to dms_user; 44 | grant SELECT on ALL_CONS_COLUMNS to dms_user; 45 | grant SELECT on ALL_TAB_COLS to dms_user; 46 | grant SELECT on ALL_IND_COLUMNS to dms_user; 47 | grant SELECT on ALL_LOG_GROUPS to dms_user; 48 | 49 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBA_TABLESPACES','DMS_USER'); 50 | grant SELECT on ALL_TAB_PARTITIONS to dms_user; 51 | exec rdsadmin.rdsadmin_util.grant_sys_object('ALL_ENCRYPTED_COLUMNS','DMS_USER'); 52 | grant SELECT on ALL_VIEWS to dms_user; 53 | 54 | exec rdsadmin.rdsadmin_util.grant_sys_object('DBMS_LOGMNR','DMS_USER'); 55 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGMNR_LOGS','DMS_USER'); 56 | exec rdsadmin.rdsadmin_util.grant_sys_object('V_$LOGMNR_CONTENTS','DMS_USER'); 57 | grant logmining to dms_user; 58 | 59 | -- for use with SCT 60 | grant SELECT ANY DICTIONARY to dms_user 61 | 62 | 63 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_user_privileges_onprem.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | --------------------------------------------------------- 19 | -- 20 | -- The following grants all privileges necessary for 21 | -- the user dms_user to use DMS to migrate 22 | -- tables and data from the dms_sample schema 23 | -- 24 | --------------------------------------------------------- 25 | grant SELECT ANY TRANSACTION to dms_user; 26 | grant select on sys.V_$ARCHIVED_LOG to dms_user; 27 | grant select on sys.V_$LOG to dms_user; 28 | grant select on sys.V_$LOGFILE to dms_user; 29 | grant select on sys.V_$DATABASE to dms_user; 30 | grant select on sys.V_$THREAD to dms_user; 31 | grant select on sys.V_$PARAMETER to dms_user; 32 | grant select on sys.V_$NLS_PARAMETERS to dms_user; 33 | grant select on sys.V_$TIMEZONE_NAMES to dms_user; 34 | grant select on sys.V_$TRANSACTION to dms_user; 35 | grant select on sys.DBA_OBJECTS to dms_user; 36 | grant select on sys.DBA_REGISTRY to dms_user; 37 | grant select on sys.OBJ$ to dms_user; 38 | grant select on sys.DBA_TABLESPACES to dms_user; 39 | grant select on sys.ALL_ENCRYPTED_COLUMNS to dms_user; 40 | grant select on sys.DBMS_LOGMNR to dms_user; 41 | grant select on sys.V_$LOGMNR_LOGS to dms_user; 42 | grant execute on sys.DBMS_LOGMNR to dms_user; 43 | 44 | grant SELECT on ALL_INDEXES to dms_user; 45 | grant SELECT on ALL_OBJECTS to dms_user; 46 | grant SELECT on ALL_TABLES to dms_user; 47 | grant SELECT on ALL_USERS to dms_user; 48 | grant SELECT on ALL_CATALOG to dms_user; 49 | grant SELECT on ALL_CONSTRAINTS to dms_user; 50 | grant SELECT on ALL_CONS_COLUMNS to dms_user; 51 | grant SELECT on ALL_TAB_COLS to dms_user; 52 | grant SELECT on ALL_IND_COLUMNS to dms_user; 53 | grant SELECT on ALL_LOG_GROUPS to dms_user; 54 | 55 | grant SELECT on ALL_TAB_PARTITIONS to dms_user; 56 | grant SELECT on ALL_VIEWS to dms_user; 57 | 58 | grant logmining to dms_user; 59 | 60 | -- for use with SCT 61 | grant SELECT ANY DICTIONARY to dms_user 62 | 63 | 64 | -------------------------------------------------------------------------------- /oracle/sampledb/v1/user/dms_user_sct_privileges.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | grant connect to dms_user; 18 | grant select_catalog_role to dms_user; 19 | grant select any dictionary to dms_user; 20 | -------------------------------------------------------------------------------- /sampledb.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/sampledb.pdf -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/data/master.csv: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/sqlserver/sampledb/v1/data/master.csv -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/remove-sampledb.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | print('Removing database dms_sample and login dms_user...') 19 | go 20 | 21 | PRINT(CONCAT('Start: ',CURRENT_TIMESTAMP)); 22 | GO 23 | 24 | print('Removing replication...') 25 | go 26 | 27 | USE [dms_sample] 28 | EXEC sp_removedbreplication @dbname=[dms_sample] 29 | GO 30 | 31 | print('Removing jobs...') 32 | go 33 | 34 | USE msdb 35 | BEGIN TRY 36 | DECLARE @jid VARCHAR(200); 37 | DECLARE @J_CUR CURSOR; 38 | SET @J_CUR = CURSOR FOR 39 | SELECT s.job_id 40 | FROM msdb..sysjobs s 41 | WHERE SUSER_SNAME(s.owner_sid) = 'dms_user'; 42 | 43 | OPEN @J_CUR; 44 | FETCH @J_CUR INTO @jid; 45 | WHILE @@FETCH_STATUS = 0 46 | BEGIN 47 | EXEC sp_delete_job @job_id = @jid; 48 | FETCH @J_CUR INTO @jid; 49 | END; 50 | PRINT('All jobs owned by dms_user have been deleted...') 51 | END TRY 52 | BEGIN CATCH 53 | PRINT('ERROR: Unable to delete all jobs..') 54 | END CATCH; 55 | go 56 | 57 | Print('Removing user: dms_user...') 58 | GO 59 | 60 | USE dms_sample; 61 | drop user dms_user; 62 | go 63 | 64 | Print('Removing database: dms_sample...') 65 | GO 66 | 67 | USE master; 68 | ALTER DATABASE dms_sample SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 69 | DROP DATABASE dms_sample; 70 | go 71 | 72 | Print('Removing login: dms_user...') 73 | GO 74 | 75 | drop login dms_user; 76 | go 77 | 78 | Print('Removing dms_sample backup devices...') 79 | EXEC sp_dropdevice 'dms_sample_backup'; 80 | EXEC sp_dropdevice 'dms_sample_log'; 81 | 82 | 83 | PRINT(CONCAT('Complete: ',CURRENT_TIMESTAMP)); 84 | GO 85 | 86 | Print('..... Done .....') 87 | GO 88 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/create_dms_sample.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | print('Creating database dms_sample...'); 19 | go 20 | 21 | create database dms_sample; 22 | go 23 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/generateTicketActivity.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | drop procedure generateTicketActivity; 19 | go 20 | 21 | create procedure generateTicketActivity(@max_transactions INT = 1000) as 22 | BEGIN TRY 23 | DECLARE @min_person_id INT; 24 | DECLARE @max_person_id INT; 25 | DECLARE @open_events TABLE (rownum INT NOT NULL PRIMARY KEY CLUSTERED, id BIGINT); 26 | DECLARE @min_row INT; 27 | DECLARE @max_row INT; 28 | DECLARE @target_row INT; 29 | DECLARE @event_id BIGINT; 30 | DECLARE @target_person_id INT; 31 | DECLARE @person_id INT; 32 | DECLARE @quantity INT; 33 | DECLARE @current_txn INT = 0; 34 | DECLARE @reset_events INT = 1; 35 | 36 | SELECT @min_person_id = MIN(id), @max_person_id = MAX(id) from person; 37 | 38 | WHILE @current_txn < @max_transactions 39 | BEGIN 40 | IF @reset_events = 1 41 | BEGIN 42 | DELETE FROM @open_events; 43 | INSERT INTO @open_events 44 | SELECT ROW_NUMBER() OVER (order by start_date), id FROM sporting_event WHERE sold_out <> 1 ORDER BY start_date; 45 | SELECT @min_row = min(rownum), @max_row = max(rownum) FROM @open_events; 46 | SET @reset_events = 0; 47 | END; 48 | 49 | SET @target_row = dbo.rand_int(@min_row, @max_row); 50 | select @event_id = id from @open_events where rownum = @target_row; 51 | 52 | SET @target_person_id = dbo.rand_int(@min_person_id, @max_person_id); 53 | select @person_id = MIN(id) from person where id > @target_person_id-1; 54 | 55 | SET @quantity = dbo.rand_int(1,6); 56 | 57 | BEGIN TRY 58 | exec dbo.sellTickets @person_id, @event_id, @quantity; 59 | SET @current_txn = @current_txn +1; 60 | -- WAITFOR DELAY '00:00:00.01'; /* we can add this in the future if needed. */ 61 | PRINT(CONCAT('event:',@event_id, ' person:', @person_id,' quantity: ',@quantity)); 62 | END TRY 63 | BEGIN CATCH 64 | SET @reset_events = 1; -- If we fail to sell tickets to this event, we reload the open events table as this one is sold out 65 | END CATCH 66 | 67 | END; 68 | END TRY 69 | BEGIN CATCH 70 | PRINT('Error: Uable to generate tickets...'); 71 | END CATCH; 72 | 73 | go 74 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/generateTransferActivity.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | create procedure generateTransferActivity(@max_transactions INT) as 19 | BEGIN TRY 20 | DECLARE @txn_count INT = 0; 21 | DECLARE @min_tik_id BIGINT; 22 | DECLARE @max_tik_id BIGINT; 23 | DECLARE @tik_id BIGINT; 24 | DECLARE @max_p_id INT; 25 | DECLARE @min_p_id INT; 26 | DECLARE @person_id INT; 27 | DECLARE @rand_p_max INT 28 | DECLARE @rand_max BIGINT; 29 | DECLARE @xfer_all BIT = 1; 30 | DECLARE @price SMALLMONEY; 31 | DECLARE @price_multiplier DECIMAL = 1; 32 | 33 | -- get max and min ticket ids 34 | SELECT @min_tik_id = min(sporting_event_ticket_id) 35 | ,@max_tik_id = max(sporting_event_ticket_id) 36 | FROM ticket_purchase_hist; 37 | 38 | -- get max and min person ids 39 | SELECT @min_p_id = min(id), @max_p_id = max(id) FROM person; 40 | 41 | print(concat('max t: ',@max_tik_id,' min t: ', @min_tik_id, 'max p: ',@max_p_id,' min p: ', @min_p_id)); 42 | 43 | WHILE @txn_count < @max_transactions 44 | BEGIN 45 | -- find a random upper bound for ticket and person ids 46 | SET @rand_max = dbo.rand_int(@min_tik_id, @max_tik_id); 47 | SET @rand_p_max = dbo.rand_int(@min_p_id, @max_p_id); 48 | 49 | SELECT @tik_id = MAX(sporting_event_ticket_id) 50 | FROM ticket_purchase_hist 51 | WHERE sporting_event_ticket_id <= @rand_max; 52 | 53 | SELECT @person_id = MAX(id) FROM person WHERE id <= @rand_p_max; 54 | 55 | -- 80% of the time transfer all tickets, 20% of the time don't 56 | IF (dbo.rand_int(1,5) = 5 ) 57 | SET @xfer_all = 0; 58 | 59 | -- 30% of the time change the price by up to 20% in either direction 60 | IF (dbo.rand_int(1,3) = 1) 61 | SET @price_multiplier = CAST(dbo.rand_int(8,12) as DECIMAL)/10; 62 | 63 | SELECT @price = @price_multiplier*ticket_price 64 | FROM sporting_event_ticket 65 | WHERE id = @tik_id; 66 | 67 | PRINT(CONCAT('Ticket to transfer: ', @tik_id, ' Transfer to person id: ' , @person_id, ' All tickets?: ',@xfer_all, ' price: ', @price)); 68 | 69 | exec dbo.transferTicket @tik_id, @person_id, @xfer_all, @price ; 70 | 71 | 72 | -- reset some variables 73 | SET @txn_count = @txn_count + 1; 74 | SET @xfer_all = 1; 75 | SET @price_multiplier = 1; 76 | 77 | 78 | END; 79 | END TRY 80 | BEGIN CATCH 81 | PRINT('Sorry, not tickets are available for transfer.'); 82 | END CATCH; 83 | 84 | go 85 | 86 | 87 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/generate_tickets.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | -- drop procedure dbo.generate_tickets; 19 | create procedure generate_tickets(@event_id BIGINT) as 20 | BEGIN 21 | DECLARE @e_id BIGINT; 22 | DECLARE @loc_id INT; 23 | DECLARE @event_cur CURSOR; 24 | SET @event_cur = CURSOR FOR 25 | SELECT id, location_id 26 | FROM sporting_event 27 | WHERE id = @event_id; 28 | 29 | 30 | -- randomly generated standard price between 30 and 50 dollars 31 | DECLARE @standard_price SMALLMONEY = ROUND(ABS(CHECKSUM(NewId())) % 20 + 30 + rand(),2); 32 | 33 | OPEN @event_cur; 34 | FETCH @event_cur INTO @e_id, @loc_id; 35 | 36 | WHILE @@FETCH_STATUS = 0 37 | BEGIN 38 | INSERT INTO sporting_event_ticket(sporting_event_id,sport_location_id,seat_level,seat_section,seat_row,seat,ticket_price) 39 | SELECT sporting_event.id 40 | ,seat.sport_location_id 41 | ,seat.seat_level 42 | ,seat.seat_section 43 | ,seat.seat_row 44 | ,seat.seat 45 | ,(CASE 46 | WHEN seat.seat_type = 'luxury' THEN 3*@standard_price 47 | WHEN seat.seat_type = 'premium' THEN 2*@standard_price 48 | WHEN seat.seat_type = 'standard' THEN @standard_price 49 | WHEN seat.seat_type = 'sub-standard' THEN 0.8*@standard_price 50 | WHEN seat.seat_type = 'obstructed' THEN 0.5*@standard_price 51 | WHEN seat.seat_type = 'standing' THEN 0.5*@standard_price 52 | END ) ticket_price 53 | FROM sporting_event 54 | ,seat 55 | WHERE sporting_event.location_id = seat.sport_location_id 56 | AND sporting_event.id = @e_id; 57 | 58 | FETCH @event_cur INTO @e_id, @loc_id; 59 | END; 60 | 61 | END; 62 | 63 | go 64 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/getNewId.vw: -------------------------------------------------------------------------------- 1 | create view getNewID as select newid() as new_id; 2 | go -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/load_mlb_tickets.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | BEGIN 19 | DECLARE @event_id BIGINT; 20 | DECLARE @event_cur CURSOR; 21 | SET @event_cur = CURSOR FOR 22 | SELECT id FROM sporting_event WHERE sport_type_name = 'baseball'; 23 | 24 | OPEN @event_cur; 25 | FETCH @event_cur INTO @event_id; 26 | 27 | WHILE @@FETCH_STATUS = 0 28 | BEGIN 29 | BEGIN TRANSACTION; 30 | EXEC generate_tickets @event_id; 31 | COMMIT TRANSACTION; 32 | FETCH @event_cur INTO @event_id; 33 | END; 34 | CLOSE @event_cur; 35 | DEALLOCATE @event_cur; 36 | END; 37 | 38 | go 39 | 40 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/load_nfl_tickets.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | BEGIN 19 | DECLARE @event_id BIGINT; 20 | DECLARE @event_cur CURSOR; 21 | SET @event_cur = CURSOR FOR 22 | SELECT id FROM sporting_event WHERE sport_type_name = 'football'; 23 | 24 | OPEN @event_cur; 25 | FETCH @event_cur INTO @event_id; 26 | 27 | WHILE @@FETCH_STATUS = 0 28 | BEGIN 29 | BEGIN TRANSACTION; 30 | EXEC generate_tickets @event_id; 31 | COMMIT TRANSACTION; 32 | FETCH @event_cur INTO @event_id; 33 | END; 34 | CLOSE @event_cur; 35 | DEALLOCATE @event_cur; 36 | END; 37 | 38 | go 39 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/mlb_data.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/aws-samples/aws-database-migration-samples/d3cc6ed393364af45883ab83dc3a057f90e46cc3/sqlserver/sampledb/v1/schema/mlb_data.sql -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/mlb_data.tab: -------------------------------------------------------------------------------- 1 | 2 | create table mlb_data(mlb_id INT, 3 | mlb_name VARCHAR(30), 4 | mlb_pos VARCHAR(30), 5 | mlb_team VARCHAR(30), 6 | mlb_team_long VARCHAR(30), 7 | bats VARCHAR(30), 8 | throws VARCHAR(30), 9 | birth_year VARCHAR(30), 10 | bp_id INT, 11 | bref_id VARCHAR(30), 12 | bref_name VARCHAR(30), 13 | cbs_id VARCHAR(30), 14 | cbs_name VARCHAR(30), 15 | cbs_pos VARCHAR(30), 16 | espn_id INT, 17 | espn_name VARCHAR(30), 18 | espn_pos VARCHAR(30), 19 | fg_id VARCHAR(30), 20 | fg_name VARCHAR(30), 21 | lahman_id VARCHAR(30), 22 | nfbc_id INT, 23 | nfbc_name VARCHAR(30), 24 | nfbc_pos VARCHAR(30), 25 | retro_id VARCHAR(30), 26 | retro_name VARCHAR(30), 27 | debut VARCHAR(30), 28 | yahoo_id INT, 29 | yahoo_name VARCHAR(30), 30 | yahoo_pos VARCHAR(30), 31 | mlb_depth VARCHAR(30)); 32 | 33 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/name_data.tab: -------------------------------------------------------------------------------- 1 | 2 | create table name_data( 3 | name_type VARCHAR(15) NOT NULL, 4 | name VARCHAR(45) NOT NULL, 5 | constraint name_data_pk primary key(name_type, name) 6 | ); 7 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/nfl_data.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table nfl_data( 4 | Position varchar(5), 5 | player_number INT, 6 | Name varchar(40), 7 | status varchar(10), 8 | stat1 varchar(10), 9 | stat1_val varchar(10), 10 | stat2 varchar(10), 11 | stat2_val varchar(10), 12 | stat3 varchar(10), 13 | stat3_val varchar(10), 14 | stat4 varchar(10), 15 | stat4_val varchar(10), 16 | team varchar(10) 17 | ); 18 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/nfl_stadium_data.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table nfl_stadium_data( 4 | stadium varchar(60), 5 | seating_capacity INT, 6 | location varchar(40), 7 | surface varchar(80), 8 | roof varchar(30), 9 | team varchar(40), 10 | opened varchar(10), 11 | sport_location_id INT 12 | ); 13 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/person.tab: -------------------------------------------------------------------------------- 1 | 2 | create table person 3 | (ID int IDENTITY(1,1) NOT NULL, 4 | full_name varchar(60) NOT NULL, 5 | last_name varchar(30), 6 | first_name varchar(30), 7 | constraint person_pk primary key(id) 8 | ); 9 | 10 | 11 | INSERT INTO person(full_name, last_name, first_name) 12 | SELECT CONCAT(first.name,' ',last.name) 13 | ,last.name 14 | ,first.name 15 | FROM name_data first, name_data last 16 | WHERE first.name_type != 'LAST' 17 | AND last.name_type = 'LAST'; 18 | 19 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/player.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table player 4 | (id INT IDENTITY(1,1) NOT NULL, 5 | sport_team_id INT NOT NULL 6 | constraint sport_team_fk references sport_team(id), 7 | last_name VARCHAR(30), 8 | first_name varchar(30), 9 | full_name varchar(30), 10 | constraint player_pk primary key(id) 11 | ); 12 | 13 | go 14 | 15 | 16 | -- Load MLB Data 17 | CREATE PROCEDURE loadMLBPlayers AS 18 | DECLARE @mlb_players CURSOR; 19 | DECLARE @sport_team_id INT; 20 | DECLARE @last_name VARCHAR(30); 21 | DECLARE @first_name VARCHAR(30); 22 | DECLARE @full_name VARCHAR(30); 23 | DECLARE @team_name VARCHAR(60); 24 | 25 | SET @mlb_players = CURSOR FOR 26 | select distinct 27 | CASE LTRIM(RTRIM(mlb_team_long)) 28 | WHEN 'Anaheim Angels' THEN 'Los Angeles Angels' 29 | ELSE LTRIM(RTRIM(mlb_team_long)) 30 | END as mlb_team_long 31 | ,LTRIM(RTRIM(mlb_name)) as name 32 | ,SUBSTRING(LTRIM(RTRIM(mlb_name)),1,CHARINDEX(' ',mlb_name)) as t_name 33 | ,SUBSTRING(LTRIM(RTRIM(mlb_name)),CHARINDEX(' ',mlb_name),LEN(mlb_name)) f_name 34 | from mlb_data; 35 | 36 | BEGIN 37 | 38 | OPEN @mlb_players 39 | FETCH NEXT 40 | FROM @mlb_players INTO @team_name, @last_name, @first_name, @full_name; 41 | 42 | WHILE @@FETCH_STATUS = 0 43 | BEGIN 44 | 45 | SELECT @sport_team_id = id FROM sport_team 46 | WHERE sport_type_name = 'baseball' 47 | AND sport_league_short_name = 'MLB' 48 | AND name = @team_name; 49 | 50 | insert into player(sport_team_id, last_name, first_name, full_name) 51 | values(@sport_team_id, @last_name, @first_name, @full_name); 52 | 53 | FETCH NEXT 54 | FROM @mlb_players INTO @team_name, @last_name, @first_name, @full_name; 55 | END; 56 | CLOSE @mlb_players; 57 | DEALLOCATE @mlb_players; 58 | END; 59 | 60 | go 61 | 62 | CREATE PROCEDURE loadNFLPlayers AS 63 | DECLARE @nfl_players CURSOR; 64 | DECLARE @team VARCHAR(10); 65 | DECLARE @name VARCHAR(60); 66 | DECLARE @l_name VARCHAR(30); 67 | DECLARE @f_name VARCHAR(30); 68 | DECLARE @sport_team_id INT; 69 | SET @nfl_players = CURSOR FOR 70 | SELECT team 71 | ,name 72 | ,SUBSTRING(RTRIM(LTRIM(name)),1,CHARINDEX(',',name)-1) as l_name 73 | ,RTRIM(LTRIM(SUBSTRING(RTRIM(LTRIM(name)),CHARINDEX(',',name)+1,LEN(name)))) as f_name 74 | FROM nfl_data; 75 | 76 | BEGIN 77 | OPEN @nfl_players; 78 | FETCH NEXT 79 | FROM @nfl_players INTO @team, @name, @l_name, @f_name; 80 | 81 | WHILE @@FETCH_STATUS = 0 82 | BEGIN 83 | SELECT @sport_team_id = id FROM sport_team 84 | WHERE sport_type_name = 'football' 85 | AND sport_league_short_name = 'NFL' 86 | AND abbreviated_name = @team; 87 | 88 | insert into player(sport_team_id, last_name, first_name, full_name) 89 | values(@sport_team_id, @l_name, @f_name, @name); 90 | 91 | FETCH NEXT 92 | FROM @nfl_players INTO @team, @name, @l_name, @f_name; 93 | END; 94 | 95 | CLOSE @nfl_players; 96 | DEALLOCATE @nfl_players; 97 | END; 98 | 99 | go -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/rand_int.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | create function dbo.rand_int(@min INT, @max INT) RETURNS INT as 19 | BEGIN 20 | DECLARE @myid uniqueidentifier; 21 | select @myid = new_id from getNewID 22 | 23 | DECLARE @randint INT; 24 | SELECT @randint = ABS(Checksum(@myid) % (@max - @min +1)) + @min; 25 | RETURN(@randint) 26 | END; 27 | 28 | go 29 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/seat_type.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table seat_type 4 | (name varchar(15) NOT NULL, 5 | description varchar(120), 6 | relative_quality INTEGER, 7 | constraint st_seat_type_pk primary key(name) 8 | ); 9 | 10 | insert into seat_type(name,description,relative_quality) 11 | values('luxury','Excellent seats - box seats, behind the plate, etc. etc.',1); 12 | insert into seat_type(name,description,relative_quality) 13 | values('premium','Really good seats - first level, mid field, etc. etc.',2); 14 | insert into seat_type(name,description,relative_quality) 15 | values('standard','Standard seats - not super awesome but pretty good',3); 16 | insert into seat_type(name,description,relative_quality) 17 | values('sub-standard','End zone, nose bleed, etc.',4); 18 | insert into seat_type(name,description,relative_quality) 19 | values('obstructed','Pretty crappy, partially obstructed seats',5); 20 | insert into seat_type(name,description,relative_quality) 21 | values('standing','Really? That''s not a seat at all now, is it?',10); 22 | 23 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/set_nfl_team_home_field.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | 19 | BEGIN 20 | DECLARE @nsd_cur CURSOR; 21 | SET @nsd_cur = CURSOR FOR SELECT sport_location_id, team, location FROM nfl_stadium_data; 22 | DECLARE @sport_location_id INT; 23 | DECLARE @team VARCHAR(40); 24 | DECLARE @loc VARCHAR(40); 25 | 26 | OPEN @nsd_cur; 27 | FETCH NEXT FROM @nsd_cur INTO @sport_location_id, @team, @loc; 28 | 29 | WHILE @@FETCH_STATUS = 0 30 | BEGIN 31 | UPDATE s 32 | SET s.home_field_id = @sport_location_id 33 | FROM sport_team s 34 | WHERE s.name = @team 35 | AND s.sport_league_short_name = 'NFL' 36 | AND s.sport_type_name = 'football'; 37 | 38 | FETCH NEXT FROM @nsd_cur INTO @sport_location_id, @team, @loc; 39 | END; 40 | CLOSE @nsd_cur; 41 | DEALLOCATE @nsd_cur; 42 | END; 43 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sport_division.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table sport_division 4 | (sport_type_name varchar(15) NOT NULL 5 | constraint sd_sport_type_fk references sport_type(name), 6 | sport_league_short_name varchar(10) NOT NULL 7 | constraint sd_sport_league_fk references sport_league(short_name), 8 | short_name varchar(10) NOT NULL, 9 | long_name varchar(60), 10 | description varchar(120), 11 | constraint sport_division_pk primary key(sport_type_name, sport_league_short_name, short_name) 12 | ); 13 | 14 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 15 | values('baseball','MLB','AL East','American League East','American League East'); 16 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 17 | values('baseball','MLB','AL Central','American League Central','American League Central'); 18 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 19 | values('baseball','MLB','AL West','American League West','American League West'); 20 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 21 | values('baseball','MLB','NL East','National League East','National League East'); 22 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 23 | values('baseball','MLB','NL Central','National League Central','National League Central'); 24 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 25 | values('baseball','MLB','NL West','National League West','National League West'); 26 | 27 | 28 | 29 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 30 | values('football','NFL','AFC East','American Football Conference East','American Football Conference East'); 31 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 32 | values('football','NFL','AFC West','American Football Conference West','American Football Conference West'); 33 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 34 | values('football','NFL','AFC North','American Football Conference North','American Football Conference North'); 35 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 36 | values('football','NFL','AFC South','American Football Conference South','American Football Conference South'); 37 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 38 | values('football','NFL','NFC East','National Football Conference East','National Football Conference East'); 39 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 40 | values('football','NFL','NFC West','National Football Conference West','National Football Conference West'); 41 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 42 | values('football','NFL','NFC North','National Football Conference North','National Football Conference North'); 43 | insert into sport_division(sport_type_name,sport_league_short_name,short_name,long_name,description) 44 | values('football','NFL','NFC South','National Football Conference South','National Football Conference South'); 45 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sport_league.tab: -------------------------------------------------------------------------------- 1 | 2 | create table sport_league 3 | (sport_type_name varchar(15) NOT NULL 4 | constraint sl_sport_type_fk references sport_type(name), 5 | short_name varchar(10) NOT NULL, 6 | long_name varchar(60) NOT NULL, 7 | description varchar(120), 8 | constraint sport_league_pk primary key(short_name) 9 | ); 10 | 11 | insert into sport_league(sport_type_name,short_name,long_name,description) 12 | values('baseball','MLB','Major League Baseball','Professional baseball league in North America.'); 13 | 14 | insert into sport_league(sport_type_name,short_name,long_name,description) 15 | values('football','NFL','National Footbal League','Professional football league in North America.'); 16 | 17 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sport_type.tab: -------------------------------------------------------------------------------- 1 | 2 | 3 | create table sport_type 4 | (name varchar(15) NOT NULL, 5 | description varchar(120), 6 | constraint sport_type_pk primary key(name) 7 | ); 8 | 9 | insert into sport_type(name,description) 10 | values('baseball','A sport with 9 players, bats, and balls - what could possibly go wrong?'); 11 | 12 | insert into sport_type(name,description) 13 | values('football','Teams of 11 players attempt to move an oblong ball 100 yards while beating the snot out of each other.'); 14 | 15 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sporting_event.tab: -------------------------------------------------------------------------------- 1 | 2 | create table sporting_event 3 | (id bigint IDENTITY(1,1) NOT NULL, 4 | sport_type_name VARCHAR(15) NOT NULL 5 | constraint se_sport_type_fk references sport_type(name), 6 | home_team_id INT NOT NULL 7 | constraint se_home_team_id_fk references sport_team(id), 8 | away_team_id INT NOT NULL 9 | constraint se_away_team_id_fk references sport_team(id), 10 | location_id INT NOT NULL 11 | constraint se_location_id_fk references sport_location(id), 12 | start_date_time DATETIME NOT NULL, 13 | start_date AS CONVERT(DATE,start_date_time), 14 | sold_out INT DEFAULT 0 NOT NULL, 15 | constraint chk_sold_out CHECK (sold_out IN (0,1)), 16 | constraint sporting_event_pk primary key(id) 17 | ) 18 | go 19 | 20 | create index se_start_date on sporting_event(start_date) 21 | go 22 | 23 | 24 | 25 | 26 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sporting_event_info.vw: -------------------------------------------------------------------------------- 1 | 2 | create view sporting_event_info as 3 | select e.id as event_id 4 | , e.sport_type_name sport 5 | , e.start_date_time event_date_time 6 | , h.name home_team 7 | , a.name away_team 8 | , l.name location 9 | , l.city city 10 | from sporting_event e, sport_team h, sport_team a, sport_location l 11 | where e.home_team_id = h.id 12 | and e.away_team_id = a.id 13 | and e.location_id = l.id; 14 | 15 | go -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/sporting_event_ticket.tab: -------------------------------------------------------------------------------- 1 | create table sporting_event_ticket 2 | ( id BIGINT IDENTITY(1,1) NOT NULL, 3 | sporting_event_id BIGINT NOT NULL 4 | constraint set_sporting_event_fk references sporting_event(id), 5 | sport_location_id INT NOT NULL, 6 | seat_level INT NOT NULL, 7 | seat_section VARCHAR(15) NOT NULL, 8 | seat_row VARCHAR(10) NOT NULL, 9 | seat VARCHAR(10) NOT NULL, 10 | ticketholder_id INT 11 | constraint set_person_id references person(id), 12 | ticket_price SMALLMONEY NOT NULL, 13 | constraint set_seat_fk foreign key (sport_location_id,seat_level,seat_section,seat_row, seat) 14 | references seat(sport_location_id,seat_level,seat_section,seat_row,seat), 15 | constraint sporting_event_ticket_pk primary key(id) 16 | ); 17 | 18 | 19 | create index set_sporting_event_idx on sporting_event_ticket(sporting_event_id); 20 | 21 | create index set_seat_idx on sporting_event_ticket(sport_location_id,seat_level,seat_section,seat_row,seat); 22 | 23 | create index set_ticketholder_idx on sporting_event_ticket(ticketholder_id); 24 | 25 | create index set_ev_id_tkholder_id_idx on sporting_event_ticket(sporting_event_id,ticketholder_id); -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/ticket_info.vw: -------------------------------------------------------------------------------- 1 | 2 | create view sporting_event_ticket_info as 3 | select t.id as ticket_id 4 | ,e.event_id 5 | ,e.sport 6 | ,e.event_date_time 7 | ,e.home_team 8 | ,e.away_team 9 | ,e.location 10 | ,e.city 11 | ,t.seat_level 12 | ,t.seat_section 13 | ,t.seat_row 14 | ,t.seat 15 | ,t.ticket_price 16 | ,p.full_name as ticketholder 17 | from sporting_event_ticket t 18 | JOIN sporting_event_info e ON t.sporting_event_id = e.event_id 19 | LEFT OUTER JOIN person p ON t.ticketholder_id = p.id; 20 | 21 | go -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/ticket_purchase_hist.tab: -------------------------------------------------------------------------------- 1 | 2 | create table ticket_purchase_hist 3 | ( sporting_event_ticket_id BIGINT NOT NUll 4 | constraint tph_sport_event_tic_id references sporting_event_ticket(id) 5 | ,purchased_by_id INT NOT NULL 6 | constraint tph_ticketholder_id references person(id) 7 | ,transaction_date_time DATETIME NOT NULL 8 | ,transferred_from_id INT 9 | constraint tph_transfer_from_id references person(id) 10 | ,purchase_price SMALLMONEY NOT NULL 11 | ,constraint ticket_purchase_hist_pk primary key(sporting_event_ticket_id, purchased_by_id, transaction_date_time) 12 | ); 13 | 14 | create index tph_purch_by_id on ticket_purchase_hist(purchased_by_id); 15 | create index tph_trans_from_id on ticket_purchase_hist(transferred_from_id); 16 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/schema/transferTicket.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | create procedure transferTicket(@ticket_id BIGINT, @new_ticketholder_id BIGINT, @transfer_all BIT = 0, @price SMALLMONEY) as 19 | BEGIN TRY 20 | DECLARE @last_txn_date DATETIME; 21 | DECLARE @old_ticketholder_id INT; 22 | DECLARE @sporting_event_ticket_id BIGINT; 23 | DECLARE @purchase_price SMALLMONEY; 24 | 25 | -- get the latest record of purchase for this particular tickeholder for that event 26 | -- note they could have purchsed, sold and repurchased the ticket 27 | SELECT @last_txn_date = max(h.transaction_date_time), 28 | @old_ticketholder_id = t.ticketholder_id 29 | FROM ticket_purchase_hist h 30 | ,sporting_event_ticket t 31 | WHERE t.id = @ticket_id 32 | AND h.purchased_by_id = t.ticketholder_id 33 | GROUP BY t.ticketholder_id; 34 | 35 | -- get all tickets purchased at the same time for that event by that ticketholder 36 | DECLARE @xfer_cur CURSOR; 37 | SET @xfer_cur = CURSOR FOR 38 | SELECT sporting_event_ticket_id, purchase_price 39 | FROM ticket_purchase_hist 40 | WHERE purchased_by_id = @old_ticketholder_id 41 | AND transaction_date_time = @last_txn_date 42 | AND ((sporting_event_ticket_id = @ticket_id) OR (@transfer_all = 1) ); 43 | 44 | OPEN @xfer_cur; 45 | FETCH @xfer_cur INTO @sporting_event_ticket_id, @purchase_price; 46 | 47 | WHILE @@FETCH_STATUS = 0 48 | BEGIN 49 | -- update the sporting event ticket with the new owner 50 | UPDATE sporting_event_ticket 51 | SET ticketholder_id = @new_ticketholder_id 52 | WHERE id = @sporting_event_ticket_id; 53 | 54 | -- record the transaction 55 | INSERT INTO ticket_purchase_hist(sporting_event_ticket_id, purchased_by_id, transferred_from_id, transaction_date_time, purchase_price) 56 | VALUES(@sporting_event_ticket_id, @new_ticketholder_id, @old_ticketholder_id, current_timestamp, ISNULL(@price,@purchase_price)); 57 | 58 | PRINT(CONCAT('Ticket id: ', @sporting_event_ticket_id, ' Original price: ', @purchase_price, ' Old Ticketholder: ',@old_ticketholder_id,' Txn Date: ', @last_txn_date)); 59 | 60 | FETCH @xfer_cur INTO @sporting_event_ticket_id, @purchase_price; 61 | END; 62 | 63 | CLOSE @xfer_cur; 64 | DEALLOCATE @xfer_cur; 65 | COMMIT; 66 | END TRY 67 | BEGIN CATCH 68 | END CATCH; 69 | 70 | go 71 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/show_server.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | :setvar DistPubServer @@SERVERNAME 18 | 19 | print($(DistPubServer)) 20 | go 21 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/system/dms_sample_backup.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | USE master; 19 | GO 20 | ALTER DATABASE dms_sample 21 | SET RECOVERY FULL; 22 | GO 23 | -- Create AdvWorksData and AdvWorksLog logical backup devices. 24 | USE master 25 | GO 26 | EXEC sp_addumpdevice 'disk', 'dms_sample_backup', 27 | 'C:\$(BACKUPDIR)\dms_sample.bak'; 28 | GO 29 | EXEC sp_addumpdevice 'disk', 'dms_sample_log', 30 | 'C:\$(BACKUPDIR)\dms_sample_log.bak'; 31 | GO 32 | 33 | -- Back up the full dms_sample database. 34 | BACKUP DATABASE dms_sample TO dms_sample_backup; 35 | GO 36 | -- Back up the dms_sample log. 37 | BACKUP LOG dms_sample 38 | TO dms_sample_log; 39 | GO 40 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/system/enable_replication.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | :setvar DistPubServer @@SERVERNAME 19 | 20 | 21 | -- This script uses sqlcmd scripting variables. They are in the form 22 | -- $(MyVariable). For information about how to use scripting variables 23 | -- on the command line and in SQL Server Management Studio, see the 24 | -- "Executing Replication Scripts" section in the topic 25 | -- "Programming Replication Using System Stored Procedures". 26 | 27 | -- Install the Distributor and the distribution database. 28 | DECLARE @distributor AS sysname; 29 | DECLARE @distributionDB AS sysname; 30 | DECLARE @publisher AS sysname; 31 | DECLARE @directory AS nvarchar(500); 32 | DECLARE @publicationDB AS sysname; 33 | -- Specify the Distributor name. 34 | SET @distributor = $(DistPubServer); 35 | -- Specify the distribution database. 36 | SET @distributionDB = N'distribution'; 37 | -- Specify the Publisher name. 38 | SET @publisher = $(DistPubServer); 39 | -- Specify the replication working directory. 40 | SET @directory = N'\\' + $(DistPubServer) + '\repldata'; 41 | -- Specify the publication database. 42 | SET @publicationDB = N'dms_sample'; 43 | 44 | -- Install the server MYDISTPUB as a Distributor using the defaults, 45 | -- including autogenerating the distributor password. 46 | USE master 47 | EXEC sp_adddistributor @distributor = @distributor; 48 | 49 | -- Create a new distribution database using the defaults, including 50 | -- using Windows Authentication. 51 | USE master 52 | EXEC sp_adddistributiondb @database = @distributionDB, 53 | @security_mode = 1; 54 | GO 55 | 56 | -- Create a Publisher and enable dms_sample for replication. 57 | -- Add MYDISTPUB as a publisher with MYDISTPUB as a local distributor 58 | -- and use Windows Authentication. 59 | DECLARE @distributionDB AS sysname; 60 | DECLARE @publisher AS sysname; 61 | -- Specify the distribution database. 62 | SET @distributionDB = N'distribution'; 63 | -- Specify the Publisher name. 64 | SET @publisher = $(DistPubServer); 65 | 66 | USE [distribution] 67 | EXEC sp_adddistpublisher @publisher=@publisher, 68 | @distribution_db=@distributionDB, 69 | @security_mode = 1; 70 | GO 71 | -------------------------------------------------------------------------------- /sqlserver/sampledb/v1/user/create_dms_user.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Copyright 2017 Amazon.com 3 | 4 | Licensed under the Apache License, Version 2.0 (the "License"); 5 | you may not use this file except in compliance with the License. 6 | You may obtain a copy of the License at 7 | 8 | http://www.apache.org/licenses/LICENSE-2.0 9 | 10 | Unless required by applicable law or agreed to in writing, software 11 | distributed under the License is distributed on an "AS IS" BASIS, 12 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 13 | See the License for the specific language governing permissions and 14 | limitations under the License. 15 | */ 16 | 17 | 18 | 19 | use master 20 | CREATE LOGIN dms_user WITH PASSWORD = 'dms_user', CHECK_POLICY = OFF, DEFAULT_DATABASE = dms_sample; 21 | GO 22 | EXEC master..sp_addsrvrolemember @loginame = N'dms_user', @rolename = N'sysadmin' 23 | GO 24 | 25 | Use dms_sample; 26 | GO 27 | 28 | IF NOT EXISTS (SELECT * FROM sys.database_principals WHERE name = N'dms_user') 29 | BEGIN 30 | CREATE USER [dms_user] FOR LOGIN [dms_user] 31 | use dms_sample 32 | EXEC sp_addrolemember N'db_owner', N'dms_user' 33 | END; 34 | GO 35 | --------------------------------------------------------------------------------