Files
school-of-sre/level101/databases_sql/query_performance/index.html
2021-08-04 16:58:59 +00:00

1812 lines
53 KiB
HTML
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

<!doctype html>
<html lang="en" class="no-js">
<head>
<meta charset="utf-8">
<meta name="viewport" content="width=device-width,initial-scale=1">
<link rel="shortcut icon" href="../../../img/favicon.ico">
<meta name="generator" content="mkdocs-1.1.2, mkdocs-material-6.2.8">
<title>Query Performance - School Of SRE</title>
<link rel="stylesheet" href="../../../assets/stylesheets/main.cb6bc1d0.min.css">
<link rel="stylesheet" href="../../../assets/stylesheets/palette.39b8e14a.min.css">
<link rel="preconnect" href="https://fonts.gstatic.com" crossorigin>
<link rel="stylesheet" href="https://fonts.googleapis.com/css?family=Roboto:300,400,400i,700%7CRoboto+Mono&display=fallback">
<style>body,input{font-family:"Roboto",-apple-system,BlinkMacSystemFont,Helvetica,Arial,sans-serif}code,kbd,pre{font-family:"Roboto Mono",SFMono-Regular,Consolas,Menlo,monospace}</style>
<link rel="stylesheet" href="../../../stylesheets/custom.css">
</head>
<body dir="ltr" data-md-color-scheme="" data-md-color-primary="none" data-md-color-accent="none">
<input class="md-toggle" data-md-toggle="drawer" type="checkbox" id="__drawer" autocomplete="off">
<input class="md-toggle" data-md-toggle="search" type="checkbox" id="__search" autocomplete="off">
<label class="md-overlay" for="__drawer"></label>
<div data-md-component="skip">
<a href="#query-performance-improvement" class="md-skip">
Skip to content
</a>
</div>
<div data-md-component="announce">
</div>
<script async defer data-domain="linkedin.github.io" src="https://tracking.eskratch.com/js/plausible.js"></script>
<header class="md-header" data-md-component="header">
<nav class="md-header-nav md-grid" aria-label="Header">
<a href="../../.." title="School Of SRE" class="md-header-nav__button md-logo" aria-label="School Of SRE">
<img src="../../../img/sos.png" alt="logo">
</a>
<!-- Button to open drawer -->
<label class="md-header-nav__button md-icon" for="__drawer">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M3 6h18v2H3V6m0 5h18v2H3v-2m0 5h18v2H3v-2z"/></svg>
</label>
<div class="md-header-nav__title" data-md-component="header-title">
<div class="md-header-nav__ellipsis">
<span class="md-header-nav__topic md-ellipsis">
<a href="../../.." title="School Of SRE" >
School Of SRE
</a>
</span>
<span class="md-header-nav__topic md-ellipsis">
Query Performance
</span>
</div>
</div>
<label class="md-header-nav__button md-icon" for="__search">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M9.5 3A6.5 6.5 0 0116 9.5c0 1.61-.59 3.09-1.56 4.23l.27.27h.79l5 5-1.5 1.5-5-5v-.79l-.27-.27A6.516 6.516 0 019.5 16 6.5 6.5 0 013 9.5 6.5 6.5 0 019.5 3m0 2C7 5 5 7 5 9.5S7 14 9.5 14 14 12 14 9.5 12 5 9.5 5z"/></svg>
</label>
<div class="md-search" data-md-component="search" role="dialog">
<label class="md-search__overlay" for="__search"></label>
<div class="md-search__inner" role="search">
<form class="md-search__form" name="search">
<input type="text" class="md-search__input" name="query" aria-label="Search" placeholder="Search" autocapitalize="off" autocorrect="off" autocomplete="off" spellcheck="false" data-md-component="search-query" data-md-state="active" required>
<label class="md-search__icon md-icon" for="__search">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M9.5 3A6.5 6.5 0 0116 9.5c0 1.61-.59 3.09-1.56 4.23l.27.27h.79l5 5-1.5 1.5-5-5v-.79l-.27-.27A6.516 6.516 0 019.5 16 6.5 6.5 0 013 9.5 6.5 6.5 0 019.5 3m0 2C7 5 5 7 5 9.5S7 14 9.5 14 14 12 14 9.5 12 5 9.5 5z"/></svg>
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M20 11v2H8l5.5 5.5-1.42 1.42L4.16 12l7.92-7.92L13.5 5.5 8 11h12z"/></svg>
</label>
<button type="reset" class="md-search__icon md-icon" aria-label="Clear" data-md-component="search-reset" tabindex="-1">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M19 6.41L17.59 5 12 10.59 6.41 5 5 6.41 10.59 12 5 17.59 6.41 19 12 13.41 17.59 19 19 17.59 13.41 12 19 6.41z"/></svg>
</button>
</form>
<div class="md-search__output">
<div class="md-search__scrollwrap" data-md-scrollfix>
<div class="md-search-result" data-md-component="search-result">
<div class="md-search-result__meta">
Initializing search
</div>
<ol class="md-search-result__list"></ol>
</div>
</div>
</div>
</div>
</div>
</nav>
</header>
<div class="md-container" data-md-component="container">
<main class="md-main" data-md-component="main">
<div class="md-main__inner md-grid">
<div class="md-sidebar md-sidebar--primary" data-md-component="navigation" >
<div class="md-sidebar__scrollwrap">
<div class="md-sidebar__inner">
<nav class="md-nav md-nav--primary" aria-label="Navigation" data-md-level="0">
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../.." class="md-nav__link">
Home
</a>
</li>
<li class="md-nav__item md-nav__item--active md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2" type="checkbox" id="nav-2" checked>
<label class="md-nav__link" for="nav-2">
Level 101
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Level 101" data-md-level="1">
<label class="md-nav__title" for="nav-2">
<span class="md-nav__icon md-icon"></span>
Level 101
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-1" type="checkbox" id="nav-2-1" >
<label class="md-nav__link" for="nav-2-1">
Fundamentals Series
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Fundamentals Series" data-md-level="2">
<label class="md-nav__title" for="nav-2-1">
<span class="md-nav__icon md-icon"></span>
Fundamentals Series
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-1-1" type="checkbox" id="nav-2-1-1" >
<label class="md-nav__link" for="nav-2-1-1">
Linux Basics
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Linux Basics" data-md-level="3">
<label class="md-nav__title" for="nav-2-1-1">
<span class="md-nav__icon md-icon"></span>
Linux Basics
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../linux_basics/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_basics/command_line_basics/" class="md-nav__link">
Command Line Basics
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_basics/linux_server_administration/" class="md-nav__link">
Server Administration
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_basics/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-1-2" type="checkbox" id="nav-2-1-2" >
<label class="md-nav__link" for="nav-2-1-2">
Git
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Git" data-md-level="3">
<label class="md-nav__title" for="nav-2-1-2">
<span class="md-nav__icon md-icon"></span>
Git
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../git/git-basics/" class="md-nav__link">
Git Basics
</a>
</li>
<li class="md-nav__item">
<a href="../../git/branches/" class="md-nav__link">
Working With Branches
</a>
</li>
<li class="md-nav__item">
<a href="../../git/github-hooks/" class="md-nav__link">
Github and Hooks
</a>
</li>
<li class="md-nav__item">
<a href="../../git/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-1-3" type="checkbox" id="nav-2-1-3" >
<label class="md-nav__link" for="nav-2-1-3">
Linux Networking
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Linux Networking" data-md-level="3">
<label class="md-nav__title" for="nav-2-1-3">
<span class="md-nav__icon md-icon"></span>
Linux Networking
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../linux_networking/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/dns/" class="md-nav__link">
DNS
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/udp/" class="md-nav__link">
UDP
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/http/" class="md-nav__link">
HTTP
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/tcp/" class="md-nav__link">
TCP
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/ipr/" class="md-nav__link">
Routing
</a>
</li>
<li class="md-nav__item">
<a href="../../linux_networking/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-2" type="checkbox" id="nav-2-2" >
<label class="md-nav__link" for="nav-2-2">
Python and Web
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Python and Web" data-md-level="2">
<label class="md-nav__title" for="nav-2-2">
<span class="md-nav__icon md-icon"></span>
Python and Web
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../python_web/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../python_web/python-concepts/" class="md-nav__link">
Some Python Concepts
</a>
</li>
<li class="md-nav__item">
<a href="../../python_web/python-web-flask/" class="md-nav__link">
Python, Web and Flask
</a>
</li>
<li class="md-nav__item">
<a href="../../python_web/url-shorten-app/" class="md-nav__link">
The URL Shortening App
</a>
</li>
<li class="md-nav__item">
<a href="../../python_web/sre-conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--active md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-3" type="checkbox" id="nav-2-3" checked>
<label class="md-nav__link" for="nav-2-3">
Data
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Data" data-md-level="2">
<label class="md-nav__title" for="nav-2-3">
<span class="md-nav__icon md-icon"></span>
Data
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item md-nav__item--active md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-3-1" type="checkbox" id="nav-2-3-1" checked>
<label class="md-nav__link" for="nav-2-3-1">
Relational Databases
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Relational Databases" data-md-level="3">
<label class="md-nav__title" for="nav-2-3-1">
<span class="md-nav__icon md-icon"></span>
Relational Databases
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../concepts/" class="md-nav__link">
Key Concepts
</a>
</li>
<li class="md-nav__item">
<a href="../mysql/" class="md-nav__link">
MySQL
</a>
</li>
<li class="md-nav__item">
<a href="../innodb/" class="md-nav__link">
InnoDB
</a>
</li>
<li class="md-nav__item">
<a href="../backup_recovery/" class="md-nav__link">
Backup and Recovery
</a>
</li>
<li class="md-nav__item">
<a href="../replication/" class="md-nav__link">
MySQL Replication
</a>
</li>
<li class="md-nav__item md-nav__item--active md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-3-1-7" type="checkbox" id="nav-2-3-1-7" checked>
<label class="md-nav__link" for="nav-2-3-1-7">
Operational Concepts
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Operational Concepts" data-md-level="4">
<label class="md-nav__title" for="nav-2-3-1-7">
<span class="md-nav__icon md-icon"></span>
Operational Concepts
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../select_query/" class="md-nav__link">
Select Query
</a>
</li>
<li class="md-nav__item md-nav__item--active">
<input class="md-nav__toggle md-toggle" data-md-toggle="toc" type="checkbox" id="__toc">
<label class="md-nav__link md-nav__link--active" for="__toc">
Query Performance
<span class="md-nav__icon md-icon"></span>
</label>
<a href="./" class="md-nav__link md-nav__link--active">
Query Performance
</a>
<nav class="md-nav md-nav--secondary" aria-label="Table of contents">
<label class="md-nav__title" for="__toc">
<span class="md-nav__icon md-icon"></span>
Table of contents
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="#query-performance-improvement" class="md-nav__link">
Query Performance Improvement
</a>
<nav class="md-nav" aria-label="Query Performance Improvement">
<ul class="md-nav__list">
<li class="md-nav__item">
<a href="#the-slow-query-log" class="md-nav__link">
The Slow Query Log
</a>
</li>
<li class="md-nav__item">
<a href="#the-explain-plan" class="md-nav__link">
The EXPLAIN Plan
</a>
</li>
<li class="md-nav__item">
<a href="#creating-an-index" class="md-nav__link">
Creating an Index
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item">
<a href="../lab/" class="md-nav__link">
Lab
</a>
</li>
<li class="md-nav__item">
<a href="../conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-3-2" type="checkbox" id="nav-2-3-2" >
<label class="md-nav__link" for="nav-2-3-2">
NoSQL
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="NoSQL" data-md-level="3">
<label class="md-nav__title" for="nav-2-3-2">
<span class="md-nav__icon md-icon"></span>
NoSQL
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../databases_nosql/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../databases_nosql/key_concepts/" class="md-nav__link">
Key Concepts
</a>
</li>
<li class="md-nav__item">
<a href="../../databases_nosql/further_reading/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-3-3" type="checkbox" id="nav-2-3-3" >
<label class="md-nav__link" for="nav-2-3-3">
Big Data
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Big Data" data-md-level="3">
<label class="md-nav__title" for="nav-2-3-3">
<span class="md-nav__icon md-icon"></span>
Big Data
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../big_data/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../big_data/evolution/" class="md-nav__link">
Evolution and Architecture of Hadoop
</a>
</li>
<li class="md-nav__item">
<a href="../../big_data/tasks/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-4" type="checkbox" id="nav-2-4" >
<label class="md-nav__link" for="nav-2-4">
Systems Design
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Systems Design" data-md-level="2">
<label class="md-nav__title" for="nav-2-4">
<span class="md-nav__icon md-icon"></span>
Systems Design
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../systems_design/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../systems_design/scalability/" class="md-nav__link">
Scalability
</a>
</li>
<li class="md-nav__item">
<a href="../../systems_design/availability/" class="md-nav__link">
Availability
</a>
</li>
<li class="md-nav__item">
<a href="../../systems_design/fault-tolerance/" class="md-nav__link">
Fault Tolerance
</a>
</li>
<li class="md-nav__item">
<a href="../../systems_design/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-5" type="checkbox" id="nav-2-5" >
<label class="md-nav__link" for="nav-2-5">
Metrics and Monitoring
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Metrics and Monitoring" data-md-level="2">
<label class="md-nav__title" for="nav-2-5">
<span class="md-nav__icon md-icon"></span>
Metrics and Monitoring
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/introduction/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/command-line_tools/" class="md-nav__link">
Command-line Tools
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/third-party_monitoring/" class="md-nav__link">
Third-party Monitoring
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/alerts/" class="md-nav__link">
Proactive Monitoring with Alerts
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/best_practices/" class="md-nav__link">
Best Practices for Monitoring
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/observability/" class="md-nav__link">
Observability
</a>
</li>
<li class="md-nav__item">
<a href="../../metrics_and_monitoring/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-2-6" type="checkbox" id="nav-2-6" >
<label class="md-nav__link" for="nav-2-6">
Security
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Security" data-md-level="2">
<label class="md-nav__title" for="nav-2-6">
<span class="md-nav__icon md-icon"></span>
Security
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../security/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../security/fundamentals/" class="md-nav__link">
Fundamentals of Security
</a>
</li>
<li class="md-nav__item">
<a href="../../security/network_security/" class="md-nav__link">
Network Security
</a>
</li>
<li class="md-nav__item">
<a href="../../security/threats_attacks_defences/" class="md-nav__link">
Threat, Attacks & Defences
</a>
</li>
<li class="md-nav__item">
<a href="../../security/writing_secure_code/" class="md-nav__link">
Writing Secure code
</a>
</li>
<li class="md-nav__item">
<a href="../../security/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-3" type="checkbox" id="nav-3" >
<label class="md-nav__link" for="nav-3">
Level 102
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Level 102" data-md-level="1">
<label class="md-nav__title" for="nav-3">
<span class="md-nav__icon md-icon"></span>
Level 102
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-3-1" type="checkbox" id="nav-3-1" >
<label class="md-nav__link" for="nav-3-1">
Linux Advanced
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Linux Advanced" data-md-level="2">
<label class="md-nav__title" for="nav-3-1">
<span class="md-nav__icon md-icon"></span>
Linux Advanced
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item md-nav__item--nested">
<input class="md-nav__toggle md-toggle" data-md-toggle="nav-3-1-1" type="checkbox" id="nav-3-1-1" >
<label class="md-nav__link" for="nav-3-1-1">
Containerization And Orchestration
<span class="md-nav__icon md-icon"></span>
</label>
<nav class="md-nav" aria-label="Containerization And Orchestration" data-md-level="3">
<label class="md-nav__title" for="nav-3-1-1">
<span class="md-nav__icon md-icon"></span>
Containerization And Orchestration
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="../../../level102/containerization_and_orchestration/intro/" class="md-nav__link">
Introduction
</a>
</li>
<li class="md-nav__item">
<a href="../../../level102/containerization_and_orchestration/intro_to_containers/" class="md-nav__link">
Introduction To Containers
</a>
</li>
<li class="md-nav__item">
<a href="../../../level102/containerization_and_orchestration/containerization_with_docker/" class="md-nav__link">
Containerization With Docker
</a>
</li>
<li class="md-nav__item">
<a href="../../../level102/containerization_and_orchestration/orchestration_with_kubernetes/" class="md-nav__link">
Orchestration With Kubernetes
</a>
</li>
<li class="md-nav__item">
<a href="../../../level102/containerization_and_orchestration/conclusion/" class="md-nav__link">
Conclusion
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</li>
<li class="md-nav__item">
<a href="../../../CONTRIBUTING/" class="md-nav__link">
Contribute
</a>
</li>
<li class="md-nav__item">
<a href="../../../CODE_OF_CONDUCT/" class="md-nav__link">
Code of Conduct
</a>
</li>
<li class="md-nav__item">
<a href="../../../sre_community/" class="md-nav__link">
SRE Community
</a>
</li>
</ul>
</nav>
</div>
</div>
</div>
<div class="md-sidebar md-sidebar--secondary" data-md-component="toc" >
<div class="md-sidebar__scrollwrap">
<div class="md-sidebar__inner">
<nav class="md-nav md-nav--secondary" aria-label="Table of contents">
<label class="md-nav__title" for="__toc">
<span class="md-nav__icon md-icon"></span>
Table of contents
</label>
<ul class="md-nav__list" data-md-scrollfix>
<li class="md-nav__item">
<a href="#query-performance-improvement" class="md-nav__link">
Query Performance Improvement
</a>
<nav class="md-nav" aria-label="Query Performance Improvement">
<ul class="md-nav__list">
<li class="md-nav__item">
<a href="#the-slow-query-log" class="md-nav__link">
The Slow Query Log
</a>
</li>
<li class="md-nav__item">
<a href="#the-explain-plan" class="md-nav__link">
The EXPLAIN Plan
</a>
</li>
<li class="md-nav__item">
<a href="#creating-an-index" class="md-nav__link">
Creating an Index
</a>
</li>
</ul>
</nav>
</li>
</ul>
</nav>
</div>
</div>
</div>
<div class="md-content">
<article class="md-content__inner md-typeset">
<h1>Query Performance</h1>
<h3 id="query-performance-improvement">Query Performance Improvement</h3>
<p>Query Performance is a very crucial aspect of relational databases. If not tuned correctly, the select queries can become slow and painful for the application, and for the MySQL server as well. The important task is to identify the slow queries and try to improve their performance by either rewriting them or creating proper indexes on the tables involved in it.</p>
<h4 id="the-slow-query-log">The Slow Query Log</h4>
<p>The slow query log contains SQL statements that take a longer time to execute then set in the config parameter long_query_time. These queries are the candidates for optimization. There are some good utilities to summarize the slow query logs like, mysqldumpslow (provided by MySQL itself), pt-query-digest (provided by Percona), etc. Following are the config parameters that are used to enable and effectively catch slow queries</p>
<table>
<thead>
<tr>
<th>Variable</th>
<th>Explanation</th>
<th>Example value</th>
</tr>
</thead>
<tbody>
<tr>
<td>slow_query_log</td>
<td>Enables or disables slow query logs</td>
<td>ON</td>
</tr>
<tr>
<td>slow_query_log_file</td>
<td>The location of the slow query log</td>
<td>/var/lib/mysql/mysql-slow.log</td>
</tr>
<tr>
<td>long_query_time</td>
<td>Threshold time. The query that takes longer than this time is logged in slow query log</td>
<td>5</td>
</tr>
<tr>
<td>log_queries_not_using_indexes</td>
<td>When enabled with the slow query log, the queries which do not make use of any index are also logged in the slow query log even though they take less time than long_query_time.</td>
<td>ON</td>
</tr>
</tbody>
</table>
<p>So, for this section, we will be enabling <strong>slow_query_log</strong>, <strong>long_query_time</strong> will be kept to <strong>0.3 (300 ms)</strong>, and <strong>log_queries_not_using</strong> index will be enabled as well.</p>
<p>Below are the queries that we will execute on the employees database.</p>
<ol>
<li>select * from employees where last_name = 'Koblick';</li>
<li>select * from salaries where salary &gt;= 100000;</li>
<li>select * from titles where title = 'Manager';</li>
<li>select * from employees where year(hire_date) = 1995;</li>
<li>select year(e.hire_date), max(s.salary) from employees e join salaries s on e.emp_no=s.emp_no group by year(e.hire_date);</li>
</ol>
<p>Now, queries <strong>1</strong>, <strong>3</strong> and <strong>4</strong> executed under 300 ms but if we check the slow query logs, we will find these queries logged as they are not using any of the index. Queries <strong>2</strong> and <strong>5</strong> are taking longer than 300ms and also not using any index.</p>
<p>Use the following command to get the summary of the slow query log</p>
<p><code>mysqldumpslow /var/lib/mysql/mysql-slow.log</code></p>
<p><img alt="slow query log analysis" src="../images/mysqldumpslow_out.png" title="slow query log analysis" /></p>
<p>There are some more queries in the snapshot that were along with the queries mentioned. Mysqldumpslow replaces actual values that were used by N (in case of numbers) and S (in case of strings). That can be overridden by <code>-a</code> option, however that will increase the output lines if different values are used in similar queries.</p>
<h4 id="the-explain-plan">The EXPLAIN Plan</h4>
<p>The <strong>EXPLAIN</strong> command is used with any query that we want to analyze. It describes the query execution plan, how MySQL sees and executes the query. EXPLAIN works with Select, Insert, Update and Delete statements. It tells about different aspects of the query like, how tables are joined, indexes used or not, etc. The important thing here is to understand the basic Explain plan output of a query to determine its performance. </p>
<p>Let's take the following query as an example,</p>
<pre><code>mysql&gt; explain select * from salaries where salary = 100000;
+----+-------------+----------+------------+------+---------------+------+---------+------+---------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+----------+------------+------+---------------+------+---------+------+---------+----------+-------------+
| 1 | SIMPLE | salaries | NULL | ALL | NULL | NULL | NULL | NULL | 2838426 | 10.00 | Using where |
+----+-------------+----------+------------+------+---------------+------+---------+------+---------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>The key aspects to understand in the above output are:-</p>
<ul>
<li><strong>Partitions</strong> - the number of partitions considered while executing the query. It is only valid if the table is partitioned.</li>
<li><strong>Possible_keys</strong> - the list of indexes that were considered during creation of the execution plan.</li>
<li><strong>Key</strong> - the index that will be used while executing the query.</li>
<li><strong>Rows</strong> - the number of rows examined during the execution.</li>
<li><strong>Filtered</strong> - the percentage of rows that were filtered out of the rows examined. The maximum and most optimized result will have 100 in this field. </li>
<li><strong>Extra</strong> - this tells some extra information on how MySQL evaluates, whether the query is using only where clause to match target rows, any index or temporary table, etc.</li>
</ul>
<p>So, for the above query, we can determine that there are no partitions, there are no candidate indexes to be used and so no index is used at all, over 2M rows are examined and only 10% of them are included in the result, and lastly, only a where clause is used to match the target rows.</p>
<h4 id="creating-an-index">Creating an Index</h4>
<p>Indexes are used to speed up selecting relevant rows for a given column value. Without an index, MySQL starts with the first row and goes through the entire table to find matching rows. If the table has too many rows, the operation becomes costly. With indexes, MySQL determines the position to start looking for the data without reading the full table.</p>
<p>A primary key is also an index which is also the fastest and is stored along with the table data. Secondary indexes are stored outside of the table data and are used to further enhance the performance of SQL statements. Indexes are mostly stored as B-Trees, with some exceptions like spatial indexes use R-Trees and memory tables use hash indexes.</p>
<p>There are 2 ways to create indexes:-</p>
<ul>
<li>While creating a table - if we know beforehand the columns that will drive the most number of where clauses in select queries, then we can put an index over them while creating a table.</li>
<li>Altering a Table - To improve the performance of a troubling query, we create an index on a table which already has data in it using ALTER or CREATE INDEX command. This operation does not block the table but might take some time to complete depending on the size of the table.</li>
</ul>
<p>Lets look at the query that we discussed in the previous section. Its clear that scanning over 2M records is not a good idea when only 10% of those records are actually in the resultset. </p>
<p>Hence, we create an index on the salary column of the salaries table.</p>
<p><code>create index idx_salary on salaries(salary)</code></p>
<p>OR</p>
<p><code>alter table salaries add index idx_salary(salary)</code></p>
<p>And the same explain plan now looks like this</p>
<pre><code>mysql&gt; explain select * from salaries where salary = 100000;
+----+-------------+----------+------------+------+---------------+------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+----------+------------+------+---------------+------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | salaries | NULL | ref | idx_salary | idx_salary | 4 | const | 13 | 100.00 | NULL |
+----+-------------+----------+------------+------+---------------+------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>Now the index used is idx_salary, the one we recently created. The index actually helped examine only 13 records and all of them are in the resultset. Also, the query execution time is also reduced from over 700ms to almost negligible. </p>
<p>Lets look at another example. Here we are searching for a specific combination of first_name and last_name. But, we might also search based on last_name only.</p>
<pre><code>mysql&gt; explain select * from employees where last_name = 'Dredge' and first_name = 'Yinghua';
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| 1 | SIMPLE | employees | NULL | ALL | NULL | NULL | NULL | NULL | 299468 | 1.00 | Using where |
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>Now only 1% record out of almost 300K is the resultset. Although the query time is particularly quick as we have only 300K records, this will be a pain if the number of records are over millions. In this case, we create an index on last_name and first_name, not separately, but a composite index including both the columns. </p>
<p><code>create index idx_last_first on employees(last_name, first_name)</code></p>
<pre><code>mysql&gt; explain select * from employees where last_name = 'Dredge' and first_name = 'Yinghua';
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------------+------+----------+-------+
| 1 | SIMPLE | employees | NULL | ref | idx_last_first | idx_last_first | 124 | const,const | 1 | 100.00 | NULL |
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>We chose to put last_name before first_name while creating the index as the optimizer starts from the leftmost prefix of the index while evaluating the query. For example, if we have a 3-column index like idx(c1, c2, c3), then the search capability of the index follows - (c1), (c1, c2) or (c1, c2, c3) i.e. if your where clause has only first_name this index wont work. </p>
<pre><code>mysql&gt; explain select * from employees where first_name = 'Yinghua';
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| 1 | SIMPLE | employees | NULL | ALL | NULL | NULL | NULL | NULL | 299468 | 10.00 | Using where |
+----+-------------+-----------+------------+------+---------------+------+---------+------+--------+----------+-------------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>But, if you have only the last_name in the where clause, it will work as expected.</p>
<pre><code>mysql&gt; explain select * from employees where last_name = 'Dredge';
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------+------+----------+-------+
| 1 | SIMPLE | employees | NULL | ref | idx_last_first | idx_last_first | 66 | const | 200 | 100.00 | NULL |
+----+-------------+-----------+------------+------+----------------+----------------+---------+-------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)
</code></pre>
<p>For another example, use the following queries:-</p>
<pre><code>create table employees_2 like employees;
create table salaries_2 like salaries;
alter table salaries_2 drop primary key;
</code></pre>
<p>We made copies of employees and salaries tables without the Primary Key of salaries table to understand an example of Select with Join.</p>
<p>When you have queries like the below, it becomes tricky to identify the pain point of the query.</p>
<pre><code>mysql&gt; select e.first_name, e.last_name, s.salary, e.hire_date from employees_2 e join salaries_2 s on e.emp_no=s.emp_no where e.last_name='Dredge';
1860 rows in set (4.44 sec)
</code></pre>
<p>This query is taking about 4.5 seconds to complete with 1860 rows in the resultset. Lets look at the Explain plan. There will be 2 records in the Explain plan as 2 tables are used in the query.</p>
<pre><code>mysql&gt; explain select e.first_name, e.last_name, s.salary, e.hire_date from employees_2 e join salaries_2 s on e.emp_no=s.emp_no where e.last_name='Dredge';
+----+-------------+-------+------------+--------+------------------------+---------+---------+--------------------+---------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+--------+------------------------+---------+---------+--------------------+---------+----------+-------------+
| 1 | SIMPLE | s | NULL | ALL | NULL | NULL | NULL | NULL | 2837194 | 100.00 | NULL |
| 1 | SIMPLE | e | NULL | eq_ref | PRIMARY,idx_last_first | PRIMARY | 4 | employees.s.emp_no | 1 | 5.00 | Using where |
+----+-------------+-------+------------+--------+------------------------+---------+---------+--------------------+---------+----------+-------------+
2 rows in set, 1 warning (0.00 sec)
</code></pre>
<p>These are in order of evaluation i.e. salaries_2 will be evaluated first and then employees_2 will be joined to it. As it looks like, it scans almost all the rows of salaries_2 table and tries to match the employees_2 rows as per the join condition. Though where clause is used in fetching the final resultset, but the index corresponding to the where clause is not used for the employees_2 table. </p>
<p>If the join is done on two indexes which have the same data-types, it will always be faster. So, lets create an index on the <em>emp_no</em> column of salaries_2 table and analyze the query again.</p>
<p><code>create index idx_empno on salaries_2(emp_no);</code></p>
<pre><code>mysql&gt; explain select e.first_name, e.last_name, s.salary, e.hire_date from employees_2 e join salaries_2 s on e.emp_no=s.emp_no where e.last_name='Dredge';
+----+-------------+-------+------------+------+------------------------+----------------+---------+--------------------+------+----------+-------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+-------+------------+------+------------------------+----------------+---------+--------------------+------+----------+-------+
| 1 | SIMPLE | e | NULL | ref | PRIMARY,idx_last_first | idx_last_first | 66 | const | 200 | 100.00 | NULL |
| 1 | SIMPLE | s | NULL | ref | idx_empno | idx_empno | 4 | employees.e.emp_no | 9 | 100.00 | NULL |
+----+-------------+-------+------------+------+------------------------+----------------+---------+--------------------+------+----------+-------+
2 rows in set, 1 warning (0.00 sec)
</code></pre>
<p>Now, not only did the index help the optimizer to examine only a few rows in both tables, it reversed the order of the tables in evaluation. The employees_2 table is evaluated first and rows are selected as per the index respective to the where clause. Then the records are joined to salaries_2 table as per the index used due to the join condition. The execution time of the query came down <strong>from 4.5s to 0.02s</strong>.</p>
<pre><code>mysql&gt; select e.first_name, e.last_name, s.salary, e.hire_date from employees_2 e join salaries_2 s on e.emp_no=s.emp_no where e.last_name='Dredge'\G
1860 rows in set (0.02 sec)
</code></pre>
</article>
</div>
</div>
</main>
<footer class="md-footer">
<div class="md-footer-nav">
<nav class="md-footer-nav__inner md-grid" aria-label="Footer">
<a href="../select_query/" class="md-footer-nav__link md-footer-nav__link--prev" rel="prev">
<div class="md-footer-nav__button md-icon">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M20 11v2H8l5.5 5.5-1.42 1.42L4.16 12l7.92-7.92L13.5 5.5 8 11h12z"/></svg>
</div>
<div class="md-footer-nav__title">
<div class="md-ellipsis">
<span class="md-footer-nav__direction">
Previous
</span>
Select Query
</div>
</div>
</a>
<a href="../lab/" class="md-footer-nav__link md-footer-nav__link--next" rel="next">
<div class="md-footer-nav__title">
<div class="md-ellipsis">
<span class="md-footer-nav__direction">
Next
</span>
Lab
</div>
</div>
<div class="md-footer-nav__button md-icon">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 24 24"><path d="M4 11v2h12l-5.5 5.5 1.42 1.42L19.84 12l-7.92-7.92L10.5 5.5 16 11H4z"/></svg>
</div>
</a>
</nav>
</div>
<div class="md-footer-meta md-typeset">
<div class="md-footer-meta__inner md-grid">
<div class="md-footer-copyright">
<div class="md-footer-copyright__highlight">
Copyright 2020 LinkedIn Corporation. All Rights Reserved. Licensed under the Creative Commons Attribution 4.0 International Public License
</div>
Made with
<a href="https://squidfunk.github.io/mkdocs-material/" target="_blank" rel="noopener">
Material for MkDocs
</a>
</div>
<div class="md-footer-social">
<a href="https://github.com/linkedin/school-of-sre" target="_blank" rel="noopener" title="github.com" class="md-footer-social__link">
<svg xmlns="http://www.w3.org/2000/svg" viewBox="0 0 496 512"><path d="M165.9 397.4c0 2-2.3 3.6-5.2 3.6-3.3.3-5.6-1.3-5.6-3.6 0-2 2.3-3.6 5.2-3.6 3-.3 5.6 1.3 5.6 3.6zm-31.1-4.5c-.7 2 1.3 4.3 4.3 4.9 2.6 1 5.6 0 6.2-2s-1.3-4.3-4.3-5.2c-2.6-.7-5.5.3-6.2 2.3zm44.2-1.7c-2.9.7-4.9 2.6-4.6 4.9.3 2 2.9 3.3 5.9 2.6 2.9-.7 4.9-2.6 4.6-4.6-.3-1.9-3-3.2-5.9-2.9zM244.8 8C106.1 8 0 113.3 0 252c0 110.9 69.8 205.8 169.5 239.2 12.8 2.3 17.3-5.6 17.3-12.1 0-6.2-.3-40.4-.3-61.4 0 0-70 15-84.7-29.8 0 0-11.4-29.1-27.8-36.6 0 0-22.9-15.7 1.6-15.4 0 0 24.9 2 38.6 25.8 21.9 38.6 58.6 27.5 72.9 20.9 2.3-16 8.8-27.1 16-33.7-55.9-6.2-112.3-14.3-112.3-110.5 0-27.5 7.6-41.3 23.6-58.9-2.6-6.5-11.1-33.3 2.6-67.9 20.9-6.5 69 27 69 27 20-5.6 41.5-8.5 62.8-8.5s42.8 2.9 62.8 8.5c0 0 48.1-33.6 69-27 13.7 34.7 5.2 61.4 2.6 67.9 16 17.7 25.8 31.5 25.8 58.9 0 96.5-58.9 104.2-114.8 110.5 9.2 7.9 17 22.9 17 46.4 0 33.7-.3 75.4-.3 83.6 0 6.5 4.6 14.4 17.3 12.1C428.2 457.8 496 362.9 496 252 496 113.3 383.5 8 244.8 8zM97.2 352.9c-1.3 1-1 3.3.7 5.2 1.6 1.6 3.9 2.3 5.2 1 1.3-1 1-3.3-.7-5.2-1.6-1.6-3.9-2.3-5.2-1zm-10.8-8.1c-.7 1.3.3 2.9 2.3 3.9 1.6 1 3.6.7 4.3-.7.7-1.3-.3-2.9-2.3-3.9-2-.6-3.6-.3-4.3.7zm32.4 35.6c-1.6 1.3-1 4.3 1.3 6.2 2.3 2.3 5.2 2.6 6.5 1 1.3-1.3.7-4.3-1.3-6.2-2.2-2.3-5.2-2.6-6.5-1zm-11.4-14.7c-1.6 1-1.6 3.6 0 5.9 1.6 2.3 4.3 3.3 5.6 2.3 1.6-1.3 1.6-3.9 0-6.2-1.4-2.3-4-3.3-5.6-2z"/></svg>
</a>
</div>
</div>
</div>
</footer>
</div>
<script src="../../../assets/javascripts/vendor.18f0862e.min.js"></script>
<script src="../../../assets/javascripts/bundle.994580cf.min.js"></script><script id="__lang" type="application/json">{"clipboard.copy": "Copy to clipboard", "clipboard.copied": "Copied to clipboard", "search.config.lang": "en", "search.config.pipeline": "trimmer, stopWordFilter", "search.config.separator": "[\\s\\-]+", "search.placeholder": "Search", "search.result.placeholder": "Type to start searching", "search.result.none": "No matching documents", "search.result.one": "1 matching document", "search.result.other": "# matching documents", "search.result.more.one": "1 more on this page", "search.result.more.other": "# more on this page", "search.result.term.missing": "Missing"}</script>
<script>
app = initialize({
base: "../../..",
features: [],
search: Object.assign({
worker: "../../../assets/javascripts/worker/search.9c0e82ba.min.js"
}, typeof search !== "undefined" && search)
})
</script>
</body>
</html>