{ "cells": [ { "cell_type": "markdown", "metadata": {}, "source": [ "# Database Queries" ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "```{contents} Table of Contents\n", ":depth: 4\n", "```" ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "## Introduction: The History of the Structured Query Language (SQL)\n", "\n", "
\n", "\n", "The structured query language (SQL) was invented by Donald D. Chamberlin and Raymond F. Boyce in 1974. Chamberlain and Boyce were both young computer scientists working at the IBM T.J. Watson Research Center in Yorktown Heights, New York, and they met E. F. Codd at a research symposium that Codd organized there. Codd, four years prior, had published the [seminal article that defined the relational model](https://www.seas.upenn.edu/~zives/03f/cis550/codd.pdf) for databases. Codd's relational model is defined using relational algebra and relational calculus, two notational standards that Codd himself created to elaborate on set theory as applied specifically to data tables. One important property of set theory is that highly abstract mathematical expressions can be expressed in plain language. For example, consider the set $A$ of holidays in the United States during which banks are closed:\n", "\n", "$$ A = \\{\\text{New Year's Day}, \\text{Birthday of Martin Luther King, Jr.}, \\\\ \\text{Washington’s Birthday}, \\text{Memorial Day}, \\text{Independence Day}, \\\\ \\text{Labor Day}, \\text{Columbus Day}, \\text{Veterans Day}, \\\\ \\text{Thanksgiving Day}, \\text{Christmas}\\}$$\n", "\n", "Also consider the set $B$ of holidays in the United Kingdom during which banks are closed:\n", "\n", "$$ B = \\{\\text{New Year's Day}, \\text{Good Friday}, \\text{Easter Monday}, \\\\ \\text{Early May bank holiday}, \\text{Spring bank holiday}, \\\\\\text{Summer bank holiday}, \\text{Christmas}, \\text{Boxing Day}\\}$$\n", "\n", "The intersection between sets $A$ and $B$ is a set that consists of all elements that exist with both set $A$ and set $B$:\n", "\n", "$$ A \\cap B = \\{\\text{New Year's Day}, \\text{Christmas}\\}$$\n", "\n", "The notation $A\\cap B$ is a mathematical abstraction of an idea that can be expressed in plain-spoken language: $\\cap$ means \"and\", and $A\\cap B$ means $A$ *and* $B$, or all elements that are in both $A$ *and* $B$. Put another way, $A\\cap B$ is the set of all holidays during which banks are closed in both the United States *and* the United Kingdom. Likewise, every piece of set notation can be expressed semantically.\n", "\n", "Although Codd laid out the broad parameters of the relational model in mathematical terms, he did not design software or a physical architecture for a relational database. He explicitly left that work up to future research:\n", "\n", "> Many questions are raised and left unanswered. For example, only a few of the more important properties of the data sublanguage . . . are mentioned. Neither the purely linguistic details of such a language nor the implementation problems are discussed. Nevertheless, the material presented should be adequate for experienced systems programmers to visualize several approaches (p. 387).\n", "\n", "Chamberlin and Boyce took up the challenge of writing a programming language to implement Codd's relational model. [As Chamberlin explains](https://ieeexplore.ieee.org/document/6359709), their primary goal was to create a version of Codd's set-theoretical relational model that could be expressed in plain language:\n", "\n", "> The more difficult barrier was at the semantic level. The basic concepts of Codd's languages were adapted from set theory and symbolic logic. This was natural given Codd's background as a mathematician, but Ray and I hoped to design a relational language based on concepts that would be familiar to a wider population of users (p. 78).\n", "\n", "In short, the idea behind SQL is to implement Codd's abstract system of using logical statements with set theoretical notation to narrow down the specific records and features in a dataset that a user wishes to read or edit, but to phrase these operations in accessable, plain language. One of the best things about SQL is that once you are used to the language, it reads just like English. That said, Chamberlin admits that SQL \"has not proved to be as accessible to untrained users as Ray and I originally hoped\" ([p. 81](https://ieeexplore.ieee.org/document/6359709)).\n", "\n", "Another benefit of SQL is that this language is one of the most universal programming languages in existence. It is designed to work with database management systems on any platform, and it works seamlessly within Python, R, C, Java, Javascript, and so on. While the standards for languages and platforms change, SQL has been in continuous use for relational database management since the 1980s and shows no sign of becoming antiquated or being replaced. The SQL syntax exists outside of any individual DBMS, and is maintained by the [American National Standards Institute (ANSI)](https://en.wikipedia.org/wiki/American_National_Standards_Institute) and the [International Organization for Standardization (ISO)](https://en.wikipedia.org/wiki/International_Organization_for_Standardization), two non-profit organizations that facilitate the development of [voluntary consensus standards](https://en.wikipedia.org/wiki/Standardization) for things like programming languages and hardware. Despite the universality of SQL, however, different DBMSs use slightly different versions of SQL, adding some unique functionality in some cases, and failing to implement the entire SQL standard in others. MySQL for example [lacks the ability to perform a full join](https://stackoverflow.com/questions/4796872/how-to-do-a-full-outer-join-in-mysql). PostgreSQL distinguishes itself from other RDBMSs by striving to implement as much of the global SQL standard as possible. While there some important differences in the version of SQL used by different DBMSs, the differences generally apply to very specific situations and all implementations of SQL use mostly the same syntax and can do mostly the same work. " ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "### Declarative and Procedural Languages\n", "\n", "SQL is considered to be a [declarative language](https://en.wikipedia.org/wiki/Declarative_programming), which means that it defines the broad task that a particular computer system must carry out, but it does not define the mechanism through which the system completes the task. For example, SQL can tell a system to access two tables and join them together, but that command must tell a DBMS to access additional code that tells the system how exactly to search and operate on the rows and columns of each data table. A language that provides specific instructions to a system on how to carry out a task - by changing the system state in some way, including how the data exist in the system - is a [procedural language](https://en.wikipedia.org/wiki/Procedural_programming). The code that a procedural language uses to make these changes on the system is called [imperative code](https://en.wikipedia.org/wiki/Imperative_programming). A DBMS can be thought of as a function that takes declarative SQL code as an input, finds and runs the imperative code that carries out the declarative task, and returns the output. MySQL, for example, [uses imperative C and C++ code](https://dev.mysql.com/doc/refman/8.0/en/features.html) to carry out SQL queries." ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "### Popularity of SQL\n", "Common standards and the most popular programming languages and environments change all the time. It's an eternal struggle for data scientists as well as programmers of all kinds, and a matter of consistent anxiety. Presently, Python is the most widely used tool for data science, but will we all have to drop Python soon and [teach ourselves Julia](https://towardsdatascience.com/bye-bye-python-hello-julia-9230bff0df62)? \n", "\n", "In this context, it is stunning that SQL has been so widely used since the 1970s. According to a [Stack Overflow survey](https://insights.stackoverflow.com/survey/2017), SQL is the one of most widely used programming languages among the people who filled out the survey, second only to Javascript. Taking into account the high-tech biases in this specific sample, it is probably the case the SQL is more widely used than any other language mentioned in this survey. What accounts for this popularity?\n", "\n", "This [blog post](https://blog.sqlizer.io/posts/sql-43/) argues that SQL achieved this level of longevity because it came to prominence during a time in which many of the baseline standards for the development of computer systems were being invented. As more and more systems were developed in a way that depends on SQL, it became harder to change this standard. But SQL is also simple and highly functional because it is a semantic language that expresses set-theoetical and logical operations. As long as relational databases are used, there's not much functionality that can be added to a query language beyond these foundational mathematical operations, and whatever additional functionality is needed can be added to a version of SQL by a particular DBMS. There are also many different open source and proprietary DBMSs that all employ SQL, so different users can have a choice over many different DBMSs and platforms without having to learn a query language other than SQL.\n", "\n", "That said, there's much less of a reason to use SQL when the database is not organized according to the relational model. NoSQL databases have much more flexible schema in general, and can store the data in one big table or in as many tables as there are records, or even datapoints, in the database. In fact, without a relational schema, the notion of a data table makes less sense in general. For example, a document store is a collection of individual records encoded using JSON or XML, and not as tables. These records can be sharded: stored in many corresponding servers in a distributed system to address challenges with the size of the database and the speed with which database transactions are conducted. Without tables, NoSQL DBMSs do not usually use SQL. MongoDB, for example, works with queries that are themselves in JSON format." ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "## Create, Read, Update, and Delete (CRUD) Operations\n", "**Persistent storage** refers to a system in which [data outlives the process that created it](https://en.wikipedia.org/wiki/Persistence_(computer_science)). When you work with software that allows you to save a file, the file is stored in persistent storage because it still exists even after you close the software application. Hard drives are examples of persistent storage, as are local and remote servers that store databases. Any persistent storage mechanism must have methods for creating, reading (or loading), updating (or editing), and deleting the data in that storage device. Create, Read, Update, and Delete are the CRUD Operations.\n", "\n", "We've previously employed CRUD operations using the `requests` library to use an API or to do web scraping. Like `requests`, SQL and other query languages have CRUD operations. The following table, adapted from a similar one that appears on the [Wikipedia page for the CRUD operations](https://en.wikipedia.org/wiki/Create%2C_read%2C_update_and_delete), shows these operations in the `requests` package, SQL, and the MongoDB query language:\n", "\n", "|Operation|`requests` method|SQL|MongoDB|\n", "|:-|:-|:-|:-|\n", "|Create|`requests.put()` or `requests.post()`|`INSERT`|`Insert`|\n", "|Read|`requests.get()`|`SELECT`|`Find`|\n", "|Update|`requests.patch()`|`UPDATE`|`Update`|\n", "|Delete|`requests.delete()`|`DELETE`|`Remove`|\n", "\n", "As a data scientist, you will most often use read operations to obtain the data you need for your analysis. However, if you are collecting original data for your project, the create, update, and delete operations become much more important. We will discuss all four operations and their variants in the context of SQL and MongoDB below.\n", "\n", "We can work with SQL using `pandas` if we first create an engine that links to a specific DBMS, server, and database with `create_engine` from `sqlalchemy`. Once we do, the `pd.read_sql_query()` function makes read operations straightforward, and the `.execute()` method applied to the engine lets us easily issue create, update, and delete commands." ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "## SQL Style: Capitalization, Quotes, New Lines, Indentation\n", "There are many ways to write an SQL query, and when you look at someone else's SQL code you will see a variety of styles. Mostly, with the exception of quotes in some cases, stylistic differences don't change the behavior of the code, but they can have an impact on how easy the code is for other people to read and understand.\n", "\n", "One requirement for SQL code is that the query must end with a semi-colon, and that no semi-colons appear elsewhere in the query. As long as that requirement is met, other stylistic choices are possible.\n", "\n", "The least readable way to write an SQL query is to write the entire code on one line, with no capitalization or indentation. The following code is valid SQL code:\n", "```\n", "select t.id, t.column1, t.column2, t.column3, r.column4 from table1 t inner join table2 r on t.id = r.id where column1>100 order by column2 desc;\n", "```\n", "We will discuss exactly what this query does. But for now, let's focus on the presentation of code. SQL uses **clauses** to represent particular functions for reading and writing data. In the above query, `select`, `from`, `inner join`, `on`, `where`, and `order by` are all clauses, and `desc` is an option applied to the `order by` clause. \n", "\n", "One stylistic choice many people make is to write SQL clauses in capital letters. That helps readers to quickly see the parts of the code that are clauses as opposed to the rest of the code that contains column names, table names, values, and aliases. If we capitalize the clauses and options in the SQL query, it looks like this:\n", "```\n", "SELECT t.id, t.column1, t.column2, t.column3, r.column4 FROM table1 t INNER JOIN table2 r ON t.id = r.id WHERE column1>100 ORDER BY column2 DESC;\n", "```\n", "Another stylistic choice people make to present the code in a more reabable way is to put clauses that are considered distinct enough from other clauses on new lines. The one common exception is `FROM`, which is considered to be closely related to `SELECT` and is often written on the same line as `SELECT`. If we put each clause other than `FROM` on a new line, the query looks like this:\n", "```\n", "SELECT t.id, t.column1, t.column2, t.column3, r.column4 FROM table1 t \n", "INNER JOIN table2 r \n", "ON t.id = r.id \n", "WHERE column1>100 \n", "ORDER BY column2 DESC;\n", "```\n", "Some clauses are considered to be elaborations upon a previous clause. Column names after `SELECT` are usually written on the same line as `SELECT`, but if these columns themselves require functions that take up more space, it is useful to put them on new lines. Likewise, `ON` is considered an elaboration of `INNER JOIN`. These lines of code are often indented to express the dependence on the previous line. If we include indentation in the code, the query is\n", "```\n", "SELECT \n", " t.id, \n", " t.column1, \n", " t.column2, \n", " t.column3, \n", " r.column4 \n", "FROM table1 t \n", "INNER JOIN table2 r \n", " ON t.id = r.id \n", "WHERE column1>100 \n", "ORDER BY column2 DESC;\n", "```\n", "I encourage you to develop good habits with how you write the SQL queries, both for other people to read your code, but more importantly, to make it easier for you yourself to read your code. You will be spending a lot of time developing and debugging SQL queries, and anything you do that cuts down the time to understand your own code will save you a lot of time and frustration in the long-run.\n", "\n", "Quotes are only used in SQL code when referring to values of a character feature in one of the data tables. When using quotes while working in Python, it is important to use single quotes, not double quotes, to ensure that the quote that is internal to SQL is not read as a termination of the Python variable that contains the SQL code. That is, it is fine to write a clause that looks like `WHERE column = 'value'`, but not `WHERE column = \"value\"`.\n", "\n", "For all of the queries we will write in the following examples, we will store the query as a string variable in Python. We will use the triple-quote syntax, which allows us to write a string that exists on multiple lines. So our SQL query definitions will look like this:\n", "```\n", "myquery = \"\"\"\n", "SELECT \n", " t.id, \n", " t.column1, \n", " t.column2, \n", " t.column3, \n", " r.column4 \n", "FROM table1 t \n", "INNER JOIN table2 r \n", " ON t.id = r.id \n", "WHERE column1>100 \n", "ORDER BY column2 DESC;\n", "\"\"\"\n", "```\n", "We will then be able to pass the `myquery` variable to functions like `pd.read_sql_query()` to be evaluated." ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "## SQL Joins\n", "The simplest SQL commands for reading data from a database are `SELECT` and `FROM`. In module 6, we issued the following query to read the entire \"reviews\" entity from the wine reviews database:\n", "```\n", "SELECT * FROM reviews\n", "```\n", "But this query does not read data from the other entities in the database. It pulls all of the rows and columns from \"reviews\" and it does not manipulate the data within \"reviews\" in any way. That might not be the best way to create a dataframe to conduct analyses.\n", "\n", "SQL read operations get data, but they can also clean data at the same time. Cleaning data is an important challenge. Even when the data are stored in a well-organized database, that organization might not be the right format for the data given the analyses we intend to do. \"[Tidy Data](https://www.jstatsoft.org/article/view/v059i10)\" by Hadley Wickham lays out a philosophy of what it means to clean a dataset. The goal is to put data into a format in which modeling and visualization is as easy as possible. There are two steps: first we create **tidy data** and then we manipulate the data to fit our specific needs. Tidy data is defined as follows:\n", "\n", "> A dataset is messy or tidy depending on how rows, columns and tables are matched up with observations, [features] and types. In tidy data:\n", "> 1. Each [feature] forms a column.\n", "> 2. Each observation forms a row.\n", "> 3. Each type of observational unit forms a table (p. 2).\n", "\n", "In other words, the dataset we will use in an analysis must exist in one table, the rows of the table must represent records (also called observations), the columns of the table must represent features, and the rows must represent comparable units. For example, if the data contain records from the 50 U.S. States, there should be a row for each state, and there should not be a row for regions or for the whole country as these units are not comparable to states. Data from a relational database are not generally in tidy format because the relevant data exists in multiple tables. The first step is to combine these tables into one dataset using **join** functions within SQL read operations. There are many different kinds of joins, and the easiest way to see the difference between these types is to see what they do to real data. \n", "\n", "Before we discuss specific examples of how to use SQL, we load the following libraries:" ] }, { "cell_type": "code", "execution_count": 1, "metadata": {}, "outputs": [], "source": [ "import numpy as np\n", "import pandas as pd\n", "import sys\n", "import os\n", "import psycopg2\n", "from sqlalchemy import create_engine\n", "import dotenv" ] }, { "cell_type": "markdown", "metadata": {}, "source": [ "### Example Database: NFL and NBA Teams\n", "As an example, I create a PostgreSQL database that contains two tables: \"nfl\" contains the location and team name of all 32 NFL teams:" ] }, { "cell_type": "code", "execution_count": 2, "metadata": {}, "outputs": [ { "data": { "text/html": [ "\n", " | city | \n", "footballteam | \n", "
---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "
1 | \n", "Miami | \n", "Miami Dolphins | \n", "
2 | \n", "Boston | \n", "New England Patriots | \n", "
3 | \n", "New York | \n", "[New York Jets, New York Giants] | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "
5 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "
6 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "
7 | \n", "Baltimore | \n", "Baltimore Ravens | \n", "
8 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "
9 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "
10 | \n", "Los Angeles | \n", "[L.A. Chargers, L.A. Rams] | \n", "
11 | \n", "Denver | \n", "Denver Broncos | \n", "
12 | \n", "Nashville | \n", "Tennessee Titans | \n", "
13 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "
14 | \n", "Houston | \n", "Houston Texans | \n", "
15 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "
16 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "
17 | \n", "Dallas | \n", "Dallas Cowboys | \n", "
18 | \n", "Washington | \n", "Washington Skins | \n", "
19 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "
20 | \n", "Charlotte | \n", "Carolina Panthers | \n", "
21 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "
22 | \n", "New Orleans | \n", "New Orleans Saints | \n", "
23 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "
24 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "
25 | \n", "Seattle | \n", "Seattle Seahawks | \n", "
26 | \n", "Chicago | \n", "Chicago Bears | \n", "
27 | \n", "Green Bay | \n", "Green Bay Packers | \n", "
28 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "
29 | \n", "Detroit | \n", "Detroit Lions | \n", "
\n", " | city | \n", "basketballteam | \n", "
---|---|---|
0 | \n", "Boston | \n", "Boston Celtics | \n", "
1 | \n", "New York | \n", "New York Knicks | \n", "
2 | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
3 | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
4 | \n", "Toronto | \n", "Toronto Raptors | \n", "
5 | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
6 | \n", "Chicago | \n", "Chicago Bulls | \n", "
7 | \n", "Detroit | \n", "Detroit Pistons | \n", "
8 | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "
9 | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
10 | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
11 | \n", "Washington | \n", "Washington Wizards | \n", "
12 | \n", "Orlando | \n", "Orlando Magic | \n", "
13 | \n", "Miami | \n", "Miami Heat | \n", "
14 | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
15 | \n", "Los Angeles | \n", "[L.A. Lakers, L.A. Clippers] | \n", "
16 | \n", "San Francisco | \n", "Golden State Warriors | \n", "
17 | \n", "Portland | \n", "Portland Trailblazers | \n", "
18 | \n", "Sacramento | \n", "Sacramento Kings | \n", "
19 | \n", "Phoenix | \n", "Phoenix Suns | \n", "
20 | \n", "San Antonio | \n", "San Antonio Spurs | \n", "
21 | \n", "Dallas | \n", "Dallas Mavericks | \n", "
22 | \n", "Houston | \n", "Houston Rockets | \n", "
23 | \n", "Oklahoma City | \n", "Oklahoma City Thunder | \n", "
24 | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
25 | \n", "Denver | \n", "Denver Nuggets | \n", "
26 | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
27 | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
28 | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
\n", " | city | \n", "footballteam | \n", "
---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "
1 | \n", "Miami | \n", "Miami Dolphins | \n", "
2 | \n", "Boston | \n", "New England Patriots | \n", "
3 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "
5 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "
6 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "
7 | \n", "Baltimore | \n", "Baltimore Ravens | \n", "
8 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "
9 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "
10 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "
11 | \n", "Denver | \n", "Denver Broncos | \n", "
12 | \n", "Nashville | \n", "Tennessee Titans | \n", "
13 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "
14 | \n", "Houston | \n", "Houston Texans | \n", "
15 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "
16 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "
17 | \n", "Dallas | \n", "Dallas Cowboys | \n", "
18 | \n", "Washington | \n", "Washington Skins | \n", "
19 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "
20 | \n", "Charlotte | \n", "Carolina Panthers | \n", "
21 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "
22 | \n", "New Orleans | \n", "New Orleans Saints | \n", "
23 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "
24 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "
25 | \n", "Seattle | \n", "Seattle Seahawks | \n", "
26 | \n", "Chicago | \n", "Chicago Bears | \n", "
27 | \n", "Green Bay | \n", "Green Bay Packers | \n", "
28 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "
29 | \n", "Detroit | \n", "Detroit Lions | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
2 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
3 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
4 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
5 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
6 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
7 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
8 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
9 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
10 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
11 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
12 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
13 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
14 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
15 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
16 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
17 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
18 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
2 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
3 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
4 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
5 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
6 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
7 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
8 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
9 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
10 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
11 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
12 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
13 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
14 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
15 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
16 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
17 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
18 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "None | \n", "None | \n", "
1 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
2 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
3 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
5 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "None | \n", "None | \n", "
6 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "None | \n", "None | \n", "
7 | \n", "Baltimore | \n", "Baltimore Ravens | \n", "None | \n", "None | \n", "
8 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "None | \n", "None | \n", "
9 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "None | \n", "None | \n", "
10 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
11 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
12 | \n", "Nashville | \n", "Tennessee Titans | \n", "None | \n", "None | \n", "
13 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "None | \n", "None | \n", "
14 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
15 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
16 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
17 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
18 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
19 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
20 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
21 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "None | \n", "None | \n", "
22 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
23 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
24 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
25 | \n", "Seattle | \n", "Seattle Seahawks | \n", "None | \n", "None | \n", "
26 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
27 | \n", "Green Bay | \n", "Green Bay Packers | \n", "None | \n", "None | \n", "
28 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
29 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
1 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
2 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
3 | \n", "None | \n", "None | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
4 | \n", "None | \n", "None | \n", "Toronto | \n", "Toronto Raptors | \n", "
5 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
6 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
7 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
8 | \n", "None | \n", "None | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "
9 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
10 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
11 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
12 | \n", "None | \n", "None | \n", "Orlando | \n", "Orlando Magic | \n", "
13 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
14 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
15 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
16 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
17 | \n", "None | \n", "None | \n", "Portland | \n", "Portland Trailblazers | \n", "
18 | \n", "None | \n", "None | \n", "Sacramento | \n", "Sacramento Kings | \n", "
19 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
20 | \n", "None | \n", "None | \n", "San Antonio | \n", "San Antonio Spurs | \n", "
21 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
22 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
23 | \n", "None | \n", "None | \n", "Oklahoma City | \n", "Oklahoma City Thunder | \n", "
24 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
25 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
26 | \n", "None | \n", "None | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
27 | \n", "None | \n", "None | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
28 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "None | \n", "None | \n", "
1 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
2 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
3 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
5 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "None | \n", "None | \n", "
6 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "None | \n", "None | \n", "
7 | \n", "Baltimore | \n", "Baltimore Ravens | \n", "None | \n", "None | \n", "
8 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "None | \n", "None | \n", "
9 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "None | \n", "None | \n", "
10 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
11 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
12 | \n", "Nashville | \n", "Tennessee Titans | \n", "None | \n", "None | \n", "
13 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "None | \n", "None | \n", "
14 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
15 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
16 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
17 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
18 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
19 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
20 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
21 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "None | \n", "None | \n", "
22 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
23 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
24 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
25 | \n", "Seattle | \n", "Seattle Seahawks | \n", "None | \n", "None | \n", "
26 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
27 | \n", "Green Bay | \n", "Green Bay Packers | \n", "None | \n", "None | \n", "
28 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
29 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
30 | \n", "None | \n", "None | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "
31 | \n", "None | \n", "None | \n", "Oklahoma City | \n", "Oklahoma City Thunder | \n", "
32 | \n", "None | \n", "None | \n", "Portland | \n", "Portland Trailblazers | \n", "
33 | \n", "None | \n", "None | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
34 | \n", "None | \n", "None | \n", "Sacramento | \n", "Sacramento Kings | \n", "
35 | \n", "None | \n", "None | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
36 | \n", "None | \n", "None | \n", "San Antonio | \n", "San Antonio Spurs | \n", "
37 | \n", "None | \n", "None | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
38 | \n", "None | \n", "None | \n", "Orlando | \n", "Orlando Magic | \n", "
39 | \n", "None | \n", "None | \n", "Toronto | \n", "Toronto Raptors | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "None | \n", "None | \n", "
1 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "None | \n", "None | \n", "
2 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "None | \n", "None | \n", "
3 | \n", "Baltimore | \n", "Baltimore Ravens | \n", "None | \n", "None | \n", "
4 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "None | \n", "None | \n", "
5 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "None | \n", "None | \n", "
6 | \n", "Nashville | \n", "Tennessee Titans | \n", "None | \n", "None | \n", "
7 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "None | \n", "None | \n", "
8 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "None | \n", "None | \n", "
9 | \n", "Seattle | \n", "Seattle Seahawks | \n", "None | \n", "None | \n", "
10 | \n", "Green Bay | \n", "Green Bay Packers | \n", "None | \n", "None | \n", "
\n", " | city | \n", "footballteam | \n", "basketballteam | \n", "
---|---|---|---|
0 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami Heat | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston Celtics | \n", "
2 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York Knicks | \n", "
3 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland Cavaliers | \n", "
4 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
5 | \n", "Denver | \n", "Denver Broncos | \n", "Denver Nuggets | \n", "
6 | \n", "Houston | \n", "Houston Texans | \n", "Houston Rockets | \n", "
7 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indiana Pacers | \n", "
8 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia 76ers | \n", "
9 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas Mavericks | \n", "
10 | \n", "Washington | \n", "Washington Skins | \n", "Washington Wizards | \n", "
11 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta Hawks | \n", "
12 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte Hornets | \n", "
13 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans Pelicans | \n", "
14 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "Golden State Warriors | \n", "
15 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix Suns | \n", "
16 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago Bulls | \n", "
17 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minnesota Timberwolves | \n", "
18 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit Pistons | \n", "
\n", " | city | \n", "team | \n", "
---|
\n", " | city | \n", "team | \n", "city | \n", "team | \n", "
---|---|---|---|---|
0 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "
2 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "
3 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
4 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
5 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "
6 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "
7 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
8 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
9 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "
10 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "
11 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
12 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
13 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
14 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "
15 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "
16 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "
17 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
18 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "
---|---|---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "Boston | \n", "Boston Celtics | \n", "
1 | \n", "Buffalo | \n", "Buffalo Bills | \n", "New York | \n", "New York Knicks | \n", "
2 | \n", "Buffalo | \n", "Buffalo Bills | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
3 | \n", "Buffalo | \n", "Buffalo Bills | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
4 | \n", "Buffalo | \n", "Buffalo Bills | \n", "Toronto | \n", "Toronto Raptors | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
865 | \n", "Detroit | \n", "Detroit Lions | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
866 | \n", "Detroit | \n", "Detroit Lions | \n", "Denver | \n", "Denver Nuggets | \n", "
867 | \n", "Detroit | \n", "Detroit Lions | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
868 | \n", "Detroit | \n", "Detroit Lions | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
869 | \n", "Detroit | \n", "Detroit Lions | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
870 rows × 4 columns
\n", "\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "city | \n", "baseballteam | \n", "
---|---|---|---|---|---|---|
0 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "Atlanta | \n", "Atlanta Braves | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "Boston | \n", "Boston Red Sox | \n", "
2 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "Chicago | \n", "{\"Chicago White Sox\",\"Chicago Cubs\"} | \n", "
3 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "Cleveland | \n", "Cleveland Indians | \n", "
4 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "Dallas | \n", "Texas Rangers | \n", "
5 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "Denver | \n", "Colorado Rockies | \n", "
6 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "Detroit | \n", "Detriot Tigers | \n", "
7 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "Houston | \n", "Houston Astros | \n", "
8 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "Los Angeles | \n", "Los Angeles Dodgers | \n", "
9 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "Miami | \n", "Miami Marlins | \n", "
10 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "Minneapolis | \n", "Minnesota Twins | \n", "
11 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "New York | \n", "{\"New York Mets\",\"New York Yankees\"} | \n", "
12 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "Philadelphia | \n", "Philadelphia Phillies | \n", "
13 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "Phoenix | \n", "Arizona Diamondbacks | \n", "
14 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "San Francisco | \n", "San Francisco Giants | \n", "
15 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "Washington | \n", "Washington Nationals | \n", "
\n", " | city | \n", "footballteam | \n", "city | \n", "basketballteam | \n", "city | \n", "baseballteam | \n", "
---|---|---|---|---|---|---|
0 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "Atlanta | \n", "Atlanta Hawks | \n", "Atlanta | \n", "Atlanta Braves | \n", "
1 | \n", "Boston | \n", "New England Patriots | \n", "Boston | \n", "Boston Celtics | \n", "Boston | \n", "Boston Red Sox | \n", "
2 | \n", "Charlotte | \n", "Carolina Panthers | \n", "Charlotte | \n", "Charlotte Hornets | \n", "None | \n", "None | \n", "
3 | \n", "Chicago | \n", "Chicago Bears | \n", "Chicago | \n", "Chicago Bulls | \n", "Chicago | \n", "{\"Chicago White Sox\",\"Chicago Cubs\"} | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "Cleveland | \n", "Cleveland Indians | \n", "
5 | \n", "Dallas | \n", "Dallas Cowboys | \n", "Dallas | \n", "Dallas Mavericks | \n", "Dallas | \n", "Texas Rangers | \n", "
6 | \n", "Denver | \n", "Denver Broncos | \n", "Denver | \n", "Denver Nuggets | \n", "Denver | \n", "Colorado Rockies | \n", "
7 | \n", "Detroit | \n", "Detroit Lions | \n", "Detroit | \n", "Detroit Pistons | \n", "Detroit | \n", "Detriot Tigers | \n", "
8 | \n", "Houston | \n", "Houston Texans | \n", "Houston | \n", "Houston Rockets | \n", "Houston | \n", "Houston Astros | \n", "
9 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "Indianapolis | \n", "Indiana Pacers | \n", "None | \n", "None | \n", "
10 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "Los Angeles | \n", "Los Angeles Dodgers | \n", "
11 | \n", "Miami | \n", "Miami Dolphins | \n", "Miami | \n", "Miami Heat | \n", "Miami | \n", "Miami Marlins | \n", "
12 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "Minneapolis | \n", "Minnesota Twins | \n", "
13 | \n", "New Orleans | \n", "New Orleans Saints | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "None | \n", "None | \n", "
14 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "New York | \n", "New York Knicks | \n", "New York | \n", "{\"New York Mets\",\"New York Yankees\"} | \n", "
15 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "Philadelphia | \n", "Philadelphia Phillies | \n", "
16 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "Phoenix | \n", "Phoenix Suns | \n", "Phoenix | \n", "Arizona Diamondbacks | \n", "
17 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "San Francisco | \n", "Golden State Warriors | \n", "San Francisco | \n", "San Francisco Giants | \n", "
18 | \n", "Washington | \n", "Washington Skins | \n", "Washington | \n", "Washington Wizards | \n", "Washington | \n", "Washington Nationals | \n", "
\n", " | city | \n", "baseballteam | \n", "city | \n", "basketballteam | \n", "city | \n", "footballteam | \n", "
---|---|---|---|---|---|---|
0 | \n", "Toronto | \n", "Toronto Blue Jays | \n", "Toronto | \n", "Toronto Raptors | \n", "None | \n", "None | \n", "
1 | \n", "Milwaukee | \n", "Milwaukee Brewers | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "None | \n", "None | \n", "
\n", " | city | \n", "basketballteam | \n", "
---|---|---|
0 | \n", "Boston | \n", "Boston Celtics | \n", "
1 | \n", "New York | \n", "New York Knicks | \n", "
2 | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
3 | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
4 | \n", "Toronto | \n", "Toronto Raptors | \n", "
5 | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
6 | \n", "Chicago | \n", "Chicago Bulls | \n", "
7 | \n", "Detroit | \n", "Detroit Pistons | \n", "
8 | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "
9 | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
10 | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
11 | \n", "Washington | \n", "Washington Wizards | \n", "
12 | \n", "Orlando | \n", "Orlando Magic | \n", "
13 | \n", "Miami | \n", "Miami Heat | \n", "
14 | \n", "Charlotte | \n", "Charlotte Hornets | \n", "
15 | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
16 | \n", "San Francisco | \n", "Golden State Warriors | \n", "
17 | \n", "Portland | \n", "Portland Trailblazers | \n", "
18 | \n", "Sacramento | \n", "Sacramento Kings | \n", "
19 | \n", "Phoenix | \n", "Phoenix Suns | \n", "
20 | \n", "San Antonio | \n", "San Antonio Spurs | \n", "
21 | \n", "Dallas | \n", "Dallas Mavericks | \n", "
22 | \n", "Houston | \n", "Houston Rockets | \n", "
23 | \n", "Oklahoma City | \n", "Oklahoma City Thunder | \n", "
24 | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
25 | \n", "Denver | \n", "Denver Nuggets | \n", "
26 | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
27 | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
28 | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
29 | \n", "Seattle | \n", "Seattle Supersonics | \n", "
\n", " | city | \n", "basketballteam | \n", "
---|---|---|
0 | \n", "Boston | \n", "Boston Celtics | \n", "
1 | \n", "New York | \n", "New York Knicks | \n", "
2 | \n", "Philadelphia | \n", "Philadelphia 76ers | \n", "
3 | \n", "Brooklyn | \n", "Brooklyn Nets | \n", "
4 | \n", "Toronto | \n", "Toronto Raptors | \n", "
5 | \n", "Cleveland | \n", "Cleveland Cavaliers | \n", "
6 | \n", "Chicago | \n", "Chicago Bulls | \n", "
7 | \n", "Detroit | \n", "Detroit Pistons | \n", "
8 | \n", "Milwaukee | \n", "Milwaukee Bucks | \n", "
9 | \n", "Indianapolis | \n", "Indiana Pacers | \n", "
10 | \n", "Atlanta | \n", "Atlanta Hawks | \n", "
11 | \n", "Washington | \n", "Washington Wizards | \n", "
12 | \n", "Orlando | \n", "Orlando Magic | \n", "
13 | \n", "Miami | \n", "Miami Heat | \n", "
14 | \n", "Los Angeles | \n", "{\"L.A. Lakers\",\"L.A. Clippers\"} | \n", "
15 | \n", "San Francisco | \n", "Golden State Warriors | \n", "
16 | \n", "Portland | \n", "Portland Trailblazers | \n", "
17 | \n", "Sacramento | \n", "Sacramento Kings | \n", "
18 | \n", "Phoenix | \n", "Phoenix Suns | \n", "
19 | \n", "San Antonio | \n", "San Antonio Spurs | \n", "
20 | \n", "Dallas | \n", "Dallas Mavericks | \n", "
21 | \n", "Houston | \n", "Houston Rockets | \n", "
22 | \n", "Oklahoma City | \n", "Oklahoma City Thunder | \n", "
23 | \n", "Minneapolis | \n", "Minnesota Timberwolves | \n", "
24 | \n", "Denver | \n", "Denver Nuggets | \n", "
25 | \n", "Salt Lake City | \n", "Utah Jazz | \n", "
26 | \n", "Memphis | \n", "Memphis Grizzlies | \n", "
27 | \n", "New Orleans | \n", "New Orleans Pelicans | \n", "
28 | \n", "Seattle | \n", "Seattle Supersonics | \n", "
29 | \n", "Charlotte | \n", "Charlotte Bobcats | \n", "
\n", " | city | \n", "footballteam | \n", "
---|---|---|
0 | \n", "Buffalo | \n", "Buffalo Bills | \n", "
1 | \n", "Miami | \n", "Miami Dolphins | \n", "
2 | \n", "Boston | \n", "New England Patriots | \n", "
3 | \n", "New York | \n", "{\"New York Jets\",\"New York Giants\"} | \n", "
4 | \n", "Cleveland | \n", "Cleveland Browns | \n", "
5 | \n", "Cincinnati | \n", "Cincinnati Bengals | \n", "
6 | \n", "Pittsburgh | \n", "Pittsburgh Steelers | \n", "
7 | \n", "Kansas City | \n", "Kansas City Chiefs | \n", "
8 | \n", "Las Vegas | \n", "Las Vegas Raiders | \n", "
9 | \n", "Los Angeles | \n", "{\"L.A. Chargers\",\"L.A. Rams\"} | \n", "
10 | \n", "Denver | \n", "Denver Broncos | \n", "
11 | \n", "Nashville | \n", "Tennessee Titans | \n", "
12 | \n", "Jacksonville | \n", "Jacksonville Jaguars | \n", "
13 | \n", "Houston | \n", "Houston Texans | \n", "
14 | \n", "Indianapolis | \n", "Indianapolis Colts | \n", "
15 | \n", "Philadelphia | \n", "Philadelphia Eagles | \n", "
16 | \n", "Dallas | \n", "Dallas Cowboys | \n", "
17 | \n", "Washington | \n", "Washington Skins | \n", "
18 | \n", "Atlanta | \n", "Atlanta Falcons | \n", "
19 | \n", "Charlotte | \n", "Carolina Panthers | \n", "
20 | \n", "Tampa Bay | \n", "Tampa Bay Buccaneers | \n", "
21 | \n", "New Orleans | \n", "New Orleans Saints | \n", "
22 | \n", "San Francisco | \n", "San Francisco 49ers | \n", "
23 | \n", "Phoenix | \n", "Arizona Cardinals | \n", "
24 | \n", "Seattle | \n", "Seattle Seahawks | \n", "
25 | \n", "Chicago | \n", "Chicago Bears | \n", "
26 | \n", "Green Bay | \n", "Green Bay Packers | \n", "
27 | \n", "Minneapolis | \n", "Minnesota Vikings | \n", "
28 | \n", "Detroit | \n", "Detroit Lions | \n", "
\n", " | title | \n", "variety | \n", "price | \n", "points | \n", "country | \n", "taster_name | \n", "
---|---|---|---|---|---|---|
0 | \n", "Olivier Leflaive 2006 Les Pucelles Premier Cru... | \n", "Chardonnay | \n", "NaN | \n", "93 | \n", "France | \n", "Roger Voss | \n", "
1 | \n", "The Foundry 2004 Syrah (Coastal Region) | \n", "Syrah | \n", "35.0 | \n", "87 | \n", "South Africa | \n", "Susan Kostrzewa | \n", "
2 | \n", "Guilbaud Frères 2007 Le Soleil Nantais (Musca... | \n", "Melon | \n", "11.0 | \n", "87 | \n", "France | \n", "Roger Voss | \n", "
3 | \n", "Domaine du Clos du Fief 2007 Cuvée Tradition ... | \n", "Gamay | \n", "NaN | \n", "86 | \n", "France | \n", "Roger Voss | \n", "
4 | \n", "Domaine Philippe Delesvaux 2005 La Montée de l... | \n", "Cabernet Sauvignon | \n", "NaN | \n", "86 | \n", "France | \n", "Roger Voss | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Sheridan Vineyard 2005 Reserve Cabernet Sauvig... | \n", "Cabernet Sauvignon | \n", "75.0 | \n", "94 | \n", "US | \n", "Paul Gregutt | \n", "
103723 | \n", "Woodward Canyon 2006 Old Vines Dedication Seri... | \n", "Cabernet Sauvignon | \n", "84.0 | \n", "94 | \n", "US | \n", "Paul Gregutt | \n", "
103724 | \n", "Chanson Père et Fils 2005 Champs Gains Premier... | \n", "Chardonnay | \n", "115.0 | \n", "93 | \n", "France | \n", "Roger Voss | \n", "
103725 | \n", "Mark Ryan 2006 Chardonnay (Columbia Valley (WA)) | \n", "Chardonnay | \n", "NaN | \n", "93 | \n", "US | \n", "Paul Gregutt | \n", "
103726 | \n", "Joseph Drouhin 2007 Grands-Echezeaux | \n", "Pinot Noir | \n", "285.0 | \n", "94 | \n", "France | \n", "Roger Voss | \n", "
103727 rows × 6 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "
---|---|---|---|
0 | \n", "Krug 2002 Brut (Champagne) | \n", "Champagne Blend | \n", "259.0 | \n", "
1 | \n", "Château Léoville Barton 2010 Saint-Julien | \n", "Bordeaux-style Red Blend | \n", "150.0 | \n", "
2 | \n", "Louis Roederer 2008 Cristal Vintage Brut (Cha... | \n", "Champagne Blend | \n", "250.0 | \n", "
3 | \n", "Salon 2006 Le Mesnil Blanc de Blancs Brut Char... | \n", "Chardonnay | \n", "617.0 | \n", "
4 | \n", "Château Lafite Rothschild 2010 Pauillac | \n", "Bordeaux-style Red Blend | \n", "1500.0 | \n", "
5 | \n", "Château Cheval Blanc 2010 Saint-Émilion | \n", "Bordeaux-style Red Blend | \n", "1500.0 | \n", "
6 | \n", "Château Léoville Las Cases 2010 Saint-Julien | \n", "Bordeaux-style Red Blend | \n", "359.0 | \n", "
7 | \n", "Château Haut-Brion 2014 Pessac-Léognan | \n", "Bordeaux-style White Blend | \n", "848.0 | \n", "
\n", " | title | \n", "variety | \n", "price | \n", "points | \n", "country | \n", "province | \n", "
---|---|---|---|---|---|---|
0 | \n", "Château Vircoulon 2016 Bordeaux Blanc | \n", "Bordeaux-style White Blend | \n", "10.0 | \n", "90 | \n", "France | \n", "Bordeaux | \n", "
1 | \n", "Mano A Mano 2011 Tempranillo (Vino de la Tierr... | \n", "Tempranillo | \n", "9.0 | \n", "90 | \n", "Spain | \n", "Central Spain | \n", "
2 | \n", "Aveleda 2014 Quinta da Aveleda Estate Bottled ... | \n", "Portuguese White | \n", "9.0 | \n", "90 | \n", "Portugal | \n", "Vinho Verde | \n", "
3 | \n", "Chateau Ste. Michelle 2011 Riesling (Columbia ... | \n", "Riesling | \n", "9.0 | \n", "91 | \n", "US | \n", "Washington | \n", "
4 | \n", "Quinta do Portal 2007 Mural Reserva Red (Douro) | \n", "Portuguese Red | \n", "10.0 | \n", "91 | \n", "Portugal | \n", "Douro | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
76 | \n", "Casaleiro 2012 Reserva Touriga Nacional-Castel... | \n", "Portuguese Red | \n", "9.0 | \n", "90 | \n", "Portugal | \n", "Tejo | \n", "
77 | \n", "Aveleda 2015 Quinta da Aveleda White (Vinho Ve... | \n", "Portuguese White | \n", "9.0 | \n", "90 | \n", "Portugal | \n", "Vinho Verde | \n", "
78 | \n", "Cookies & Cream 2010 Merlot (California) | \n", "Merlot | \n", "10.0 | \n", "90 | \n", "US | \n", "California | \n", "
79 | \n", "Lovingston 2012 Josie's Knoll Merlot (Monticello) | \n", "Merlot | \n", "20.0 | \n", "91 | \n", "US | \n", "Virginia | \n", "
80 | \n", "Aveleda 2016 Quinta da Aveleda White (Vinho Ve... | \n", "Portuguese White | \n", "10.0 | \n", "90 | \n", "Portugal | \n", "Vinho Verde | \n", "
81 rows × 6 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "points | \n", "country | \n", "province | \n", "
---|---|---|---|---|---|---|
0 | \n", "Veramar 2016 JB Winemaker Series Cabernet Fran... | \n", "Cabernet Franc | \n", "34.0 | \n", "86 | \n", "US | \n", "Virginia | \n", "
1 | \n", "Château Vircoulon 2016 Bordeaux Blanc | \n", "Bordeaux-style White Blend | \n", "10.0 | \n", "90 | \n", "France | \n", "Bordeaux | \n", "
2 | \n", "Mano A Mano 2011 Tempranillo (Vino de la Tierr... | \n", "Tempranillo | \n", "9.0 | \n", "90 | \n", "Spain | \n", "Central Spain | \n", "
3 | \n", "Trump 2014 Rosé (Monticello) | \n", "Rosé | \n", "14.0 | \n", "86 | \n", "US | \n", "Virginia | \n", "
4 | \n", "The Boneyard 2014 Chardonnay (Virginia) | \n", "Chardonnay | \n", "15.0 | \n", "86 | \n", "US | \n", "Virginia | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
444 | \n", "Annefield Vineyards 2009 Cabernet Franc (Virgi... | \n", "Cabernet Franc | \n", "29.0 | \n", "88 | \n", "US | \n", "Virginia | \n", "
445 | \n", "Lovingston 2012 Josie's Knoll Merlot (Monticello) | \n", "Merlot | \n", "20.0 | \n", "91 | \n", "US | \n", "Virginia | \n", "
446 | \n", "Aveleda 2016 Quinta da Aveleda White (Vinho Ve... | \n", "Portuguese White | \n", "10.0 | \n", "90 | \n", "Portugal | \n", "Vinho Verde | \n", "
447 | \n", "Tarara 2013 Cabernet Franc (Virginia) | \n", "Cabernet Franc | \n", "25.0 | \n", "85 | \n", "US | \n", "Virginia | \n", "
448 | \n", "Paradise Springs 2014 Nana's Rosé (Virginia) | \n", "Rosé | \n", "22.0 | \n", "86 | \n", "US | \n", "Virginia | \n", "
449 rows × 6 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "country | \n", "
---|---|---|---|---|
0 | \n", "The Foundry 2004 Syrah (Coastal Region) | \n", "Syrah | \n", "35.0 | \n", "South Africa | \n", "
1 | \n", "Guilbaud Frères 2007 Le Soleil Nantais (Musca... | \n", "Melon | \n", "11.0 | \n", "France | \n", "
2 | \n", "Domaine du Clos du Fief 2007 Cuvée Tradition ... | \n", "Gamay | \n", "NaN | \n", "France | \n", "
3 | \n", "Domaine Philippe Delesvaux 2005 La Montée de l... | \n", "Cabernet Sauvignon | \n", "NaN | \n", "France | \n", "
4 | \n", "Georges Duboeuf 2007 Beaujolais-Villages | \n", "Gamay | \n", "NaN | \n", "France | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
57429 | \n", "Indomita NV Rosé Sparkling (Casablanca Valley) | \n", "Sparkling Blend | \n", "18.0 | \n", "Chile | \n", "
57430 | \n", "Intipalka 2013 Valle del Sol Tannat (Ica) | \n", "Tannat | \n", "14.0 | \n", "Peru | \n", "
57431 | \n", "Lobster Reef 2014 Sauvignon Blanc (Marlborough) | \n", "Sauvignon Blanc | \n", "12.0 | \n", "New Zealand | \n", "
57432 | \n", "Millaman 2014 Estate Reserve Sauvignon Blanc (... | \n", "Sauvignon Blanc | \n", "10.0 | \n", "Chile | \n", "
57433 | \n", "Royal Tokaji 1999 Mézes Mály Aszú 6 Puttonyos ... | \n", "Tokaji | \n", "175.0 | \n", "Hungary | \n", "
57434 rows × 4 columns
\n", "\n", " | wine_id | \n", "title | \n", "variety | \n", "description | \n", "points | \n", "price | \n", "taster_id | \n", "winery_id | \n", "location_id | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "6792 | \n", "Guardian Peak 2006 Shiraz (Western Cape) | \n", "Shiraz | \n", "A gorgeous nose of plums, chocolate and red fr... | \n", "89 | \n", "15.0 | \n", "16 | \n", "7363 | \n", "1141 | \n", "
1 | \n", "7812 | \n", "Hightower 2006 Cabernet Sauvignon (Columbia Va... | \n", "Cabernet Sauvignon | \n", "Sourced largely from Red Mountain fruit, this ... | \n", "87 | \n", "35.0 | \n", "3 | \n", "7629 | \n", "1474 | \n", "
2 | \n", "7866 | \n", "Viña Cobos 2012 Bramare Marchiori Vineyard Mal... | \n", "Malbec | \n", "Toasty woodsmoke aromas are matched by wild be... | \n", "94 | \n", "90.0 | \n", "5 | \n", "13962 | \n", "4 | \n", "
3 | \n", "8110 | \n", "Mendel 2013 Unus Red (Mendoza) | \n", "Bordeaux-style Red Blend | \n", "Rich aromas of raisin, cassis and blackberry a... | \n", "93 | \n", "50.0 | \n", "5 | \n", "9746 | \n", "7 | \n", "
4 | \n", "9262 | \n", "Freakshow 2014 Cabernet Sauvignon (Lodi) | \n", "Cabernet Sauvignon | \n", "Rich, ripe and oaky, this full-bodied wine has... | \n", "91 | \n", "20.0 | \n", "10 | \n", "6893 | \n", "1304 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
260 | \n", "4862 | \n", "Hearst Ranch 2013 Lone Tree Cabernet Franc (Pa... | \n", "Cabernet Franc | \n", "Made in a thick, oaky style, this shows burned... | \n", "87 | \n", "35.0 | \n", "8 | \n", "7498 | \n", "1337 | \n", "
261 | \n", "4690 | \n", "Pear Valley 2013 Distraction Red (Paso Robles) | \n", "Bordeaux-style Red Blend | \n", "The signature bottling from this winery, this ... | \n", "91 | \n", "35.0 | \n", "8 | \n", "10762 | \n", "1337 | \n", "
262 | \n", "4794 | \n", "Estate Constantin Gofas 2008 Agiorgitiko (Nemea) | \n", "Agiorgitiko | \n", "This wine has the plucky character typical of ... | \n", "85 | \n", "18.0 | \n", "16 | \n", "6366 | \n", "668 | \n", "
263 | \n", "6574 | \n", "Fielding Hills 2006 RiverBend Vineyard Syrah (... | \n", "Syrah | \n", "Bold and forward, this estate-grown Syrah fair... | \n", "94 | \n", "40.0 | \n", "3 | \n", "6619 | \n", "1483 | \n", "
264 | \n", "5020 | \n", "Corliss Estates 2007 Cabernet Sauvignon (Colum... | \n", "Cabernet Sauvignon | \n", "Concentrated and wonderfully aromatic, this ag... | \n", "94 | \n", "75.0 | \n", "3 | \n", "4677 | \n", "1474 | \n", "
265 rows × 9 columns
\n", "\n", " | wine_id | \n", "title | \n", "variety | \n", "description | \n", "points | \n", "price | \n", "taster_id | \n", "winery_id | \n", "location_id | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "8110 | \n", "Mendel 2013 Unus Red (Mendoza) | \n", "Bordeaux-style Red Blend | \n", "Rich aromas of raisin, cassis and blackberry a... | \n", "93 | \n", "50.0 | \n", "5 | \n", "9746 | \n", "7 | \n", "
1 | \n", "9262 | \n", "Freakshow 2014 Cabernet Sauvignon (Lodi) | \n", "Cabernet Sauvignon | \n", "Rich, ripe and oaky, this full-bodied wine has... | \n", "91 | \n", "20.0 | \n", "10 | \n", "6893 | \n", "1304 | \n", "
2 | \n", "9746 | \n", "Carmel 2013 Admon Vineyard Cabernet Sauvignon ... | \n", "Cabernet Sauvignon | \n", "This wine has offers aromas of dark plum and c... | \n", "89 | \n", "35.0 | \n", "14 | \n", "1925 | \n", "694 | \n", "
3 | \n", "10326 | \n", "De Martino 2009 Alto de Piedras Single Vineyar... | \n", "Carmenère | \n", "A big, earthy type of wine with a ton of ripen... | \n", "90 | \n", "45.0 | \n", "5 | \n", "4973 | \n", "182 | \n", "
\n", " | title | \n", "points | \n", "price | \n", "
---|---|---|---|
0 | \n", "King Family 2015 Orange Viognier (Monticello) | \n", "92 | \n", "35.0 | \n", "
1 | \n", "Lovingston 2012 Josie's Knoll Merlot (Monticello) | \n", "91 | \n", "20.0 | \n", "
2 | \n", "Lovingston 2015 Josie's Knoll Rotunda Red (Mon... | \n", "90 | \n", "20.0 | \n", "
3 | \n", "Barboursville Vineyards 2015 Reserve Cabernet ... | \n", "90 | \n", "25.0 | \n", "
4 | \n", "King Family 2012 Meritage (Monticello) | \n", "90 | \n", "31.0 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "
374 | \n", "Narmada 2013 Reserve Cabernet Franc (Virginia) | \n", "82 | \n", "34.0 | \n", "
375 | \n", "Veramar 2009 Chardonnay (Virginia) | \n", "81 | \n", "18.0 | \n", "
376 | \n", "Bogati 2013 Black Label Club Fumé Blanc Sauvig... | \n", "81 | \n", "26.0 | \n", "
377 | \n", "Three Fox 2014 Calabrese Pinot Grigio (Middleb... | \n", "81 | \n", "28.0 | \n", "
378 | \n", "Winery at La Grange 2012 Cabernet Sauvignon (V... | \n", "81 | \n", "43.0 | \n", "
379 rows × 3 columns
\n", "\n", " | name | \n", "type | \n", "score | \n", "
---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "86 | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "86 | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "86 | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "86 | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "86 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "86 | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "86 | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "86 | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "86 | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "86 | \n", "
103727 rows × 3 columns
\n", "\n", " | title | \n", "variety | \n", "price_dollars | \n", "price_euros | \n", "
---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "12.0 | \n", "10.92 | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "24.0 | \n", "21.84 | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "NaN | \n", "NaN | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "18.0 | \n", "16.38 | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "22.0 | \n", "20.02 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "15.0 | \n", "13.65 | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "18.0 | \n", "16.38 | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "24.0 | \n", "21.84 | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "19.0 | \n", "17.29 | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "24.0 | \n", "21.84 | \n", "
103727 rows × 4 columns
\n", "\n", " | price | \n", "price_exp | \n", "price_natlog | \n", "price_commonlog | \n", "price_loground | \n", "price_sqrt | \n", "price_squared | \n", "price_cubed | \n", "price_morethan50 | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "12.0 | \n", "1.012072 | \n", "1.079181 | \n", "1.079181 | \n", "1.0 | \n", "3.464102 | \n", "144.0 | \n", "1728.0 | \n", "-1.0 | \n", "
1 | \n", "24.0 | \n", "1.024290 | \n", "1.380211 | \n", "1.380211 | \n", "1.0 | \n", "4.898979 | \n", "576.0 | \n", "13824.0 | \n", "-1.0 | \n", "
2 | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "
3 | \n", "18.0 | \n", "1.018163 | \n", "1.255273 | \n", "1.255273 | \n", "1.0 | \n", "4.242641 | \n", "324.0 | \n", "5832.0 | \n", "-1.0 | \n", "
4 | \n", "22.0 | \n", "1.022244 | \n", "1.342423 | \n", "1.342423 | \n", "1.0 | \n", "4.690416 | \n", "484.0 | \n", "10648.0 | \n", "-1.0 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "15.0 | \n", "1.015113 | \n", "1.176091 | \n", "1.176091 | \n", "1.0 | \n", "3.872983 | \n", "225.0 | \n", "3375.0 | \n", "-1.0 | \n", "
103723 | \n", "18.0 | \n", "1.018163 | \n", "1.255273 | \n", "1.255273 | \n", "1.0 | \n", "4.242641 | \n", "324.0 | \n", "5832.0 | \n", "-1.0 | \n", "
103724 | \n", "24.0 | \n", "1.024290 | \n", "1.380211 | \n", "1.380211 | \n", "1.0 | \n", "4.898979 | \n", "576.0 | \n", "13824.0 | \n", "-1.0 | \n", "
103725 | \n", "19.0 | \n", "1.019182 | \n", "1.278754 | \n", "1.278754 | \n", "1.0 | \n", "4.358899 | \n", "361.0 | \n", "6859.0 | \n", "-1.0 | \n", "
103726 | \n", "24.0 | \n", "1.024290 | \n", "1.380211 | \n", "1.380211 | \n", "1.0 | \n", "4.898979 | \n", "576.0 | \n", "13824.0 | \n", "-1.0 | \n", "
103727 rows × 9 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "price_level | \n", "
---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "12.0 | \n", "cheap | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "24.0 | \n", "moderately priced | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "NaN | \n", "None | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "18.0 | \n", "cheap | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "22.0 | \n", "moderately priced | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "15.0 | \n", "cheap | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "18.0 | \n", "cheap | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "24.0 | \n", "moderately priced | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "19.0 | \n", "cheap | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "24.0 | \n", "moderately priced | \n", "
103727 rows × 4 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "description_upper | \n", "description_lower | \n", "description_initcap | \n", "
---|---|---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "12.0 | \n", "IT'S PRETTY EASY PEGGING THIS FOR CHILEAN SB; ... | \n", "it's pretty easy pegging this for chilean sb; ... | \n", "It'S Pretty Easy Pegging This For Chilean Sb; ... | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "24.0 | \n", "OPAQUE IN COLOR, WITH BLACKBERRY AND LICORICE ... | \n", "opaque in color, with blackberry and licorice ... | \n", "Opaque In Color, With Blackberry And Licorice ... | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "NaN | \n", "ATTRACTIVE RIPE FRUITS GO WITH LIME AND TOAST ... | \n", "attractive ripe fruits go with lime and toast ... | \n", "Attractive Ripe Fruits Go With Lime And Toast ... | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "18.0 | \n", "SMOKY AND A BIT STARK WITH WHIFFS OF STRUCK FL... | \n", "smoky and a bit stark with whiffs of struck fl... | \n", "Smoky And A Bit Stark With Whiffs Of Struck Fl... | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "22.0 | \n", "SOURCED FROM A HIGH-ALTITUDE VINEYARD NEAR THE... | \n", "sourced from a high-altitude vineyard near the... | \n", "Sourced From A High-Altitude Vineyard Near The... | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "15.0 | \n", "SWEET ON THE NOSE, WITH SCENTS OF PINK GRAPEFR... | \n", "sweet on the nose, with scents of pink grapefr... | \n", "Sweet On The Nose, With Scents Of Pink Grapefr... | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "18.0 | \n", "WAXY FRUIT FLAVORS OF PEACH, MELON AND BANANA,... | \n", "waxy fruit flavors of peach, melon and banana,... | \n", "Waxy Fruit Flavors Of Peach, Melon And Banana,... | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "24.0 | \n", "THIS ALCOHOLIC WINE (15.9%, AND YOU CAN TASTE ... | \n", "this alcoholic wine (15.9%, and you can taste ... | \n", "This Alcoholic Wine (15.9%, And You Can Taste ... | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "19.0 | \n", "LIGHT FRUIT FLAVORS RUN FROM MELON INTO PALE S... | \n", "light fruit flavors run from melon into pale s... | \n", "Light Fruit Flavors Run From Melon Into Pale S... | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "24.0 | \n", "FROM HUSBAND-AND-WIFE TEAM IN CALIFORNIA REDWO... | \n", "from husband-and-wife team in california redwo... | \n", "From Husband-And-Wife Team In California Redwo... | \n", "
103727 rows × 6 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "description | \n", "description_substr | \n", "
---|---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "12.0 | \n", "It's pretty easy pegging this for Chilean SB; ... | \n", "pretty ea | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "24.0 | \n", "Opaque in color, with blackberry and licorice ... | \n", "ue in colo | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "NaN | \n", "Attractive ripe fruits go with lime and toast ... | \n", "active rip | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "18.0 | \n", "Smoky and a bit stark with whiffs of struck fl... | \n", "y and a bi | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "22.0 | \n", "Sourced from a high-altitude vineyard near the... | \n", "ced from a | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "15.0 | \n", "Sweet on the nose, with scents of pink grapefr... | \n", "t on the n | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "18.0 | \n", "Waxy fruit flavors of peach, melon and banana,... | \n", "fruit fla | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "24.0 | \n", "This alcoholic wine (15.9%, and you can taste ... | \n", "alcoholic | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "19.0 | \n", "Light fruit flavors run from melon into pale s... | \n", "t fruit fl | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "24.0 | \n", "From husband-and-wife team in California redwo... | \n", "husband-a | \n", "
103727 rows × 5 columns
\n", "\n", " | title | \n", "variety | \n", "price | \n", "place | \n", "
---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "12.0 | \n", "Casablanca Valley, Chile | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "24.0 | \n", "Northern Spain, Spain | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "NaN | \n", "Burgundy, France | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "18.0 | \n", "New York, US | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "22.0 | \n", "Marlborough, New Zealand | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "15.0 | \n", "New York, US | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "18.0 | \n", "Washington, US | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "24.0 | \n", "Washington, US | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "19.0 | \n", "Washington, US | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "24.0 | \n", "California, US | \n", "
103727 rows × 4 columns
\n", "\n", " | title | \n", "points | \n", "price | \n", "description | \n", "length | \n", "
---|---|---|---|---|---|
0 | \n", "Craggy Range 2007 Kidnappers Vineyard Chardonn... | \n", "88 | \n", "24.0 | \n", "Imported by Kobrand. | \n", "20 | \n", "
1 | \n", "Chasing Venus 2007 Sauvignon Blanc (Marlborough) | \n", "88 | \n", "16.0 | \n", "Imported by JL Giguiere. | \n", "24 | \n", "
2 | \n", "Philip Shaw 2007 No. 19 Sauvignon Blanc (Orange) | \n", "86 | \n", "20.0 | \n", "Imported by Lion Nathan USA. | \n", "28 | \n", "
3 | \n", "Peconic Bay Winery 2001 Riesling (North Fork o... | \n", "84 | \n", "13.0 | \n", "Review not available at this time. | \n", "34 | \n", "
4 | \n", "Mount Baker Vineyards 2006 Barrel Select Sangi... | \n", "82 | \n", "16.0 | \n", "Very light, could almost be a rosé. | \n", "35 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "René Muré 2015 Clos Saint Landelin Vorbourg Gr... | \n", "97 | \n", "50.0 | \n", "The heady aromatic scent of fresh tangerine pe... | \n", "698 | \n", "
103723 | \n", "Domaine Marcel Deiss 2009 Altenberg de Berghei... | \n", "95 | \n", "66.0 | \n", "Lifted notes of dried pear, dried chamomile fl... | \n", "699 | \n", "
103724 | \n", "De Toren 2014 Book 17 XVII Red (Stellenbosch) | \n", "95 | \n", "330.0 | \n", "Only 95 cases were made of this Bordeaux-style... | \n", "723 | \n", "
103725 | \n", "Domaine Ostertag 2015 Muenchberg Grand Cru Rie... | \n", "97 | \n", "66.0 | \n", "There is something incredibly fruity and simul... | \n", "753 | \n", "
103726 | \n", "Saggi 2007 Red (Columbia Valley (WA)) | \n", "91 | \n", "45.0 | \n", "Dark, dusty, strongly scented with barrel toas... | \n", "829 | \n", "
103727 rows × 5 columns
\n", "\n", " | country | \n", "average_points | \n", "numberofwines | \n", "
---|---|---|---|
0 | \n", "England | \n", "91.6 | \n", "74 | \n", "
1 | \n", "India | \n", "90.2 | \n", "9 | \n", "
2 | \n", "Austria | \n", "90.1 | \n", "3337 | \n", "
3 | \n", "Germany | \n", "89.9 | \n", "2134 | \n", "
4 | \n", "Canada | \n", "89.4 | \n", "256 | \n", "
5 | \n", "Hungary | \n", "89.2 | \n", "145 | \n", "
6 | \n", "China | \n", "89.0 | \n", "1 | \n", "
7 | \n", "US | \n", "89.0 | \n", "37730 | \n", "
8 | \n", "France | \n", "88.9 | \n", "21828 | \n", "
9 | \n", "Italy | \n", "88.8 | \n", "11042 | \n", "
10 | \n", "Australia | \n", "88.8 | \n", "2037 | \n", "
11 | \n", "Luxembourg | \n", "88.7 | \n", "6 | \n", "
12 | \n", "None | \n", "88.6 | \n", "63 | \n", "
13 | \n", "Morocco | \n", "88.6 | \n", "28 | \n", "
14 | \n", "Switzerland | \n", "88.6 | \n", "7 | \n", "
15 | \n", "Israel | \n", "88.5 | \n", "500 | \n", "
16 | \n", "New Zealand | \n", "88.3 | \n", "1311 | \n", "
17 | \n", "South Africa | \n", "88.2 | \n", "1328 | \n", "
18 | \n", "Portugal | \n", "88.2 | \n", "5686 | \n", "
19 | \n", "Slovenia | \n", "88.1 | \n", "87 | \n", "
20 | \n", "Turkey | \n", "88.1 | \n", "90 | \n", "
21 | \n", "Bulgaria | \n", "87.9 | \n", "141 | \n", "
22 | \n", "Georgia | \n", "87.7 | \n", "86 | \n", "
23 | \n", "Lebanon | \n", "87.7 | \n", "35 | \n", "
24 | \n", "Armenia | \n", "87.5 | \n", "2 | \n", "
25 | \n", "Serbia | \n", "87.5 | \n", "12 | \n", "
26 | \n", "Czech Republic | \n", "87.3 | \n", "12 | \n", "
27 | \n", "Greece | \n", "87.3 | \n", "466 | \n", "
28 | \n", "Spain | \n", "87.3 | \n", "6581 | \n", "
29 | \n", "Moldova | \n", "87.2 | \n", "59 | \n", "
30 | \n", "Croatia | \n", "87.2 | \n", "73 | \n", "
31 | \n", "Cyprus | \n", "87.2 | \n", "11 | \n", "
32 | \n", "Slovakia | \n", "87.0 | \n", "1 | \n", "
33 | \n", "Uruguay | \n", "86.8 | \n", "109 | \n", "
34 | \n", "Macedonia | \n", "86.8 | \n", "12 | \n", "
35 | \n", "Argentina | \n", "86.7 | \n", "3797 | \n", "
36 | \n", "Bosnia and Herzegovina | \n", "86.5 | \n", "2 | \n", "
37 | \n", "Chile | \n", "86.5 | \n", "4361 | \n", "
38 | \n", "Romania | \n", "86.4 | \n", "120 | \n", "
39 | \n", "Mexico | \n", "85.3 | \n", "65 | \n", "
40 | \n", "Brazil | \n", "84.7 | \n", "52 | \n", "
41 | \n", "Ukraine | \n", "84.1 | \n", "14 | \n", "
42 | \n", "Egypt | \n", "84.0 | \n", "1 | \n", "
43 | \n", "Peru | \n", "83.6 | \n", "16 | \n", "
\n", " | country | \n", "average_points | \n", "numberofwines | \n", "
---|---|---|---|
0 | \n", "Austria | \n", "90.1 | \n", "3337 | \n", "
1 | \n", "Germany | \n", "89.9 | \n", "2134 | \n", "
2 | \n", "US | \n", "89.0 | \n", "37730 | \n", "
3 | \n", "France | \n", "88.9 | \n", "21828 | \n", "
4 | \n", "Italy | \n", "88.8 | \n", "11042 | \n", "
5 | \n", "Australia | \n", "88.8 | \n", "2037 | \n", "
6 | \n", "Israel | \n", "88.5 | \n", "500 | \n", "
7 | \n", "New Zealand | \n", "88.3 | \n", "1311 | \n", "
8 | \n", "Portugal | \n", "88.2 | \n", "5686 | \n", "
9 | \n", "South Africa | \n", "88.2 | \n", "1328 | \n", "
10 | \n", "Spain | \n", "87.3 | \n", "6581 | \n", "
11 | \n", "Argentina | \n", "86.7 | \n", "3797 | \n", "
12 | \n", "Chile | \n", "86.5 | \n", "4361 | \n", "
\n", " | country | \n", "average_points | \n", "numberofwines | \n", "
---|---|---|---|
0 | \n", "Austria | \n", "91.4 | \n", "581 | \n", "
1 | \n", "France | \n", "90.5 | \n", "691 | \n", "
2 | \n", "Germany | \n", "90.1 | \n", "1768 | \n", "
3 | \n", "Australia | \n", "89.4 | \n", "111 | \n", "
4 | \n", "US | \n", "88.1 | \n", "1600 | \n", "
\n", " | country | \n", "variety | \n", "average_points | \n", "numberofwines | \n", "
---|---|---|---|---|
0 | \n", "France | \n", "Tannat | \n", "91.5 | \n", "59 | \n", "
1 | \n", "Austria | \n", "Riesling | \n", "91.4 | \n", "581 | \n", "
2 | \n", "South Africa | \n", "Bordeaux-style Red Blend | \n", "90.6 | \n", "84 | \n", "
3 | \n", "France | \n", "Riesling | \n", "90.5 | \n", "691 | \n", "
4 | \n", "Austria | \n", "Chardonnay | \n", "90.4 | \n", "62 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
190 | \n", "Argentina | \n", "Chardonnay | \n", "84.9 | \n", "295 | \n", "
191 | \n", "Spain | \n", "Rosé | \n", "84.9 | \n", "149 | \n", "
192 | \n", "Portugal | \n", "Rosé | \n", "84.6 | \n", "235 | \n", "
193 | \n", "Spain | \n", "Rosado | \n", "84.6 | \n", "71 | \n", "
194 | \n", "Argentina | \n", "Sauvignon Blanc | \n", "84.3 | \n", "78 | \n", "
195 rows × 4 columns
\n", "\n", " | avg | \n", "
---|---|
0 | \n", "88.612107 | \n", "
\n", " | stddev_samp | \n", "
---|---|
0 | \n", "2.955039 | \n", "
\n", " | title | \n", "variety | \n", "points | \n", "points_z | \n", "
---|---|---|---|---|
0 | \n", "Casas del Bosque 2011 Reserva Sauvignon Blanc ... | \n", "Sauvignon Blanc | \n", "86 | \n", "-0.88395 | \n", "
1 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "86 | \n", "-0.88395 | \n", "
2 | \n", "Maurice Ecard 2009 Bourgogne | \n", "Chardonnay | \n", "86 | \n", "-0.88395 | \n", "
3 | \n", "McGregor 2010 Semi-Dry Riesling (Finger Lakes) | \n", "Riesling | \n", "86 | \n", "-0.88395 | \n", "
4 | \n", "Jules Taylor 2009 Ballochdale Estate Pinot Noi... | \n", "Pinot Noir | \n", "86 | \n", "-0.88395 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103722 | \n", "Glenora 2010 Gewürztraminer (Finger Lakes) | \n", "Gewürztraminer | \n", "86 | \n", "-0.88395 | \n", "
103723 | \n", "Hard Row To Hoe 2010 Marsanne (Yakima Valley) | \n", "Marsanne | \n", "86 | \n", "-0.88395 | \n", "
103724 | \n", "Animale 2009 Dolcetto (Columbia Valley (WA)) | \n", "Dolcetto | \n", "86 | \n", "-0.88395 | \n", "
103725 | \n", "Beresan 2008 The Buzz Yellow Jacket Vineyard R... | \n", "Red Blend | \n", "86 | \n", "-0.88395 | \n", "
103726 | \n", "Cabot Vineyards 2007 Syrah (Humboldt County) | \n", "Syrah | \n", "86 | \n", "-0.88395 | \n", "
103727 rows × 4 columns
\n", "\n", " | winery_id | \n", "
---|---|
0 | \n", "9112 | \n", "
1 | \n", "4562 | \n", "
2 | \n", "9557 | \n", "
3 | \n", "13540 | \n", "
4 | \n", "13381 | \n", "
5 | \n", "1547 | \n", "
6 | \n", "4257 | \n", "
7 | \n", "13118 | \n", "
8 | \n", "2007 | \n", "
9 | \n", "7060 | \n", "
10 | \n", "224 | \n", "
11 | \n", "9995 | \n", "
12 | \n", "8022 | \n", "
13 | \n", "5076 | \n", "
14 | \n", "4586 | \n", "
15 | \n", "2375 | \n", "
16 | \n", "14401 | \n", "
17 | \n", "12042 | \n", "
18 | \n", "9111 | \n", "
19 | \n", "4124 | \n", "
\n", " | winery_id | \n", "title | \n", "variety | \n", "points | \n", "price | \n", "
---|---|---|---|---|---|
0 | \n", "14401 | \n", "Wines & Winemakers 2012 Pegos Claros Colheita ... | \n", "Castelão | \n", "87 | \n", "15.0 | \n", "
1 | \n", "14401 | \n", "Wines & Winemakers 2013 Lua Cheia em Vinhas Ve... | \n", "Portuguese Red | \n", "87 | \n", "18.0 | \n", "
2 | \n", "14401 | \n", "Wines & Winemakers 2013 Lua Cheia em Vinhas Ve... | \n", "Portuguese Red | \n", "87 | \n", "12.0 | \n", "
3 | \n", "4124 | \n", "Chateau Ste. Michelle 2008 Syrah (Columbia Val... | \n", "Syrah | \n", "87 | \n", "13.0 | \n", "
4 | \n", "4586 | \n", "Concha y Toro 2010 Gravas del Maipo Syrah (Mai... | \n", "Syrah | \n", "91 | \n", "200.0 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
2742 | \n", "13381 | \n", "Trapiche 2016 Pure Malbec (Uco Valley) | \n", "Malbec | \n", "88 | \n", "15.0 | \n", "
2743 | \n", "9111 | \n", "Louis Jadot 2005 La Dominode Premier Cru (Sav... | \n", "Pinot Noir | \n", "90 | \n", "37.0 | \n", "
2744 | \n", "9995 | \n", "Montes 2009 Limited Selection Pinot Noir (Casa... | \n", "Pinot Noir | \n", "89 | \n", "20.0 | \n", "
2745 | \n", "4124 | \n", "Chateau Ste. Michelle 2012 Canoe Ridge Estate ... | \n", "Chardonnay | \n", "89 | \n", "22.0 | \n", "
2746 | \n", "14401 | \n", "Wines & Winemakers 2015 Nostalgia Alvarinho (V... | \n", "Alvarinho | \n", "88 | \n", "23.0 | \n", "
2747 rows × 5 columns
\n", "\n", " | winery_id | \n", "maxpoints | \n", "
---|---|---|
0 | \n", "11233 | \n", "91 | \n", "
1 | \n", "4790 | \n", "95 | \n", "
2 | \n", "3936 | \n", "87 | \n", "
3 | \n", "12502 | \n", "87 | \n", "
4 | \n", "5468 | \n", "92 | \n", "
... | \n", "... | \n", "... | \n", "
14566 | \n", "4035 | \n", "89 | \n", "
14567 | \n", "9180 | \n", "92 | \n", "
14568 | \n", "4827 | \n", "94 | \n", "
14569 | \n", "790 | \n", "83 | \n", "
14570 | \n", "10896 | \n", "91 | \n", "
14571 rows × 2 columns
\n", "\n", " | title | \n", "variety | \n", "points | \n", "price | \n", "
---|---|---|---|---|
0 | \n", "Marqués de Terán 2009 Selección Especial (Rioja) | \n", "Tempranillo | \n", "86 | \n", "24.0 | \n", "
1 | \n", "Alessandro Veglio 2011 Gattera (Barolo) | \n", "Nebbiolo | \n", "87 | \n", "NaN | \n", "
2 | \n", "Pingao 2013 Rioja | \n", "Tempranillo | \n", "87 | \n", "13.0 | \n", "
3 | \n", "Chateau Walla Walla 2008 Syrah (Walla Walla Va... | \n", "Syrah | \n", "87 | \n", "40.0 | \n", "
4 | \n", "Sweet Valley 2008 Cabernet Sauvignon (Walla Wa... | \n", "Cabernet Sauvignon | \n", "87 | \n", "35.0 | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
20643 | \n", "Kicker Cane 2014 Cabernet Sauvignon (Alexander... | \n", "Cabernet Sauvignon | \n", "88 | \n", "20.0 | \n", "
20644 | \n", "Tenuta Grimani 2015 Farinaldo (Soave) | \n", "Garganega | \n", "88 | \n", "NaN | \n", "
20645 | \n", "Vin Vault NV Cabernet Sauvignon (California) | \n", "Cabernet Sauvignon | \n", "88 | \n", "20.0 | \n", "
20646 | \n", "Dachshund NV Bubbles Sparkling (Germany) | \n", "Sparkling Blend | \n", "88 | \n", "17.0 | \n", "
20647 | \n", "Domaine Guillot-Broux 2009 Beaumont (Mâcon-Cr... | \n", "Pinot Noir | \n", "88 | \n", "NaN | \n", "
20648 rows × 4 columns
\n", "\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "location | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dbca25fcf746119e3aa | \n", "0.0 | \n", "Italy | \n", "Aromas include tropical fruit, broom, brimston... | \n", "87.0 | \n", "None | \n", "Sicily & Sardinia | \n", "Etna | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Nicosia 2013 Vulkà Bianco (Etna) | \n", "White Blend | \n", "Nicosia | \n", "NaN | \n", "
1 | \n", "5ed80dcca25fcf746119e3ab | \n", "1.0 | \n", "Portugal | \n", "This is ripe and fruity, a wine that is smooth... | \n", "87.0 | \n", "15 | \n", "Douro | \n", "None | \n", "Roger Voss | \n", "@vossroger | \n", "Quinta dos Avidagos 2011 Avidagos Red (Douro) | \n", "Portuguese Red | \n", "Quinta dos Avidagos | \n", "NaN | \n", "
2 | \n", "5ed80dcca25fcf746119e3ac | \n", "2.0 | \n", "US | \n", "Tart and snappy, the flavors of lime flesh and... | \n", "87.0 | \n", "14 | \n", "Oregon | \n", "Willamette Valley | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Rainstorm 2013 Pinot Gris (Willamette Valley) | \n", "Pinot Gris | \n", "Rainstorm | \n", "NaN | \n", "
3 | \n", "5ed80dcca25fcf746119e3ad | \n", "3.0 | \n", "US | \n", "Pineapple rind, lemon pith and orange blossom ... | \n", "87.0 | \n", "13 | \n", "Michigan | \n", "Lake Michigan Shore | \n", "Alexander Peartree | \n", "None | \n", "St. Julian 2013 Reserve Late Harvest Riesling ... | \n", "Riesling | \n", "St. Julian | \n", "NaN | \n", "
4 | \n", "5ed80dcca25fcf746119e3ae | \n", "4.0 | \n", "US | \n", "Much like the regular bottling from 2012, this... | \n", "87.0 | \n", "65 | \n", "Oregon | \n", "Willamette Valley | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Sweet Cheeks 2012 Vintner's Reserve Wild Child... | \n", "Pinot Noir | \n", "Sweet Cheeks | \n", "NaN | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
103726 | \n", "5ed80dcfa25fcf74611b78d8 | \n", "129970.0 | \n", "France | \n", "Big, rich and off-dry, this is powered by inte... | \n", "90.0 | \n", "21 | \n", "Alsace | \n", "Alsace | \n", "Roger Voss | \n", "@vossroger | \n", "Domaine Schoffit 2012 Lieu-dit Harth Cuvée Car... | \n", "Gewürztraminer | \n", "Domaine Schoffit | \n", "NaN | \n", "
103727 | \n", "5edd56e5b4e58ce3841e5dea | \n", "NaN | \n", "NaN | \n", "This wine goes great with dinner just like Dwy... | \n", "NaN | \n", "35 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "Red Blend | \n", "NaN | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "
103728 | \n", "5edd56e6b4e58ce3841e5deb | \n", "NaN | \n", "NaN | \n", "This wine will make you speak differently. May... | \n", "NaN | \n", "40.99 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "Anta Banderas A 10 2008 | \n", "Red Blend | \n", "NaN | \n", "{'region_1': 'Ribera del Duoro', 'region_2': N... | \n", "
103729 | \n", "5edd56e6b4e58ce3841e5dec | \n", "NaN | \n", "NaN | \n", "Someone drank my entire bottle of wine! | \n", "NaN | \n", "14.99 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "Barrymore Rose 2013 | \n", "Rose | \n", "NaN | \n", "{'region_1': 'Monterey', 'region_2': None, 'pr... | \n", "
103730 | \n", "5edd56e6b4e58ce3841e5ded | \n", "NaN | \n", "NaN | \n", "This upscale crunk juice is OOOKAAAAAAY. | \n", "NaN | \n", "NaN | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "2006 Little Jonathan Winery Cabernet Sauvignon | \n", "Cabernet Sauvignon | \n", "NaN | \n", "{'region_1': 'Central Coast', 'region_2': 'Pas... | \n", "
103731 rows × 14 columns
\n", "\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcca25fcf746119e498 | \n", "345 | \n", "Australia | \n", "This wine contains some material over 100 year... | \n", "100 | \n", "350.0 | \n", "Victoria | \n", "Rutherglen | \n", "Joe Czerwinski | \n", "@JoeCz | \n", "Chambers Rosewood Vineyards NV Rare Muscat (Ru... | \n", "Muscat | \n", "Chambers Rosewood Vineyards | \n", "
1 | \n", "5ed80dcea25fcf74611a5511 | \n", "36528 | \n", "France | \n", "This is a fabulous wine from the greatest Cham... | \n", "100 | \n", "259.0 | \n", "Champagne | \n", "Champagne | \n", "Roger Voss | \n", "@vossroger | \n", "Krug 2002 Brut (Champagne) | \n", "Champagne Blend | \n", "Krug | \n", "
2 | \n", "5ed80dcea25fcf74611a66df | \n", "42197 | \n", "Portugal | \n", "This is the latest release of what has long be... | \n", "100 | \n", "450.0 | \n", "Douro | \n", "None | \n", "Roger Voss | \n", "@vossroger | \n", "Casa Ferreirinha 2008 Barca-Velha Red (Douro) | \n", "Portuguese Red | \n", "Casa Ferreirinha | \n", "
3 | \n", "5ed80dcea25fcf74611a7214 | \n", "45781 | \n", "Italy | \n", "This gorgeous, fragrant wine opens with classi... | \n", "100 | \n", "550.0 | \n", "Tuscany | \n", "Brunello di Montalcino | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Biondi Santi 2010 Riserva (Brunello di Montal... | \n", "Sangiovese | \n", "Biondi Santi | \n", "
4 | \n", "5ed80dcea25fcf74611a9877 | \n", "58352 | \n", "France | \n", "This is a magnificently solid wine, initially ... | \n", "100 | \n", "150.0 | \n", "Bordeaux | \n", "Saint-Julien | \n", "Roger Voss | \n", "@vossroger | \n", "Château Léoville Barton 2010 Saint-Julien | \n", "Bordeaux-style Red Blend | \n", "Château Léoville Barton | \n", "
5 | \n", "5ed80dcfa25fcf74611afacd | \n", "89728 | \n", "France | \n", "This latest incarnation of the famous brand is... | \n", "100 | \n", "250.0 | \n", "Champagne | \n", "Champagne | \n", "Roger Voss | \n", "@vossroger | \n", "Louis Roederer 2008 Cristal Vintage Brut (Cha... | \n", "Champagne Blend | \n", "Louis Roederer | \n", "
6 | \n", "5ed80dcfa25fcf74611aface | \n", "89729 | \n", "France | \n", "This new release from a great vintage for Char... | \n", "100 | \n", "617.0 | \n", "Champagne | \n", "Champagne | \n", "Roger Voss | \n", "@vossroger | \n", "Salon 2006 Le Mesnil Blanc de Blancs Brut Char... | \n", "Chardonnay | \n", "Salon | \n", "
7 | \n", "5ed80dcfa25fcf74611b3fc4 | \n", "111753 | \n", "France | \n", "Almost black in color, this stunning wine is g... | \n", "100 | \n", "1500.0 | \n", "Bordeaux | \n", "Pauillac | \n", "Roger Voss | \n", "@vossroger | \n", "Château Lafite Rothschild 2010 Pauillac | \n", "Bordeaux-style Red Blend | \n", "Château Lafite Rothschild | \n", "
8 | \n", "5ed80dcfa25fcf74611b3fc5 | \n", "111755 | \n", "France | \n", "This is the finest Cheval Blanc for many years... | \n", "100 | \n", "1500.0 | \n", "Bordeaux | \n", "Saint-Émilion | \n", "Roger Voss | \n", "@vossroger | \n", "Château Cheval Blanc 2010 Saint-Émilion | \n", "Bordeaux-style Red Blend | \n", "Château Cheval Blanc | \n", "
9 | \n", "5ed80dcfa25fcf74611b3fc6 | \n", "111756 | \n", "France | \n", "A hugely powerful wine, full of dark, brooding... | \n", "100 | \n", "359.0 | \n", "Bordeaux | \n", "Saint-Julien | \n", "Roger Voss | \n", "@vossroger | \n", "Château Léoville Las Cases 2010 Saint-Julien | \n", "Bordeaux-style Red Blend | \n", "Château Léoville Las Cases | \n", "
10 | \n", "5ed80dcfa25fcf74611b4648 | \n", "113929 | \n", "US | \n", "In 2005 Charles Smith introduced three high-en... | \n", "100 | \n", "80.0 | \n", "Washington | \n", "Columbia Valley (WA) | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Charles Smith 2006 Royal City Syrah (Columbia ... | \n", "Syrah | \n", "Charles Smith | \n", "
11 | \n", "5ed80dcfa25fcf74611b499d | \n", "114972 | \n", "Portugal | \n", "A powerful and ripe wine, strongly influenced ... | \n", "100 | \n", "650.0 | \n", "Port | \n", "None | \n", "Roger Voss | \n", "@vossroger | \n", "Quinta do Noval 2011 Nacional Vintage (Port) | \n", "Port | \n", "Quinta do Noval | \n", "
12 | \n", "5ed80dcfa25fcf74611b6300 | \n", "122935 | \n", "France | \n", "Full of ripe fruit, opulent and concentrated, ... | \n", "100 | \n", "848.0 | \n", "Bordeaux | \n", "Pessac-Léognan | \n", "Roger Voss | \n", "@vossroger | \n", "Château Haut-Brion 2014 Pessac-Léognan | \n", "Bordeaux-style White Blend | \n", "Château Haut-Brion | \n", "
13 | \n", "5ed80dcfa25fcf74611b64d4 | \n", "123545 | \n", "US | \n", "Initially a rather subdued Frog; as if it has ... | \n", "100 | \n", "80.0 | \n", "Washington | \n", "Walla Walla Valley (WA) | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Cayuse 2008 Bionic Frog Syrah (Walla Walla Val... | \n", "Syrah | \n", "Cayuse | \n", "
\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcfa25fcf74611b4648 | \n", "113929 | \n", "US | \n", "In 2005 Charles Smith introduced three high-en... | \n", "100 | \n", "80.0 | \n", "Washington | \n", "Columbia Valley (WA) | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Charles Smith 2006 Royal City Syrah (Columbia ... | \n", "Syrah | \n", "Charles Smith | \n", "
1 | \n", "5ed80dcfa25fcf74611b64d4 | \n", "123545 | \n", "US | \n", "Initially a rather subdued Frog; as if it has ... | \n", "100 | \n", "80.0 | \n", "Washington | \n", "Walla Walla Valley (WA) | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Cayuse 2008 Bionic Frog Syrah (Walla Walla Val... | \n", "Syrah | \n", "Cayuse | \n", "
\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcea25fcf74611a0d3f | \n", "13402 | \n", "US | \n", "Clove and pepper spice the dark red cherry aro... | \n", "86 | \n", "17.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Anna Lee C. Iijima | \n", "None | \n", "Raffaldini 2007 Montepulciano (Swan Creek) | \n", "Montepulciano | \n", "Raffaldini | \n", "
1 | \n", "5ed80dcea25fcf74611a167b | \n", "16270 | \n", "US | \n", "The nose shows an aroma of blackberry that is ... | \n", "86 | \n", "17.0 | \n", "North Carolina | \n", "Yadkin Valley | \n", "Alexander Peartree | \n", "None | \n", "Shadow Springs 2011 Cabernet Franc (Yadkin Val... | \n", "Cabernet Franc | \n", "Shadow Springs | \n", "
2 | \n", "5ed80dcea25fcf74611a20a2 | \n", "19566 | \n", "US | \n", "Fruits, flowers and spice should lead the nose... | \n", "80 | \n", "15.0 | \n", "Ohio | \n", "Ohio | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Hermes 2006 Estate Bottled Nebbiolo (Ohio) | \n", "Nebbiolo | \n", "Hermes | \n", "
3 | \n", "5ed80dcea25fcf74611a23ee | \n", "20592 | \n", "US | \n", "Stewed blackberries and muddled cherries perva... | \n", "86 | \n", "23.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Alexander Peartree | \n", "None | \n", "Raffaldini 2012 Riserva Sangiovese (Swan Creek) | \n", "Sangiovese | \n", "Raffaldini | \n", "
4 | \n", "5ed80dcea25fcf74611a5fc4 | \n", "39935 | \n", "US | \n", "Friendly, appealing flavors fo pear, lychee, a... | \n", "84 | \n", "12.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Debonné 2008 Reserve Riesling (Grand River Val... | \n", "Riesling | \n", "Debonné | \n", "
5 | \n", "5ed80dcea25fcf74611a686c | \n", "42692 | \n", "US | \n", "Friendly, appealing flavors fo pear, lychee, a... | \n", "84 | \n", "12.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Debonné 2008 Reserve Riesling (Grand River Val... | \n", "Riesling | \n", "Debonné | \n", "
6 | \n", "5ed80dcea25fcf74611a7033 | \n", "45209 | \n", "US | \n", "Freshly squeezed lemons, lime and pretty white... | \n", "84 | \n", "16.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Anna Lee C. Iijima | \n", "None | \n", "Raffaldini 2009 Pinot Grigio (Swan Creek) | \n", "Pinot Grigio | \n", "Raffaldini | \n", "
7 | \n", "5ed80dcea25fcf74611a74db | \n", "46670 | \n", "US | \n", "Black fruit aromas show over toasted vanilla a... | \n", "85 | \n", "29.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Alexander Peartree | \n", "None | \n", "Raffaldini 2012 Riserva Montepulciano (Swan Cr... | \n", "Montepulciano | \n", "Raffaldini | \n", "
8 | \n", "5ed80dcea25fcf74611a7c95 | \n", "49154 | \n", "US | \n", "Lean and racy, with limes and tart green apple... | \n", "86 | \n", "10.0 | \n", "North Carolina | \n", "North Carolina | \n", "Joe Czerwinski | \n", "@JoeCz | \n", "Shelton Vineyards 2002 Riesling (North Carolina) | \n", "Riesling | \n", "Shelton Vineyards | \n", "
9 | \n", "5ed80dcea25fcf74611a8518 | \n", "52078 | \n", "US | \n", "Charred oak, green herbs and vanilla spice not... | \n", "82 | \n", "18.0 | \n", "North Carolina | \n", "Yadkin Valley | \n", "Anna Lee C. Iijima | \n", "None | \n", "Divine Llama 2007 In a Heart Beat Red (Yadkin ... | \n", "R. Blend | \n", "Divine Llama | \n", "
10 | \n", "5ed80dcea25fcf74611a8fe5 | \n", "55687 | \n", "US | \n", "Mostly Sangiovese with a small dose of Petit V... | \n", "84 | \n", "17.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Anna Lee C. Iijima | \n", "None | \n", "Raffaldini 2007 Riserva Sangiovese (Swan Creek) | \n", "Sangiovese | \n", "Raffaldini | \n", "
11 | \n", "5ed80dcea25fcf74611a8fe9 | \n", "55693 | \n", "US | \n", "Aromas of toasted oak, green leaves, vanilla a... | \n", "84 | \n", "25.0 | \n", "North Carolina | \n", "North Carolina | \n", "Anna Lee C. Iijima | \n", "None | \n", "RayLen 2006 Eagle's Select Red Wine Red (North... | \n", "Bordeaux-style Red Blend | \n", "RayLen | \n", "
12 | \n", "5ed80dcfa25fcf74611ac51f | \n", "72535 | \n", "US | \n", "Who knew Ohio made such tasty Chardonnay? Brig... | \n", "87 | \n", "11.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Anna Lee C. Iijima | \n", "None | \n", "Debonné 2009 Chardonnay (Grand River Valley) | \n", "Chardonnay | \n", "Debonné | \n", "
13 | \n", "5ed80dcfa25fcf74611ae168 | \n", "81619 | \n", "US | \n", "Strawberry and raspberry Kool-Aid aromas are s... | \n", "85 | \n", "21.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Alexander Peartree | \n", "None | \n", "Laurel Gray 2012 Estate Grown Cabernet Franc (... | \n", "Cabernet Franc | \n", "Laurel Gray | \n", "
14 | \n", "5ed80dcfa25fcf74611af839 | \n", "88841 | \n", "US | \n", "This is a vibrant, energetic Chardonnay that s... | \n", "84 | \n", "17.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Debonné 2007 Vintner's Selection Chardonnay (G... | \n", "Chardonnay | \n", "Debonné | \n", "
15 | \n", "5ed80dcfa25fcf74611b08bb | \n", "94267 | \n", "US | \n", "Although the nose offers darker notes of petro... | \n", "83 | \n", "15.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Anna Lee C. Iijima | \n", "None | \n", "Debonné 2008 Lot 807 Reserve Riesling (Grand R... | \n", "Riesling | \n", "Debonné | \n", "
16 | \n", "5ed80dcfa25fcf74611b08be | \n", "94275 | \n", "US | \n", "The nose on this bright red blend from Sanders... | \n", "83 | \n", "18.0 | \n", "North Carolina | \n", "Yadkin Valley | \n", "Anna Lee C. Iijima | \n", "None | \n", "Sanders Ridge 2008 Big Woods Red (Yadkin Valley) | \n", "Bordeaux-style Red Blend | \n", "Sanders Ridge | \n", "
17 | \n", "5ed80dcfa25fcf74611b13ff | \n", "97836 | \n", "US | \n", "Smoke wafts over pressed apple and lemon notes... | \n", "83 | \n", "13.0 | \n", "North Carolina | \n", "North Carolina | \n", "Anna Lee C. Iijima | \n", "None | \n", "RayLen 2009 Riesling (North Carolina) | \n", "Riesling | \n", "RayLen | \n", "
18 | \n", "5ed80dcfa25fcf74611b1c1f | \n", "100445 | \n", "US | \n", "Fresh minerality and dancing floral notes make... | \n", "84 | \n", "11.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Debonné 2006 Reserve Riesling (Grand River Val... | \n", "Riesling | \n", "Debonné | \n", "
19 | \n", "5ed80dcfa25fcf74611b1c23 | \n", "100452 | \n", "US | \n", "A slightly floral but lively nose is followed ... | \n", "84 | \n", "15.0 | \n", "Ohio | \n", "Grand River Valley | \n", "Susan Kostrzewa | \n", "@suskostrzewa | \n", "Debonné 2006 Lot 707 Reserve Riesling (Grand R... | \n", "Riesling | \n", "Debonné | \n", "
20 | \n", "5ed80dcfa25fcf74611b29f1 | \n", "104722 | \n", "US | \n", "There are enticing hints of berries and cream ... | \n", "86 | \n", "15.0 | \n", "North Carolina | \n", "North Carolina | \n", "Anna Lee C. Iijima | \n", "None | \n", "Biltmore Estate 2010 Reserve Chardonnay (North... | \n", "Chardonnay | \n", "Biltmore Estate | \n", "
21 | \n", "5ed80dcfa25fcf74611b4fb6 | \n", "116912 | \n", "US | \n", "Black cherry aromas are dwarfed by notes of wi... | \n", "83 | \n", "24.0 | \n", "North Carolina | \n", "Swan Creek | \n", "Alexander Peartree | \n", "None | \n", "Raffaldini 2012 Montepulciano (Swan Creek) | \n", "Montepulciano | \n", "Raffaldini | \n", "
22 | \n", "5ed80dcfa25fcf74611b55ee | \n", "118895 | \n", "US | \n", "Bright red fruits achieve a decent amount of r... | \n", "84 | \n", "18.0 | \n", "North Carolina | \n", "North Carolina | \n", "Anna Lee C. Iijima | \n", "None | \n", "RayLen 2008 Category 5 Red Wine Red (North Car... | \n", "R. Blend | \n", "RayLen | \n", "
\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcca25fcf746119e3bd | \n", "19 | \n", "US | \n", "Red fruit aromas pervade on the nose, with cig... | \n", "87 | \n", "32.0 | \n", "Virginia | \n", "Virginia | \n", "Alexander Peartree | \n", "None | \n", "Quiévremont 2012 Meritage (Virginia) | \n", "Meritage | \n", "Quiévremont | \n", "
1 | \n", "5ed80dcca25fcf746119e3be | \n", "20 | \n", "US | \n", "Ripe aromas of dark berries mingle with ample ... | \n", "87 | \n", "23.0 | \n", "Virginia | \n", "Virginia | \n", "Alexander Peartree | \n", "None | \n", "Quiévremont 2012 Vin de Maison Red (Virginia) | \n", "R. Blend | \n", "Quiévremont | \n", "
2 | \n", "5ed80dcca25fcf746119e498 | \n", "345 | \n", "Australia | \n", "This wine contains some material over 100 year... | \n", "100 | \n", "350.0 | \n", "Victoria | \n", "Rutherglen | \n", "Joe Czerwinski | \n", "@JoeCz | \n", "Chambers Rosewood Vineyards NV Rare Muscat (Ru... | \n", "Muscat | \n", "Chambers Rosewood Vineyards | \n", "
3 | \n", "5ed80dcea25fcf746119e8d0 | \n", "1625 | \n", "US | \n", "Popping with aromas of lychee, rose, geranium ... | \n", "85 | \n", "16.0 | \n", "Virginia | \n", "Virginia | \n", "Carrie Dykes | \n", "None | \n", "The Williamsburg Winery 2015 A Midsummer Night... | \n", "White Blend | \n", "The Williamsburg Winery | \n", "
4 | \n", "5ed80dcea25fcf746119e8d6 | \n", "1631 | \n", "US | \n", "Powerful aromas of lychee, mango and peach giv... | \n", "85 | \n", "22.0 | \n", "Virginia | \n", "Middleburg | \n", "Carrie Dykes | \n", "None | \n", "Blue Valley 2015 Muskat Ottonel (Middleburg) | \n", "Muskat Ottonel | \n", "Blue Valley | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
388 | \n", "5ed80dcfa25fcf74611b71b3 | \n", "127736 | \n", "US | \n", "Dense with alluring aromas, this wine is full ... | \n", "88 | \n", "30.0 | \n", "Virginia | \n", "Virginia | \n", "Carrie Dykes | \n", "None | \n", "Early Mountain 2015 Elevation Red (Virginia) | \n", "R. Blend | \n", "Early Mountain | \n", "
389 | \n", "5ed80dcfa25fcf74611b71bd | \n", "127746 | \n", "US | \n", "A grape known in Uruguay and Madiran has prove... | \n", "88 | \n", "25.0 | \n", "Virginia | \n", "Virginia | \n", "Carrie Dykes | \n", "None | \n", "Horton 2014 Tannat (Virginia) | \n", "Tannat | \n", "Horton | \n", "
390 | \n", "5ed80dcfa25fcf74611b7447 | \n", "128576 | \n", "US | \n", "Peach and steely lemon aromas carry to a citru... | \n", "87 | \n", "28.0 | \n", "Virginia | \n", "Monticello | \n", "Alexander Peartree | \n", "None | \n", "Pollak 2012 Reserve Chardonnay (Monticello) | \n", "Chardonnay | \n", "Pollak | \n", "
391 | \n", "5ed80dcfa25fcf74611b7708 | \n", "129422 | \n", "US | \n", "The nose of this wine is bursting with raspber... | \n", "89 | \n", "32.0 | \n", "Virginia | \n", "Monticello | \n", "Carrie Dykes | \n", "None | \n", "Stinson 2014 Meritage (Monticello) | \n", "Meritage | \n", "Stinson | \n", "
392 | \n", "5ed80dcfa25fcf74611b772a | \n", "129459 | \n", "US | \n", "Somehow, winemaker Luca Paschina manages to ma... | \n", "87 | \n", "23.0 | \n", "Virginia | \n", "Virginia | \n", "Carrie Dykes | \n", "None | \n", "Barboursville Vineyards 2015 Reserve Vermentin... | \n", "Vermentino | \n", "Barboursville Vineyards | \n", "
393 rows × 13 columns
\n", "\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "location | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcca25fcf746119e3d4 | \n", "60.0 | \n", "US | \n", "Syrupy and dense, this wine is jammy in plum a... | \n", "86.0 | \n", "100 | \n", "California | \n", "Napa Valley | \n", "Virginie Boone | \n", "@vboone | \n", "Okapi 2013 Estate Cabernet Sauvignon (Napa Val... | \n", "Cabernet Sauvignon | \n", "Okapi | \n", "NaN | \n", "
1 | \n", "5ed80dcca25fcf746119e42c | \n", "168.0 | \n", "US | \n", "A fairly elegant expression of the variety, th... | \n", "91.0 | \n", "95 | \n", "California | \n", "Napa Valley | \n", "Virginie Boone | \n", "@vboone | \n", "Duckhorn 2012 Rector Creek Vineyard Merlot (Na... | \n", "Merlot | \n", "Duckhorn | \n", "NaN | \n", "
2 | \n", "5ed80dcca25fcf746119e476 | \n", "284.0 | \n", "Argentina | \n", "This huge Malbec defines jammy and concentrate... | \n", "92.0 | \n", "215 | \n", "Mendoza Province | \n", "Perdriel | \n", "Michael Schachner | \n", "@wineschach | \n", "Viña Cobos 2011 Marchiori Vineyard Block C2 Ma... | \n", "Malbec | \n", "Viña Cobos | \n", "NaN | \n", "
3 | \n", "5ed80dcca25fcf746119e498 | \n", "345.0 | \n", "Australia | \n", "This wine contains some material over 100 year... | \n", "100.0 | \n", "350 | \n", "Victoria | \n", "Rutherglen | \n", "Joe Czerwinski | \n", "@JoeCz | \n", "Chambers Rosewood Vineyards NV Rare Muscat (Ru... | \n", "Muscat | \n", "Chambers Rosewood Vineyards | \n", "NaN | \n", "
4 | \n", "5ed80dcca25fcf746119e499 | \n", "346.0 | \n", "Australia | \n", "This deep brown wine smells like a damp, mossy... | \n", "98.0 | \n", "350 | \n", "Victoria | \n", "Rutherglen | \n", "Joe Czerwinski | \n", "@JoeCz | \n", "Chambers Rosewood Vineyards NV Rare Muscadelle... | \n", "Muscadelle | \n", "Chambers Rosewood Vineyards | \n", "NaN | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
3697 | \n", "5ed80dcfa25fcf74611b78a8 | \n", "129919.0 | \n", "US | \n", "This ripe, rich, almost decadently thick wine ... | \n", "91.0 | \n", "105 | \n", "Washington | \n", "Walla Walla Valley (WA) | \n", "Paul Gregutt | \n", "@paulgwine | \n", "Nicholas Cole Cellars 2004 Reserve Red (Walla ... | \n", "R. Blend | \n", "Nicholas Cole Cellars | \n", "NaN | \n", "
3698 | \n", "5ed80dcfa25fcf74611b78b2 | \n", "129931.0 | \n", "France | \n", "A powerful, chunky wine, packed with solid tan... | \n", "91.0 | \n", "107 | \n", "Burgundy | \n", "Grands-Echezeaux | \n", "Roger Voss | \n", "@vossroger | \n", "Henri de Villamont 2005 Grands-Echezeaux | \n", "Pinot Noir | \n", "Henri de Villamont | \n", "NaN | \n", "
3699 | \n", "5edd56e5b4e58ce3841e5dea | \n", "NaN | \n", "NaN | \n", "This wine goes great with dinner just like Dwy... | \n", "NaN | \n", "35 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "Red Blend | \n", "NaN | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "
3700 | \n", "5edd56e6b4e58ce3841e5deb | \n", "NaN | \n", "NaN | \n", "This wine will make you speak differently. May... | \n", "NaN | \n", "40.99 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "Anta Banderas A 10 2008 | \n", "Red Blend | \n", "NaN | \n", "{'region_1': 'Ribera del Duoro', 'region_2': N... | \n", "
3701 | \n", "5edd56e6b4e58ce3841e5dec | \n", "NaN | \n", "NaN | \n", "Someone drank my entire bottle of wine! | \n", "NaN | \n", "14.99 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "Barrymore Rose 2013 | \n", "Rose | \n", "NaN | \n", "{'region_1': 'Monterey', 'region_2': None, 'pr... | \n", "
3702 rows × 14 columns
\n", "\n", " | _id | \n", "title | \n", "description | \n", "taster_name | \n", "taster_twitter_handle | \n", "price | \n", "variety | \n", "location | \n", "
---|---|---|---|---|---|---|---|---|
0 | \n", "5edd56e5b4e58ce3841e5dea | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "This wine goes great with dinner just like Dwy... | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "35 | \n", "Red Blend | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "
\n", " | _id | \n", "title | \n", "
---|---|---|
0 | \n", "5ed80dcca25fcf746119e3c1 | \n", "Bianchi 2011 Signature Selection Merlot (Paso ... | \n", "
1 | \n", "5ed80dcca25fcf746119e3cd | \n", "Sundance 2011 Merlot (Maule Valley) | \n", "
2 | \n", "5ed80dcca25fcf746119e3ef | \n", "Passaggio 2014 Blau Vineyards Merlot (Knights ... | \n", "
3 | \n", "5ed80dcca25fcf746119e42c | \n", "Duckhorn 2012 Rector Creek Vineyard Merlot (Na... | \n", "
4 | \n", "5ed80dcca25fcf746119e437 | \n", "Viña Bisquertt 2007 Casa La Joya Reserve Merlo... | \n", "
... | \n", "... | \n", "... | \n", "
2094 | \n", "5ed80dcfa25fcf74611b77f0 | \n", "Castillo de Monjardin 2009 Deyo Merlot (Navarra) | \n", "
2095 | \n", "5ed80dcfa25fcf74611b7862 | \n", "Bonair 2006 Chateau Puryear Vineyard Merlot (R... | \n", "
2096 | \n", "5ed80dcfa25fcf74611b7865 | \n", "Hyatt 2005 Merlot (Rattlesnake Hills) | \n", "
2097 | \n", "5ed80dcfa25fcf74611b786b | \n", "Ca' Momi 2013 Reserve Merlot (Carneros) | \n", "
2098 | \n", "5ed80dcfa25fcf74611b7896 | \n", "Psagot 2014 Merlot | \n", "
2099 rows × 2 columns
\n", "\n", " | title | \n", "
---|---|
0 | \n", "Bianchi 2011 Signature Selection Merlot (Paso ... | \n", "
1 | \n", "Sundance 2011 Merlot (Maule Valley) | \n", "
2 | \n", "Passaggio 2014 Blau Vineyards Merlot (Knights ... | \n", "
3 | \n", "Duckhorn 2012 Rector Creek Vineyard Merlot (Na... | \n", "
4 | \n", "Viña Bisquertt 2007 Casa La Joya Reserve Merlo... | \n", "
... | \n", "... | \n", "
2094 | \n", "Castillo de Monjardin 2009 Deyo Merlot (Navarra) | \n", "
2095 | \n", "Bonair 2006 Chateau Puryear Vineyard Merlot (R... | \n", "
2096 | \n", "Hyatt 2005 Merlot (Rattlesnake Hills) | \n", "
2097 | \n", "Ca' Momi 2013 Reserve Merlot (Carneros) | \n", "
2098 | \n", "Psagot 2014 Merlot | \n", "
2099 rows × 1 columns
\n", "\n", " | points | \n", "price | \n", "title | \n", "variety | \n", "
---|---|---|---|---|
0 | \n", "87 | \n", "22.0 | \n", "Bianchi 2011 Signature Selection Merlot (Paso ... | \n", "Merlot | \n", "
1 | \n", "86 | \n", "9.0 | \n", "Sundance 2011 Merlot (Maule Valley) | \n", "Merlot | \n", "
2 | \n", "86 | \n", "55.0 | \n", "Passaggio 2014 Blau Vineyards Merlot (Knights ... | \n", "Merlot | \n", "
3 | \n", "91 | \n", "95.0 | \n", "Duckhorn 2012 Rector Creek Vineyard Merlot (Na... | \n", "Merlot | \n", "
4 | \n", "88 | \n", "11.0 | \n", "Viña Bisquertt 2007 Casa La Joya Reserve Merlo... | \n", "Merlot | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
2094 | \n", "87 | \n", "18.0 | \n", "Castillo de Monjardin 2009 Deyo Merlot (Navarra) | \n", "Merlot | \n", "
2095 | \n", "86 | \n", "20.0 | \n", "Bonair 2006 Chateau Puryear Vineyard Merlot (R... | \n", "Merlot | \n", "
2096 | \n", "86 | \n", "10.0 | \n", "Hyatt 2005 Merlot (Rattlesnake Hills) | \n", "Merlot | \n", "
2097 | \n", "90 | \n", "44.0 | \n", "Ca' Momi 2013 Reserve Merlot (Carneros) | \n", "Merlot | \n", "
2098 | \n", "91 | \n", "32.0 | \n", "Psagot 2014 Merlot | \n", "Merlot | \n", "
2099 rows × 4 columns
\n", "\n", " | _id | \n", "title | \n", "description | \n", "taster_name | \n", "taster_twitter_handle | \n", "price | \n", "variety | \n", "location | \n", "
---|---|---|---|---|---|---|---|---|
0 | \n", "5edd56e5b4e58ce3841e5dea | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "This wine goes great with dinner just like Dwy... | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "45 | \n", "Red Blend | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "
\n", " | _id | \n", "title | \n", "description | \n", "taster_name | \n", "taster_twitter_handle | \n", "price | \n", "variety | \n", "location | \n", "score | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "5edd56e5b4e58ce3841e5dea | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "This wine goes great with dinner just like Dwy... | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "45 | \n", "Red Blend | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "90 | \n", "
\n", " | _id | \n", "title | \n", "description | \n", "taster_name | \n", "taster_twitter_handle | \n", "price | \n", "variety | \n", "location | \n", "score | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "5edd56e5b4e58ce3841e5dea | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "This wine goes great with dinner just like Dwy... | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "50 | \n", "Red Blend | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "95 | \n", "
\n", " | _id | \n", "title | \n", "description | \n", "taster_name | \n", "taster_twitter_handle | \n", "price | \n", "variety | \n", "location | \n", "score | \n", "
---|---|---|---|---|---|---|---|---|---|
0 | \n", "5edd56e5b4e58ce3841e5dea | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "This wine is very good. Not as great as me. Bu... | \n", "LeBron James | \n", "@kingjames | \n", "45 | \n", "Red Blend | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "99 | \n", "
\n", " | _id | \n", "wine_id | \n", "country | \n", "description | \n", "points | \n", "price | \n", "province | \n", "region | \n", "taster_name | \n", "taster_twitter_handle | \n", "title | \n", "variety | \n", "winery | \n", "location | \n", "score | \n", "
---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|
0 | \n", "5ed80dcca25fcf746119e3be | \n", "20.0 | \n", "US | \n", "Ripe aromas of dark berries mingle with ample ... | \n", "87.0 | \n", "23 | \n", "Virginia | \n", "Virginia | \n", "Alexander Peartree | \n", "None | \n", "Quiévremont 2012 Vin de Maison Red (Virginia) | \n", "R. Blend | \n", "Quiévremont | \n", "NaN | \n", "NaN | \n", "
1 | \n", "5ed80dcca25fcf746119e3c6 | \n", "28.0 | \n", "Italy | \n", "Aromas suggest mature berry, scorched earth, a... | \n", "87.0 | \n", "17 | \n", "Sicily & Sardinia | \n", "Cerasuolo di Vittoria | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Terre di Giurfo 2011 Mascaria Barricato (Cera... | \n", "R. Blend | \n", "Terre di Giurfo | \n", "NaN | \n", "NaN | \n", "
2 | \n", "5ed80dcca25fcf746119e3dc | \n", "68.0 | \n", "US | \n", "Very deep in color and spicy-smoky in flavor, ... | \n", "86.0 | \n", "12 | \n", "California | \n", "California | \n", "Jim Gordon | \n", "@gordone_cellars | \n", "Cocobon 2014 Red (California) | \n", "R. Blend | \n", "Cocobon | \n", "NaN | \n", "NaN | \n", "
3 | \n", "5ed80dcca25fcf746119e3f2 | \n", "90.0 | \n", "US | \n", "This blend of Sangiovese, Malbec, Cabernet Sau... | \n", "88.0 | \n", "23 | \n", "California | \n", "Sonoma County | \n", "Virginie Boone | \n", "@vboone | \n", "Ferrari-Carano 2014 Siena Red (Sonoma County) | \n", "R. Blend | \n", "Ferrari-Carano | \n", "NaN | \n", "NaN | \n", "
4 | \n", "5ed80dcca25fcf746119e400 | \n", "104.0 | \n", "Italy | \n", "Made with 65% Sangiovese, 20% Merlot and 15% C... | \n", "87.0 | \n", "16 | \n", "Tuscany | \n", "Toscana | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Madonna Alta 2014 Nativo Red (Toscana) | \n", "R. Blend | \n", "Madonna Alta | \n", "NaN | \n", "NaN | \n", "
... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "... | \n", "
7106 | \n", "5ed80dcfa25fcf74611b78b3 | \n", "129932.0 | \n", "Argentina | \n", "Andeluna's top wines tend to be ripe and plump... | \n", "91.0 | \n", "55 | \n", "Mendoza Province | \n", "Uco Valley | \n", "Michael Schachner | \n", "@wineschach | \n", "Andeluna 2004 Pasionado Red (Uco Valley) | \n", "R. Blend | \n", "Andeluna | \n", "NaN | \n", "NaN | \n", "
7107 | \n", "5ed80dcfa25fcf74611b78bd | \n", "129943.0 | \n", "Italy | \n", "A blend of Nero d'Avola and Syrah, this convey... | \n", "90.0 | \n", "29 | \n", "Sicily & Sardinia | \n", "Sicilia | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Baglio del Cristo di Campobello 2012 Adènzia R... | \n", "R. Blend | \n", "Baglio del Cristo di Campobello | \n", "NaN | \n", "NaN | \n", "
7108 | \n", "5ed80dcfa25fcf74611b78c1 | \n", "129947.0 | \n", "Italy | \n", "A blend of 65% Cabernet Sauvignon, 30% Merlot ... | \n", "90.0 | \n", "20 | \n", "Sicily & Sardinia | \n", "Terre Siciliane | \n", "Kerin O’Keefe | \n", "@kerinokeefe | \n", "Feudo Principi di Butera 2012 Symposio Red (Te... | \n", "R. Blend | \n", "Feudo Principi di Butera | \n", "NaN | \n", "NaN | \n", "
7109 | \n", "5edd56e5b4e58ce3841e5dea | \n", "NaN | \n", "NaN | \n", "This wine is very good. Not as great as me. Bu... | \n", "NaN | \n", "45 | \n", "NaN | \n", "NaN | \n", "LeBron James | \n", "@kingjames | \n", "2016 Napa Valley Three By Wade Red Blend | \n", "R. Blend | \n", "NaN | \n", "{'region_1': 'Napa Valley', 'region_2': None, ... | \n", "99.0 | \n", "
7110 | \n", "5edd56e6b4e58ce3841e5deb | \n", "NaN | \n", "NaN | \n", "This wine will make you speak differently. May... | \n", "NaN | \n", "40.99 | \n", "NaN | \n", "NaN | \n", "Jonathan Kropko | \n", "@jmk5131 | \n", "Anta Banderas A 10 2008 | \n", "R. Blend | \n", "NaN | \n", "{'region_1': 'Ribera del Duoro', 'region_2': N... | \n", "NaN | \n", "
7111 rows × 15 columns
\n", "