INSERT OVERWRITE (Databricks SQL)

Sobrescribe los datos existentes en la tabla con los nuevos valores. Especifique las filas insertadas por expresiones de valor o el resultado de una consulta.

Sintaxis

INSERT OVERWRITE [ TABLE ] table_name [ partition_spec [ IF NOT EXISTS ] ]
    { VALUES { ( { value | NULL } [ , ... ] ) } [ , ... ] |
      query }

Parámetros

  • Table_name

    Identifica la tabla en la que se va a insertar. El nombre no debe incluir una especificación temporal.

  • partition_spec

    Parámetro opcional que especifica una lista separada por comas de pares clave-valor para particiones.

    Sintaxis:PARTITION ( partition_col_name [ = partition_col_val ] [ , ... ] )

  • VALUES ( { value | NULL } [ , ... ] ) [ , ( ... ) ]

    Valores que se van a insertar. Se puede insertar un valor especificado explícitamente o un valor NULL. Se debe usar una coma para separar cada valor de la cláusula . Se puede especificar más de un conjunto de valores para insertar varias filas.

  • consulta

    Consulta que genera las filas que se insertarán. Puede estar en uno de los siguientes formatos:

    • Una SELECT instrucción
    • Una TABLE instrucción
    • Una FROM instrucción

Ejemplos

En esta sección:

Inserción mediante una VALUES cláusula

-- Assuming the students table has already been created and populated.
SELECT * FROM students;
+-------------+-------------------------+----------+
|         name|                  address|student_id|
+-------------+-------------------------+----------+
|    Amy Smith|   123 Park Ave, San Jose|    111111|
|    Bob Brown| 456 Taylor St, Cupertino|    222222|
|Cathy Johnson|  789 Race Ave, Palo Alto|    333333|
|Dora Williams|134 Forest Ave, Melo Park|    444444|
|Fleur Laurent|    345 Copper St, London|    777777|
|Gordon Martin|     779 Lake Ave, Oxford|    888888|
|  Helen Davis|469 Mission St, San Diego|    999999|
|   Jason Wang|    908 Bird St, Saratoga|    121212|
+-------------+-------------------------+----------+

INSERT OVERWRITE students VALUES
    ('Ashua Hill', '456 Erica Ct, Cupertino', 111111),
    ('Brian Reed', '723 Kern Ave, Palo Alto', 222222);

SELECT * FROM students;
+----------+-----------------------+----------+
|      name|                address|student_id|
+----------+-----------------------+----------+
|Ashua Hill|456 Erica Ct, Cupertino|    111111|
|Brian Reed|723 Kern Ave, Palo Alto|    222222|
+----------+-----------------------+----------+

Inserción mediante una SELECT instrucción

-- Assuming the persons table has already been created and populated.
SELECT * FROM persons;
+-------------+-------------------------+---------+
|         name|                  address|      ssn|
+-------------+-------------------------+---------+
|Dora Williams|134 Forest Ave, Melo Park|123456789|
+-------------+-------------------------+---------+
|  Eddie Davis|   245 Market St,Milpitas|345678901|
+-------------+-------------------------+---------+

INSERT OVERWRITE students PARTITION (student_id = 222222)
    SELECT name, address FROM persons WHERE name = "Dora Williams";

SELECT * FROM students;
+-------------+-------------------------+----------+
|         name|                  address|student_id|
+-------------+-------------------------+----------+
|   Ashua Hill|  456 Erica Ct, Cupertino|    111111|
+-------------+-------------------------+----------+
|Dora Williams|134 Forest Ave, Melo Park|    222222|
+-------------+-------------------------+----------+

Inserción mediante una TABLE instrucción

-- Assuming the visiting_students table has already been created and populated.
SELECT * FROM visiting_students;
+-------------+---------------------+----------+
|         name|              address|student_id|
+-------------+---------------------+----------+
|Fleur Laurent|345 Copper St, London|    777777|
+-------------+---------------------+----------+
|Gordon Martin| 779 Lake Ave, Oxford|    888888|
+-------------+---------------------+----------+

INSERT OVERWRITE students TABLE visiting_students;

SELECT * FROM students;
+-------------+---------------------+----------+
|         name|              address|student_id|
+-------------+---------------------+----------+
|Fleur Laurent|345 Copper St, London|    777777|
+-------------+---------------------+----------+
|Gordon Martin| 779 Lake Ave, Oxford|    888888|
+-------------+---------------------+----------+

Inserción mediante una FROM instrucción

-- Assuming the applicants table has already been created and populated.
SELECT * FROM applicants;
+-----------+--------------------------+----------+---------+
|       name|                   address|student_id|qualified|
+-----------+--------------------------+----------+---------+
|Helen Davis| 469 Mission St, San Diego|    999999|     true|
+-----------+--------------------------+----------+---------+
|   Ivy King|367 Leigh Ave, Santa Clara|    101010|    false|
+-----------+--------------------------+----------+---------+
| Jason Wang|     908 Bird St, Saratoga|    121212|     true|
+-----------+--------------------------+----------+---------+

INSERT OVERWRITE students
    FROM applicants SELECT name, address, id applicants WHERE qualified = true;

SELECT * FROM students;
+-----------+-------------------------+----------+
|       name|                  address|student_id|
+-----------+-------------------------+----------+
|Helen Davis|469 Mission St, San Diego|    999999|
+-----------+-------------------------+----------+
| Jason Wang|    908 Bird St, Saratoga|    121212|
+-----------+-------------------------+----------+

Inserción de sobrescritura de un directorio

CREATE TABLE students (name VARCHAR(64), address VARCHAR(64), student_id INT)
    PARTITIONED BY (student_id)
    LOCATION "/mnt/user1/students";

INSERT OVERWRITE delta.`/mnt/user1/students` VALUES
    ('Amy Smith', '123 Park Ave, San Jose', 111111);
SELECT * FROM students;
+-------------+-------------------------+----------+
|         name|                  address|student_id|
+-------------+-------------------------+----------+
|    Amy Smith|   123 Park Ave, San Jose|    111111|
+-------------+-------------------------+----------+