Using window function

pull/95940/head
Georges Chaudy 9 months ago
parent e43bec2cd8
commit b3259699eb
No known key found for this signature in database
GPG Key ID: 0EE887FFCA1DB6EF
  1. 83
      pkg/storage/unified/sql/data/resource_history_list.sql
  2. 12
      pkg/storage/unified/sql/test/integration_test.go
  3. 42
      pkg/storage/unified/sql/testdata/mysql--resource_history_list-single path.sql
  4. 42
      pkg/storage/unified/sql/testdata/postgres--resource_history_list-single path.sql
  5. 42
      pkg/storage/unified/sql/testdata/sqlite--resource_history_list-single path.sql

@ -3,51 +3,42 @@ SELECT
kv.{{ .Ident "namespace" }},
kv.{{ .Ident "name" }},
kv.{{ .Ident "value" }}
FROM {{ .Ident "resource_history" }} as kv
INNER JOIN (
SELECT {{ .Ident "namespace" }}, {{ .Ident "group" }}, {{ .Ident "resource" }}, {{ .Ident "name" }}, max({{ .Ident "resource_version" }}) AS {{ .Ident "resource_version" }}
FROM {{ .Ident "resource_history" }} AS mkv
WHERE 1 = 1
AND {{ .Ident "resource_version" }} <= {{ .Arg .Request.ResourceVersion }}
{{ if and .Request.Options .Request.Options.Key }}
{{ if .Request.Options.Key.Namespace }}
AND {{ .Ident "namespace" }} = {{ .Arg .Request.Options.Key.Namespace }}
{{ end }}
{{ if .Request.Options.Key.Group }}
AND {{ .Ident "group" }} = {{ .Arg .Request.Options.Key.Group }}
{{ end }}
{{ if .Request.Options.Key.Resource }}
AND {{ .Ident "resource" }} = {{ .Arg .Request.Options.Key.Resource }}
{{ end }}
{{ if .Request.Options.Key.Name }}
AND {{ .Ident "name" }} = {{ .Arg .Request.Options.Key.Name }}
{{ end }}
FROM (
SELECT
{{ .Ident "resource_version" }},
{{ .Ident "namespace" }},
{{ .Ident "group" }},
{{ .Ident "resource" }},
{{ .Ident "name" }},
{{ .Ident "value" }},
{{ .Ident "action" }},
MAX({{ .Ident "resource_version" }}) OVER (
PARTITION BY {{ .Ident "namespace" }}, {{ .Ident "group" }}, {{ .Ident "resource" }}, {{ .Ident "name" }}
ORDER BY {{ .Ident "resource_version" }}
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
) AS max_resource_version
FROM {{ .Ident "resource_history" }}
WHERE 1 = 1
AND {{ .Ident "resource_version" }} <= {{ .Arg .Request.ResourceVersion }}
{{ if and .Request.Options .Request.Options.Key }}
{{ if .Request.Options.Key.Namespace }}
AND {{ .Ident "namespace" }} = {{ .Arg .Request.Options.Key.Namespace }}
{{ end }}
{{ if .Request.Options.Key.Group }}
AND {{ .Ident "group" }} = {{ .Arg .Request.Options.Key.Group }}
{{ end }}
{{ if .Request.Options.Key.Resource }}
AND {{ .Ident "resource" }} = {{ .Arg .Request.Options.Key.Resource }}
{{ end }}
{{ if .Request.Options.Key.Name }}
AND {{ .Ident "name" }} = {{ .Arg .Request.Options.Key.Name }}
{{ end }}
GROUP BY mkv.{{ .Ident "namespace" }}, mkv.{{ .Ident "group" }}, mkv.{{ .Ident "resource" }}, mkv.{{ .Ident "name" }}
) AS maxkv
ON
maxkv.{{ .Ident "resource_version" }} = kv.{{ .Ident "resource_version" }}
AND maxkv.{{ .Ident "namespace" }} = kv.{{ .Ident "namespace" }}
AND maxkv.{{ .Ident "group" }} = kv.{{ .Ident "group" }}
AND maxkv.{{ .Ident "resource" }} = kv.{{ .Ident "resource" }}
AND maxkv.{{ .Ident "name" }} = kv.{{ .Ident "name" }}
WHERE kv.{{ .Ident "action" }} != 3
{{ if and .Request.Options .Request.Options.Key }}
{{ if .Request.Options.Key.Namespace }}
AND kv.{{ .Ident "namespace" }} = {{ .Arg .Request.Options.Key.Namespace }}
{{ end }}
{{ if .Request.Options.Key.Group }}
AND kv.{{ .Ident "group" }} = {{ .Arg .Request.Options.Key.Group }}
{{ end }}
{{ if .Request.Options.Key.Resource }}
AND kv.{{ .Ident "resource" }} = {{ .Arg .Request.Options.Key.Resource }}
{{ end }}
{{ if .Request.Options.Key.Name }}
AND kv.{{ .Ident "name" }} = {{ .Arg .Request.Options.Key.Name }}
{{ end }}
{{ end }}
ORDER BY kv.{{ .Ident "namespace" }} ASC, kv.{{ .Ident "name" }} ASC
{{ if (gt .Request.Limit 0) }}
LIMIT {{ .Arg .Request.Limit }} OFFSET {{ .Arg .Request.Offset }}
{{ end }}
;
) AS kv
WHERE kv.{{ .Ident "resource_version" }} = kv.max_resource_version
AND kv.{{ .Ident "action" }} != 3
ORDER BY kv.{{ .Ident "namespace" }} ASC, kv.{{ .Ident "name" }} ASC
{{ if (gt .Request.Limit 0) }}
LIMIT {{ .Arg .Request.Limit }} OFFSET {{ .Arg .Request.Offset }}
{{ end }}
;

@ -63,9 +63,9 @@ func newServer(t *testing.T, cfg *setting.Cfg) (sql.Backend, resource.ResourceSe
}
func TestIntegrationBackendHappyPath(t *testing.T) {
if infraDB.IsTestDbSQLite() {
t.Skip("TODO: test blocking, skipping to unblock Enterprise until we fix this")
}
// if infraDB.IsTestDbSQLite() {
// t.Skip("TODO: test blocking, skipping to unblock Enterprise until we fix this")
// }
if testing.Short() {
t.Skip("skipping integration test")
}
@ -199,9 +199,9 @@ func TestIntegrationBackendWatchWriteEventsFromLastest(t *testing.T) {
}
func TestIntegrationBackendList(t *testing.T) {
if infraDB.IsTestDbSQLite() {
t.Skip("TODO: test blocking, skipping to unblock Enterprise until we fix this")
}
// if infraDB.IsTestDbSQLite() {
// t.Skip("TODO: test blocking, skipping to unblock Enterprise until we fix this")
// }
if testing.Short() {
t.Skip("skipping integration test")
}

@ -3,23 +3,27 @@ SELECT
kv.`namespace`,
kv.`name`,
kv.`value`
FROM `resource_history` as kv
INNER JOIN (
SELECT `namespace`, `group`, `resource`, `name`, max(`resource_version`) AS `resource_version`
FROM `resource_history` AS mkv
WHERE 1 = 1
AND `resource_version` <= 0
AND `namespace` = 'ns'
GROUP BY mkv.`namespace`, mkv.`group`, mkv.`resource`, mkv.`name`
) AS maxkv
ON
maxkv.`resource_version` = kv.`resource_version`
AND maxkv.`namespace` = kv.`namespace`
AND maxkv.`group` = kv.`group`
AND maxkv.`resource` = kv.`resource`
AND maxkv.`name` = kv.`name`
WHERE kv.`action` != 3
AND kv.`namespace` = 'ns'
ORDER BY kv.`namespace` ASC, kv.`name` ASC
LIMIT 10 OFFSET 0
FROM (
SELECT
`resource_version`,
`namespace`,
`group`,
`resource`,
`name`,
`value`,
`action`,
MAX(`resource_version`) OVER (
PARTITION BY `namespace`, `group`, `resource`, `name`
ORDER BY `resource_version`
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
) AS max_resource_version
FROM `resource_history`
WHERE 1 = 1
AND `resource_version` <= 0
AND `namespace` = 'ns'
) AS kv
WHERE kv.`resource_version` = kv.max_resource_version
AND kv.`action` != 3
ORDER BY kv.`namespace` ASC, kv.`name` ASC
LIMIT 10 OFFSET 0
;

@ -3,23 +3,27 @@ SELECT
kv."namespace",
kv."name",
kv."value"
FROM "resource_history" as kv
INNER JOIN (
SELECT "namespace", "group", "resource", "name", max("resource_version") AS "resource_version"
FROM "resource_history" AS mkv
WHERE 1 = 1
AND "resource_version" <= 0
AND "namespace" = 'ns'
GROUP BY mkv."namespace", mkv."group", mkv."resource", mkv."name"
) AS maxkv
ON
maxkv."resource_version" = kv."resource_version"
AND maxkv."namespace" = kv."namespace"
AND maxkv."group" = kv."group"
AND maxkv."resource" = kv."resource"
AND maxkv."name" = kv."name"
WHERE kv."action" != 3
AND kv."namespace" = 'ns'
ORDER BY kv."namespace" ASC, kv."name" ASC
LIMIT 10 OFFSET 0
FROM (
SELECT
"resource_version",
"namespace",
"group",
"resource",
"name",
"value",
"action",
MAX("resource_version") OVER (
PARTITION BY "namespace", "group", "resource", "name"
ORDER BY "resource_version"
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
) AS max_resource_version
FROM "resource_history"
WHERE 1 = 1
AND "resource_version" <= 0
AND "namespace" = 'ns'
) AS kv
WHERE kv."resource_version" = kv.max_resource_version
AND kv."action" != 3
ORDER BY kv."namespace" ASC, kv."name" ASC
LIMIT 10 OFFSET 0
;

@ -3,23 +3,27 @@ SELECT
kv."namespace",
kv."name",
kv."value"
FROM "resource_history" as kv
INNER JOIN (
SELECT "namespace", "group", "resource", "name", max("resource_version") AS "resource_version"
FROM "resource_history" AS mkv
WHERE 1 = 1
AND "resource_version" <= 0
AND "namespace" = 'ns'
GROUP BY mkv."namespace", mkv."group", mkv."resource", mkv."name"
) AS maxkv
ON
maxkv."resource_version" = kv."resource_version"
AND maxkv."namespace" = kv."namespace"
AND maxkv."group" = kv."group"
AND maxkv."resource" = kv."resource"
AND maxkv."name" = kv."name"
WHERE kv."action" != 3
AND kv."namespace" = 'ns'
ORDER BY kv."namespace" ASC, kv."name" ASC
LIMIT 10 OFFSET 0
FROM (
SELECT
"resource_version",
"namespace",
"group",
"resource",
"name",
"value",
"action",
MAX("resource_version") OVER (
PARTITION BY "namespace", "group", "resource", "name"
ORDER BY "resource_version"
ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
) AS max_resource_version
FROM "resource_history"
WHERE 1 = 1
AND "resource_version" <= 0
AND "namespace" = 'ns'
) AS kv
WHERE kv."resource_version" = kv.max_resource_version
AND kv."action" != 3
ORDER BY kv."namespace" ASC, kv."name" ASC
LIMIT 10 OFFSET 0
;

Loading…
Cancel
Save