DBA Seguridad y Optimización MySQL 2
Termino formación adicional MySQL
This commit is contained in:
parent
be1862facf
commit
2286ef5f62
@ -61,9 +61,10 @@ systemctl stop mysql
|
||||
|
||||
La puesta a punto de MySQL se puede realizar de 4 maneras
|
||||
|
||||
### 1. Esquemas, índices, variables interdas de MySQL (mysqld), Hardware y S.O.
|
||||
### Esquemas, índices, variables internas de MySQL (mysqld), Hardware y S.O.
|
||||
|
||||
#### HARDWARE
|
||||
|
||||
- HARDWARE
|
||||
- Utilizar sistemas operativos de 64-bits. Mysql puede usar procesamiento
|
||||
en paralelo y consumir toda la memoria
|
||||
- Configuración de RAM. Parametro que permite indicar el máximo de memoria
|
||||
@ -85,12 +86,10 @@ La puesta a punto de MySQL se puede realizar de 4 maneras
|
||||
- **RAID 1 y 10**: Utilizan mas espacio producto de la redundancia, pero
|
||||
son mas seguros por tener backup disponible
|
||||
|
||||
|
||||
> RAID [wiki](https://en.wikipedia.org/wiki/Standard_RAID_levels)
|
||||
Nested RAID [wiki](https://en.wikipedia.org/wiki/Nested_RAID_levels)
|
||||
RAID [ArchWiki](https://wiki.archlinux.org/title/RAID)
|
||||
|
||||
|
||||
<details><summary markdown="span">RAID</summary>
|
||||
|
||||
#### RAID 0
|
||||
@ -409,3 +408,617 @@ LOCK instance for backup;
|
||||
|
||||
UNLOCK INSTANCE;
|
||||
```
|
||||
|
||||
## Plan de ejecución
|
||||
|
||||
Tomar como ejemplo esta consulta
|
||||
|
||||
```sql
|
||||
SELECT P.codigo, YEAR(F.fecha) as "Año", SUM(I.cantidad) AS "Cantidad"
|
||||
FROM productos P
|
||||
INNER JOIN items I
|
||||
ON P.codigo = I.codigo
|
||||
INNER JOIN facturas F
|
||||
ON I.numero = F.numero
|
||||
GROUP BY P.codigo, YEAR(F.fecha)
|
||||
ORDER BY P.codigo,YEAR(F.fecha);
|
||||
```
|
||||
|
||||
### EXPLAIN
|
||||
|
||||
```sql
|
||||
EXPLAIN FORMAT=JSON
|
||||
SELECT P.codigo, YEAR(F.fecha) as "Año", SUM(I.cantidad) AS "Cantidad"
|
||||
FROM productos P
|
||||
INNER JOIN items I
|
||||
ON P.codigo = I.codigo
|
||||
INNER JOIN facturas F
|
||||
ON I.numero = F.numero
|
||||
GROUP BY P.codigo, YEAR(F.fecha)
|
||||
ORDER BY P.codigo,YEAR(F.fecha)\G;
|
||||
```
|
||||
|
||||
<details><summary markdown="span">Salida</summary>
|
||||
|
||||
```json
|
||||
*************************** 1. row ***************************
|
||||
EXPLAIN: {
|
||||
"query_block": {
|
||||
"select_id": 1,
|
||||
"filesort": {
|
||||
"sort_key": "P.codigo, year(F.fecha)",
|
||||
"temporary_table": {
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "P",
|
||||
"access_type": "index",
|
||||
"possible_keys": ["PRIMARY"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "42",
|
||||
"used_key_parts": ["codigo"],
|
||||
"rows": 35,
|
||||
"filtered": 100,
|
||||
"using_index": true
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "I",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["PRIMARY", "codigo"],
|
||||
"key": "codigo",
|
||||
"key_length": "42",
|
||||
"used_key_parts": ["codigo"],
|
||||
"ref": ["empresa.P.codigo"],
|
||||
"rows": 3329,
|
||||
"filtered": 100
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "F",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["numero"],
|
||||
"ref": ["empresa.I.numero"],
|
||||
"rows": 1,
|
||||
"filtered": 100
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
### ANALYZE
|
||||
|
||||
```sql
|
||||
ANALYZE FORMAT=JSON
|
||||
SELECT P.codigo, YEAR(F.fecha) as "Año", SUM(I.cantidad) AS "Cantidad"
|
||||
FROM productos P
|
||||
INNER JOIN items I
|
||||
ON P.codigo = I.codigo
|
||||
INNER JOIN facturas F
|
||||
ON I.numero = F.numero
|
||||
GROUP BY P.codigo, YEAR(F.fecha)
|
||||
ORDER BY P.codigo,YEAR(F.fecha)\G;
|
||||
```
|
||||
|
||||
<details><summary markdown="span">Salida</summary>
|
||||
|
||||
```json
|
||||
*************************** 1. row ***************************
|
||||
ANALYZE: {
|
||||
"query_optimization": {
|
||||
"r_total_time_ms": 0.587444996
|
||||
},
|
||||
"query_block": {
|
||||
"select_id": 1,
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": 7608.934695,
|
||||
"filesort": {
|
||||
"sort_key": "P.codigo, year(F.fecha)",
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": 0.187826969,
|
||||
"r_used_priority_queue": false,
|
||||
"r_output_rows": 155,
|
||||
"r_buffer_size": "6Kb",
|
||||
"r_sort_mode": "sort_key,rowid",
|
||||
"temporary_table": {
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "P",
|
||||
"access_type": "index",
|
||||
"possible_keys": ["PRIMARY"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "42",
|
||||
"used_key_parts": ["codigo"],
|
||||
"r_loops": 1,
|
||||
"rows": 35,
|
||||
"r_rows": 35,
|
||||
"r_table_time_ms": 0.15660869,
|
||||
"r_other_time_ms": 0.195472139,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100,
|
||||
"using_index": true
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "I",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["PRIMARY", "codigo"],
|
||||
"key": "codigo",
|
||||
"key_length": "42",
|
||||
"used_key_parts": ["codigo"],
|
||||
"ref": ["empresa.P.codigo"],
|
||||
"r_loops": 35,
|
||||
"rows": 3329,
|
||||
"r_rows": 6098.6,
|
||||
"r_table_time_ms": 2265.69671,
|
||||
"r_other_time_ms": 306.4226053,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100
|
||||
}
|
||||
},
|
||||
{
|
||||
"table": {
|
||||
"table_name": "F",
|
||||
"access_type": "eq_ref",
|
||||
"possible_keys": ["PRIMARY"],
|
||||
"key": "PRIMARY",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["numero"],
|
||||
"ref": ["empresa.I.numero"],
|
||||
"r_loops": 213451,
|
||||
"rows": 1,
|
||||
"r_rows": 1,
|
||||
"r_table_time_ms": 2630.998751,
|
||||
"r_other_time_ms": 2405.134662,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
## Indices
|
||||
|
||||
Facilitan la búsqueda de datos dentro de las tablas (Diccionario). Si no se
|
||||
cuenta con una estructura de índices se debe recorrer toda la tabla hasta
|
||||
encontrar el registro
|
||||
|
||||
### Indices en MyISAM
|
||||
|
||||
| ID | TITULO | AUTOR |
|
||||
| - | - | - |
|
||||
| 23-4567-8 | Cien años de soledad | Gabriel García Márquez |
|
||||
| 12-3456-7 | El Túnel | Ernesto Sábato |
|
||||
| 89-0123-4 | 1984 | George Orwell |
|
||||
|
||||
El índice crea estas tablas de referencia
|
||||
|
||||
| TITULO | Ref |
|
||||
| - | - |
|
||||
| 1984 | {3} |
|
||||
| Cien años de soledad | {1} |
|
||||
| El Túnel | {2} |
|
||||
|
||||
| AUTOR | Ref |
|
||||
| - | - |
|
||||
| Gabriel García Márquez | {1} |
|
||||
| George Orwell | {3} |
|
||||
| Ernesto Sábato | {2} |
|
||||
|
||||
| ID | Ref |
|
||||
| - | - |
|
||||
| 12-3456-7 | {2} |
|
||||
| 23-4567-8 | {1} |
|
||||
| 89-0123-4 | {3} |
|
||||
|
||||
- Siempre que se modifique una tabla, todos los índices se actualizan
|
||||
- A mayor cantidad de datos, mayor tiempo de ejecución
|
||||
- Crea una estructura separada para índices PK y no PK
|
||||
- La columna inicial del índice es ordenada y toma como referencia la
|
||||
posición de la fila de la tabla original
|
||||
- Implenta índices **HASH** y **B-TREE**
|
||||
|
||||
### Indices en InnoDB
|
||||
|
||||
La clave primaria es el índice
|
||||
|
||||
| ID | TITULO | AUTOR |
|
||||
| - | - | - |
|
||||
| **23-4567-8** | Cien años de soledad | Gabriel García Márquez |
|
||||
| **12-3456-7** | El Túnel | Ernesto Sábato |
|
||||
| **89-0123-4** | 1984 | George Orwell |
|
||||
|
||||
Si se utiliza otro campo como índice, la referencia de este va a ser la clave
|
||||
primaria
|
||||
|
||||
| TITULO | Ref |
|
||||
| - | - |
|
||||
| 1984 | 89-0123-4 |
|
||||
| Cien años de soledad | 23-4567-8 |
|
||||
| El Túnel | 12-3456-7 |
|
||||
|
||||
| AUTOR | Ref |
|
||||
| - | - |
|
||||
| Gabriel García Márquez | 23-4567-8 |
|
||||
| George Orwell | 89-0123-4 |
|
||||
| Ernesto Sábato | 12-3456-7 |
|
||||
|
||||
- La tabla se ordena automáticamente con la clave primaria
|
||||
- Tiene mayor desempeño en consultas buscando a través de clave primaria
|
||||
- En el caso de buscar en un campo que no seas llave primaria, el costo es el
|
||||
mismo que usando MyISAM
|
||||
- La tabla esta ordenada con la PK por defecto
|
||||
- Los índices que no son PK poseen estructuras separadas y toman como
|
||||
referencia el valor de la PK
|
||||
- Solo trabaja con **B-TREE**
|
||||
|
||||
> **HASH** y **B-TREE** son algoritmos de busqueda en listas ordenadas
|
||||
|
||||
## Arbol Binario
|
||||
|
||||
- Valores a la izquierda del nodo son menores
|
||||
- Valores a la derecha del nodo son mayores
|
||||
|
||||
```mermaid
|
||||
graph TD
|
||||
idA((27)) --> idB1((13))
|
||||
idA --> idB2((35))
|
||||
idB1 --> idC1((26))
|
||||
idB2 --> idC3((33))
|
||||
idB2 --> idC4((39))
|
||||
```
|
||||
|
||||
Consideraciones sobre **B-TREE**
|
||||
|
||||
- Balanced - Binary Tree
|
||||
- +4 Mil millones de registros en 32 niveles
|
||||
|
||||
|
||||
```mermaid
|
||||
graph TD
|
||||
iA((.)) --> iB1((.))
|
||||
iA((.)) --> iB2((.))
|
||||
iB1((.)) --> iC1((.))
|
||||
iB1((.)) --> iC2((.))
|
||||
iB2((.)) --> iC3((.))
|
||||
iB2((.)) --> iC4((.))
|
||||
iC1((.)) --> iD1((.))
|
||||
iC1((.)) --> iD2((.))
|
||||
iC1((.)) --> iD3((.))
|
||||
iC1((.)) --> iD4((.))
|
||||
iC2((.)) --> iD5((.))
|
||||
iC2((.)) --> iD6((.))
|
||||
iC2((.)) --> iD7((.))
|
||||
iC2((.)) --> iD8((.))
|
||||
iC3((.)) --> iD9((.))
|
||||
iC3((.)) --> iD10((.))
|
||||
iC3((.)) --> iD11((.))
|
||||
iC3((.)) --> iD12((.))
|
||||
iC4((.)) --> iD13((.))
|
||||
iC4((.)) --> iD14((.))
|
||||
iC4((.)) --> iD15((.))
|
||||
iC4((.)) --> iD16((.))
|
||||
```
|
||||
|
||||
Ejemplo
|
||||
|
||||
```mermaid
|
||||
%%{init: {'theme': 'dark','themeVariables': {'clusterBkg': '#2b2f38'}}}%%
|
||||
graph TD
|
||||
|
||||
subgraph " "
|
||||
A1 ---> B
|
||||
A2 ---> C
|
||||
A3 ---> D
|
||||
subgraph A[" "]
|
||||
direction TB
|
||||
A1[256]
|
||||
A2[521]
|
||||
A3[768]
|
||||
end
|
||||
subgraph B[" "]
|
||||
direction TB
|
||||
B11[64]
|
||||
B12[128]
|
||||
B13[192]
|
||||
end
|
||||
subgraph C[" "]
|
||||
direction TB
|
||||
B21[256]
|
||||
B22[521]
|
||||
B23[768]
|
||||
end
|
||||
subgraph D[" "]
|
||||
direction TB
|
||||
B31[832]
|
||||
B32[896]
|
||||
B33[960]
|
||||
end
|
||||
end
|
||||
```
|
||||
|
||||
## HASH
|
||||
|
||||
Mapea datos grandes de tamaño variable en una "palabra" de tamaño fijo
|
||||
|
||||
Ejemplo
|
||||
|
||||
| Dato | Hash |
|
||||
| - | - |
|
||||
| ASDWERSDFJJKSHDFHKCUENVSIUUVSIUEURIHSCVIUHSER | 49855139 |
|
||||
| KSDFHEHS | f9c0591e |
|
||||
| 123IERUDJFH124IUDF26HD45 | f2188c85 |
|
||||
| DF | 795741b2 |
|
||||
|
||||
[<img src="./imgs/hash_table.svg" width="1000"/>](./imgs/hash_table.svg)
|
||||
|
||||
## Creando indices
|
||||
|
||||
```sql
|
||||
ANALYZE FORMAT=JSON SELECT * FROM facturas WHERE fecha = '20170101'\G;
|
||||
1 row in set (0.211 sec)
|
||||
```
|
||||
|
||||
<details><summary markdown="span">Detalle ANALYZE</summary>
|
||||
|
||||
```json
|
||||
ANALYZE: {
|
||||
"query_optimization": {
|
||||
"r_total_time_ms": 0.228188173
|
||||
},
|
||||
"query_block": {
|
||||
"select_id": 1,
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": 208.0312466,
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "facturas",
|
||||
"access_type": "ALL",
|
||||
"r_loops": 1,
|
||||
"rows": 87768,
|
||||
"r_rows": 87877,
|
||||
"r_table_time_ms": 159.3170115,
|
||||
"r_other_time_ms": 48.68916427,
|
||||
"filtered": 100,
|
||||
"r_filtered": 0.08420861,
|
||||
"attached_condition": "facturas.FECHA_VENTA = DATE'2017-01-01'"
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
#### Agregando indice `fecha`
|
||||
|
||||
```sql
|
||||
ALTER TABLE facturas ADD INDEX(fecha_venta);
|
||||
|
||||
ANALYZE FORMAT=JSON SELECT * FROM facturas WHERE fecha = '20170101'\G;
|
||||
1 row in set (0.004 sec)
|
||||
```
|
||||
|
||||
<details><summary markdown="span">Detalle ANALYZE</summary>
|
||||
|
||||
```json
|
||||
ANALYZE: {
|
||||
"query_optimization": {
|
||||
"r_total_time_ms": 0.383672043
|
||||
},
|
||||
"query_block": {
|
||||
"select_id": 1,
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": 1.303775168,
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "facturas",
|
||||
"access_type": "ref",
|
||||
"possible_keys": ["FECHA_VENTA"],
|
||||
"key": "FECHA_VENTA",
|
||||
"key_length": "4",
|
||||
"used_key_parts": ["FECHA_VENTA"],
|
||||
"ref": ["const"],
|
||||
"r_loops": 1,
|
||||
"rows": 74,
|
||||
"r_rows": 74,
|
||||
"r_table_time_ms": 1.180700563,
|
||||
"r_other_time_ms": 0.099922552,
|
||||
"filtered": 100,
|
||||
"r_filtered": 100
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
#### Quitando el índice
|
||||
|
||||
```sql
|
||||
ALTER TABLE facturas DROP INDEX(fecha_venta);
|
||||
|
||||
ANALYZE FORMAT=JSON SELECT * FROM facturas WHERE fecha = '20170101'\G;
|
||||
1 row in set (0.180 sec)
|
||||
```
|
||||
|
||||
<details><summary markdown="span">Detalle ANALYZE</summary>
|
||||
|
||||
```json
|
||||
ANALYZE: {
|
||||
"query_optimization": {
|
||||
"r_total_time_ms": 0.192326251
|
||||
},
|
||||
"query_block": {
|
||||
"select_id": 1,
|
||||
"r_loops": 1,
|
||||
"r_total_time_ms": 177.6817744,
|
||||
"nested_loop": [
|
||||
{
|
||||
"table": {
|
||||
"table_name": "facturas",
|
||||
"access_type": "ALL",
|
||||
"r_loops": 1,
|
||||
"rows": 87768,
|
||||
"r_rows": 87877,
|
||||
"r_table_time_ms": 135.9970415,
|
||||
"r_other_time_ms": 41.66515984,
|
||||
"filtered": 100,
|
||||
"r_filtered": 0.08420861,
|
||||
"attached_condition": "facturas.FECHA_VENTA = DATE'2017-01-01'"
|
||||
}
|
||||
}
|
||||
]
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
</details>
|
||||
|
||||
|
||||
### Plan de ejecución gráfico en Workbench
|
||||
|
||||
Ejemplo
|
||||
|
||||
[<img src="./imgs/wb-visual-explain-hash-join-sakila.png" width="350"/>](./imgs/wb-visual-explain-hash-join-sakila.png)
|
||||
|
||||
```sql
|
||||
SELECT P.codigo_del_producto, I.cantidad FROM tabla_de_productos P
|
||||
INNER JOIN items_facturas I
|
||||
ON P.codigo_del_producto = I.codigo_del_producto;
|
||||
```
|
||||
|
||||
[<img src="./imgs/graph_cost_query1.png" width="400"/>](./imgs/graph_cost_query1.png)
|
||||
|
||||
```sql
|
||||
SELECT P.codigo_del_producto, YEAR(F.fecha_venta) AS "AÑO", I.cantidad
|
||||
FROM tabla_de_productos P
|
||||
INNER JOIN items_facturas I
|
||||
ON P.codigo_del_producto = I.codigo_del_producto
|
||||
INNER JOIN facturas F ON I.numero = F.numero;
|
||||
```
|
||||
|
||||
[<img src="./imgs/graph_cost_query2.png" width="450"/>](./imgs/graph_cost_query2.png)
|
||||
|
||||
Sin índices ni claves primarias
|
||||
|
||||
```sql
|
||||
SELECT P.codigo_del_producto, YEAR(F.fecha_venta) AS "AÑO", I.cantidad
|
||||
FROM tabla_de_productos2 P
|
||||
INNER JOIN items_facturas2 I
|
||||
ON P.codigo_del_producto = I.codigo_del_producto
|
||||
INNER JOIN facturas2 F ON I.numero = F.numero;
|
||||
```
|
||||
|
||||
[<img src="./imgs/graph_cost_query3.png" width="450"/>](./imgs/graph_cost_query3.png)
|
||||
|
||||
### mysqslap
|
||||
|
||||
`mysqslap` o `mariadb-slap`
|
||||
|
||||
```txt
|
||||
mariadb-slap -u <user> -p -h <dbaddres> -P 3306 \
|
||||
--concurrency=100 --iterations=10 --create-schema=jugos2 \
|
||||
--query="SELECT * FROM facturas WHERE fecha_venta='20170101'";
|
||||
Enter password:
|
||||
Benchmark
|
||||
Average number of seconds to run all queries: 15.112 seconds
|
||||
Minimum number of seconds to run all queries: 15.022 seconds
|
||||
Maximum number of seconds to run all queries: 15.287 seconds
|
||||
Number of clients running queries: 100
|
||||
Average number of queries per client: 1
|
||||
```
|
||||
|
||||
## Administración de usuarios
|
||||
|
||||
Esto se puede realizar desde Workbench:
|
||||
|
||||
`-> Pestaña Administración -> Users and Privileges` Donde se pueden escoger
|
||||
los roles que se quieran asignar al usuario
|
||||
|
||||
### User Administrador Manual
|
||||
|
||||
```sql
|
||||
CREATE USER 'dbadmin-user' identified by 'dbadmin-password';
|
||||
GRANT USAGE ON *.* TO `%`@`%` IDENTIFIED BY 'dbadmin-password';
|
||||
GRANT ALL PRIVILEGES ON *.* TO 'dbadmin-user'@`%` WITH GRANT OPTION;
|
||||
FLUSH PRIVILEGES;
|
||||
```
|
||||
|
||||
### Usuario con privilegios para schema `schema1`, uso local
|
||||
|
||||
```sql
|
||||
CREATE USER 'basic-admin' identified by 'basic-admin-password';
|
||||
GRANT USAGE ON 'schema1'.* TO 'basic-admin'@'localhost' IDENTIFIED BY 'basic-admin-password';
|
||||
GRANT ALL PRIVILEGES ON 'schema1'.* TO 'basic-admin'@`%`;
|
||||
FLUSH PRIVILEGES;
|
||||
```
|
||||
|
||||
### Usuario con privilegios limitados
|
||||
|
||||
`SELECT`, `UPDATE`, `INSERT`, `DELETE`, `EXECUTE`, `LOCK TABLES`, `CREATE TEMPORARY TABLES` para schema `schema1`, uso local:
|
||||
|
||||
```sql
|
||||
CREATE USER 'limited-user' identified by 'limited-user-password';
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE, CREATE TEMPORARY TABLES, LOCK TABLES,
|
||||
EXECUTE ON 'schema1'.* TO 'limited-user'@'localhost'
|
||||
IDENTIFIED BY 'limited-user-password';
|
||||
FLUSH PRIVILEGES;
|
||||
```
|
||||
|
||||
### Usuario con privilegios solo lectura
|
||||
|
||||
Para todas los schemas con acceso remoto:
|
||||
|
||||
```sql
|
||||
CREATE USER 'limited-user' identified by 'limited-user-password';
|
||||
GRANT SELECT, EXECUTE ON *.* TO 'limited-user'@'%'
|
||||
IDENTIFIED BY 'limited-user-password';
|
||||
FLUSH PRIVILEGES;
|
||||
```
|
||||
|
||||
### Backup user
|
||||
|
||||
```sql
|
||||
CREATE USER 'backup-user' identified by 'backup-user-password';
|
||||
GRANT SELECT, RELOAD, LOCK TABLES, REPLICATION CLIENT ON *.* TO 'backup-user'@'%'
|
||||
IDENTIFIED BY 'backup-user-password';
|
||||
FLUSH PRIVILEGES;
|
||||
```
|
||||
|
||||
### Limitando accesos remotos
|
||||
|
||||
- `192.168.1.%`: 192.168.1.0 - 192.168.1.255
|
||||
- `192.168.1.1_`: 192.168.1.100 - 192.168.1.255
|
||||
- `cliente_.empresa.com`: clientXY.empresa.com
|
||||
|
||||
### Revocar todos los privilegios
|
||||
|
||||
```sql
|
||||
SHOW GRANTS FOR 'usuario'@'localhost';
|
||||
REVOKE ALL PRIVILEGES, GRATN OPTION FROM 'user'@'localhost';
|
||||
```
|
||||
|
BIN
011_mysql/imgs/graph_cost_query1.png
Normal file
BIN
011_mysql/imgs/graph_cost_query1.png
Normal file
Binary file not shown.
After Width: | Height: | Size: 34 KiB |
BIN
011_mysql/imgs/graph_cost_query2.png
Normal file
BIN
011_mysql/imgs/graph_cost_query2.png
Normal file
Binary file not shown.
After Width: | Height: | Size: 47 KiB |
BIN
011_mysql/imgs/graph_cost_query3.png
Normal file
BIN
011_mysql/imgs/graph_cost_query3.png
Normal file
Binary file not shown.
After Width: | Height: | Size: 40 KiB |
254
011_mysql/imgs/hash_table.svg
Normal file
254
011_mysql/imgs/hash_table.svg
Normal file
@ -0,0 +1,254 @@
|
||||
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
|
||||
<!DOCTYPE svg PUBLIC "-//W3C//DTD SVG 1.1//EN" "http://www.w3.org/Graphics/SVG/1.1/DTD/svg11.dtd">
|
||||
<!-- Created on 2009-04-10 by Jorge Stolfi with the script make-hash-table-figure -->
|
||||
|
||||
<svg
|
||||
xmlns="http://www.w3.org/2000/svg"
|
||||
xmlns:xlink="http://www.w3.org/1999/xlink"
|
||||
width="450.0"
|
||||
height="310.0"
|
||||
id="fig"
|
||||
stroke-linejoin="round"
|
||||
stroke-opacity="1"
|
||||
stroke-linecap="round"
|
||||
fill-opacity="1"
|
||||
fill-rule="evenodd"
|
||||
font-family="Bitstream Courier"
|
||||
font-style="normal"
|
||||
font-weight="normal"
|
||||
pagecolor="#ffff00"
|
||||
pageopacity="0.0">
|
||||
|
||||
|
||||
<g
|
||||
font-size="12px"
|
||||
transform="scale(1.0) translate(10,60)"
|
||||
>
|
||||
|
||||
<defs>
|
||||
<!-- Start marker for non-null pointers: -->
|
||||
<marker id="linkdot_N" viewBox="0 0 8 8" refX="4" refY="4" markerWidth="8" markerHeight="8" orient="auto">
|
||||
<circle cx="4" cy="4" r="3" stroke="#000000" fill="#000000" />
|
||||
</marker>
|
||||
<!-- Start marker for null pointers: -->
|
||||
<marker id="linkdot_U" viewBox="0 0 8 8" refX="4" refY="4" markerWidth="8" markerHeight="8" orient="auto">
|
||||
<line x1="1" y1="1" x2="7" y2="7" stroke="#000000" />
|
||||
<line x1="1" y1="7" x2="7" y2="1" stroke="#000000" />
|
||||
</marker>
|
||||
|
||||
<!-- Tip for arrows: -->
|
||||
<marker id="arrowtip_N" viewBox="0 0 14 8" refX="13" refY="4" markerWidth="14" markerHeight="8" orient="auto">
|
||||
<polygon points="1,4 1,1 13,4 1,7" stroke="#000000" fill="#000000" />
|
||||
</marker>
|
||||
<!-- Tip for highlighted arrows: -->
|
||||
<marker id="arrowtip_C" viewBox="0 0 14 8" refX="13" refY="4" markerWidth="14" markerHeight="8" orient="auto">
|
||||
<polygon points="1,4 1,1 13,4 1,7" stroke="#cc0000" fill="#cc0000" />
|
||||
</marker>
|
||||
|
||||
<!-- Key box in input column, normal: -->
|
||||
<rect id="key_box_N" y="0" x="0" width="90" height="20" fill="#00ffff" stroke="none" />
|
||||
<!-- Key box in input column, highlighted : -->
|
||||
<rect id="key_box_C" y="0" x="0" width="90" height="20" fill="#00ffff" stroke="none" />
|
||||
<!-- Key box in bucket or overflow columns, normal: -->
|
||||
<rect id="key_box_E" y="0" x="0" width="90" height="20" fill="#9cff9c" stroke="#000000" />
|
||||
<!-- Key box in bucket or overflow columns, vacant: -->
|
||||
<rect id="key_box_U" y="0" x="0" width="90" height="20" fill="#ddeedd" stroke="#000000" />
|
||||
|
||||
<!-- Value box in bucket or overflow columns, occupied: -->
|
||||
<rect id="val_box_E" y="0" x="0" width="80" height="20" fill="#9cff9c" stroke="#000000" />
|
||||
<!-- Value box in bucket or overflow columns, vacant: -->
|
||||
<rect id="val_box_U" y="0" x="0" width="80" height="20" fill="#ddeedd" stroke="#000000" />
|
||||
|
||||
<!-- Pointer box in bucket or overflow columns, used and non-null: -->
|
||||
<rect id="ptr_box_E" y="0" x="0" width="20" height="20" fill="#9cff9c" stroke="#000000" />
|
||||
<!-- Pointer box in bucket or overflow columns, null/vacant: -->
|
||||
<rect id="ptr_box_U" y="0" x="0" width="20" height="20" fill="#ddeedd" stroke="#000000" />
|
||||
|
||||
<!-- Background for hash value, unused: -->
|
||||
<rect id="hsh_box_U" x="3" y="1" width="34" height="18" fill="#ddeedd" stroke="none" />
|
||||
<!-- Background for hash value, used: -->
|
||||
<rect id="hsh_box_N" x="3" y="1" width="34" height="18" fill="#a8a8ff" stroke="none" />
|
||||
<!-- Background for hash value, highlighted: -->
|
||||
<rect id="hsh_box_C" x="3" y="1" width="34" height="18" fill="#ee4444" stroke="none" />
|
||||
|
||||
<!-- Vertical dots: -->
|
||||
<g id="vdots">
|
||||
<rect x="0" y="06" width="2" height="2" />
|
||||
<rect x="0" y="12" width="2" height="2" />
|
||||
</g>
|
||||
</defs>
|
||||
|
||||
<!-- Keys and hash function -->
|
||||
<g transform="translate(0,000)" text-anchor="middle" stroke="none">
|
||||
|
||||
<text x="45" y="-10" font-size="15px" font-weight="bold" fill="#000000" stroke="none"> keys
|
||||
</text>
|
||||
|
||||
<g transform="translate(0,30)">
|
||||
<use xlink:href="#key_box_C" />
|
||||
<text x="45" y="14" stroke="none">John Smith</text>
|
||||
<line x1="95" y1="10" x2="100" y2="10" stroke="#dd0000" />
|
||||
<line x1="100" y1="10" x2="130" y2="80" stroke="#dd0000" />
|
||||
<line x1="130" y1="80" x2="150" y2="80" stroke="#dd0000" marker-end="url(#arrowtip_C)" />
|
||||
</g>
|
||||
<g transform="translate(0,70)">
|
||||
<use xlink:href="#key_box_N" />
|
||||
<text x="45" y="14" stroke="none">Lisa Smith</text>
|
||||
<line x1="95" y1="10" x2="100" y2="10" stroke="#000000" />
|
||||
<line x1="100" y1="10" x2="130" y2="-40" stroke="#000000" />
|
||||
<line x1="130" y1="-40" x2="150" y2="-40" stroke="#000000" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(0,110)">
|
||||
<use xlink:href="#key_box_N" />
|
||||
<text x="45" y="14" stroke="none">Sam Doe</text>
|
||||
<line x1="95" y1="10" x2="100" y2="10" stroke="#000000" />
|
||||
<line x1="100" y1="10" x2="130" y2="100" stroke="#000000" />
|
||||
<line x1="130" y1="100" x2="150" y2="100" stroke="#000000" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(0,150)">
|
||||
<use xlink:href="#key_box_C" />
|
||||
<text x="45" y="14" stroke="none">Sandra Dee</text>
|
||||
<line x1="95" y1="10" x2="100" y2="10" stroke="#dd0000" />
|
||||
<line x1="100" y1="10" x2="130" y2="-40" stroke="#dd0000" />
|
||||
<line x1="130" y1="-40" x2="150" y2="-40" stroke="#dd0000" marker-end="url(#arrowtip_C)" />
|
||||
</g>
|
||||
<g transform="translate(0,190)">
|
||||
<use xlink:href="#key_box_N" />
|
||||
<text x="45" y="14" stroke="none">Ted Baker</text>
|
||||
<line x1="95" y1="10" x2="100" y2="10" stroke="#000000" />
|
||||
<line x1="100" y1="10" x2="130" y2="-60" stroke="#000000" />
|
||||
<line x1="130" y1="-60" x2="150" y2="-60" stroke="#000000" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
|
||||
</g>
|
||||
|
||||
<!-- Hash values and bucket array -->
|
||||
<g transform="translate(150,000)" text-anchor="middle" stroke="none">
|
||||
|
||||
<text x="50" y="-10" font-size="15px" font-weight="bold" fill="#000000" stroke="none">
|
||||
buckets
|
||||
</text>
|
||||
|
||||
<g transform="translate(000,0)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">000</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
<g transform="translate(000,20)">
|
||||
<use x="0" xlink:href="#hsh_box_N" />
|
||||
<text x="20" y="14">001</text>
|
||||
<use x="40" xlink:href="#ptr_box_E" />
|
||||
<line x1="50" y1="10" x2="90" y2="0" stroke="#000000" marker-start="url(#linkdot_N)" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(000,40)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">002</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
<g transform="translate(000,60)">
|
||||
<text x="20" y="14" font-weight="bold">:</text>
|
||||
<text x="50" y="14" font-weight="bold">:</text>
|
||||
</g>
|
||||
<g transform="translate(000,80)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">151</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
<g transform="translate(000,100)">
|
||||
<use x="0" xlink:href="#hsh_box_C" />
|
||||
<text x="20" y="14">152</text>
|
||||
<use x="40" xlink:href="#ptr_box_E" />
|
||||
<line x1="50" y1="10" x2="90" y2="-30" stroke="#000000" marker-start="url(#linkdot_N)" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(000,120)">
|
||||
<use x="0" xlink:href="#hsh_box_N" />
|
||||
<text x="20" y="14">153</text>
|
||||
<use x="40" xlink:href="#ptr_box_E" />
|
||||
<line x1="50" y1="10" x2="90" y2="50" stroke="#000000" marker-start="url(#linkdot_N)" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(000,140)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">154</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
<g transform="translate(000,160)">
|
||||
<text x="20" y="14" font-weight="bold">:</text>
|
||||
<text x="50" y="14" font-weight="bold">:</text>
|
||||
</g>
|
||||
<g transform="translate(000,180)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">253</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
<g transform="translate(000,200)">
|
||||
<use x="0" xlink:href="#hsh_box_N" />
|
||||
<text x="20" y="14">254</text>
|
||||
<use x="40" xlink:href="#ptr_box_E" />
|
||||
<line x1="50" y1="10" x2="90" y2="20" stroke="#000000" marker-start="url(#linkdot_N)" marker-end="url(#arrowtip_N)" />
|
||||
</g>
|
||||
<g transform="translate(000,220)">
|
||||
<use x="0" xlink:href="#hsh_box_U" />
|
||||
<text x="20" y="14">255</text>
|
||||
<use x="40" xlink:href="#ptr_box_U" />
|
||||
<line x1="50" y1="10" x2="50.000999999999998" y2="10" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
</g>
|
||||
|
||||
</g>
|
||||
|
||||
<!-- Hash values and bucket array -->
|
||||
<g transform="translate(240,000)" text-anchor="middle" stroke="none">
|
||||
|
||||
<text x="95" y="-10" font-size="15px" font-weight="bold" fill="#000000" stroke="none">
|
||||
entries
|
||||
</text>
|
||||
|
||||
<g transform="translate(000,10)">
|
||||
<use x="0" xlink:href="#ptr_box_E" />
|
||||
<line x1="10" y1="10" x2="10" y2="10.000999999999999" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
<use x="20" xlink:href="#key_box_E" />
|
||||
<text x="65" y="14">Lisa Smith</text>
|
||||
<use x="110" xlink:href="#val_box_E" />
|
||||
<text x="150" y="14">521-8976</text>
|
||||
</g>
|
||||
<g transform="translate(000,60)">
|
||||
<use x="0" xlink:href="#ptr_box_E" />
|
||||
<line x1="10" y1="10" x2="10" y2="50" stroke="#000000" marker-start="url(#linkdot_N)" marker-end="url(#arrowtip_N)" />
|
||||
<use x="20" xlink:href="#key_box_E" />
|
||||
<text x="65" y="14">John Smith</text>
|
||||
<use x="110" xlink:href="#val_box_E" />
|
||||
<text x="150" y="14">521-1234</text>
|
||||
</g>
|
||||
<g transform="translate(000,110)">
|
||||
<use x="0" xlink:href="#ptr_box_E" />
|
||||
<line x1="10" y1="10" x2="10" y2="10.000999999999999" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
<use x="20" xlink:href="#key_box_E" />
|
||||
<text x="65" y="14">Sandra Dee</text>
|
||||
<use x="110" xlink:href="#val_box_E" />
|
||||
<text x="150" y="14">521-9655</text>
|
||||
</g>
|
||||
<g transform="translate(000,160)">
|
||||
<use x="0" xlink:href="#ptr_box_E" />
|
||||
<line x1="10" y1="10" x2="10" y2="10.000999999999999" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
<use x="20" xlink:href="#key_box_E" />
|
||||
<text x="65" y="14">Ted Baker</text>
|
||||
<use x="110" xlink:href="#val_box_E" />
|
||||
<text x="150" y="14">418-4165</text>
|
||||
</g>
|
||||
<g transform="translate(000,210)">
|
||||
<use x="0" xlink:href="#ptr_box_E" />
|
||||
<line x1="10" y1="10" x2="10" y2="10.000999999999999" stroke="#000000" marker-start="url(#linkdot_U)" />
|
||||
<use x="20" xlink:href="#key_box_E" />
|
||||
<text x="65" y="14">Sam Doe</text>
|
||||
<use x="110" xlink:href="#val_box_E" />
|
||||
<text x="150" y="14">521-5030</text>
|
||||
</g>
|
||||
|
||||
</g>
|
||||
|
||||
</g>
|
||||
</svg>
|
After Width: | Height: | Size: 11 KiB |
BIN
011_mysql/imgs/wb-visual-explain-hash-join-sakila.png
Normal file
BIN
011_mysql/imgs/wb-visual-explain-hash-join-sakila.png
Normal file
Binary file not shown.
After Width: | Height: | Size: 6.9 KiB |
@ -7,38 +7,42 @@ while read LINE; do
|
||||
declare "$LINE" 2>/dev/null
|
||||
done < $BASEDIR/.env
|
||||
|
||||
connect_db(){
|
||||
maria_connect(){
|
||||
echo "mariadb -u ${DBUSER} -p${DBPASS} -h ${DBADDR%%:*} ${DBNAME} -P ${DBADDR##*:}"
|
||||
}
|
||||
|
||||
connect_db(){
|
||||
$(maria_connect)
|
||||
}
|
||||
|
||||
create_tables(){
|
||||
$(connect_db) < ./create_tables.sql
|
||||
$(maria_connect) < ./create_tables.sql
|
||||
}
|
||||
|
||||
populate_tables(){
|
||||
$(connect_db) < ./populate_tables.sql
|
||||
$(maria_connect) < ./populate_tables.sql
|
||||
}
|
||||
|
||||
import_records(){
|
||||
$(connect_db) < ./import_records.sql
|
||||
$(maria_connect) < ./import_records.sql
|
||||
}
|
||||
|
||||
re_create_tables(){
|
||||
$(connect_db) < ./re_create_tables.sql
|
||||
$(maria_connect) < ./re_create_tables.sql
|
||||
}
|
||||
|
||||
create_f_sp(){
|
||||
$(connect_db) < ./funcs_sp.sql
|
||||
$(maria_connect) < ./funcs_sp.sql
|
||||
}
|
||||
|
||||
create_triggers(){
|
||||
$(connect_db) < ./triggers.sql
|
||||
$(maria_connect) < ./triggers.sql
|
||||
}
|
||||
|
||||
deactivate_session(){
|
||||
unset DBNAME DBUSER DBPASS DBADDR PEPPER
|
||||
unset VersionStr BASEDIR
|
||||
unset connect_db create_populate_tables
|
||||
unset VersionStr BASEDIR connect_db
|
||||
unset maria_connect create_populate_tables
|
||||
unset populate_tables import_records
|
||||
unset re_create_tables create_f_sp
|
||||
unset create_triggers deactivate_session
|
||||
|
Loading…
Reference in New Issue
Block a user