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

Reuse sql for large get item queries #3482

Draft
wants to merge 2 commits into
base: develop
Choose a base branch
from
Draft
Show file tree
Hide file tree
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
18 changes: 0 additions & 18 deletions src/main/java/org/craftercms/studio/api/v2/dal/ItemDAO.java
Original file line number Diff line number Diff line change
Expand Up @@ -97,24 +97,6 @@ List<Item> getChildrenByPath(@Param(SITE_ID) Long siteId,
*/
void upsertEntry(Item item);

/**
* Get item by id
*
* @param id item id
* @param siteId site identifier
* @param systemTypeFolder value for system type folder
* @param completedState completed state
* @param liveEnvironment live environment
* @param stagingEnvironment staging environment
* @return item identified by given id
*/
DetailedItem getItemById(@Param(ID) long id,
@Param(SITE_ID) String siteId,
@Param(SYSTEM_TYPE_FOLDER) String systemTypeFolder,
@Param(COMPLETED_STATE) String completedState,
@Param(STAGING_ENVIRONMENT) String stagingEnvironment,
@Param(LIVE_ENVIRONMENT) String liveEnvironment);

/**
* Get item for given site and path
* @param siteId site identifier
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -37,14 +37,6 @@ public interface ItemServiceInternal {
*/
boolean upsertEntry(Item item);

/**
* Get item by given id
* @param siteId site identifier
* @param id item id
* @return item
*/
DetailedItem getItem(String siteId, long id);

/**
* Get item fir given site and path
* @param siteId site identifier
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -70,13 +70,6 @@ public boolean upsertEntry(Item item) {
return true;
}

@Override
public DetailedItem getItem(String siteId, long id) {
String stagingEnv = servicesConfig.getStagingEnvironment(siteId);
String liveEnv = servicesConfig.getLiveEnvironment(siteId);
return itemDao.getItemById(id, siteId, CONTENT_TYPE_FOLDER, COMPLETED, stagingEnv, liveEnv);
}

@Override
public Item getItem(String siteId, String path) {
return getItem(siteId, path, false);
Expand Down
152 changes: 10 additions & 142 deletions src/main/resources/org/craftercms/studio/api/v2/dal/ItemDAO.xml
Original file line number Diff line number Diff line change
Expand Up @@ -243,67 +243,6 @@
<include refid="getChildrenByPathFilters"/>
</select>

<select id="getItemById" resultMap="DetailedItemMap">
SELECT i.*, u1.id AS lock_owner, u2.id AS creator, u3.id AS modifier,
w1.schedule AS staging_scheduleddate, staging1.published_on AS staging_published_on,
staging1.username AS staging_username,
w2.schedule AS live_scheduleddate, live1.published_on AS live_published_on,
live1.username AS live_username,
COUNT(DISTINCT i3.id) AS children_count
FROM item i INNER JOIN site s1 ON i.site_id = s1.id
LEFT OUTER JOIN item i3 ON i.id = i3.parent_id
LEFT OUTER JOIN user u1 ON i.locked_by = u1.id
LEFT OUTER JOIN user u2 ON i.created_by = u2.id
LEFT OUTER JOIN user u3 ON i.last_modified_by = u3.id
LEFT OUTER JOIN (
SELECT pr1.*
FROM publish_request pr1, item i11
WHERE i11.id = #{id} AND pr1.site = #{siteId} AND pr1.path = i11.path
AND pr1.environment = #{stagingEnvironment} AND pr1.state = #{completedState}
ORDER BY pr1.published_on desc limit 0, 1) AS staging1
ON s1.site_id = staging1.site AND i.path = staging1.path
LEFT OUTER JOIN (
(SELECT item_id, schedule
FROM workflow
WHERE target_environment = #{stagingEnvironment}
AND state = 'OPENED')
UNION
(SELECT w.item_id, pr.scheduleddate AS schedule
FROM workflow w INNER JOIN publish_request pr ON w.publishing_package_id = pr.package_id
WHERE w.target_environment = #{stagingEnvironment}
AND w.state = 'APPROVED'
AND pr.state = 'READY_FOR_LIVE'
ORDER BY scheduleddate DESC)) AS w1 ON i.id = w1.item_id
LEFT OUTER JOIN (
SELECT pr2.*
FROM publish_request pr2, item i12
WHERE i12.id = #{id}
AND pr2.site = #{siteId}
AND pr2.path = i12.path
AND pr2.environment = #{liveEnvironment}
AND pr2.state = #{completedState}
ORDER BY pr2.published_on DESC LIMIT 0, 1)
AS live1 ON s1.site_id = live1.site AND i.path = live1.path
LEFT OUTER JOIN (
(SELECT item_id, schedule
FROM workflow
WHERE target_environment = #{liveEnvironment}
AND state = 'OPENED')
UNION
(SELECT w.item_id, pr.scheduleddate AS schedule
FROM workflow w INNER JOIN publish_request pr ON w.publishing_package_id = pr.package_id
WHERE w.target_environment = #{liveEnvironment}
AND w.state = 'APPROVED'
AND pr.state = 'READY_FOR_LIVE'
ORDER BY scheduleddate DESC)) AS w2 ON i.id = w2.item_id
WHERE i.id = #{id}
AND (i3.ignored = 0 OR i3.ignored IS NULL)
AND (i3.system_type &lt;&gt; #{systemTypeFolder} OR NOT EXISTS
(SELECT * FROM item i10 WHERE i10.site_id = i3.site_id AND i10.path = CONCAT(i3.path, '/index.xml')))
GROUP BY i.id
limit 0, 1
</select>

<select id="getDetailedItemsByStates" resultMap="DetailedItemMap">
SELECT i.*, i.locked_by AS lock_owner, i.created_by AS creator, i.last_modified_by AS modifier,
(
Expand Down Expand Up @@ -387,6 +326,9 @@
</select>

<select id="getItemByPath" resultMap="DetailedItemMap">
<include refid="getItemByPathQuery"/>
</select>
<sql id="getItemByPathQuery">
SELECT i.*, i.locked_by AS lock_owner, i.created_by AS creator, i.last_modified_by AS modifier,
(
SELECT w.submitted_on
Expand Down Expand Up @@ -423,17 +365,15 @@
FROM workflow w
WHERE target_environment = #{liveEnvironment}
AND state = 'OPENED'
AND i.id = w.item_id
)
AND i.id = w.item_id)
UNION
(SELECT pr.scheduleddate AS schedule
FROM workflow w INNER JOIN publish_request pr ON w.publishing_package_id = pr.package_id
WHERE w.target_environment = #{liveEnvironment}
AND w.state = 'APPROVED'
AND pr.state = 'READY_FOR_LIVE'
AND i.id = w.item_id
)
ORDER BY schedule DESC
AND i.id = w.item_id)
ORDER BY schedule DESC LIMIT 0, 1
) AS live_scheduleddate,
live1.published_on AS live_published_on,
live1.username AS live_username,
Expand Down Expand Up @@ -465,7 +405,7 @@
(SELECT * FROM item i10 WHERE i10.site_id = i3.site_id AND i10.path = CONCAT(i3.path, '/index.xml')))
GROUP BY i.id
LIMIT 0, 1
</select>
</sql>

<select id="getItemByPathPreferContent" resultMap="DetailedItemMap">
(SELECT i1.*, i1.locked_by AS lock_owner, i1.created_by AS creator, i1.last_modified_by AS modifier,
Expand Down Expand Up @@ -548,81 +488,9 @@
(SELECT * FROM item i10 WHERE i10.site_id = i5.site_id AND i10.path = concat(i5.path, '/index.xml')))
GROUP BY i1.id)
UNION
(select i3.*, i3.locked_by AS lock_owner, i3.created_by AS creator, i3.last_modified_by AS modifier,
(
SELECT w.submitted_on
FROM workflow w
WHERE w.item_id = i3.id
ORDER BY w.id DESC LIMIT 0, 1
) as submitted_on,
(
SELECT w.submitter_id
FROM workflow w
WHERE w.item_id = i3.id
ORDER BY w.id DESC LIMIT 0, 1
) AS submitter,
(
(SELECT schedule
FROM workflow w
WHERE target_environment = #{stagingEnvironment}
AND state = 'OPENED'
AND i3.id = w.item_id
)
UNION
(SELECT pr.scheduleddate AS schedule
FROM workflow w INNER JOIN publish_request pr ON w.publishing_package_id = pr.package_id
WHERE w.target_environment = #{stagingEnvironment}
AND w.state = 'APPROVED'
AND pr.state = 'READY_FOR_LIVE'
AND i3.id = w.item_id
ORDER BY schedule DESC LIMIT 0, 1)
) AS staging_scheduleddate,
staging2.published_on AS staging_published_on,
staging2.username AS staging_username,
(
(SELECT schedule
FROM workflow w
WHERE target_environment = #{liveEnvironment}
AND state = 'OPENED'
AND i3.id = w.item_id)
UNION
(SELECT pr.scheduleddate AS schedule
FROM workflow w INNER JOIN publish_request pr ON w.publishing_package_id = pr.package_id
WHERE w.target_environment = #{liveEnvironment}
AND w.state = 'APPROVED'
AND pr.state = 'READY_FOR_LIVE'
AND i3.id = w.item_id)
ORDER BY schedule DESC LIMIT 0, 1
) AS live_scheduleddate,
live2.published_on AS live_published_on,
live2.username AS live_username,
COUNT(DISTINCT i6.id) AS children_count
FROM item i3 INNER JOIN site s4 ON i3.site_id = s4.id
LEFT OUTER JOIN item i6 ON i3.id = i6.parent_id
LEFT OUTER JOIN (
SELECT pr3.*
FROM publish_request pr3 INNER JOIN site s5 ON pr3.site = s5.site_id
WHERE s5.id = #{siteId}
AND pr3.path = #{path}
AND pr3.environment = #{stagingEnvironment}
AND pr3.state = #{completedState}
ORDER BY pr3. published_on DESC LIMIT 0, 1
) AS staging2 ON s4.site_id = staging2.site AND i3.path = staging2.path
LEFT OUTER JOIN (
SELECT pr4.*
FROM publish_request pr4 INNER JOIN site s6 ON pr4.site = s6.site_id
WHERE s6.id = #{siteId}
AND pr4.path = #{path}
AND pr4.environment = #{liveEnvironment}
AND pr4.state = #{completedState}
ORDER BY pr4.published_on DESC LIMIT 0, 1
) AS live2 ON s4.site_id = live2.site AND i3.path = live2.path
WHERE i3.site_id = #{siteId}
AND i3.path = #{path}
AND (i6.ignored = 0 OR i6.ignored IS NULL)
AND (i6.system_type &lt;&gt; #{systemTypeFolder} OR NOT EXISTS
(SELECT * FROM item i11 WHERE i11.site_id = i6.site_id AND i11.path = CONCAT(i6.path, '/index.xml')))
GROUP BY i3.id)
(
<include refid="getItemByPathQuery" />
)
LIMIT 0, 1
</select>

Expand Down