diff --git a/binder/2024 Open Source India MariaDB Workshop .ipynb b/binder/2024 Open Source India MariaDB Workshop .ipynb new file mode 100644 index 0000000..d433d57 --- /dev/null +++ b/binder/2024 Open Source India MariaDB Workshop .ipynb @@ -0,0 +1,2205 @@ +{ + "cells": [ + { + "cell_type": "markdown", + "id": "8b9099f6-8b19-4a8f-8657-590712e6d006", + "metadata": { + "jp-MarkdownHeadingCollapsed": true + }, + "source": [ + "# Fine Tuning and Optimising MariaDB Query\n", + "\n", + "Tutor: Daniel Black\n", + "\n", + "Welcome!\n", + "\n", + "**Please load this notebook in your browser** This will provide a remote running instance of MariaDB to complete this workshop.\n", + "\n", + "# URL https://tinyurl.com/2024osimariadb\n", + "\n", + "Optional alternative: If you want to run against a existing MariaDB-10.11+ version installed locally or at your displosal, you can copy SQL commands there." + ] + }, + { + "cell_type": "markdown", + "id": "caa87ed0-0c1e-419f-ac21-4b94c374704e", + "metadata": {}, + "source": [ + "# Outline for today\n", + "\n", + "* MariaDB and MySQL basics\n", + "* Data types\n", + "* Date and Time\n", + "* Geometry\n", + "* Structured Queries and Tables\n", + "* Basic normalization\n", + "* Joins\n", + "* Window Functions\n", + "* Indexing for performance\n", + "* Temoral Tables (also known as System Version Tables)\n", + "* Transactions\n", + "* Basic Tuning\n", + "* Problem diagnosis\n", + "* Getting Help" + ] + }, + { + "cell_type": "markdown", + "id": "474f8b78-b792-479f-9916-51075d6f2787", + "metadata": {}, + "source": [ + "# MariaDB and MySQL basics\n", + "\n", + "MariaDB improves/fixes MySQL.\n", + "\n", + "## MariaDB History\n", + "\n", + "Common codebase originated in 2009. So 15 years of new features and bug fixes by large engineering team and community contributors.\n", + "\n", + "| Version | Original Release Date | Latest Version | Release Date | Status | End of Life |\n", + "|------------------|-----------------------|----------------|--------------|--------------|----------------------------------------------------------------------------------------------|\n", + "| 5.1 LTS | 2009-10-29 | 5.1.67 | 2013-01-30 | Stable (GA) | [Feb 2015](https://mariadb.org/about/maintenance-policy/) |\n", + "| 5.2 LTS | 2010-04-10 | 5.2.14 | 2013-01-30 | Stable (GA) | [Nov 2015](https://mariadb.org/about/maintenance-policy/) |\n", + "| 5.3 LTS | 2011-07-26 | 5.3.12 | 2013-01-30 | Stable (GA) | [Mar 2017](https://mariadb.org/about/maintenance-policy/) |\n", + "| 5.5 LTS | 2012-02-25 | 5.5.68 | 2020-05-12 | Stable (GA) | [Apr 2020](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.0 LTS | 2012-11-12 | 10.0.38 | 2019-01-31 | Stable (GA) | [Mar 2019](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.1 LTS | 2014-06-30 | 10.1.48 | 2020-11-04 | Stable (GA) | [Oct 2020](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.2 LTS | 2016-04-18 | 10.2.44 | 2022-05-20 | Stable (GA) | [May 2022](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.3 LTS | 2017-04-16 | 10.3.39 | 2023-05-10 | Stable (GA) | [May 2023](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.4 LTS | 2018-11-09 | 10.4.34 | 2024-05-16 | Stable (GA) | [Jun 2024](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.5 LTS | 2019-12-03 | 10.5.26 | 2024-08-08 | Stable (GA) | [Jun 2025](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.6 LTS | 2021-04-26 | 10.6.19 | 2024-08-08 | Stable (GA) | [Jul 2026](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.7 | 2021-09-17 | 10.7.8 | 2023-02-06 | Stable (GA) | [Feb 2023](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.8 | 2021-12-22 | 10.8.8 | 2023-05-10 | Stable (GA) | [May 2023](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.9 | 2022-03-23 | 10.9.8 | 2023-08-14 | Stable (GA) | [Aug 2023](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.10 | 2022-06-23 | 10.10.7 | 2023-11-13 | Stable (GA) | [Nov 2023](https://mariadb.org/about/maintenance-policy/) |\n", + "| 10.11 LTS | 2022-09-26 | 10.11.9 | 2024-08-08 | Stable (GA) | [Feb 2028](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.0 | 2022-12-27 | 11.0.6 | 2024-05-16 | Stable (GA) | [Jun 2024](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.1 | 2023-03-27 | 11.1.6 | 2024-08-08 | Stable (GA) | [Aug 2024](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.2 | 2023-06-20 | 11.2.5 | 2024-08-08 | Stable (GA) | [Nov 2024](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.4 LTS | 2023-12-24 | 11.4.3 | 2024-08-08 | Stable (GA) | [May 2029](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.5 R | 2023-09-20 | 11.5.2 | 2024-08-14 | Stable (GA) | [Rolling](https://mariadb.org/about/maintenance-policy/) |\n", + "| 11.6 R | 2023-09-20 | 11.6.1 | 2024-08-14 | Release Candidate | [Rolling](https://mariadb.org/about/maintenance-policy/) |\n", + "\n", + "**Legend:** \n", + "- **LTS** = Long-Term Support\n", + "- **R** = Rolling Release\n", + "\n", + "(Source: Wikipedia: https://en.wikipedia.org/wiki/MariaDB and conversion by chatGPT)" + ] + }, + { + "cell_type": "markdown", + "id": "af51619f-2990-4c15-8265-8d1e52978192", + "metadata": {}, + "source": [ + "## MariaDB Availability\n", + "\n", + "### Repositories released by MariaDB\n", + "\n", + "https://mariadb.org/download/#mariadb-repositories\n", + "\n", + "* Debian\n", + "* Ubuntu\n", + "* RHEL\n", + "* Fedora\n", + "* SLES\n", + "\n", + "Architectures;\n", + "* x86_64\n", + "* x86_32\n", + "* AArch64\n", + "* IBM Z\n", + "* IBM POWER\n", + "\n", + "Note: not all distros have all options.\n", + "\n", + "### Packages released by MariaDB\n", + "\n", + "https://mariadb.org/download\n", + "\n", + "* Microsoft Windows\n", + "* Source Tarball\n", + "* Binary Tarball for Linux\n", + "\n", + "### Containers - Via Docker Official Images\n", + "\n", + "* docker.io/library/mariadb\n", + "\n", + "## Distros\n", + "\n", + "* Linux distros (too many to list)\n", + "* Homebrew (macos)\n", + "* FreeBSD / OpenBSD / NetBSD\n", + "* Container bitnami/mariadb\n", + "* Container Linux Server / mariadb\n" + ] + }, + { + "cell_type": "markdown", + "id": "c75d586c-7e28-451b-a51f-6058ca06d430", + "metadata": {}, + "source": [ + "## MariaDB Configuration\n", + "\n", + "In .cnf files. Like\n", + "\n", + "RPM distros **/etc/my.cnf**\n", + "\n", + " !includedir /etc/my.cnf.d\n", + "\n", + "Deb distros **/etc/mysql/my.cnf**\n", + "\n", + " !includedir /etc/mysql/mariadb.conf.d/\n", + " !includedir /etc/mysql/conf.d/\n", + "\n", + "This is giving you directories to put config options so upgrades don't overwrite them:\n", + "\n", + "E.g. Ubuntu:\n", + "\n", + " ls -al /etc/mysql/mariadb.conf.d/\n", + " total 32\n", + " drwxr-xr-x. 3 root root 4096 Sep 17 00:59 .\n", + " drwxr-xr-x. 4 root root 4096 Sep 17 00:59 ..\n", + " -rw-r--r--. 1 root root 46 Sep 17 00:59 05-skipcache.cnf\n", + " -rw-r--r--. 1 root root 575 Aug 3 07:29 50-client.cnf\n", + " -rw-r--r--. 1 root root 231 Aug 3 07:29 50-mysql-clients.cnf\n", + " -rw-r--r--. 1 root root 3760 Sep 17 00:59 50-server.cnf\n", + " -rw-r--r--. 1 root root 570 Aug 3 07:29 60-galera.cnf\n", + "\n", + "So file per purpose, (good for Ansible rules where types of servers overlap)\n", + "\n", + "Contents of file, group, followed by options:\n", + "\n", + "Groups examples **[server]** or **[client]**, **[client-server]**, **[mariadbd-10.11]**.\n", + "\n", + "What options does a MariaDB server of client use? Look at the help\n", + "\n", + " mariadbd --help --verbose\n", + " ....\n", + " The following groups are read: mysqld server mysqld-10.11 mariadb mariadb-10.11 mariadbd mariadbd-10.11 client-server galera\n", + "\n", + "Same with a client:\n", + "\n", + " mariadb --help --verbose\n", + " ...\n", + " The following groups are read: mysql mariadb-client client client-server client-mariadb\n", + "\n", + "### What needs to be configured\n", + "\n", + "Normally nothing.\n", + "\n", + "Configuration is designed to work as default. Its designed to work with a low end 1G VMs in its default configuration. For production systems recommend increasing `innodb_buffer_pool_size` to enough to hold the active portion of your database(s) contents in RAM (we'll come back to this at the end with tuning)." + ] + }, + { + "cell_type": "markdown", + "id": "342f50c4-5d77-4533-a823-a1c12057a91d", + "metadata": {}, + "source": [ + "## Why this structure?\n", + "\n", + "Good design gains the best performance results.\n", + "\n", + "To perform well by design:\n", + "1. Datatypes\n", + "1. Table structure\n", + "1. Queries / Indexes\n", + "1. Tuning\n", + "\n", + "To resolving perforamce problem\n", + "1. Tuning\n", + "1. Queries / Indexes\n", + "1. Table structure\n", + "1. Datatypes\n", + "\n", + "(normally easy of change)" + ] + }, + { + "cell_type": "markdown", + "id": "b8ff5f4c-eaa2-4bf9-bbb4-f2a813b6a14f", + "metadata": {}, + "source": [ + "# Data Types\n", + "\n", + "## Numeric types\n", + "\n", + "* TINYINT (1 byte)\n", + "* BOOLEAN - Synonym for TINYINT\n", + "* SMALLINT (2 byte)\n", + "* MEDIUMINT (3 bytes- weird)\n", + "* INT, INTEGER (4 byte)\n", + "* BIGINT (8 byte)\n", + "* DECIMAL\n", + "* FLOAT\n", + "* DOUBLE\n", + "* BIT\n", + "\n", + "DECIMAL(M, D)\n", + "* M is the total number of digits (the precision); and\n", + "* D is the number of digits after the decimal point (the scale)\n", + "\n", + "Note: *Ignoring alias(mostly)\n", + "\n", + "* SIGNED - allow negative\n", + "* UNSIGNED - all positive or 0\n", + "\n", + "Ref: https://mariadb.com/kb/en/numeric-data-type-overview/\n", + "\n", + "### EXERCISE 1 - examine the limits\n", + "\n", + "What are the lower/upper limits of these?\n", + "\n", + "Adjust TINYINT and SIGNED, adjust the values.\n", + "Use the Play button on the notebook to run the particular line.\n", + "Then run the next line.\n", + "Go back to run with a different set." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "59e6c138-e86f-4841-8a8e-54a90b6ff762", + "metadata": {}, + "outputs": [], + "source": [ + "use test;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "ab3f39d3-8de5-4edb-94e0-66d78ee68917", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE datatypetest_numeric( ID TINYINT SIGNED);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "1d9336e1-e4c4-4a10-8cc9-11a11b516c6d", + "metadata": {}, + "outputs": [], + "source": [ + "INSERT INTO datatypetest_numeric VALUES ( fillmein ),( fillmein );" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "5d686721-12b5-4a65-9f3b-81a6eeff2862", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT * FROM datatypetest_numberic;" + ] + }, + { + "cell_type": "markdown", + "id": "7dd481b1-a118-4025-a36b-04ee80b854d8", + "metadata": {}, + "source": [ + "### Auto increment\n", + "\n", + "To populate integer types automaticly.\n", + "\n", + "Guarantees:\n", + "* Will be unique\n", + "* Will be bigger than previous\n", + "\n", + "Not Guaranteed:\n", + "* Will be exactly 1 more\n", + "* There will be no gaps\n", + "\n", + "ref: https://mariadb.com/kb/en/auto_increment/\n", + "\n", + "### EXERCISE 2 - how auto increment behaves" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "647535a2-150e-416f-aeb5-477740e59025", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE datatypetest_autoincrement( ID TINYINT UNSIGNED AUTO_INCREMENT PRIMARY KEY, data TEXT);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "2798b217-1ea9-485f-ae00-2b7b9e00fc6e", + "metadata": {}, + "outputs": [], + "source": [ + "INSERT INTO datatypetest_autoincrement (data) VALUES ('dog'), ('cat'), ('chicken');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "69fd2fda-a3f9-4855-a139-f3b71d1e2240", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT LAST_INSERT_ID();" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "9d5ed17e-3716-4609-a66d-785518df8c08", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT * FROM datatypetest_autoincrement;" + ] + }, + { + "cell_type": "markdown", + "id": "a3c37e1c-90b6-4eb7-8935-b5c6544d0044", + "metadata": {}, + "source": [ + "## String types\n", + "\n", + "* BINARY / VARBINARY\n", + "* CHAR / VARCHAR\n", + "* BLOB (TINYBLOB, BLOB, MEDIUMBLOB, LONGBLOB)\n", + "* TEXT (TINYTEXT..... LONGTEXT)\n", + "* ENUM\n", + "* INET4 /INET6\n", + "* JSON (`LONGTEXT COLLATE utf8mb4_bin` alias)\n", + "* SET (avoid - your breaking normalization)\n", + "* UUID\n", + "\n", + "BINARY and BLOB, INET4/6 and UUID - no character set\n", + "\n", + "CHAR, VARCHAR and BINARY, VARBINARY have a specified maximum length.\n", + "\n", + "Variable types, VARBINARY/VARCHAR/BLOB/TEXT store length, then data. Can be compact.\n", + "\n", + "Note: Stick to what is needed on VARCHAR/VARBINARY - complex SQL may use CHAR(X), BINARY(X) (fixed full size) as temporary storage\n", + "\n", + "ref: https://mariadb.com/kb/en/string-data-types/" + ] + }, + { + "cell_type": "markdown", + "id": "99dc7dd3-5a8a-4d4b-a611-15100d160bfa", + "metadata": {}, + "source": [ + "### Character sets\n", + "\n", + "Define the range of characters. Usual choices 'utf8mb4' or 'latin1'." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "79561d9e-9957-4f9e-a632-89e4fada377b", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW CHARACTER SET /* Run me */;" + ] + }, + { + "cell_type": "markdown", + "id": "f9158bb3-7315-4d2e-86bf-0810bbfd1df7", + "metadata": {}, + "source": [ + "### Collations\n", + "\n", + "Define the order. Is 'o' < = > 'รถ'?\n", + "\n", + "What collations are useful - uca1400_{language}{_nopad}{_a[is]}{_c[is]}\n", + "\n", + "nopad - treats \" this is it \" = \"this is it\"\n", + "as - accent sensitive\n", + "ai - accent insensitive\n", + "cs - case sensitive\n", + "ci - case insensitive" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4569bd61-4f76-4cea-acfd-98f536251fa2", + "metadata": {}, + "outputs": [], + "source": [ + "show collation /* Run me too */;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "36917f0f-07f5-4858-a616-25cdfaea885d", + "metadata": {}, + "outputs": [], + "source": [ + "create or replace table datatypes_string(t TEXT CHARACTER SET utf8mb4 COLLATE uca1400_ai_ci);" + ] + }, + { + "cell_type": "markdown", + "id": "f4ca0bc9-c39c-47e7-ab2a-0b47e07613f2", + "metadata": {}, + "source": [ + "### Collation Comparsion\n", + "\n", + "Collations affect how values are compared. What happens for:" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "308af609-deae-460b-9749-c768d8477f74", + "metadata": {}, + "outputs": [], + "source": [ + "create table collation_compare_t520 (t varchar(30) character set utf8mb4 collate utf8mb4_unicode_520_ci);\n", + "\n", + "create table collation_compare_t1400 (t varchar(30) character set utf8mb4 collate utf8mb4_uca1400_ai_ci);\n", + "\n", + "insert into collation_compare_t520 values ('bob'),('jack'), ('jane');\n", + "\n", + "insert into collation_compare_t1400 values ('bob'),('jack'), ('jane');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4f56b4a5-7384-4ce6-9901-3cdf27972b01", + "metadata": {}, + "outputs": [], + "source": [ + "select * from collation_compare_t1400 t1400 join collation_compare_t520 t520 on t1400.t = t520.t;" + ] + }, + { + "cell_type": "markdown", + "id": "8eb6c162-bffb-4efa-bd88-690c9ed3840b", + "metadata": {}, + "source": [ + "### Coercibiliy (to which collations does conversion occur)\n", + " \n", + "Coercibility defines what will be converted to what in case of collation conflict, with an expression with higher coercibility being converted to the collation of an expression with lower coercibility.\n", + "\n", + "| Coercibility | Description | Example |\n", + "|------------------|--------------------------------------------------|---------------------------------------------------|\n", + "| 0 | Explicit | Value using a COLLATE clause |\n", + "| 1 | No collation | Concatenated strings using different collations |\n", + "| 2 | Implicit | A string data type column value, CAST to a string data type |\n", + "| 3 | System constant | DATABASE(), USER() return value |\n", + "| 4 | Coercible | Literal string |\n", + "| 5 | Numeric | Numeric and temporal values |\n", + "| 6 | Ignorable | NULL or derived from NULL |\n", + "\n", + "\n", + "ref: https://mariadb.com/kb/en/coercibility/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "f66fe231-ed10-42b4-966c-2b562a65a4ec", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY(_latin1 'abc' COLLATE latin1_swedish_ci);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "9507b3de-f94c-450e-b46f-769ff3603ac5", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE coercibility (a VARCHAR(30) COLLATE uca1400_swedish_ai_ci, b VARCHAR(30) COLLATE uca1400_german2_ai_ci) CHARSET utf8mb4;\n", + "INSERT INTO coercibility VALUES ('abc', 'def'); /* a 2 coercibility */\n", + "SELECT COERCIBILITY(CONCAT(a, b)) FROM coercibility;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "e61d5ad5-8db6-4ad3-8131-fe11a42b074d", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY(CAST(1 AS CHAR));" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c6b35351-2160-42da-ad4a-bb02f761d26a", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY(USER());" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "f9b707e5-d532-4767-b1a1-ae92f66cc0c3", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY('abc');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "6803a257-5066-43bd-ba19-579c1690dd12", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY(1);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "e821a383-e08e-44d8-ac4c-39fd8e2a936c", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT COERCIBILITY(NULL);" + ] + }, + { + "cell_type": "markdown", + "id": "44910d78-adeb-4526-9005-39c6b3531d5d", + "metadata": {}, + "source": [ + "### Collations and JOIN performance\n", + "\n", + "Observer the difference in performance time" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4d4173d8-50a9-496e-bd4b-f85169846efb", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE collate_join1 (\n", + " id varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NOT NULL DEFAULT '',\n", + " date datetime NOT NULL DEFAULT '0000-00-00 00:00:00',\n", + " PRIMARY KEY (id)\n", + ");\n", + "CREATE OR REPLACE TABLE collate_join2 (\n", + " id varchar(64) CHARACTER SET latin1 COLLATE latin1_swedish_ci NOT NULL DEFAULT '',\n", + " date datetime NOT NULL DEFAULT '0000-00-00 00:00:00',\n", + " PRIMARY KEY (id)\n", + ");\n", + "insert into collate_join1 (id) select * from seq_1_to_6500;\n", + "insert into collate_join2 (id) select * from seq_1_to_6500;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "1f7ce9cf-7ba1-4ad0-ac52-92f0d7c13782", + "metadata": {}, + "outputs": [], + "source": [ + "select t2.* from collate_join1 t1 left join collate_join2 t2 using (id) where t2.id is null;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "9affa65e-e185-4323-976e-6ae355d9dd4f", + "metadata": {}, + "outputs": [], + "source": [ + "analyze format=json select t2.* from collate_join1 t1 left join collate_join2 t2 using (id) where t2.id is null;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "b1dd1bfa-16d0-4dd1-8267-fa2ecbfe84ca", + "metadata": {}, + "outputs": [], + "source": [ + "alter table collate_join2 modify id varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci NOT NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4535184b-c87f-4a0f-8081-8a0ba94fe6a2", + "metadata": {}, + "outputs": [], + "source": [ + " select t2.* from collate_join1 t1 left join collate_join2 t2 using (id) where t2.id is null;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "75d82ef5-fe03-4ff5-b4e1-30b2d9c4f4a8", + "metadata": {}, + "outputs": [], + "source": [ + "analyze format=json select t2.* from collate_join1 t1 left join collate_join2 t2 using (id) where t2.id is null;" + ] + }, + { + "cell_type": "markdown", + "id": "333ac120-6dfa-412e-a6ea-670a51733df6", + "metadata": {}, + "source": [ + "## Date and Time\n", + "\n", + "* DATE\n", + "* TIME\n", + "* DATETIME\n", + "* TIMESTAMP\n", + "* YEAR\n", + "\n", + "TIMESTAMP doesn't have a timezone.\n", + "\n", + "TIME*s can have up to (6) precision (microseconds). defaults to (0) seconds." + ] + }, + { + "cell_type": "markdown", + "id": "556b7232-0f20-4b75-af2c-b95f254d1b1f", + "metadata": {}, + "source": [ + "## GEOMETRY\n", + "\n", + "(skipping - short on time)\n", + "\n", + "ref: https://mariadb.com/kb/en/geometry-types/" + ] + }, + { + "cell_type": "markdown", + "id": "7870b6e3-d4ce-4b08-b3fb-fc8c4dfa0d65", + "metadata": {}, + "source": [ + "## NULL\n", + "\n", + "NULL represents an unknown value. It is not an empty string (by default), or a zero value. These are all valid values, and are not NULLs.\n", + "\n", + "ref: https://mariadb.com/kb/en/null-values/\n", + "\n", + "### Exercise how to NULLs compare" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "31e66d67-6a45-49c5-9391-704068d2b103", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NULL = NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "82c8a2fe-9938-48b1-9a4a-75e3b1a54008", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NULL != NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "76782ce3-fc1b-4d5d-b647-79b5acc2910c", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NULL < NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "862210dd-2674-4d4e-8d49-5d8882cc6286", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT 99 = NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "56232104-fe24-4867-bf3b-8e4f099c396b", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT \"apple\" = NULL;" + ] + }, + { + "cell_type": "markdown", + "id": "d8ef9521-7fdd-4d21-a6ff-1f6425fdc61a", + "metadata": {}, + "source": [ + "But there is truth\n", + "* \"IS NULL\" is an operator\n", + "* \"IS NOT NULL\" is an operator\n", + "* <=> Null safe equal\n", + "* ISNULL is a function" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "63a7d479-51ff-45bc-a3a7-cda80dcf9b60", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NULL IS NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "05857585-de32-4ee7-96b8-fcadb888ecf2", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT 9 IS NOT NULL;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "39894c05-199e-4a8b-8372-8012ba142f64", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT ISNULL(NULL);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c17f0927-38e9-435d-974c-e2d5d9eeb2b3", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NOT ISNULL(9);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c22ee7f6-a236-4a56-9cf8-713f3e90ed19", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT NULL <=> NULL;" + ] + }, + { + "cell_type": "markdown", + "id": "cbb70e29-ba27-42cc-b468-9511f15e8984", + "metadata": {}, + "source": [ + "## Type Conversion\n", + "\n", + "### Rules for Conversion on Comparison\n", + "* If either argument is NULL, the result of the comparison is NULL unless the NULL-safe <=> equality comparison operator is used.\n", + "* If both arguments are integers, they are compared as integers.\n", + "* If both arguments are strings, they are compared as strings.\n", + "* If one argument is decimal and the other argument is decimal or integer, they are compared as decimals.\n", + "* If one argument is decimal and the other argument is a floating point, they are compared as floating point values.\n", + "* If one argument is string and the other argument is integer, they are compared as decimals. This conversion was added in MariaDB 10.3.36. Prior to 10.3.36, this combination was compared as floating point values, which did not always work well for huge 64-bit integers because of a possible precision loss on conversion to double.\n", + "* If a hexadecimal argument is not compared to a number, it is treated as a binary string.\n", + "* If a constant is compared to a TIMESTAMP or DATETIME, the constant is converted to a timestamp, unless used as an argument to the IN function.\n", + "* In other cases, arguments are compared as floating point, or real, numbers.\n", + "\n", + "Note that if a string column is being compared with a numeric value, MariaDB will not use the index on the column, as there are numerous alternatives that may evaluate as equal (see examples below).\n", + "\n", + "ref: https://mariadb.com/kb/en/type-conversion/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "7468f116-3143-4f84-95f4-1cbe7a16930d", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT 15+'15';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "874eb410-823f-49f7-8891-1d33c9a13f47", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT '9746718491924563214' = 9746718491924563213;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "39bfb7b0-7be1-434f-8aab-27f85f323a7c", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT '5' = 5;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "7243d101-cf9d-4160-9fe3-2d27c6021ff0", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT ' 5' = 5;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "68f2da3b-bb34-4fc5-b41c-93551d03c8ed", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE typeconversion (a VARCHAR(10), b VARCHAR(10), INDEX idx_a (a));" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "b43ac725-6a5f-476d-95be-219c53766cda", + "metadata": {}, + "outputs": [], + "source": [ + "INSERT INTO typeconversion VALUES \n", + " ('1', '1'), ('2', '2'), ('3', '3'), \n", + " ('4', '4'), ('5', '5'), ('1', '5');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "faa14b13-ee32-4e4d-86df-54f0de22ed4f", + "metadata": {}, + "outputs": [], + "source": [ + "EXPLAIN SELECT * FROM typeconversion WHERE a = '3';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c01eb2b9-3ff2-4561-81b0-423a723281f2", + "metadata": {}, + "outputs": [], + "source": [ + "EXPLAIN SELECT * FROM typeconversion WHERE a = 3 ;" + ] + }, + { + "cell_type": "markdown", + "id": "28e20b68-e53e-47e6-9bd7-0af7cde01493", + "metadata": {}, + "source": [ + "Conversions occur in functions that compare arguments. Some functions take multiple types, but return the common type of all. So conversion rules take place. Conversions also happen between functions. Sometimes functions expect a type, so its converted.\n", + "\n", + "### Execise Conversions\n", + "\n", + "Can you explain the results observed?\n", + "\n", + "references:\n", + "* NULLIF - https://mariadb.com/kb/en/nullif\n", + "* FIELD - https://mariadb.com/kb/en/field\n", + "* operators - https://mariadb.com/kb/en/function-and-operator-reference/\n", + "* case operator - https://mariadb.com/kb/en/case-operator/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "11e3f714-2dc2-49bf-91c3-1835ac1477dc", + "metadata": {}, + "outputs": [], + "source": [ + "select nullif(\"dog\", 0) as c /* MDEV-35120 */;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "45a03d60-28aa-4a25-affa-e3736e0620bb", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW WARNINGS;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "bf33d037-4de3-4d43-adbe-5b3d684839fb", + "metadata": {}, + "outputs": [], + "source": [ + " select FIELD(0, 'c') as c0 /* MDEV-35121 */;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "130c33c7-3355-4186-a9ad-39d3c52deb1a", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW WARNINGS;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4ec697a3-b0be-4423-b9cc-55f785d6c730", + "metadata": {}, + "outputs": [], + "source": [ + "select FIELD('0', 'c') as c0 /* MDEV-35121 */;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "f9b4ac11-40f0-4791-a092-709dc67de307", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW WARNINGS;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c5826ae6-67cf-4439-b6dd-e0401cd64c80", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT 'o' || 'i';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "a04ccd98-db3c-4b73-861e-faa19e46dd42", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT CASE WHEN true THEN '1' ELSE 0 END;" + ] + }, + { + "cell_type": "markdown", + "id": "14cabc43-b76a-47be-b6cb-c266d75fbf86", + "metadata": {}, + "source": [ + "# Structured Tables and Queries" + ] + }, + { + "cell_type": "markdown", + "id": "6f9ab6ee-4d5a-4519-97bd-e4f6eac548bc", + "metadata": {}, + "source": [ + "**Structured** Query Language\n", + "\n", + "Every (row,column) should have 1 item, if you're going to making any decision on this.\n", + "\n", + "If its a Value, like Key/Value store - sure could be a JSON doc.\n", + "\n", + "## Data normalization\n", + "\n", + "3rd Normal Form (3NF) etc may be gold standard.\n", + "\n", + "For the practictioners guide:\n", + "1. design some tables,\n", + "2. write some queries around them that match to what you are doing.\n", + "3. If #2 was hard to do, or messy/complicated, your table structure should be different\n", + "4. if performance matters a lot - prototype and test\n", + "\n", + "### Joining tables\n", + "\n", + "This is for many to many relationships. More tables aren't inherently bad.\n", + "\n", + "e.g. Supplier - many, of which many provide the same Product\n", + "\n", + "Supplier:\n", + "* supplier_id\n", + "* supplier_name\n", + "* address\n", + "\n", + "Product:\n", + "* product_id\n", + "* product_name\n", + "* product_description\n", + "\n", + "Supplier_product (a joining table)\n", + "* supplier_id\n", + "* product_id\n", + "* quantity_available\n", + "\n", + "```sql\n", + "SELECT supplier_name, product_name, quantity_available\n", + "FROM Supplier\n", + "JOIN Supplier_product USING (supplier_id)\n", + "JOIN Product ON Supplier_product.product_id = Product.id\n", + "```" + ] + }, + { + "cell_type": "markdown", + "id": "ca4d8c30-0340-4b4e-bafd-7977209427bc", + "metadata": {}, + "source": [ + "## JOINS\n", + "\n", + "List all suppliers, even if they don't have a product\n", + "\n", + "```SQL\n", + "SELECT supplier_name, product_name, quantity_available\n", + "FROM Supplier\n", + "LEFT JOIN Supplier_product USING (supplier_id)\n", + "LEFT JOIN Product USING (product_id)\n", + "```" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "3e1584aa-50b0-4486-9fc3-a3b995f5f1bb", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE Supplier (supplier_id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,\n", + " supplier_name VARCHAR(40) NOT NULL,\n", + " supplier_address VARCHAR(200));\n", + "CREATE OR REPLACE TABLE Product (product_id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,\n", + " product_name VARCHAR(40) NOT NULL,\n", + " product_description VARCHAR(200));\n", + "CREATE OR REPLACE TABLE Supplier_Product(\n", + " supplier_id INT UNSIGNED NOT NULL,\n", + " product_id INT UNSIGNED NOT NULL,\n", + " quantity_available INT UNSIGNED,\n", + " PRIMARY KEY (supplier_id, product_id));\n", + "\n", + "INSERT INTO Supplier(supplier_name, supplier_address) VALUES\n", + " ('Joe', '12 Polloc st'),\n", + " ('Suresh', '55 Oloc Rd'),\n", + " ('Hanna', '1 Old Northern Rd');\n", + " INSERT INTO Product(product_name, product_description) VALUES\n", + " ('Bananas', 'big yellow'),\n", + " ('Apples', 'granny smith');\n", + "INSERT INTO Supplier_Product VALUES\n", + " (1, 1, 0),\n", + " (1, 2, 5),\n", + " (2, 1, 4);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "891f3a0a-c06e-49e8-b10a-53626ffdc6e9", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT supplier_name, product_name, quantity_available\n", + "FROM Supplier\n", + "LEFT JOIN Supplier_Product USING (supplier_id)\n", + "LEFT JOIN Product USING (product_id);" + ] + }, + { + "cell_type": "markdown", + "id": "d8b6cf09-5980-4cc8-9d4f-f35253a21ea6", + "metadata": {}, + "source": [ + "If the first one wasn't a `LEFT JOIN`, just `JOIN`?" + ] + }, + { + "cell_type": "markdown", + "id": "97bf61fb-4c1f-448b-839e-cd9cf6fc2dd1", + "metadata": {}, + "source": [ + "### Aggregations\n", + "\n", + "Need a summary? can let the database do this. Less transmitted data and the aggregation normally isn't expensive.\n", + "\n", + "How many products types does each supplier have?\n", + "\n", + "Syntax (simplified):\n", + "\n", + "```sql\n", + "SELECT column1, Aggregatefunction(columns)....\n", + "FROM tables\n", + "[JOIN other tables]\n", + "[GROUP BY column1[, column2....]\n", + "```\n", + "\n", + "What out for Invalid aggregation (Not detected by default).\n", + "This is when you `GROUP BY` something, and expect something in the same table to be there.\n", + "\n", + "There will be one output row for the unique `GROUP BY` expression.\n", + "\n", + "```sql\n", + "INSERT INTO Product(product_name, product_description) VALUES ('Bananas', 'lady finger'), ('Bananas', 'from Jamacia');\n", + "SELECT product_name, product_description FROM Product GROUP BY product_name;\n", + "```" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "d3362066-fd30-44e5-bd56-db3ba7ca3d56", + "metadata": {}, + "outputs": [], + "source": [ + "INSERT INTO Product(product_name, product_description) VALUES ('Bananas', 'lady finger'), ('Bananas', 'from Jamacia');\n" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "ba3a8a1e-dc3b-433e-80bf-8a662e72a4c8", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT product_name, product_description, COUNT(*) as c FROM Product GROUP BY product_name;" + ] + }, + { + "cell_type": "markdown", + "id": "43538c18-85c5-4e6d-aa5f-aa2d1acc5e28", + "metadata": {}, + "source": [ + "Which Banana description did you get?" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "8e1ab67b-d535-438f-971a-8142055e952c", + "metadata": {}, + "outputs": [], + "source": [ + "SET STATEMENT sql_mode=ONLY_FULL_GROUP_BY FOR\n", + " SELECT product_name, product_description, COUNT(*) as c\n", + " FROM Product\n", + " GROUP BY product_name;" + ] + }, + { + "cell_type": "markdown", + "id": "a10a6a4a-5c64-402a-a82a-c531811e4aa1", + "metadata": {}, + "source": [ + "Common mistake - overjoining when you don't need the other table" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "335d3fef-06a0-4ff9-a1d4-c87d2a035482", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT product_name,\n", + " product_description,\n", + " COUNT(*) AS c\n", + "FROM Product\n", + "LEFT JOIN Supplier_Product USING (product_id)\n", + "LEFT JOIN Supplier USING (supplier_id)\n", + "GROUP BY product_name;" + ] + }, + { + "cell_type": "markdown", + "id": "a8ec1d1f-642d-4913-bd48-b0dd6066d907", + "metadata": {}, + "source": [ + "Was `Supplier` / `Supplier_product` actually used? Are they used if `LEFT JOIN` was just `JOIN`. Test and see, then explain." + ] + }, + { + "cell_type": "markdown", + "id": "64ca6306-09a1-483a-b4e6-dbb901bca4c7", + "metadata": {}, + "source": [ + "### Window Functions\n", + "\n", + "Window function queries are characterised by the OVER keyword, following which the set of rows used for the calculation is specified\n", + "\n", + "ref: https://mariadb.com/kb/en/window-functions-overview/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "cc977cd9-d05c-4d7b-8ccf-c8445e4e0253", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE student (name CHAR(10), test CHAR(10), score TINYINT); \n", + "\n", + "INSERT INTO student VALUES \n", + " ('Chun', 'SQL', 75), ('Chun', 'Tuning', 73), \n", + " ('Esben', 'SQL', 43), ('Esben', 'Tuning', 31), \n", + " ('Kaolin', 'SQL', 56), ('Kaolin', 'Tuning', 88), \n", + " ('Tatiana', 'SQL', 87), ('Tatiana', 'Tuning', 83);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "f4231075-3f5f-4e76-b3c9-f5fae5344c9b", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT name, test, score, AVG(score) OVER (PARTITION BY name) \n", + " AS average_by_name FROM student;" + ] + }, + { + "cell_type": "markdown", + "id": "ef7e6fbc-24ac-4504-a855-ac2f1768118c", + "metadata": {}, + "source": [ + "# Indexing\n", + "\n", + "Query planning/execution is how databases take a problem statment, your `SELECT` query, and give a result as quickly as possible.\n", + "\n", + "Indexs are the mechanims for MariaDB:\n", + "* Fetch less data (ranges/ key lookups)\n", + "* Identify unique values\n", + "* Enforce unique and foreign key constraints\n", + "* Hold locks associated with transactions\n", + "\n", + "Indexs /Indicies are a B-tree. There is a hash form, B-tree is just as efficient.\n", + "\n", + "Primary key index, clustered (always in MariaDB), is the order of the rows in the table.\n", + "\n", + "Secondary Indexs /Indicies are a B-tree of the index contents that point to the primary key of the table. The PRIMARY KEY is at the end of the index. Don't do `CREATE INDEX b (b, PK)`, internally it will be `(b, PK, PK)` which wastes space.\n", + "\n", + "Created with `CREATE TABLE`, or `ALTER TABLE`, or `CREATE INDEX`.\n", + "\n", + "What index is my query using:\n", + "* `EXPLAIN {query}`\n", + "* `ANALYZE FORMAT=JSON {query}`\n", + "\n", + "Special reference to https://use-the-index-luke.com/, that has all this and helped me form this section. It has more detail than will cover now." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "c4edffbd-5554-4805-aa9d-d9b62af92c1f", + "metadata": {}, + "outputs": [], + "source": [ + "EXPLAIN SELECT supplier_name FROM Supplier WHERE supplier_id=1;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "078649f1-6bf9-456a-96e8-474501c60327", + "metadata": {}, + "outputs": [], + "source": [ + " ANALYZE FORMAT=JSON SELECT supplier_name FROM Supplier WHERE supplier_id=1;" + ] + }, + { + "cell_type": "markdown", + "id": "fa153bfc-3f07-4541-bd19-e777ae5abced", + "metadata": {}, + "source": [ + "## Concatinated indexes\n", + " \n", + "Also called multi-column, composite or combined index.\n", + "\n", + "This is where multiple items are in index.\n", + "\n", + "As this is a Btree, `INDEX name_of_index (a, b)` is first inserted by `a` then `b`. Order is exceptionally supported.\n", + "\n", + "E.g.\n", + "\n", + "```sql\n", + "ALTER TABLE employees ADD PRIMARY KEY(employee_id, subsidiary_id)\n", + "```\n", + "\n", + "Example index as flattened list:\n", + "\n", + "| employee_id | subsiduary_id | other fields.... |\n", + "|-----|----|--|\n", + "| 120 | 10 | |\n", + "| 120 | 20 | |\n", + "| 123 | 10 | |\n", + "| 123 | 20 | |\n", + "| 123 | 30 | |\n", + "| 140 | 20 | |\n", + "\n", + "\n", + "```sql\n", + "SELECT first_name, last_name\n", + " FROM employees\n", + " WHERE employee_id = 123\n", + " AND subsidiary_id = 30\n", + "```\n", + "\n", + "Will find `employee_id` = 123, then continue in the same index looking for `subsiduary_id = 30`.\n", + "\n", + "```sql\n", + "SELECT first_name, last_name\n", + " FROM employees\n", + " WHERE subsidiary_id = 20\n", + "```\n", + "\n", + "Cannot use the index without looking for every element.\n", + "\n", + "\n", + "### One Index\n", + "\n", + "A SQL statement will use* ONE index per table (alias) in a SQL query.\n", + "\n", + "By alias I mean instance of table.\n", + "\n", + "```sql\n", + "SELECT super.name, emp.name\n", + "FROM employee super\n", + "JOIN employee emp WHERE emp.super = super.employe_id\n", + "```\n", + "By \"alias\" mean the index used for `super` might be different to index used by \"emp\".\n", + "\n", + "Note: * minor exceptions apply (https://mariadb.com/kb/en/rowid-filtering-optimization/)" + ] + }, + { + "cell_type": "markdown", + "id": "e023a52a-0197-4a0e-b7d9-0298977ed93a", + "metadata": {}, + "source": [ + "### Functions and indexes\n", + "\n", + "Normally when you use a function, this prohibits index usage.\n", + "\n", + "So `SELECT name FROM table WHERE LOWER(name) = 'bobby'`;\n", + "\n", + "The index isn't on `LOWER(name)` , its on `name`, which might be a different order.\n", + "\n", + "### Special Sargable Functions\n", + "\n", + "Functions require special server handing to use an index and only in special circumstances.\n", + "\n", + "The query optimzer will rewrite query or use special logic so acheive optimizer usage.\n", + "\n", + "Identified by the \"using index\" part of `EXPLAIN`/`ANALYZE FORMAT=JSON`.\n", + "\n", + "#### Sargable DATE/YEAR\n", + "E.g. below where added MariaDB 11.1 for functions `DATE` and `YEAR` for `TIMESTAMP`/`DATETIME` types\n", + "\n", + "ref: https://mariadb.com/kb/en/sargable-date-and-year/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "3e3f84c5-c7e8-4286-9d5f-aaf99fc6b459", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE sargeable_date (a TIMESTAMP,KEY(a));\n", + "INSERT INTO sargeable_date VALUES\n", + " ('2023-12-31 23:59:59'),\n", + " ('2024-01-22 10:20:30'),\n", + " ('2024-01-23 10:20:30'),\n", + " ('2024-01-23 23:59:59'),\n", + " ('2024-01-24 00:00:00'),\n", + " ('2024-12-31 23:59:59'),\n", + " ('2025-01-01 00:00:00');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "d00b3ad4-0586-47e4-a7c8-2143785b1fbd", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT * FROM sargeable_date WHERE DATE(a) <= '2024-01-23';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "2a55d361-458a-4912-a483-1c2a8a4d515d", + "metadata": {}, + "outputs": [], + "source": [ + "ANALYZE FORMAT=JSON SELECT * FROM sargeable_date WHERE DATE(a) <= '2024-01-23';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4f6bf895-11d9-43de-8942-086e6bde4add", + "metadata": {}, + "outputs": [], + "source": [ + "ANALYZE FORMAT=JSON SELECT * FROM sargeable_date WHERE YEAR(a) >= 2024;" + ] + }, + { + "cell_type": "markdown", + "id": "d332b5c2-ef11-4eac-88a6-20189813021d", + "metadata": {}, + "source": [ + "#### Sargable UPPER\n", + "\n", + "Highlighted by access type=ref\n", + "\n", + "ref: https://mariadb.com/kb/en/sargable-upper/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "91186e50-c83c-41df-9372-8aacc8abd93d", + "metadata": {}, + "outputs": [], + "source": [ + "create or replace table sargable_upper (\n", + " v varchar(32) collate utf8mb4_general_ci,\n", + " key(v)\n", + ");" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "f76d1be5-7246-49c5-b92a-eaff543f8c6e", + "metadata": {}, + "outputs": [], + "source": [ + "insert into sargable_upper VALUES ('dog'), ('cat'), ('chicken');" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "5687e1a5-aacb-40e9-9efd-41e701fa28c6", + "metadata": {}, + "outputs": [], + "source": [ + "analyze format=json select * from sargable_upper where UPPER(v)='ABC';" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "16b3faf1-9001-45eb-9fc1-5444db4d061c", + "metadata": {}, + "outputs": [], + "source": [ + " analyze format=json select * from sargable_upper where UPPER(v) LIKE 'ABC%' /* not supported here */;" + ] + }, + { + "cell_type": "markdown", + "id": "3953dcd8-b069-43a1-9722-e0c71e756a65", + "metadata": {}, + "source": [ + "### What SQL uses and index\n", + "\n", + "* WHERE\n", + "* JOIN\n", + "* ORDER BY\n", + "* result `SELECT a,b FROM tbl WHERE a=3` when using `INDEX(a,b)` will return `b` from the index" + ] + }, + { + "cell_type": "markdown", + "id": "2f00e062-3ef6-498b-bb60-bc3d71a7f67d", + "metadata": {}, + "source": [ + "### Indexes and Expressions\n", + "\n", + "```sql\n", + "SELECT numeric_number\n", + " FROM table_name\n", + " WHERE numeric_number - 1000 > 10\n", + "```\n", + " \n", + "Even the numeric_number indexed, the operatorion cannot succeed. So keep field unincumbered by expressions:\n", + "\n", + "```sql\n", + "SELECT numeric_number\n", + " FROM table_name\n", + " WHERE numeric_number > (10 + 1000)\n", + "```\n", + "\n", + "### Complex expressions\n", + "\n", + "What if we have a table and need to select quickly on a combined attribute.\n", + "\n", + "E.g." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "24be26b0-3ca8-47cd-bce5-faf6da5d6877", + "metadata": {}, + "outputs": [], + "source": [ + "CREATE OR REPLACE TABLE package (name VARCHAR(30), x INT UNSIGNED, y INT UNSIGNED, z INT UNSIGNED);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4af820c6-fc6d-416e-971b-f24878e09d43", + "metadata": {}, + "outputs": [], + "source": [ + "INSERT INTO package(name, x, y, z) VALUES ('cat', 30, 20, 30), ('dog', 1000, 40, 60), ('luggage', 50, 40, 20);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "dc821c98-f260-4cb2-aead-45f1ff6a0e1f", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT name FROM package WHERE x * y * z > 18000;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "8199bc72-40d1-47c9-b3a1-3c619955bcc4", + "metadata": {}, + "outputs": [], + "source": [ + "EXPLAIN SELECT name FROM package WHERE x * y * z > 18000;\n" + ] + }, + { + "cell_type": "markdown", + "id": "ec310eab-0026-42ad-91c2-65deae9f8b9b", + "metadata": {}, + "source": [ + "Generated expressions to the rescue:\n", + "\n", + "Create an expression (must be causal (for same input, same output) and not depend on system variables):\n", + "\n", + "ref: https://mariadb.com/kb/en/generated-columns/" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "1e3f0f44-53d8-4dc9-8eda-d03bab5bef49", + "metadata": {}, + "outputs": [], + "source": [ + "ALTER TABLE package ADD volume INT UNSIGNED AS (x * y * z) STORED, ADD INDEX v_index(volume);" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "ea26db8f-40b7-4f08-8dc5-5b9dc9e28bd7", + "metadata": {}, + "outputs": [], + "source": [ + "SELECT name FROM package WHERE volume > 18000;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "0fdfaa87-3751-491f-9535-8f75f019e7d7", + "metadata": {}, + "outputs": [], + "source": [ + "EXPLAIN SELECT name FROM package WHERE volume > 18000;" + ] + }, + { + "cell_type": "markdown", + "id": "218e2327-173f-4b11-900b-6e4f00f30f23", + "metadata": {}, + "source": [ + "# Basic Tuning\n", + "\n", + "Tuning is via system variables. There are 3 forms:\n", + "* Global variables\n", + "* Global and session variables\n", + "* Session only variables\n", + "\n", + "Most can be changed at runtime (especially in later MariaDB versions). Always remember to persist global changes in the configuration file or they will be lost.\n", + "\n", + "## Tuning methodology\n", + "\n", + "Default configuration is good. Tune where there is a problem, like slow queries.\n", + "\n", + "Make a change, measure/test its inmpact.\n", + "\n", + "## InnoDB Tuning\n", + "\n", + "InnoDB is the storage engine most likely used for tables.\n", + "\n", + "### InnoDB Buffer Pool Size\n", + "\n", + "InnoDB Buffer Pool is a dynamic global system variable. This is a big cache as to what data can be cached in memory.\n", + "\n", + "What's the limit. Its all RAM, how much do you have?\n", + "\n", + "The ideal size to hold what data is frequently accessed. If there's an infrequent access data will be read from storage.\n", + "\n", + "Frequently quoted things:\n", + "* Use 80% of available RAM (empasis on available, not total).\n", + "* There should be 20% free pages in the buffer pool.\n" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "4d8b2e5b-6af6-4435-abd4-81dc5cec6a56", + "metadata": {}, + "outputs": [], + "source": [ + "select @@innodb_buffer_pool_size;" + ] + }, + { + "cell_type": "markdown", + "id": "bdacc7a1-4c9a-48d8-9b55-c0f7dd8b20e4", + "metadata": {}, + "source": [ + "What is being accessed?\n", + "\n", + "Look at:" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "6a0e8229-3d7b-4747-9fd4-37d52f68a2b6", + "metadata": {}, + "outputs": [], + "source": [ + "show global status like 'innodb_buffer_pool_pages%';" + ] + }, + { + "cell_type": "markdown", + "id": "74d41eec-5f28-4534-ad4d-88d1d26a1e9e", + "metadata": {}, + "source": [ + "This shows:\n", + "* **Innodb_buffer_pool_pages_data** - number of pages (of 16k bytes in size by default), out of **Innodb_buffer_pool_pages_total** are used.\n", + "\n", + "If very small %, then you have overallocated innodb buffer pool, (or this is idle and you aren't looking at anything meaningful).\n", + "\n", + "ref: https://mariadb.com/kb/en/innodb-status-variables" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "67de6232-07c4-4a27-af5c-3a7b02c67a80", + "metadata": {}, + "outputs": [], + "source": [ + "show global status like 'innodb_buffer_pool_read%';" + ] + }, + { + "cell_type": "markdown", + "id": "78caf5b9-a7ef-40e5-8eb0-5f210f6b8425", + "metadata": {}, + "source": [ + "* **Innodb_buffer_pool_read_requests** - number of times SQL requests a page of data from innodb\n", + "* **Innodb_buffer_pool_reads** - number of time those requests made it to being a storage read.\n", + "\n", + "note: At startup they are all going to be read from storage. Looking at this 10 minutes after start is pretty biased.\n", + "\n", + "Rough metric, if **Innodb_buffer_pool_reads** / **Innodb_buffer_pool_read_requests** < 1%, then that's the amount of storage reads.\n", + "\n", + "If its 10+ % and its a production workload that has been running for a while, then your buffer pool is too small.\n", + "\n", + "If its < 0.01% then its probably too big.\n", + "\n", + "Changing the value \"SET GLOBAL innodb_buffer_pool = \"(size in bytes) - can be expression like \"12 * 1024 *1024 *1024\" (12GB);\n", + "\n", + "Alternate on Linux 11.0 **[innodb_data_file_buffering=ON](https://mariadb.com/kb/en/innodb-system-variables/#innodb_data_file_buffering)**, <11.0 - **[innodb_flush_method=fsync](https://mariadb.com/kb/en/innodb-system-variables/#innodb_flush_method)** - with buffered pages OS acts as a cache." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "1edfd03e-ef76-453a-baa3-78b40b7c9fce", + "metadata": {}, + "outputs": [], + "source": [ + "SET GLOBAL innodb_buffer_pool_size=1024*1024*1024;" + ] + }, + { + "cell_type": "markdown", + "id": "63eefa2b-7093-4af7-8c0a-2eebd2c2f311", + "metadata": {}, + "source": [ + "### Innodb Log File Size\n", + "\n", + "This is the Redo log. This is the ib_logfile* (s). These ensure that a power outage preserves chanages. Never delete these.\n", + "\n", + "This records UPDATE/DELETE/INSERT data quickly to disk so its durable, and can return success quickly to application.\n", + "\n", + "Because changes are in the Redo Log and the InnoDB Buffer Pool, it can be handy if these are of the same size so that large bulk changes are limited by the InnoDB buffer pool rather than the log file.\n", + "\n", + "ref: https://mariadb.com/kb/en/innodb-system-variables/#innodb_log_file_size\n", + "\n", + "Dynamic (since 10.11+ (ignoring end of life releases)).\n", + "\n", + "Default value 128M. If you are doing bulk updates or lots of them, this may not be enough. A too big value will mean crash recovery is slow.\n", + "\n", + "ref: https://mariadb.com/kb/en/innodb-page-flushing\n" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "0e74b2cb-d47c-40b3-b198-022dd5146008", + "metadata": {}, + "outputs": [], + "source": [ + "show global status like \"Innodb_checkpoint_%\";" + ] + }, + { + "cell_type": "markdown", + "id": "c64c43f3-987b-4500-9e5f-9ce6ae9430ab", + "metadata": {}, + "source": [ + "This is a volume of data in bytes.\n", + "\n", + "If `Innodb_checkpoint_max_age` / `@@innodb_log_file_size` is close to 1, then innodb_log_file_size should be increased.\n", + "\n", + "But also check that Innodb_checkpoint_max_age is something that Innodb_checkpoint_age approaches semi frequently.\n", + "\n", + "Live example: https://grafana.wikimedia.org/d/000000273/mysql?orgId=1&refresh=1m&from=now-24h&to=now\n", + "\n", + "ref:\n", + "* https://mariadb.com/kb/en/innodb-redo-log/#redo-log-group-capacity" + ] + }, + { + "cell_type": "markdown", + "id": "1b5e2375-8df1-4c7a-b921-89edc2636e6c", + "metadata": {}, + "source": [ + "### InnoDB Flushing\n", + "\n", + "A background process called flushing moves the buffer pool changes to the tablespaces of each table.\n", + "\n", + "Triggered by:\n", + "* Adaptive flushing (enabled), then [innodb_adaptive_flushing_lwm](https://mariadb.com/kb/en/innodb-system-variables/#innodb_adaptive_flushing_lwm) is percentage of **innodb_log_file_size** to start flushing\n", + "* \n", + "Set **[innodb_io_capacity](https://mariadb.com/kb/en/innodb-system-variables/#innodb_io_capacity)** to the IOPs capacity of the storage. This ensure that background flushing can occur without affecting reads from storage.\n", + "\n", + "ref:\n", + "\n", + "* https://mariadb.com/kb/en/innodb-page-flushing/#configuring-the-innodb-io-capacity" + ] + }, + { + "cell_type": "markdown", + "id": "9081f291-cad1-4623-9e6f-4a312d9ad031", + "metadata": {}, + "source": [ + "## Tuning Connections\n", + "\n", + "* MariaDB maintains a thread pool of connections ready to process a connection\n", + "* MariaDB has a limit of max_connections that poses an upper limit of connections (doesn't apply to CONNECTION ADMIN granted users)\n", + "\n", + "Slow queries can impose pressure of the number of connections:\n", + "* A slow query ties up the use of a connection\n", + "* If it finished sooner then another client connection could be using it.\n", + "* because a concurrent web or application is imposing multiple queries at once, quick queries overall with reduce **max_connections** requirements.\n", + "\n", + "After (or while if really pushed) solving slow queries\n", + "\n", + "ref: https://mariadb.com/kb/en/grant/#connection-admin" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "89c3de00-3608-46cc-bbb8-b34f6994b81d", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW PROCESSLIST;" + ] + }, + { + "cell_type": "markdown", + "id": "3e303df5-168f-4707-b9a2-1ce8b3204c68", + "metadata": {}, + "source": [ + "Run this a few times to get the idea of how may active connections there are." + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "cef8d062-42d4-40c8-8ef7-6a9636c58b1a", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW GLOBAL STATUS LIKE 'Max_used_connections';" + ] + }, + { + "cell_type": "markdown", + "id": "b58a6f62-cc8d-4ed8-b0a6-64658b5570f6", + "metadata": {}, + "source": [ + "This shows it as well,\n", + "\n", + "if this is the same as the **max_connections** system variable then its possible a stall of queries.\n", + "\n", + "potential causes:\n", + "* insufficient **innodb_buffer_pool_size** or **innodb_log_file_size**, (slow flushing as one cause)\n", + "* storage speed slowing flushing (check **innodb_io_capacity**),\n", + "* bulk large analytic queries (all the buffer pool pages are needed to preserve repeatable read)\n", + "* insufficient indexs on long open transactions causing REPEATIABLE READ pages to be fixed buffer.\n", + "* hot locked index caused delaying other queries.\n", + "\n", + "Resolve these first before deciding a **max_connections** value. A **max_connections** value needs to be supported by hardware (CPU/RAM) depends on your workload." + ] + }, + { + "cell_type": "markdown", + "id": "f003b977-ca58-4e71-a2e7-2819a6eccb97", + "metadata": {}, + "source": [ + "## Before Query Optimization\n", + "\n", + "Query Execution is based on how much of the table it will read.\n", + "\n", + "If the choice is between reading 30% of a index, and also needing to read the main table, it will ignore index.\n", + "\n", + "Also large table changes may impact results and the index statistics will not be current.\n", + "\n", + "ANALYZE TABLE analyzes and stores the key distribution for a table.\n", + "\n", + "Quick version:\n", + "\n", + " ANALYZE TABLE tbl PERSISTENT FOR ALL\n", + "\n", + "ref: https://mariadb.com/kb/en/analyze-table/" + ] + }, + { + "cell_type": "markdown", + "id": "eda009ce-046d-4e94-a5ef-36e509892f25", + "metadata": {}, + "source": [ + "## Optimizer switch\n", + "\n", + "There are large number of ways MariaDB can consider executing your query.\n", + "\n", + "Some are not enabled by default.\n", + "\n", + "Reasons for an optimizer plan to not be available:\n", + "* It was added after the MariaDB version was GA, e.g. [optimizer_switch=cset_narrowing](https://mariadb.com/kb/en/charset-narrowing-optimization/).\n", + "* Known to work really well in some circumstances, but choice of this optimization method can be suboptimizal in other circumstances.\n", + "\n", + "ref: https://mariadb.com/kb/en/optimizer-switch/\n", + "\n", + "Recommended use, enable for specific queries.\n", + "\n", + "As a session:\n", + "\n", + "SET SESSION optimizer_switch={optimization=on}\n", + "\n", + "Or statement:\n", + "\n", + "SET STATEMENT optimizer_switch={optimization=on} FOR SELECT ....\n" + ] + }, + { + "cell_type": "markdown", + "id": "122ed4d5-7ec5-4554-b973-205fbacfce76", + "metadata": {}, + "source": [ + "# Problem Diagnosis\n", + "\n", + "Understand the problem before jumping to conclusions.\n", + "\n", + "## MariaDB Error Log\n", + "\n", + "std/stderr by default - means it goes to systemd service - so journalctl -u mariadb.service\n", + "\n", + "Take note of types:\n", + "* \\[Note\\] InnoDB: Initializing buffer pool, total size = 128.000MiB, chunk size = 2.000MiB\n", + "* \\[Warning\\] mariadbd: io_uring_queue_init() failed with ENOSYS: check seccomp filters, and the kernel version (newer than 5.1 required)\n", + "* \\[ERROR\\] mariadbd: Can't lock aria control file '/var/lib/mysql/aria_log_control' for exclusive use, error: 11. Will retry\n", + "\n", + "To control what is logged **[log_warnings](https://mariadb.com/kb/en/server-system-variables/#log_warnings)** has levels.\n", + "\n", + "## Analyze format=json / explain\n", + "\n", + "Elements of EXPLAIN {EXTENDED}\n", + "```\n", + "MariaDB [test]> explain extended select seq from seq_1_to_30;\n", + "+------+-------------+-------------+-------+---------------+---------+---------+------+------+----------+-------------+\n", + "| id | select_type | table | type | possible_keys | key | key_len | ref | rows | filtered | Extra |\n", + "+------+-------------+-------------+-------+---------------+---------+---------+------+------+----------+-------------+\n", + "| 1 | SIMPLE | seq_1_to_30 | index | NULL | PRIMARY | 8 | NULL | 30 | 100.00 | Using index |\n", + "+------+-------------+-------------+-------+---------------+---------+---------+------+------+----------+-------------+\n", + "```\n", + "\n", + "This a plan. There may be changes. `ANALYZE` runs the query\n", + "\n", + "```\n", + "ANALYZE FORMAT=JSON select seq from seq_1_to_30\\G\n", + "*************************** 1. row ***************************\n", + "ANALYZE: {\n", + " \"query_optimization\": {\n", + " \"r_total_time_ms\": 0.211595358\n", + " },\n", + " \"query_block\": {\n", + " \"select_id\": 1,\n", + " \"r_loops\": 1,\n", + " \"r_total_time_ms\": 0.128058752,\n", + " \"nested_loop\": [\n", + " {\n", + " \"table\": {\n", + " \"table_name\": \"seq_1_to_30\",\n", + " \"access_type\": \"index\",\n", + " \"key\": \"PRIMARY\",\n", + " \"key_length\": \"8\",\n", + " \"used_key_parts\": [\"seq\"],\n", + " \"r_loops\": 1,\n", + " \"rows\": 30,\n", + " \"r_rows\": 30,\n", + " \"r_table_time_ms\": 0.005894714,\n", + " \"r_other_time_ms\": 0.112255834,\n", + " \"r_engine_stats\": {},\n", + " \"filtered\": 100,\n", + " \"r_filtered\": 100,\n", + " \"using_index\": true\n", + " }\n", + " }\n", + " ]\n", + " }\n", + "```\n", + "\n", + "As you can see ANALYZE has measurements, identification of what parts of the index where used.\n", + "\n", + "*r_* is the real what happened during execution. Non *r_* lows rows/filtered where an estimate. When they differ signficantly, try updating table statistics." + ] + }, + { + "cell_type": "markdown", + "id": "eed9dd6b-6bf2-41e2-9a47-56e0fc929930", + "metadata": {}, + "source": [ + "## Slow Query Log\n", + "\n", + "Since 10.11 - all dynamic, and session/global.\n", + "\n", + "* **[slow_query_log=1](https://mariadb.com/kb/en/server-system-variables/#slow_query_log)** - boolean variable to enable\n", + "* **[log_slow_query_time=0.4](https://mariadb.com/kb/en/server-system-variables/#log_slow_query_time)** - what constitues a slow query (default of 10s) is too big for many cases\n", + "* **[log_slow_verbosity=full](https://mariadb.com/kb/en/server-system-variables/#log_slow_verbosity)** - how much detail - *full* include EXPLAIN EXTENDED information.\n", + "\n", + "ref: https://mariadb.com/kb/en/slow-query-log-overview/#configuring-the-slow-query-log-time" + ] + }, + { + "cell_type": "markdown", + "id": "380179f1-b395-42c4-8858-d184b27a5621", + "metadata": {}, + "source": [ + "## SHOW STATUS" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "13669255-7193-47dd-96b5-fee3f710495e", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW GLOBAL STATUS;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "40c4c39b-b4e7-4cf6-aac8-4ae7a12c7724", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW SESSION STATUS;" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "6f7cb5d9-0d11-4861-b267-9e490b343e88", + "metadata": {}, + "outputs": [], + "source": [ + "SHOW ENGINE INNODB STATUS;" + ] + }, + { + "cell_type": "markdown", + "id": "7420b9b2-5d2e-43c6-bf39-ad2e8f1be5e6", + "metadata": {}, + "source": [ + "Last Dead lock infomation\n", + "\n", + "```\n", + "=====================================\n", + "2024-10-22 16:03:46 0x7f64bad016c0 INNODB MONITOR OUTPUT\n", + "=====================================\n", + "Per second averages calculated from the last 50 seconds\n", + "-----------------\n", + "BACKGROUND THREAD\n", + "-----------------\n", + "srv_master_thread loops: 0 srv_active, 0 srv_shutdown, 891 srv_idle\n", + "srv_master_thread log flush and writes: 891\n", + "----------\n", + "SEMAPHORES\n", + "----------\n", + "------------\n", + "TRANSACTIONS\n", + "------------\n", + "Trx id counter 111\n", + "Purge done for trx's n:o < 0 undo n:o < 0 state: running but idle\n", + "History list length 0\n", + "LIST OF TRANSACTIONS FOR EACH SESSION:\n", + "---TRANSACTION (0x7f64ca202340), not started\n", + "0 lock struct(s), heap size 1128, 0 row lock(s)\n", + "--------\n", + "FILE I/O\n", + "--------\n", + "Pending flushes (fsync): 0\n", + "187 OS file reads, 0 OS file writes, 1 OS fsyncs\n", + "0.00 reads/s, 0 avg bytes/read, 0.00 writes/s, 0.00 fsyncs/s\n", + "---\n", + "LOG\n", + "---\n", + "Log sequence number 7704857\n", + "Log flushed up to 7704857\n", + "Pages flushed up to 7704857\n", + "Last checkpoint at 7704841\n", + "----------------------\n", + "BUFFER POOL AND MEMORY\n", + "----------------------\n", + "Total large memory allocated 167772160\n", + "Dictionary memory allocated 857728\n", + "Buffer pool size 8064\n", + "Free buffers 7756\n", + "Database pages 308\n", + "Old database pages 0\n", + "Modified db pages 0\n", + "Percent of dirty pages(LRU & free pages): 0.000\n", + "Max dirty pages percent: 90.000\n", + "Pending reads 0\n", + "Pending writes: LRU 0, flush list 0\n", + "Pages made young 0, not young 0\n", + "0.00 youngs/s, 0.00 non-youngs/s\n", + "Pages read 177, created 131, written 0\n", + "0.00 reads/s, 0.00 creates/s, 0.00 writes/s\n", + "Buffer pool hit rate 1000 / 1000, young-making rate 0 / 1000 not 0 / 1000\n", + "Pages read ahead 0.00/s, evicted without access 0.00/s, Random read ahead 0.00/s\n", + "LRU len: 308, unzip_LRU len: 0\n", + "I/O sum[0]:cur[0], unzip sum[0]:cur[0]\n", + "--------------\n", + "ROW OPERATIONS\n", + "--------------\n", + "0 read views open inside InnoDB\n", + "state: sleeping\n", + "----------------------------\n", + "END OF INNODB MONITOR OUTPUT\n", + "============================\n", + "\n", + "```" + ] + }, + { + "cell_type": "markdown", + "id": "79da27ff-0406-44b8-a382-74051d4280ac", + "metadata": {}, + "source": [ + "## Seeking Help\n", + "\n", + "Where to get help:\n", + " \n", + "* https://mariadb.com/kb\n", + "* https://stackoverflow.com/ (for SQL questions)\n", + "* https://dba.stackexchange.com/ (for DBA tuning and adminstration questions)\n", + "* https://mariadb.zulipchat.com" + ] + }, + { + "cell_type": "code", + "execution_count": null, + "id": "3af1d4f0-7e63-415c-a7b6-a2e41afbe2d6", + "metadata": {}, + "outputs": [], + "source": [] + } + ], + "metadata": { + "kernelspec": { + "display_name": "MariaDB", + "language": "SQL", + "name": "mariadb_kernel" + }, + "language_info": { + "file_extension": ".sql", + "mimetype": "text/plain", + "name": "SQL" + } + }, + "nbformat": 4, + "nbformat_minor": 5 +}