浏览代码

search: refactor search sql into a builder class

Daniel Lee 8 年之前
父节点
当前提交
f47673ab5c
共有 3 个文件被更改,包括 263 次插入116 次删除
  1. 14 116
      pkg/services/sqlstore/dashboard.go
  2. 212 0
      pkg/services/sqlstore/search_builder.go
  3. 37 0
      pkg/services/sqlstore/search_builder_test.go

+ 14 - 116
pkg/services/sqlstore/dashboard.go

@@ -1,9 +1,6 @@
 package sqlstore
 
 import (
-	"bytes"
-	"fmt"
-	"strings"
 	"time"
 
 	"github.com/grafana/grafana/pkg/bus"
@@ -189,137 +186,38 @@ type DashboardSearchProjection struct {
 }
 
 func findDashboards(query *search.FindPersistedDashboardsQuery) ([]DashboardSearchProjection, error) {
-	var sql bytes.Buffer
-	params := make([]interface{}, 0)
 	limit := query.Limit
 	if limit == 0 {
 		limit = 1000
 	}
 
-	sql.WriteString(`
-	SELECT
-		dashboard.id,
-		dashboard.title,
-		dashboard.slug,
-		dashboard_tag.term,
-		dashboard.is_folder,
-		dashboard.folder_id,
-		folder.slug as folder_slug,
-		folder.title as folder_title
-	FROM `)
-
-	// add tags filter
-	if len(query.Tags) > 0 {
-		sql.WriteString(
-			`(
-		SELECT
-			dashboard.id FROM dashboard
-			LEFT OUTER JOIN dashboard_tag ON dashboard_tag.dashboard_id = dashboard.id
-		`)
-		if query.IsStarred {
-			sql.WriteString(" INNER JOIN star on star.dashboard_id = dashboard.id")
-		}
-
-		sql.WriteString(` WHERE dashboard_tag.term IN (?` + strings.Repeat(",?", len(query.Tags)-1) + `) AND `)
-		for _, tag := range query.Tags {
-			params = append(params, tag)
-		}
-		params = createSearchWhereClause(query, &sql, params)
-		fmt.Printf("params2 %v", params)
-
-		// this ends the inner select (tag filtered part)
-		sql.WriteString(`
-			GROUP BY dashboard.id HAVING COUNT(dashboard.id) >= ?
-			LIMIT ?) as ids
-			INNER JOIN dashboard on ids.id = dashboard.id
-		`)
-
-		params = append(params, len(query.Tags))
-		params = append(params, limit)
-	} else {
-		sql.WriteString(`( SELECT dashboard.id FROM dashboard `)
-		if query.IsStarred {
-			sql.WriteString(" INNER JOIN star on star.dashboard_id = dashboard.id")
-		}
-		sql.WriteString(` WHERE `)
-		params = createSearchWhereClause(query, &sql, params)
-
-		sql.WriteString(`
-			LIMIT ?) as ids
-		INNER JOIN dashboard on ids.id = dashboard.id
-		`)
-		params = append(params, limit)
-	}
-
-	sql.WriteString(`
-		LEFT OUTER JOIN dashboard folder on folder.id = dashboard.folder_id
-		LEFT OUTER JOIN dashboard_tag on dashboard.id = dashboard_tag.dashboard_id`)
-
-	sql.WriteString(fmt.Sprintf(" ORDER BY dashboard.title ASC LIMIT 5000"))
-
-	var res []DashboardSearchProjection
-
-	err := x.Sql(sql.String(), params...).Find(&res)
-	if err != nil {
-		return nil, err
-	}
-
-	return res, nil
-}
-
-func createSearchWhereClause(query *search.FindPersistedDashboardsQuery, sql *bytes.Buffer, params []interface{}) []interface{} {
-	sql.WriteString(` dashboard.org_id=?`)
-	params = append(params, query.SignedInUser.OrgId)
+	sb := NewSearchBuilder(query.SignedInUser, limit).WithTags(query.Tags).WithDashboardIdsIn(query.DashboardIds)
 
 	if query.IsStarred {
-		sql.WriteString(` AND star.user_id=?`)
-		params = append(params, query.SignedInUser.UserId)
-	}
-
-	if len(query.DashboardIds) > 0 {
-		sql.WriteString(` AND dashboard.id IN (?` + strings.Repeat(",?", len(query.DashboardIds)-1) + `)`)
-		for _, dashboardId := range query.DashboardIds {
-			params = append(params, dashboardId)
-		}
-	}
-
-	if query.SignedInUser.OrgRole != m.ROLE_ADMIN {
-		allowedDashboardsSubQuery := ` AND (dashboard.has_acl = 0 OR dashboard.id in (
-			SELECT distinct d.id AS DashboardId
-			FROM dashboard AS d
-	      		LEFT JOIN dashboard_acl as da on d.folder_id = da.dashboard_id or d.id = da.dashboard_id
-	      		LEFT JOIN user_group_member as ugm on ugm.user_group_id =  da.user_group_id
-	      		LEFT JOIN org_user ou on ou.role = da.role
-			WHERE
-			  d.has_acl = 1 and
-				(da.user_id = ? or ugm.user_id = ? or ou.id is not null)
-			  and d.org_id = ?
-			)
-		)`
-
-		sql.WriteString(allowedDashboardsSubQuery)
-		params = append(params, query.SignedInUser.UserId, query.SignedInUser.UserId, query.SignedInUser.OrgId)
+		sb.IsStarred()
 	}
 
 	if len(query.Title) > 0 {
-		sql.WriteString(" AND dashboard.title " + dialect.LikeStr() + " ?")
-		params = append(params, "%"+query.Title+"%")
+		sb.WithTitle(query.Title)
 	}
 
-	if len(query.Type) > 0 && query.Type == "dash-folder" {
-		sql.WriteString(" AND dashboard.is_folder = 1")
+	if len(query.Type) > 0 {
+		sb.WithType(query.Type)
 	}
 
-	if len(query.Type) > 0 && query.Type == "dash-db" {
-		sql.WriteString(" AND dashboard.is_folder = 0")
+	if query.FolderId > 0 {
+		sb.WithFolderId(query.FolderId)
 	}
 
-	if query.FolderId > 0 {
-		sql.WriteString(" AND dashboard.folder_id = ?")
-		params = append(params, query.FolderId)
+	var res []DashboardSearchProjection
+
+	sql, params := sb.ToSql()
+	err := x.Sql(sql, params...).Find(&res)
+	if err != nil {
+		return nil, err
 	}
 
-	return params
+	return res, nil
 }
 
 func SearchDashboards(query *search.FindPersistedDashboardsQuery) error {

+ 212 - 0
pkg/services/sqlstore/search_builder.go

@@ -0,0 +1,212 @@
+package sqlstore
+
+import (
+	"bytes"
+	"strings"
+
+	m "github.com/grafana/grafana/pkg/models"
+)
+
+// SearchBuilder is a builder/object mother that builds a dashboard search query
+type SearchBuilder struct {
+	tags                []string
+	isStarred           bool
+	limit               int
+	signedInUser        *m.SignedInUser
+	whereDashboardIdsIn []int64
+	whereTitle          string
+	whereTypeFolder     bool
+	whereTypeDash       bool
+	whereFolderId       int64
+	sql                 bytes.Buffer
+	params              []interface{}
+}
+
+func NewSearchBuilder(signedInUser *m.SignedInUser, limit int) *SearchBuilder {
+	searchBuilder := &SearchBuilder{
+		signedInUser: signedInUser,
+		limit:        limit,
+	}
+
+	return searchBuilder
+}
+
+func (sb *SearchBuilder) WithTags(tags []string) *SearchBuilder {
+	if len(tags) > 0 {
+		sb.tags = tags
+	}
+
+	return sb
+}
+
+func (sb *SearchBuilder) IsStarred() *SearchBuilder {
+	sb.isStarred = true
+
+	return sb
+}
+
+func (sb *SearchBuilder) WithDashboardIdsIn(ids []int64) *SearchBuilder {
+	if len(ids) > 0 {
+		sb.whereDashboardIdsIn = ids
+	}
+
+	return sb
+}
+
+func (sb *SearchBuilder) WithTitle(title string) *SearchBuilder {
+	sb.whereTitle = title
+
+	return sb
+}
+
+func (sb *SearchBuilder) WithType(queryType string) *SearchBuilder {
+	if len(queryType) > 0 && queryType == "dash-folder" {
+		sb.whereTypeFolder = true
+	}
+
+	if len(queryType) > 0 && queryType == "dash-db" {
+		sb.whereTypeDash = true
+	}
+
+	return sb
+}
+
+func (sb *SearchBuilder) WithFolderId(folderId int64) *SearchBuilder {
+	sb.whereFolderId = folderId
+
+	return sb
+}
+
+func (sb *SearchBuilder) ToSql() (string, []interface{}) {
+	sb.params = make([]interface{}, 0)
+
+	sb.buildSelect()
+
+	if len(sb.tags) > 0 {
+		sb.buildTagQuery()
+	} else {
+		sb.buildMainQuery()
+	}
+
+	sb.sql.WriteString(`
+		LEFT OUTER JOIN dashboard folder on folder.id = dashboard.folder_id
+		LEFT OUTER JOIN dashboard_tag on dashboard.id = dashboard_tag.dashboard_id`)
+
+	sb.sql.WriteString(" ORDER BY dashboard.title ASC LIMIT 5000")
+
+	return sb.sql.String(), sb.params
+}
+
+func (sb *SearchBuilder) buildSelect() {
+	sb.sql.WriteString(
+		`SELECT
+			dashboard.id,
+			dashboard.title,
+			dashboard.slug,
+			dashboard_tag.term,
+			dashboard.is_folder,
+			dashboard.folder_id,
+			folder.slug as folder_slug,
+			folder.title as folder_title
+		FROM `)
+}
+
+func (sb *SearchBuilder) buildTagQuery() {
+	sb.sql.WriteString(
+		`(
+	SELECT
+		dashboard.id FROM dashboard
+		LEFT OUTER JOIN dashboard_tag ON dashboard_tag.dashboard_id = dashboard.id
+	`)
+
+	if sb.isStarred {
+		sb.sql.WriteString(" INNER JOIN star on star.dashboard_id = dashboard.id")
+	}
+
+	sb.sql.WriteString(` WHERE dashboard_tag.term IN (?` + strings.Repeat(",?", len(sb.tags)-1) + `) AND `)
+	for _, tag := range sb.tags {
+		sb.params = append(sb.params, tag)
+	}
+
+	sb.buildSearchWhereClause()
+
+	// this ends the inner select (tag filtered part)
+	sb.sql.WriteString(`
+		GROUP BY dashboard.id HAVING COUNT(dashboard.id) >= ?
+		LIMIT ?) as ids
+		INNER JOIN dashboard on ids.id = dashboard.id
+	`)
+
+	sb.params = append(sb.params, len(sb.tags))
+	sb.params = append(sb.params, sb.limit)
+}
+
+func (sb *SearchBuilder) buildMainQuery() {
+	sb.sql.WriteString(`( SELECT dashboard.id FROM dashboard `)
+
+	if sb.isStarred {
+		sb.sql.WriteString(" INNER JOIN star on star.dashboard_id = dashboard.id")
+	}
+
+	sb.sql.WriteString(` WHERE `)
+	sb.buildSearchWhereClause()
+
+	sb.sql.WriteString(`
+		LIMIT ?) as ids
+	INNER JOIN dashboard on ids.id = dashboard.id
+	`)
+	sb.params = append(sb.params, sb.limit)
+}
+
+func (sb *SearchBuilder) buildSearchWhereClause() {
+	sb.sql.WriteString(` dashboard.org_id=?`)
+	sb.params = append(sb.params, sb.signedInUser.OrgId)
+
+	if sb.isStarred {
+		sb.sql.WriteString(` AND star.user_id=?`)
+		sb.params = append(sb.params, sb.signedInUser.UserId)
+	}
+
+	if len(sb.whereDashboardIdsIn) > 0 {
+		sb.sql.WriteString(` AND dashboard.id IN (?` + strings.Repeat(",?", len(sb.whereDashboardIdsIn)-1) + `)`)
+		for _, dashboardId := range sb.whereDashboardIdsIn {
+			sb.params = append(sb.params, dashboardId)
+		}
+	}
+
+	if sb.signedInUser.OrgRole != m.ROLE_ADMIN {
+		allowedDashboardsSubQuery := ` AND (dashboard.has_acl = 0 OR dashboard.id in (
+			SELECT distinct d.id AS DashboardId
+			FROM dashboard AS d
+	      		LEFT JOIN dashboard_acl as da on d.folder_id = da.dashboard_id or d.id = da.dashboard_id
+	      		LEFT JOIN user_group_member as ugm on ugm.user_group_id =  da.user_group_id
+	      		LEFT JOIN org_user ou on ou.role = da.role
+			WHERE
+			  d.has_acl = 1 and
+				(da.user_id = ? or ugm.user_id = ? or ou.id is not null)
+			  and d.org_id = ?
+			)
+		)`
+
+		sb.sql.WriteString(allowedDashboardsSubQuery)
+		sb.params = append(sb.params, sb.signedInUser.UserId, sb.signedInUser.UserId, sb.signedInUser.OrgId)
+	}
+
+	if len(sb.whereTitle) > 0 {
+		sb.sql.WriteString(" AND dashboard.title " + dialect.LikeStr() + " ?")
+		sb.params = append(sb.params, "%"+sb.whereTitle+"%")
+	}
+
+	if sb.whereTypeFolder {
+		sb.sql.WriteString(" AND dashboard.is_folder = 1")
+	}
+
+	if sb.whereTypeDash {
+		sb.sql.WriteString(" AND dashboard.is_folder = 0")
+	}
+
+	if sb.whereFolderId > 0 {
+		sb.sql.WriteString(" AND dashboard.folder_id = ?")
+		sb.params = append(sb.params, sb.whereFolderId)
+	}
+}

+ 37 - 0
pkg/services/sqlstore/search_builder_test.go

@@ -0,0 +1,37 @@
+package sqlstore
+
+import (
+	"testing"
+
+	m "github.com/grafana/grafana/pkg/models"
+	"github.com/grafana/grafana/pkg/services/sqlstore/migrator"
+	. "github.com/smartystreets/goconvey/convey"
+)
+
+func TestSearchBuilder(t *testing.T) {
+	dialect = migrator.NewDialect("sqlite3")
+
+	Convey("Testing building a search", t, func() {
+		signedInUser := &m.SignedInUser{
+			OrgId:  1,
+			UserId: 1,
+		}
+		sb := NewSearchBuilder(signedInUser, 1000)
+
+		Convey("When building a normal search", func() {
+			sql, params := sb.IsStarred().WithTitle("test").ToSql()
+			So(sql, ShouldStartWith, "SELECT")
+			So(sql, ShouldContainSubstring, "INNER JOIN dashboard on ids.id = dashboard.id")
+			So(sql, ShouldEndWith, "ORDER BY dashboard.title ASC LIMIT 5000")
+			So(len(params), ShouldBeGreaterThan, 0)
+		})
+
+		Convey("When building a search with tag filter", func() {
+			sql, params := sb.WithTags([]string{"tag1", "tag2"}).ToSql()
+			So(sql, ShouldStartWith, "SELECT")
+			So(sql, ShouldContainSubstring, "LEFT OUTER JOIN dashboard_tag")
+			So(sql, ShouldEndWith, "ORDER BY dashboard.title ASC LIMIT 5000")
+			So(len(params), ShouldBeGreaterThan, 0)
+		})
+	})
+}