SnowConvert: Redshift SELECT-Anweisung¶
SELECT¶
Beschreibung¶
Gibt Zeilen aus Tabellen, Ansichten und benutzerdefinierten Funktionen zurück. (Redshift SQL-Referenz: SELECT-Anweisung)
Grammatikalische Syntax¶
[ WITH with_subquery [, ...] ]
SELECT
[ TOP number | [ ALL | DISTINCT ]
* | expression [ AS output_name ] [, ...] ]
[ FROM table_reference [, ...] ]
[ WHERE condition ]
[ [ START WITH expression ] CONNECT BY expression ]
[ GROUP BY expression [, ...] ]
[ HAVING condition ]
[ QUALIFY condition ]
[ { UNION | ALL | INTERSECT | EXCEPT | MINUS } query ]
[ ORDER BY expression [ ASC | DESC ] ]
[ LIMIT { number | ALL } ]
[ OFFSET start ]
Weitere Informationen finden Sie unter den folgenden Links:
CONNECT BY-Klausel.¶
Beschreibung¶
Die CONNECT BY
-Klausel gibt die Beziehung zwischen den Zeilen in einer Hierarchie an. Sie können CONNECT BY
verwenden, um Zeilen in einer hierarchischen Reihenfolge auszuwählen, indem Sie die Tabelle mit sich selbst verbinden und die hierarchischen Daten verarbeiten. (Redshift SQL-Referenz: CONNECT BY-Klausel)
Die CONNECTBY-Klausel wird in Snowflake unterstützt.
Grammar Syntax
[START WITH start_with_conditions]
CONNECT BY connect_by_conditions
Beispielhafte Quellcode-Muster
Eingabecode:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT COUNT(*)
FROM
Employee "start"
CONNECT BY PRIOR id = manager_id
START WITH name = 'John';
COUNT(*) |
---|
12 |
Ausgabecode:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT COUNT(*)
FROM
Employee "start"
CONNECT BY PRIOR id = manager_id
START WITH RTRIM( name) = RTRIM( 'John');
COUNT(*) |
---|
12 |
Zugehörige EWIs
Es gibt keine bekannten Probleme.
FROM-Klausel.
Description
Die FROM
-Klausel in einer Abfrage listet die Tabellenverweise (Tabellen, Ansichten und Unterabfragen) auf, aus denen die Daten ausgewählt werden. Wenn mehrere Tabellenreferenzen aufgeführt sind, müssen die Tabellen unter Verwendung der entsprechenden Syntax entweder in der FROM
-Klausel oder der WHERE
-Klausel verbunden werden. Wenn keine Verknüpfungskriterien angegeben werden, verarbeitet das System die Abfrage als Cross-Join. (Redshift SQL-Referenz: FROM-Klausel)
Warnung
Die FROM-Klausel wird in Snowflake teilweise unterstützt. Entpivotieren von Objekten wird derzeit nicht unterstützt.
Grammatikalische Syntax¶
FROM table_reference [, ...]
<table_reference> ::=
with_subquery_table_name [ table_alias ]
table_name [ * ] [ table_alias ]
( subquery ) [ table_alias ]
table_reference [ NATURAL ] join_type table_reference
[ ON join_condition | USING ( join_column [, ...] ) ]
table_reference PIVOT (
aggregate(expr) [ [ AS ] aggregate_alias ]
FOR column_name IN ( expression [ AS ] in_alias [, ...] )
) [ table_alias ]
table_reference UNPIVOT [ INCLUDE NULLS | EXCLUDE NULLS ] (
value_column_name
FOR name_column_name IN ( column_reference [ [ AS ]
in_alias ] [, ...] )
) [ table_alias ]
UNPIVOT expression AS value_alias [ AT attribute_alias ]
Beispielhafte Quellcode-Muster¶
Verknüpfungstypen (Join Types)¶
Snowflake unterstützt alle Arten von Verknüpfungen. Weitere Informationen finden Sie in der Dokumentation JOIN.
Eingabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
CREATE TABLE department (
id INT,
name VARCHAR(50),
manager_id INT
);
INSERT INTO department(id, name, manager_id) VALUES
(1, 'HR', 100),
(2, 'Sales', 101),
(3, 'Engineering', 102),
(4, 'Marketing', 103);
SELECT e.name AS employee_name, d.name AS department_name
FROM employee e
INNER JOIN department d ON e.manager_id = d.manager_id;
SELECT e.name AS employee_name, d.name AS department_name
FROM employee e
LEFT JOIN department d ON e.manager_id = d.manager_id;
SELECT d.name AS department_name, e.name AS manager_name
FROM department d
RIGHT JOIN employee e ON d.manager_id = e.id;
SELECT e.name AS employee_name, d.name AS department_name
FROM employee e
FULL JOIN department d ON e.manager_id = d.manager_id;
Innere Verknüpfung (Inner Join)¶
EMPLOYEE_NAME | DEPARTMENT_NAME |
---|---|
John | HR |
Jorge | Sales |
Kwaku | Sales |
Liu | Sales |
Mateo | Engineering |
Nikki | Marketing |
Paulo | Marketing |
Richard | Marketing |
Sofía | Engineering |
Linke Verknüpfung (Left Join)¶
EMPLOYEE_NAME |
DEPARTMENT_NAME |
---|---|
Carlos |
null |
John |
HR |
Jorge |
Sales |
Kwaku |
Sales |
Liu |
Sales |
Mateo |
Engineering |
Nikki |
Marketing |
Paulo |
Marketing |
Richard |
Marketing |
Saanvi |
null |
Shirley |
null |
Sofía |
Engineering |
Zhang |
null |
Rechte Verknüpfung (Right Join)¶
DEPARTMENT_NAME |
MANAGER_NAME |
---|---|
HR |
Carlos |
Sales |
John |
Engineering |
Jorge |
Marketing |
Kwaku |
null |
Liu |
null |
Mateo |
null |
Nikki |
null |
Paulo |
null |
Richard |
null |
Saanvi |
null |
Shirley |
null |
Sofía |
null |
Zhang |
Vollständige Verknüpfung (Full Join)¶
EMPLOYEE_NAME |
DEPARTMENT_NAME |
---|---|
Carlos |
null |
John |
HR |
Jorge |
Sales |
Kwaku |
Sales |
Liu |
Sales |
Mateo |
Engineering |
Nikki |
Marketing |
Paulo |
Marketing |
Richard |
Marketing |
Saanvi |
null |
Shirley |
null |
Sofía |
Engineering |
Zhang |
null |
Ausgabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
CREATE TABLE department (
id INT,
name VARCHAR(50),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO department (id, name, manager_id) VALUES
(1, 'HR', 100),
(2, 'Sales', 101),
(3, 'Engineering', 102),
(4, 'Marketing', 103);
SELECT e.name AS employee_name, d.name AS department_name
FROM
employee e
INNER JOIN
department d ON e.manager_id = d.manager_id;
SELECT e.name AS employee_name, d.name AS department_name
FROM
employee e
LEFT JOIN
department d ON e.manager_id = d.manager_id;
SELECT d.name AS department_name, e.name AS manager_name
FROM
department d
RIGHT JOIN
employee e ON d.manager_id = e.id;
SELECT e.name AS employee_name, d.name AS department_name
FROM
employee e
FULL JOIN
department d ON e.manager_id = d.manager_id;
Innere Verknüpfung (Inner Join)¶
EMPLOYEE_NAME |
DEPARTMENT_NAME |
---|---|
John |
HR |
Jorge |
Sales |
Kwaku |
Sales |
Liu |
Sales |
Mateo |
Engineering |
Nikki |
Marketing |
Paulo |
Marketing |
Richard |
Marketing |
Sofía |
Engineering |
Linke Verknüpfung (Left Join)¶
EMPLOYEE_NAME |
DEPARTMENT_NAME |
---|---|
Carlos |
null |
John |
HR |
Jorge |
Sales |
Kwaku |
Sales |
Liu |
Sales |
Mateo |
Engineering |
Nikki |
Marketing |
Paulo |
Marketing |
Richard |
Marketing |
Saanvi |
null |
Shirley |
null |
Sofía |
Engineering |
Zhang |
null |
Rechte Verknüpfung (Right Join)¶
DEPARTMENT_NAME |
MANAGER_NAME |
---|---|
HR |
Carlos |
Sales |
John |
Engineering |
Jorge |
Marketing |
Kwaku |
null |
Liu |
null |
Mateo |
null |
Nikki |
null |
Paulo |
null |
Richard |
null |
Saanvi |
null |
Shirley |
null |
Sofía |
null |
Zhang |
Vollständige Verknüpfung (Full Join)¶
EMPLOYEE_NAME |
DEPARTMENT_NAME |
---|---|
Carlos |
null |
John |
HR |
Jorge |
Sales |
Kwaku |
Sales |
Liu |
Sales |
Mateo |
Engineering |
Nikki |
Marketing |
Paulo |
Marketing |
Richard |
Marketing |
Saanvi |
null |
Shirley |
null |
Sofía |
Engineering |
Zhang |
null |
PIVOT-Klausel¶
Bemerkung
Spalten-Aliase können in der IN-Klausel der PIVOT-Abfrage in Snowflake nicht verwendet werden.
Eingabecode:¶
SELECT *
FROM
(SELECT e.manager_id, d.name AS department, e.id AS employee_id
FROM employee e
JOIN department d ON e.manager_id = d.manager_id) AS SourceTable
PIVOT
(
COUNT(employee_id)
FOR department IN ('HR', 'Sales', 'Engineering', 'Marketing')
) AS PivotTable;
MANAGER_ID |
‚HR‘ |
‚Sales‘ |
„Engineering“ |
‚Marketing‘ |
---|---|---|---|---|
100 |
1 |
0 |
0 |
0 |
101 |
0 |
3 |
0 |
0 |
102 |
0 |
0 |
2 |
0 |
103 |
0 |
0 |
0 |
3 |
Ausgabecode:¶
SELECT *
FROM
(SELECT e.manager_id, d.name AS department, e.id AS employee_id
FROM
employee e
JOIN
department d ON e.manager_id = d.manager_id) AS SourceTable
PIVOT
(
COUNT(employee_id)
FOR department IN ('HR', 'Sales', 'Engineering', 'Marketing')
) AS PivotTable;
MANAGER_ID |
‚HR‘ |
‚Sales‘ |
„Engineering“ |
‚Marketing‘ |
---|---|---|---|---|
100 |
1 |
0 |
0 |
0 |
101 |
0 |
3 |
0 |
0 |
102 |
0 |
0 |
2 |
0 |
103 |
0 |
0 |
0 |
3 |
Unpivot-Klausel¶
Bemerkung
Spalten-Aliase können in der IN-Klausel der UNPIVOT-Abfrage in Snowflake nicht verwendet werden.
Eingabecode:¶
CREATE TABLE count_by_color (quality VARCHAR, red INT, green INT, blue INT);
INSERT INTO count_by_color VALUES ('high', 15, 20, 7);
INSERT INTO count_by_color VALUES ('normal', 35, NULL, 40);
INSERT INTO count_by_color VALUES ('low', 10, 23, NULL);
SELECT *
FROM (SELECT red, green, blue FROM count_by_color) UNPIVOT (
cnt FOR color IN (red, green, blue)
);
SELECT *
FROM (SELECT red, green, blue FROM count_by_color) UNPIVOT (
cnt FOR color IN (red r, green as g, blue)
);
COLOR |
CNT |
---|---|
RED |
15 |
RED |
35 |
RED |
10 |
GREEN |
20 |
GREEN |
23 |
BLUE |
7 |
BLUE |
40 |
Ausgabecode:¶
CREATE TABLE count_by_color (quality VARCHAR, red INT, green INT, blue INT)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO count_by_color
VALUES ('high', 15, 20, 7);
INSERT INTO count_by_color
VALUES ('normal', 35, NULL, 40);
INSERT INTO count_by_color
VALUES ('low', 10, 23, NULL);
SELECT *
FROM (SELECT red, green, blue FROM
count_by_color
) UNPIVOT (
cnt FOR color IN (red, green, blue)
);
SELECT *
FROM (SELECT red, green, blue FROM
count_by_color
) UNPIVOT (
cnt FOR color IN (red
!!!RESOLVE EWI!!! /*** SSC-EWI-RS0005 - COLUMN ALIASES CANNOT BE USED IN THE IN CLAUSE OF THE PIVOT/UNPIVOT QUERY IN SNOWFLAKE. ***/!!!
r, green
!!!RESOLVE EWI!!! /*** SSC-EWI-RS0005 - COLUMN ALIASES CANNOT BE USED IN THE IN CLAUSE OF THE PIVOT/UNPIVOT QUERY IN SNOWFLAKE. ***/!!!
as g, blue)
);
COLOR |
CNT |
---|---|
RED |
15 |
GREEN |
20 |
BLUE |
7 |
RED |
35 |
BLUE |
40 |
RED |
10 |
GREEN |
23 |
Zugehörige EWIs¶
[SSC-EWI-RS0005](../../general/technical-documentation/issues-and-troubleshooting/conversion-issues/redshiftEWI. md#ssc-ewi-rs0005): Spalten-Aliase können in der IN-Klausel der PIVOT/UNPIVOT-Abfrage in Snowflake nicht verwendet werden.
GROUP BY-Klausel.¶
Beschreibung¶
Die GROUP BY
-Klausel identifiziert die Gruppierungsspalten für die Abfrage. Gruppierungsspalten müssen deklariert werden, wenn die Abfrage Aggregate mit Standardfunktionen wie SUM
, AVG
und COUNT
berechnet. (Redshift SQL-Referenz: GROUP BY-Klausel)
Die GROUP BY-Klausel wird in Snowflake vollständig unterstützt.
Grammar Syntax
GROUP BY group_by_clause [, ...]
group_by_clause := {
expr |
GROUPING SETS ( () | group_by_clause [, ...] ) |
ROLLUP ( expr [, ...] ) |
CUBE ( expr [, ...] )
}
Sample Source Patterns
Gruppierungssätze
Input Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT
manager_id,
COUNT(id) AS total_employees
FROM employee
GROUP BY GROUPING SETS
((manager_id), ())
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
Output Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT
manager_id,
COUNT(id) AS total_employees
FROM
employee
GROUP BY GROUPING SETS
((manager_id), ())
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
GROUP BY CUBE
Input Code:
SELECT
manager_id,
COUNT(id) AS total_employees
FROM
employee
GROUP BY CUBE(manager_id)
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
Output Code:
SELECT
manager_id,
COUNT(id) AS total_employees
FROM
employee
GROUP BY CUBE(manager_id)
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
GROUP BY ROLLUP
Input Code:
SELECT
manager_id,
COUNT(id) AS total_employees
FROM
employee
GROUP BY ROLLUP(manager_id)
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
Output Code:
SELECT
manager_id,
COUNT(id) AS total_employees
FROM
employee
GROUP BY ROLLUP(manager_id)
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
100 |
1 |
101 |
3 |
102 |
2 |
103 |
3 |
104 |
3 |
null |
1 |
null |
13 |
Related EWIs
Es gibt keine bekannten Probleme.
HAVING-Klausel.
Description
Die HAVING
-Klausel wendet eine Bedingung auf das gruppierte Resultset an, das eine Abfrage zurückgibt. (Redshift SQL-Referenz: HAVING-Klausel)
Die HAVING-Klausel wird in Snowflake vollständig unterstützt.
Grammatikalische Syntax¶
[ HAVING condition ]
Beispielhafte Quellcode-Muster¶
Eingabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT manager_id, COUNT(id) AS total_employees
FROM
employee
GROUP BY manager_id
HAVING COUNT(id) > 2
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
101 |
3 |
103 |
3 |
104 |
3 |
Ausgabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT manager_id, COUNT(id) AS total_employees
FROM
employee
GROUP BY manager_id
HAVING COUNT(id) > 2
ORDER BY manager_id;
MANAGER_ID |
TOTAL_EMPLOYEES |
---|---|
101 |
3 |
103 |
3 |
104 |
3 |
Zugehörige EWIs¶
Es gibt keine bekannten Probleme.
ORDER BY-Klausel.¶
Beschreibung¶
Die ORDER BY
-Klausel sortiert das Resultset einer Abfrage. (Redshift SQL-Referenz: ORDER BY-Klausel)
The ORDER BY-Klausel wird in Snowflake vollständig unterstützt.
Grammar Syntax
[ ORDER BY expression [ ASC | DESC ] ]
[ NULLS FIRST | NULLS LAST ]
[ LIMIT { count | ALL } ]
[ OFFSET start ]
Sample Source Patterns
Input Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT,
salary DECIMAL(10, 2)
);
INSERT INTO employee (id, name, manager_id, salary) VALUES
(100, 'Carlos', NULL, 120000.00),
(101, 'John', 100, 90000.00),
(102, 'Jorge', 101, 95000.00),
(103, 'Kwaku', 101, 105000.00),
(104, 'Paulo', 102, 110000.00),
(105, 'Richard', 102, 85000.00),
(106, 'Mateo', 103, 95000.00),
(107, 'Liu', 103, 108000.00),
(108, 'Zhang', 104, 95000.00);
SELECT id, name, manager_id, salary
FROM employee
ORDER BY salary DESC NULLS LAST, name ASC NULLS FIRST
LIMIT 5
OFFSET 2;
ID |
NAME |
MANAGER_ID |
SALARY |
---|---|---|---|
107 |
Liu |
103 |
108000,00 |
103 |
Kwaku |
101 |
105000,00 |
102 |
Jorge |
101 |
95000,00 |
106 |
Mateo |
103 |
95000,00 |
108 |
Zhang |
104 |
95000,00 |
Output Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT,
salary DECIMAL(10, 2)
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id, salary) VALUES
(100, 'Carlos', NULL, 120000.00),
(101, 'John', 100, 90000.00),
(102, 'Jorge', 101, 95000.00),
(103, 'Kwaku', 101, 105000.00),
(104, 'Paulo', 102, 110000.00),
(105, 'Richard', 102, 85000.00),
(106, 'Mateo', 103, 95000.00),
(107, 'Liu', 103, 108000.00),
(108, 'Zhang', 104, 95000.00);
SELECT id, name, manager_id, salary
FROM
employee
ORDER BY salary DESC NULLS LAST, name ASC NULLS FIRST
LIMIT 5
OFFSET 2;
ID |
NAME |
MANAGER_ID |
SALARY |
---|---|---|---|
107 |
Liu |
103 |
108000,00 |
103 |
Kwaku |
101 |
105000,00 |
102 |
Jorge |
101 |
95000,00 |
106 |
Mateo |
103 |
95000,00 |
108 |
Zhang |
104 |
95000,00 |
Related EWIs
Es gibt keine bekannten Probleme.
QUALIFY-Klausel.
Description
Die QUALIFY
-Klausel filtert die Ergebnisse einer zuvor berechneten Fensterfunktion nach den vom Benutzer angegebenen Suchbedingungen. Sie können die Klausel verwenden, um Filterbedingungen auf das Ergebnis einer Fensterfunktion anzuwenden, ohne eine Unterabfrage zu verwenden. (Redshift SQL-Referenz: QUALIFY-Klausel)
Die QUALIFY-Klausel wird in Snowflake unterstützt.
Grammatikalische Syntax¶
QUALIFY condition
Beispielhafte Quellcode-Muster¶
Eingabecode:¶
CREATE TABLE store_sales
(
ss_sold_date DATE,
ss_sold_time TIME,
ss_item TEXT,
ss_sales_price FLOAT
);
INSERT INTO store_sales VALUES ('2022-01-01', '09:00:00', 'Product 1', 100.0),
('2022-01-01', '11:00:00', 'Product 2', 500.0),
('2022-01-01', '15:00:00', 'Product 3', 20.0),
('2022-01-01', '17:00:00', 'Product 4', 1000.0),
('2022-01-01', '18:00:00', 'Product 5', 30.0),
('2022-01-02', '10:00:00', 'Product 6', 5000.0),
('2022-01-02', '16:00:00', 'Product 7', 5.0);
SELECT *
FROM store_sales ss
WHERE ss_sold_time > time '12:00:00'
QUALIFY row_number()
OVER (PARTITION BY ss_sold_date ORDER BY ss_sales_price DESC) <= 2;
SS_SOLD_DATE |
SS_SOLD_TIME |
SS_ITEM |
SS_SALES_PRICE |
---|---|---|---|
2022-01-01 |
17:00:00 |
Produkt 4 |
1000 |
2022-01-01 |
18:00:00 |
Produkt 5 |
30 |
2022-01-02 |
16:00:00 |
Produkt 7 |
5 |
Ausgabecode:¶
CREATE TABLE store_sales
(
ss_sold_date DATE,
ss_sold_time TIME,
ss_item TEXT,
ss_sales_price FLOAT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO store_sales
VALUES ('2022-01-01', '09:00:00', 'Product 1', 100.0),
('2022-01-01', '11:00:00', 'Product 2', 500.0),
('2022-01-01', '15:00:00', 'Product 3', 20.0),
('2022-01-01', '17:00:00', 'Product 4', 1000.0),
('2022-01-01', '18:00:00', 'Product 5', 30.0),
('2022-01-02', '10:00:00', 'Product 6', 5000.0),
('2022-01-02', '16:00:00', 'Product 7', 5.0);
SELECT *
FROM
store_sales ss
WHERE ss_sold_time > time '12:00:00'
QUALIFY row_number()
OVER (PARTITION BY ss_sold_date ORDER BY ss_sales_price DESC) <= 2;
SS_SOLD_DATE |
SS_SOLD_TIME |
SS_ITEM |
SS_SALES_PRICE |
---|---|---|---|
2022-01-02 |
16:00:00 |
Produkt 7 |
5 |
2022-01-01 |
17:00:00 |
Produkt 4 |
1000 |
2022-01-01 |
18:00:00 |
Produkt 5 |
30 |
Zugehörige EWIs¶
Es gibt keine bekannten Probleme.
SELECT-Liste¶
Beschreibung¶
Die SELECT-Liste nennt die Spalten, Funktionen und Ausdrücke, die die Abfrage zurückgeben soll. Die Liste stellt die Ausgabe der Abfrage dar. (Redshift SQL-Referenz: SELECT-Liste)
Die Startoptionen für Abfragen werden in Snowflake vollständig unterstützt. Denken Sie nur daran, dass in Snowflake die Optionen DISTINCT
und ALL
am Anfang der Abfrage stehen müssen.
Bemerkung
Wenn Ihre Anwendung in Redshift Fremdschlüssel oder ungültige Primärschlüssel zulässt, kann dies dazu führen, dass Abfragen falsche Ergebnisse liefern. Eine SELECT DISTINCT-Abfrage könnte zum Beispiel doppelte Zeilen zurückgeben, wenn die Primärschlüsselspalte nicht alle eindeutigen Werte enthält. (Redshift SQL-Referenz: SELECT-Liste)
Grammatikalische Syntax¶
SELECT
[ TOP number ]
[ ALL | DISTINCT ] * | expression [ AS column_alias ] [, ...]
Beispielhafte Quellcode-Muster¶
TOP-Klausel¶
Eingabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT TOP 5 id, name, manager_id
FROM employee;
ID |
NAME |
MANAGER_ID |
---|---|---|
100 |
Carlos |
null |
101 |
John |
100 |
102 |
Jorge |
101 |
103 |
Kwaku |
101 |
110 |
Liu |
101 |
Ausgabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT TOP 5 id, name, manager_id
FROM
employee;
ID |
NAME |
MANAGER_ID |
---|---|---|
100 |
Carlos |
null |
101 |
John |
100 |
102 |
Jorge |
101 |
103 |
Kwaku |
101 |
110 |
Liu |
101 |
ALL¶
Eingabecode:¶
SELECT ALL manager_id
FROM employee;
MANAGER_ID |
---|
null |
100 |
101 |
101 |
101 |
102 |
103 |
103 |
103 |
104 |
104 |
102 |
104 |
Ausgabecode:¶
SELECT ALL manager_id
FROM
employee;
MANAGER_ID |
---|
null |
100 |
101 |
101 |
101 |
102 |
103 |
103 |
103 |
104 |
104 |
102 |
104 |
DISTINCT¶
Eingabecode:¶
SELECT DISTINCT manager_id
FROM employee;
MANAGER_ID |
---|
null |
100 |
101 |
102 |
103 |
104 |
Ausgabecode:¶
SELECT DISTINCT manager_id
FROM
employee;
MANAGER_ID |
---|
null |
100 |
101 |
102 |
103 |
104 |
Zugehörige EWIs¶
Es gibt keine bekannten Probleme.
UNION, INTERSECT und EXCEPT¶
Beschreibung¶
Die UNION
-, INTERSECT
- und EXCEPT
-Satzperatoren werden verwendet, um die Ergebnisse von zwei separaten Abfrageausdrücken zu vergleichen und zusammenzuführen. (Redshift SQL-Referenz: Satzoperatoren)
Set-Operatoren werden in Snowflake vollständig unterstützt.
Grammar Syntax
query
{ UNION [ ALL ] | INTERSECT | EXCEPT | MINUS }
query
Sample Source Patterns
Input Code:
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 101
UNION
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 102
UNION ALL
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 101
INTERSECT
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 103
EXCEPT
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 104;
ID |
NAME |
MANAGER_ID |
---|---|---|
103 |
Kwaku |
101 |
110 |
Liu |
101 |
102 |
Jorge |
101 |
106 |
Mateo |
102 |
201 |
Sofía |
102 |
Output Code:
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 101
UNION
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 102
UNION ALL
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 101
INTERSECT
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 103
EXCEPT
SELECT id, name, manager_id
FROM
employee
WHERE manager_id = 104;
ID |
NAME |
MANAGER_ID |
---|---|---|
102 |
Jorge |
101 |
103 |
Kwaku |
101 |
110 |
Liu |
101 |
106 |
Mateo |
102 |
201 |
Sofía |
102 |
Related EWIs
Es gibt keine bekannten Probleme.
WHERE-Klausel.
Description
Die WHERE
-Klausel enthält Bedingungen, die entweder Tabellen verbinden oder Prädikate auf Spalten in Tabellen anwenden. (Redshift SQL-Referenz: WHERE-Klausel)
Die WHERE-Klausel wird in Snowflake vollständig unterstützt.
Grammatikalische Syntax¶
[ WHERE condition ]
Beispielhafte Quellcode-Muster¶
Eingabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT id, name, manager_id
FROM employee
WHERE name LIKE 'J%';
ID |
NAME |
MANAGER_ID |
---|---|---|
101 |
John |
100 |
102 |
Jorge |
101 |
Ausgabecode:¶
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
SELECT id, name, manager_id
FROM
employee
WHERE name LIKE 'J%' ESCAPE '\\';
ID |
NAME |
MANAGER_ID |
---|---|---|
101 |
John |
100 |
102 |
Jorge |
101 |
Zugehörige EWIs¶
Es gibt keine bekannten Probleme.
WITH-Klausel.¶
Beschreibung¶
Eine WITH
-Klausel ist eine optionale Klausel, die der SELECT-Liste in einer Abfrage vorausgeht. Die WITH
-Klausel definiert eine oder mehrere common_table_expressions. Jeder gemeinsame Tabellenausdruck (CTE) definiert eine temporäre Tabelle, die einer View-Definition ähnlich ist. Sie können diese temporären Tabellen in der FROM
-Klausel referenzieren. (Redshift SQL-Referenz: WITH-Klausel)
Die WITH-Klausel wird in Snowflake vollständig unterstützt.
Grammar Syntax
[ WITH [RECURSIVE] common_table_expression [, common_table_expression , ...] ]
--Where common_table_expression can be either non-recursive or recursive.
--Following is the non-recursive form:
CTE_table_name [ ( column_name [, ...] ) ] AS ( query )
--Following is the recursive form of common_table_expression:
CTE_table_name (column_name [, ...] ) AS ( recursive_query )
Sample Source Patterns
Rekursive Form
Input Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
);
INSERT INTO employee(id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
WITH RECURSIVE john_org(id, name, manager_id, level) AS
( SELECT id, name, manager_id, 1 AS level
FROM employee
WHERE name = 'John'
UNION ALL
SELECT e.id, e.name, e.manager_id, level + 1 AS next_level
FROM employee e, john_org j
WHERE e.manager_id = j.id and level < 4
)
SELECT DISTINCT id, name, manager_id FROM john_org ORDER BY manager_id;
ID |
NAME |
MANAGER_ID |
---|---|---|
101 |
John |
100 |
110 |
Liu |
101 |
102 |
Jorge |
101 |
103 |
Kwaku |
101 |
201 |
Sofía |
102 |
106 |
Mateo |
102 |
105 |
Richard |
103 |
104 |
Paulo |
103 |
110 |
Nikki |
103 |
205 |
Zhang |
104 |
120 |
Saanvi |
104 |
200 |
Shirley |
104 |
Output Code:
CREATE TABLE employee (
id INT,
name VARCHAR(20),
manager_id INT
)
COMMENT = '{ "origin": "sf_sc", "name": "snowconvert", "version": { "major": 0, "minor": 0, "patch": "0" }, "attributes": { "component": "redshift", "convertedOn": "11/05/2024", "domain": "test" }}';
INSERT INTO employee (id, name, manager_id) VALUES
(100, 'Carlos', null),
(101, 'John', 100),
(102, 'Jorge', 101),
(103, 'Kwaku', 101),
(110, 'Liu', 101),
(106, 'Mateo', 102),
(110, 'Nikki', 103),
(104, 'Paulo', 103),
(105, 'Richard', 103),
(120, 'Saanvi', 104),
(200, 'Shirley', 104),
(201, 'Sofía', 102),
(205, 'Zhang', 104);
WITH RECURSIVE john_org(id, name, manager_id, level) AS
( SELECT id, name, manager_id, 1 AS level
FROM
employee
WHERE
RTRIM( name) = RTRIM( 'John')
UNION ALL
SELECT e.id, e.name, e.manager_id, level + 1 AS next_level
FROM
employee e,
john_org j
WHERE e.manager_id = j.id and level < 4
)
SELECT DISTINCT id, name, manager_id FROM
john_org
ORDER BY manager_id;
ID |
NAME |
MANAGER_ID |
---|---|---|
101 |
John |
100 |
102 |
Jorge |
101 |
103 |
Kwaku |
101 |
110 |
Liu |
101 |
106 |
Mateo |
102 |
201 |
Sofía |
102 |
110 |
Nikki |
103 |
104 |
Paulo |
103 |
105 |
Richard |
103 |
120 |
Saanvi |
104 |
200 |
Shirley |
104 |
205 |
Zhang |
104 |
Nicht-rekursive Form
Input Code:
WITH ManagerHierarchy AS (
SELECT id AS employee_id, name AS employee_name, manager_id
FROM employee
)
SELECT e.employee_name AS employee, m.employee_name AS manager
FROM ManagerHierarchy e
LEFT JOIN ManagerHierarchy m ON e.manager_id = m.employee_id;
EMPLOYEE |
MANAGER |
---|---|
Carlos |
null |
John |
Carlos |
Jorge |
John |
Kwaku |
John |
Liu |
John |
Mateo |
Jorge |
Sofía |
Jorge |
Nikki |
Kwaku |
Paulo |
Kwaku |
Richard |
Kwaku |
Saanvi |
Paulo |
Shirley |
Paulo |
Zhang |
Paulo |
Output Code:
WITH ManagerHierarchy AS (
SELECT id AS employee_id, name AS employee_name, manager_id
FROM
employee
)
SELECT e.employee_name AS employee, m.employee_name AS manager
FROM
ManagerHierarchy e
LEFT JOIN
ManagerHierarchy m ON e.manager_id = m.employee_id;
EMPLOYEE |
MANAGER |
---|---|
John |
Carlos |
Jorge |
John |
Kwaku |
John |
Liu |
John |
Mateo |
Jorge |
Sofía |
Jorge |
Nikki |
Kwaku |
Paulo |
Kwaku |
Richard |
Kwaku |
Saanvi |
Paulo |
Shirley |
Paulo |
Zhang |
Paulo |
Carlos |
null |
Related EWIs
Es gibt keine bekannten Probleme.