mirror of
https://github.com/zitadel/zitadel.git
synced 2025-08-11 18:17:35 +00:00
feat(projections): resource counters (#9979)
# Which Problems Are Solved Add the ability to keep track of the current counts of projection resources. We want to prevent calling `SELECT COUNT(*)` on tables, as that forces a full scan and sudden spikes of DB resource uses. # How the Problems Are Solved - A resource_counts table is added - Triggers that increment and decrement the counted values on inserts and deletes - Triggers that delete all counts of a table when the source table is TRUNCATEd. This is not in the business logic, but prevents wrong counts in case someone want to force a re-projection. - Triggers that delete all counts if the parent resource is deleted - Script to pre-populate the resource_counts table when a new source table is added. The triggers are reusable for any type of resource, in case we choose to add more in the future. Counts are aggregated by a given parent. Currently only `instance` and `organization` are defined as possible parent. This can later be extended to other types, such as `project`, should the need arise. I deliberately chose to use `parent_id` to distinguish from the de-factor `resource_owner` which is usually an organization ID. For example: - For users the parent is an organization and the `parent_id` matches `resource_owner`. - For organizations the parent is an instance, but the `resource_owner` is the `org_id`. In this case the `parent_id` is the `instance_id`. - Applications would have a similar problem, where the parent is a project, but the `resource_owner` is the `org_id` # Additional Context Closes https://github.com/zitadel/zitadel/issues/9957
This commit is contained in:
43
internal/migration/count_trigger.sql
Normal file
43
internal/migration/count_trigger.sql
Normal file
@@ -0,0 +1,43 @@
|
||||
{{ define "count_trigger" -}}
|
||||
CREATE OR REPLACE TRIGGER count_{{ .Resource }}
|
||||
AFTER INSERT OR DELETE
|
||||
ON {{ .Table }}
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION projections.count_resource(
|
||||
'{{ .ParentType }}',
|
||||
'{{ .InstanceIDColumn }}',
|
||||
'{{ .ParentIDColumn }}',
|
||||
'{{ .Resource }}'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE TRIGGER truncate_{{ .Resource }}_counts
|
||||
AFTER TRUNCATE
|
||||
ON {{ .Table }}
|
||||
FOR EACH STATEMENT
|
||||
EXECUTE FUNCTION projections.delete_table_counts();
|
||||
|
||||
-- Prevent inserts and deletes while we populate the counts.
|
||||
LOCK TABLE {{ .Table }} IN SHARE MODE;
|
||||
|
||||
-- Populate the resource counts for the existing data in the table.
|
||||
INSERT INTO projections.resource_counts(
|
||||
instance_id,
|
||||
table_name,
|
||||
parent_type,
|
||||
parent_id,
|
||||
resource_name,
|
||||
amount
|
||||
)
|
||||
SELECT
|
||||
{{ .InstanceIDColumn }},
|
||||
'{{ .Table }}',
|
||||
'{{ .ParentType }}',
|
||||
{{ .ParentIDColumn }},
|
||||
'{{ .Resource }}',
|
||||
COUNT(*) AS amount
|
||||
FROM {{ .Table }}
|
||||
GROUP BY ({{ .InstanceIDColumn }}, {{ .ParentIDColumn }})
|
||||
ON CONFLICT (instance_id, table_name, parent_type, parent_id) DO
|
||||
UPDATE SET updated_at = now(), amount = EXCLUDED.amount;
|
||||
|
||||
{{- end -}}
|
13
internal/migration/delete_parent_counts_trigger.sql
Normal file
13
internal/migration/delete_parent_counts_trigger.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
{{ define "delete_parent_counts_trigger" -}}
|
||||
|
||||
CREATE OR REPLACE TRIGGER delete_parent_counts_trigger
|
||||
AFTER DELETE
|
||||
ON {{ .Table }}
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION projections.delete_parent_counts(
|
||||
'{{ .ParentType }}',
|
||||
'{{ .InstanceIDColumn }}',
|
||||
'{{ .ParentIDColumn }}'
|
||||
);
|
||||
|
||||
{{- end -}}
|
@@ -36,7 +36,10 @@ type errCheckerMigration interface {
|
||||
|
||||
type RepeatableMigration interface {
|
||||
Migration
|
||||
Check(lastRun map[string]interface{}) bool
|
||||
|
||||
// Check if the migration should be executed again.
|
||||
// True will repeat the migration, false will not.
|
||||
Check(lastRun map[string]any) bool
|
||||
}
|
||||
|
||||
func Migrate(ctx context.Context, es *eventstore.Eventstore, migration Migration) (err error) {
|
||||
|
127
internal/migration/trigger.go
Normal file
127
internal/migration/trigger.go
Normal file
@@ -0,0 +1,127 @@
|
||||
package migration
|
||||
|
||||
import (
|
||||
"context"
|
||||
"embed"
|
||||
"fmt"
|
||||
"strings"
|
||||
"text/template"
|
||||
|
||||
"github.com/mitchellh/mapstructure"
|
||||
|
||||
"github.com/zitadel/zitadel/internal/database"
|
||||
"github.com/zitadel/zitadel/internal/domain"
|
||||
"github.com/zitadel/zitadel/internal/eventstore"
|
||||
)
|
||||
|
||||
const (
|
||||
countTriggerTmpl = "count_trigger"
|
||||
deleteParentCountsTmpl = "delete_parent_counts_trigger"
|
||||
)
|
||||
|
||||
var (
|
||||
//go:embed *.sql
|
||||
templateFS embed.FS
|
||||
templates = template.Must(template.ParseFS(templateFS, "*.sql"))
|
||||
)
|
||||
|
||||
// CountTrigger registers the existing projections.count_trigger function.
|
||||
// The trigger than takes care of keeping count of existing
|
||||
// rows in the source table.
|
||||
// It also pre-populates the projections.resource_counts table with
|
||||
// the counts for the given table.
|
||||
//
|
||||
// During the population of the resource_counts table,
|
||||
// the source table is share-locked to prevent concurrent modifications.
|
||||
// Projection handlers will be halted until the lock is released.
|
||||
// SELECT statements are not blocked by the lock.
|
||||
//
|
||||
// This migration repeats when any of the arguments are changed,
|
||||
// such as renaming of a projection table.
|
||||
func CountTrigger(
|
||||
db *database.DB,
|
||||
table string,
|
||||
parentType domain.CountParentType,
|
||||
instanceIDColumn string,
|
||||
parentIDColumn string,
|
||||
resource string,
|
||||
) RepeatableMigration {
|
||||
return &triggerMigration{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: table,
|
||||
ParentType: parentType.String(),
|
||||
InstanceIDColumn: instanceIDColumn,
|
||||
ParentIDColumn: parentIDColumn,
|
||||
Resource: resource,
|
||||
},
|
||||
db: db,
|
||||
templateName: countTriggerTmpl,
|
||||
}
|
||||
}
|
||||
|
||||
// DeleteParentCountsTrigger
|
||||
//
|
||||
// This migration repeats when any of the arguments are changed,
|
||||
// such as renaming of a projection table.
|
||||
func DeleteParentCountsTrigger(
|
||||
db *database.DB,
|
||||
table string,
|
||||
parentType domain.CountParentType,
|
||||
instanceIDColumn string,
|
||||
parentIDColumn string,
|
||||
resource string,
|
||||
) RepeatableMigration {
|
||||
return &triggerMigration{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: table,
|
||||
ParentType: parentType.String(),
|
||||
InstanceIDColumn: instanceIDColumn,
|
||||
ParentIDColumn: parentIDColumn,
|
||||
Resource: resource,
|
||||
},
|
||||
db: db,
|
||||
templateName: deleteParentCountsTmpl,
|
||||
}
|
||||
}
|
||||
|
||||
type triggerMigration struct {
|
||||
triggerConfig
|
||||
db *database.DB
|
||||
templateName string
|
||||
}
|
||||
|
||||
// String implements [Migration] and [fmt.Stringer].
|
||||
func (m *triggerMigration) String() string {
|
||||
return fmt.Sprintf("repeatable_%s_%s", m.Resource, m.templateName)
|
||||
}
|
||||
|
||||
// Execute implements [Migration]
|
||||
func (m *triggerMigration) Execute(ctx context.Context, _ eventstore.Event) error {
|
||||
var query strings.Builder
|
||||
err := templates.ExecuteTemplate(&query, m.templateName, m.triggerConfig)
|
||||
if err != nil {
|
||||
return fmt.Errorf("%s: execute trigger template: %w", m, err)
|
||||
}
|
||||
_, err = m.db.ExecContext(ctx, query.String())
|
||||
if err != nil {
|
||||
return fmt.Errorf("%s: exec trigger query: %w", m, err)
|
||||
}
|
||||
return nil
|
||||
}
|
||||
|
||||
type triggerConfig struct {
|
||||
Table string `json:"table,omitempty" mapstructure:"table"`
|
||||
ParentType string `json:"parent_type,omitempty" mapstructure:"parent_type"`
|
||||
InstanceIDColumn string `json:"instance_id_column,omitempty" mapstructure:"instance_id_column"`
|
||||
ParentIDColumn string `json:"parent_id_column,omitempty" mapstructure:"parent_id_column"`
|
||||
Resource string `json:"resource,omitempty" mapstructure:"resource"`
|
||||
}
|
||||
|
||||
// Check implements [RepeatableMigration].
|
||||
func (c *triggerConfig) Check(lastRun map[string]any) bool {
|
||||
var dst triggerConfig
|
||||
if err := mapstructure.Decode(lastRun, &dst); err != nil {
|
||||
panic(err)
|
||||
}
|
||||
return dst != *c
|
||||
}
|
253
internal/migration/trigger_test.go
Normal file
253
internal/migration/trigger_test.go
Normal file
@@ -0,0 +1,253 @@
|
||||
package migration
|
||||
|
||||
import (
|
||||
"context"
|
||||
"regexp"
|
||||
"testing"
|
||||
|
||||
"github.com/DATA-DOG/go-sqlmock"
|
||||
"github.com/stretchr/testify/assert"
|
||||
"github.com/stretchr/testify/require"
|
||||
|
||||
"github.com/zitadel/zitadel/internal/database"
|
||||
)
|
||||
|
||||
const (
|
||||
expCountTriggerQuery = `CREATE OR REPLACE TRIGGER count_resource
|
||||
AFTER INSERT OR DELETE
|
||||
ON table
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION projections.count_resource(
|
||||
'instance',
|
||||
'instance_id',
|
||||
'parent_id',
|
||||
'resource'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE TRIGGER truncate_resource_counts
|
||||
AFTER TRUNCATE
|
||||
ON table
|
||||
FOR EACH STATEMENT
|
||||
EXECUTE FUNCTION projections.delete_table_counts();
|
||||
|
||||
-- Prevent inserts and deletes while we populate the counts.
|
||||
LOCK TABLE table IN SHARE MODE;
|
||||
|
||||
-- Populate the resource counts for the existing data in the table.
|
||||
INSERT INTO projections.resource_counts(
|
||||
instance_id,
|
||||
table_name,
|
||||
parent_type,
|
||||
parent_id,
|
||||
resource_name,
|
||||
amount
|
||||
)
|
||||
SELECT
|
||||
instance_id,
|
||||
'table',
|
||||
'instance',
|
||||
parent_id,
|
||||
'resource',
|
||||
COUNT(*) AS amount
|
||||
FROM table
|
||||
GROUP BY (instance_id, parent_id)
|
||||
ON CONFLICT (instance_id, table_name, parent_type, parent_id) DO
|
||||
UPDATE SET updated_at = now(), amount = EXCLUDED.amount;`
|
||||
|
||||
expDeleteParentCountsQuery = `CREATE OR REPLACE TRIGGER delete_parent_counts_trigger
|
||||
AFTER DELETE
|
||||
ON table
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION projections.delete_parent_counts(
|
||||
'instance',
|
||||
'instance_id',
|
||||
'parent_id'
|
||||
);`
|
||||
)
|
||||
|
||||
func Test_triggerMigration_Execute(t *testing.T) {
|
||||
type fields struct {
|
||||
triggerConfig triggerConfig
|
||||
templateName string
|
||||
}
|
||||
tests := []struct {
|
||||
name string
|
||||
fields fields
|
||||
expects func(sqlmock.Sqlmock)
|
||||
wantErr bool
|
||||
}{
|
||||
{
|
||||
name: "template error",
|
||||
fields: fields{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: "table",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "resource",
|
||||
},
|
||||
templateName: "foo",
|
||||
},
|
||||
expects: func(_ sqlmock.Sqlmock) {},
|
||||
wantErr: true,
|
||||
},
|
||||
{
|
||||
name: "db error",
|
||||
fields: fields{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: "table",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "resource",
|
||||
},
|
||||
templateName: countTriggerTmpl,
|
||||
},
|
||||
expects: func(mock sqlmock.Sqlmock) {
|
||||
mock.ExpectExec(regexp.QuoteMeta(expCountTriggerQuery)).
|
||||
WillReturnError(assert.AnError)
|
||||
},
|
||||
wantErr: true,
|
||||
},
|
||||
{
|
||||
name: "count trigger",
|
||||
fields: fields{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: "table",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "resource",
|
||||
},
|
||||
templateName: countTriggerTmpl,
|
||||
},
|
||||
expects: func(mock sqlmock.Sqlmock) {
|
||||
mock.ExpectExec(regexp.QuoteMeta(expCountTriggerQuery)).
|
||||
WithoutArgs().
|
||||
WillReturnResult(
|
||||
sqlmock.NewResult(1, 1),
|
||||
)
|
||||
},
|
||||
},
|
||||
{
|
||||
name: "count trigger",
|
||||
fields: fields{
|
||||
triggerConfig: triggerConfig{
|
||||
Table: "table",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "resource",
|
||||
},
|
||||
templateName: deleteParentCountsTmpl,
|
||||
},
|
||||
expects: func(mock sqlmock.Sqlmock) {
|
||||
mock.ExpectExec(regexp.QuoteMeta(expDeleteParentCountsQuery)).
|
||||
WithoutArgs().
|
||||
WillReturnResult(
|
||||
sqlmock.NewResult(1, 1),
|
||||
)
|
||||
},
|
||||
},
|
||||
}
|
||||
for _, tt := range tests {
|
||||
t.Run(tt.name, func(t *testing.T) {
|
||||
db, mock, err := sqlmock.New()
|
||||
require.NoError(t, err)
|
||||
defer func() {
|
||||
err := mock.ExpectationsWereMet()
|
||||
require.NoError(t, err)
|
||||
}()
|
||||
defer db.Close()
|
||||
tt.expects(mock)
|
||||
mock.ExpectClose()
|
||||
|
||||
m := &triggerMigration{
|
||||
db: &database.DB{
|
||||
DB: db,
|
||||
},
|
||||
triggerConfig: tt.fields.triggerConfig,
|
||||
templateName: tt.fields.templateName,
|
||||
}
|
||||
err = m.Execute(context.Background(), nil)
|
||||
if tt.wantErr {
|
||||
assert.Error(t, err)
|
||||
return
|
||||
}
|
||||
require.NoError(t, err)
|
||||
})
|
||||
}
|
||||
}
|
||||
|
||||
func Test_triggerConfig_Check(t *testing.T) {
|
||||
type fields struct {
|
||||
Table string
|
||||
ParentType string
|
||||
InstanceIDColumn string
|
||||
ParentIDColumn string
|
||||
Resource string
|
||||
}
|
||||
type args struct {
|
||||
lastRun map[string]any
|
||||
}
|
||||
tests := []struct {
|
||||
name string
|
||||
fields fields
|
||||
args args
|
||||
want bool
|
||||
}{
|
||||
{
|
||||
name: "should",
|
||||
fields: fields{
|
||||
Table: "users2",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "user",
|
||||
},
|
||||
args: args{
|
||||
lastRun: map[string]any{
|
||||
"table": "users1",
|
||||
"parent_type": "instance",
|
||||
"instance_id_column": "instance_id",
|
||||
"parent_id_column": "parent_id",
|
||||
"resource": "user",
|
||||
},
|
||||
},
|
||||
want: true,
|
||||
},
|
||||
{
|
||||
name: "should not",
|
||||
fields: fields{
|
||||
Table: "users1",
|
||||
ParentType: "instance",
|
||||
InstanceIDColumn: "instance_id",
|
||||
ParentIDColumn: "parent_id",
|
||||
Resource: "user",
|
||||
},
|
||||
args: args{
|
||||
lastRun: map[string]any{
|
||||
"table": "users1",
|
||||
"parent_type": "instance",
|
||||
"instance_id_column": "instance_id",
|
||||
"parent_id_column": "parent_id",
|
||||
"resource": "user",
|
||||
},
|
||||
},
|
||||
want: false,
|
||||
},
|
||||
}
|
||||
for _, tt := range tests {
|
||||
t.Run(tt.name, func(t *testing.T) {
|
||||
c := &triggerConfig{
|
||||
Table: tt.fields.Table,
|
||||
ParentType: tt.fields.ParentType,
|
||||
InstanceIDColumn: tt.fields.InstanceIDColumn,
|
||||
ParentIDColumn: tt.fields.ParentIDColumn,
|
||||
Resource: tt.fields.Resource,
|
||||
}
|
||||
got := c.Check(tt.args.lastRun)
|
||||
assert.Equal(t, tt.want, got)
|
||||
})
|
||||
}
|
||||
}
|
Reference in New Issue
Block a user