Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Optimize queries and indexes on posts table #13217

Merged
merged 7 commits into from
Jan 10, 2020
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
194 changes: 145 additions & 49 deletions store/sqlstore/post_store.go
Original file line number Diff line number Diff line change
Expand Up @@ -455,37 +455,69 @@ func (s *SqlPostStore) GetPostsSince(options model.GetPostsSinceOptions, allowFr
replyCountQuery1 := ""
replyCountQuery2 := ""
if options.SkipFetchThreads {
replyCountQuery1 = ` ,(SELECT COUNT(Posts.Id) FROM Posts WHERE p1.RootId = '' AND Posts.RootId = p1.Id AND Posts.DeleteAt = 0) as ReplyCount`
replyCountQuery2 = ` ,(SELECT COUNT(Posts.Id) FROM Posts WHERE p2.RootId = '' AND Posts.RootId = p2.Id AND Posts.DeleteAt = 0) as ReplyCount`
replyCountQuery1 = `, (SELECT COUNT(Posts.Id) FROM Posts WHERE p1.RootId = '' AND Posts.RootId = p1.Id AND Posts.DeleteAt = 0) as ReplyCount`
replyCountQuery2 = `, (SELECT COUNT(Posts.Id) FROM Posts WHERE p2.RootId = '' AND Posts.RootId = p2.Id AND Posts.DeleteAt = 0) as ReplyCount`
}
var query string

_, err := s.GetReplica().Select(&posts,
`(SELECT
*`+replyCountQuery1+`
FROM
Posts p1
WHERE
(UpdateAt > :Time
AND ChannelId = :ChannelId)
LIMIT 1000)
UNION
// union of IDs and then join to get full posts is faster in mysql
if s.DriverName() == model.DATABASE_DRIVER_MYSQL {
query = `SELECT *` + replyCountQuery1 + ` FROM Posts p1 JOIN (
(SELECT
*`+replyCountQuery2+`
FROM
Posts p2
WHERE
Id
IN
(SELECT * FROM (SELECT
RootId
FROM
Posts
WHERE
UpdateAt > :Time
AND ChannelId = :ChannelId
LIMIT 1000) temp_tab))
ORDER BY CreateAt DESC`,
map[string]interface{}{"ChannelId": options.ChannelId, "Time": options.Time})
Id
FROM
Posts p2
WHERE
(UpdateAt > :Time
AND ChannelId = :ChannelId)
LIMIT 1000)
UNION
(SELECT
Id
FROM
Posts p3
WHERE
Id
IN
(SELECT * FROM (SELECT
RootId
FROM
Posts
WHERE
UpdateAt > :Time
AND ChannelId = :ChannelId
LIMIT 1000) temp_tab))
) j ON p1.Id = j.Id
ORDER BY CreateAt DESC`
} else if s.DriverName() == model.DATABASE_DRIVER_POSTGRES {
query = `
(SELECT
*` + replyCountQuery1 + `
FROM
Posts p1
WHERE
(UpdateAt > :Time
AND ChannelId = :ChannelId)
LIMIT 1000)
UNION
(SELECT
*` + replyCountQuery2 + `
FROM
Posts p2
WHERE
Id
IN
(SELECT * FROM (SELECT
RootId
FROM
Posts
WHERE
UpdateAt > :Time
AND ChannelId = :ChannelId
LIMIT 1000) temp_tab))
ORDER BY CreateAt DESC`
}
_, err := s.GetReplica().Select(&posts, query, map[string]interface{}{"ChannelId": options.ChannelId, "Time": options.Time})

if err != nil {
return nil, model.NewAppError("SqlPostStore.GetPostsSince", "store.sql_post.get_posts_since.app_error", nil, "channelId="+options.ChannelId+err.Error(), http.StatusInternalServerError)
Expand Down Expand Up @@ -697,6 +729,70 @@ func (s *SqlPostStore) getRootPosts(channelId string, offset int, limit int, ski
}

func (s *SqlPostStore) getParentsPosts(channelId string, offset int, limit int, skipFetchThreads bool) ([]*model.Post, *model.AppError) {
if s.DriverName() == model.DATABASE_DRIVER_POSTGRES {
return s.getParentsPostsPostgreSQL(channelId, offset, limit, skipFetchThreads)
}

// query parent Ids first
var roots []*struct {
RootId string
}
rootQuery := `
SELECT DISTINCT
q.RootId
FROM
(SELECT
RootId
FROM
Posts
WHERE
ChannelId = :ChannelId
AND DeleteAt = 0
ORDER BY CreateAt DESC
LIMIT :Limit OFFSET :Offset) q
WHERE q.RootId != ''`

_, err := s.GetReplica().Select(&roots, rootQuery, map[string]interface{}{"ChannelId": channelId, "Offset": offset, "Limit": limit})
if err != nil {
return nil, model.NewAppError("SqlPostStore.GetLinearPosts", "store.sql_post.get_parents_posts.app_error", nil, "channelId="+channelId+" err="+err.Error(), http.StatusInternalServerError)
}
if len(roots) == 0 {
return nil, nil
}
params := make(map[string]interface{})
placeholders := make([]string, len(roots))
for idx, r := range roots {
key := fmt.Sprintf(":Root%v", idx)
params[key[1:]] = r.RootId
placeholders[idx] = key
}
placeholderString := strings.Join(placeholders, ", ")
params["ChannelId"] = channelId
replyCountQuery := ""
whereStatement := "p.Id IN (" + placeholderString + ")"
if skipFetchThreads {
replyCountQuery = `, (SELECT COUNT(Posts.Id) FROM Posts WHERE p.RootId = '' AND Posts.RootId = p.Id AND Posts.DeleteAt = 0) as ReplyCount`
} else {
whereStatement += " OR p.RootId IN (" + placeholderString + ")"
}
var posts []*model.Post
_, err = s.GetReplica().Select(&posts, `
SELECT p.*`+replyCountQuery+`
FROM
Posts p
WHERE
(`+whereStatement+`)
AND ChannelId = :ChannelId
AND DeleteAt = 0
ORDER BY CreateAt`,
params)
if err != nil {
return nil, model.NewAppError("SqlPostStore.GetLinearPosts", "store.sql_post.get_parents_posts.app_error", nil, "channelId="+channelId+" err="+err.Error(), http.StatusInternalServerError)
}
return posts, nil
}

func (s *SqlPostStore) getParentsPostsPostgreSQL(channelId string, offset int, limit int, skipFetchThreads bool) ([]*model.Post, *model.AppError) {
var posts []*model.Post
replyCountQuery := ""
onStatement := "q1.RootId = q2.Id"
Expand All @@ -707,27 +803,27 @@ func (s *SqlPostStore) getParentsPosts(channelId string, offset int, limit int,
}
_, err := s.GetReplica().Select(&posts,
`SELECT q2.*`+replyCountQuery+`
FROM
Posts q2
INNER JOIN
(SELECT DISTINCT
q3.RootId
FROM
(SELECT
RootId
FROM
Posts
WHERE
ChannelId = :ChannelId1
AND DeleteAt = 0
ORDER BY CreateAt DESC
LIMIT :Limit OFFSET :Offset) q3
WHERE q3.RootId != '') q1
ON `+onStatement+`
WHERE
ChannelId = :ChannelId2
AND DeleteAt = 0
ORDER BY CreateAt`,
FROM
Posts q2
INNER JOIN
(SELECT DISTINCT
q3.RootId
FROM
(SELECT
RootId
FROM
Posts
WHERE
ChannelId = :ChannelId1
AND DeleteAt = 0
ORDER BY CreateAt DESC
LIMIT :Limit OFFSET :Offset) q3
WHERE q3.RootId != '') q1
ON `+onStatement+`
WHERE
ChannelId = :ChannelId2
AND DeleteAt = 0
ORDER BY CreateAt`,
map[string]interface{}{"ChannelId1": channelId, "Offset": offset, "Limit": limit, "ChannelId2": channelId})
if err != nil {
return nil, model.NewAppError("SqlPostStore.GetLinearPosts", "store.sql_post.get_parents_posts.app_error", nil, "channelId="+channelId+" err="+err.Error(), http.StatusInternalServerError)
Expand Down