SQL zum Kusto-Abfragesprache Spickzettel
Gilt für: ✅Microsoft Fabric✅Azure Data Explorer✅Azure Monitor✅Microsoft Sentinel
Wenn Sie mit SQL vertraut sind und KQL erlernen möchten, übersetzen Sie SQL-Abfragen in KQL, indem Sie die SQL-Abfrage mit einer Kommentarzeile --
und dem Schlüsselwort explain
vorkonfigurieren. Die Ausgabe zeigt die KQL-Version der Abfrage, die Ihnen dabei helfen kann, die KQL-Syntax und -Konzepte zu verstehen.
--
explain
SELECT COUNT_BIG(*) as C FROM StormEvents
Output
Abfrage |
---|
StormEvents<br> | summarize C=count()<br> | Project C |
Cheat Sheet für die Übersetzung von SQL in Kusto
Die folgende Tabelle zeigt Beispielabfragen in SQL und deren KQL-Entsprechungen.
Kategorie | SQL-Abfrage | Kusto-Abfrage | Weitere Informationen |
---|---|---|---|
Auswählen von Daten aus einer Tabelle | SELECT * FROM dependencies |
dependencies |
Tabellarische Ausdrucksanweisungen |
-- | SELECT name, resultCode FROM dependencies |
dependencies | project name, resultCode |
project |
-- | SELECT TOP 100 * FROM dependencies |
dependencies | take 100 |
take |
Null-Auswertung | SELECT * FROM dependencies WHERE resultCode IS NOT NULL |
dependencies | where isnotnull(resultCode) |
isnotnull() |
Vergleichsoperatoren (Datum) | SELECT * FROM dependencies WHERE timestamp > getdate()-1 |
dependencies | where timestamp > ago(1d) |
ago() |
-- | SELECT * FROM dependencies WHERE timestamp BETWEEN ... AND ... |
dependencies | where timestamp between (datetime(2016-10-01) .. datetime(2016-11-01)) |
between |
Vergleichsoperatoren (Zeichenfolge) | SELECT * FROM dependencies WHERE type = "Azure blob" |
dependencies | where type == "Azure blob" |
Logische Operatoren |
-- | -- substring SELECT * FROM dependencies WHERE type like "%blob%" |
// substring dependencies | where type has "blob" |
hat |
-- | -- wildcard SELECT * FROM dependencies WHERE type like "Azure%" |
// wildcard dependencies | where type startswith "Azure" // or dependencies | where type matches regex "^Azure.*" |
startswith matches regex |
Vergleich (Boolesch) | SELECT * FROM dependencies WHERE !(success) |
dependencies | where success == False |
Logische Operatoren |
Gruppierung, Aggregation | SELECT name, AVG(duration) FROM dependencies GROUP BY name |
dependencies | summarize avg(duration) by name |
zusammenfassung avg() |
Distinct | SELECT DISTINCT name, type FROM dependencies |
dependencies | summarize by name, type |
unterschiedliche Zusammenfassung |
-- | SELECT name, COUNT(DISTINCT type) FROM dependencies GROUP BY name |
dependencies | summarize by name, type | summarize count() by name // or approximate for large sets dependencies | summarize dcount(type) by name |
count() dcount() |
Spaltenaliase, Erweitern | SELECT operationName as Name, AVG(duration) as AvgD FROM dependencies GROUP BY name |
dependencies | summarize AvgD = avg(duration) by Name=operationName |
Alias-Anweisung |
-- | SELECT conference, CONCAT(sessionid, ' ' , session_title) AS session FROM ConferenceSessions |
ConferenceSessions | extend session=strcat(sessionid, " ", session_title) | project conference, session |
strcat() project |
Sortieren | SELECT name, timestamp FROM dependencies ORDER BY timestamp ASC |
dependencies | project name, timestamp | sort by timestamp asc nulls last |
sortieren |
Top n nach Measure | SELECT TOP 100 name, COUNT(*) as Count FROM dependencies GROUP BY name ORDER BY Count DESC |
dependencies | summarize Count = count() by name | top 100 by Count desc |
top |
Union | SELECT * FROM dependencies UNION SELECT * FROM exceptions |
union dependencies, exceptions |
union |
-- | SELECT * FROM dependencies WHERE timestamp > ... UNION SELECT * FROM exceptions WHERE timestamp > ... |
dependencies | where timestamp > ago(1d) | union (exceptions | where timestamp > ago(1d)) |
|
Join | SELECT * FROM dependencies LEFT OUTER JOIN exceptions ON dependencies.operation_Id = exceptions.operation_Id |
dependencies | join kind = leftouter (exceptions) on $left.operation_Id == $right.operation_Id |
Verknüpfen |
Geschachtelte Abfragen | SELECT * FROM dependencies WHERE resultCode == (SELECT TOP 1 resultCode FROM dependencies WHERE resultId = 7 ORDER BY timestamp DESC) |
dependencies | where resultCode == toscalar( dependencies | where resultId == 7 | top 1 by timestamp desc | project resultCode) |
Toscalar |
Having | SELECT COUNT(\*) FROM dependencies GROUP BY name HAVING COUNT(\*) > 3 |
dependencies | summarize Count = count() by name | where Count > 3 |
zusammenfassen , wo |
Zugehöriger Inhalt
- Verwenden von T-SQL zum Abfragen von Daten