-
Notifications
You must be signed in to change notification settings - Fork 1
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
Order story titles with method #28
Merged
Merged
Conversation
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Closed
Finally (and obviously in retrospect) the order of the story titles is in Window function: SELECT gcd_issue.id AS 'id', gcd_issue.key_date AS 'key_date', gcd_issue.number AS 'number',
gcd_issue.title AS 'issue_title', gcd_issue.series_id AS 'series_id',
gcd_issue.price AS 'price', gcd_issue.valid_isbn AS 'isbn',
gcd_issue.notes AS 'issue_notes', gcd_issue.volume AS 'volume',
gcd_issue.rating AS 'maturity_rating', gcd_story.characters AS 'characters',
stddata_country.name AS 'country', stddata_country.code AS 'country_iso',
stddata_language.name AS 'language', stddata_language.code AS 'language_iso',
(
SELECT GROUP_CONCAT(story_title, '\n')
FROM (
SELECT gcd_story.title AS story_title,
ROW_NUMBER() OVER (PARTITION BY gcd_story.issue_id ORDER BY gcd_story.sequence_number) AS row_num
FROM gcd_story
WHERE gcd_story.issue_id = gcd_issue.id
AND gcd_story.type_id = 19
AND gcd_issue.variant_of_id IS NULL
AND gcd_story.title IS NOT NULL
AND gcd_story.title != ''
)
) AS 'story_titles',
GROUP_CONCAT(CASE WHEN gcd_story.genre IS NOT NULL AND gcd_story.genre != '' THEN
gcd_story.genre END, ';') AS 'genres',
GROUP_CONCAT(CASE WHEN gcd_story.synopsis IS NOT NULL AND gcd_story.synopsis != '' THEN
gcd_story.synopsis END, '\n\n') AS 'synopses',
GROUP_CONCAT(CASE WHEN gcd_story.id IS NOT NULL AND gcd_story.id != '' THEN
gcd_story.id END, '\n') AS 'story_ids',
(SELECT GROUP_CONCAT(gcd_brand_group.name, '; ')
FROM gcd_issue
LEFT JOIN gcd_brand ON gcd_issue.brand_id=gcd_brand.id
LEFT JOIN gcd_brand_emblem_group ON gcd_brand.id=gcd_brand_emblem_group.brand_id
LEFT JOIN gcd_brand_group ON gcd_brand_emblem_group.brandgroup_id=gcd_brand_group.id
LEFT JOIN gcd_series ON gcd_issue.series_id=gcd_series.id
LEFT JOIN gcd_publisher ON gcd_series.publisher_id=gcd_publisher.id
WHERE gcd_issue.id=?
AND gcd_publisher.name != gcd_brand_group.name
) AS 'imprint'
FROM gcd_issue
LEFT JOIN gcd_story ON gcd_story.issue_id = gcd_issue.id AND gcd_story.type_id = 19
LEFT JOIN gcd_indicia_publisher ON gcd_issue.indicia_publisher_id = gcd_indicia_publisher.id
LEFT JOIN gcd_series ON gcd_issue.series_id = gcd_series.id
LEFT JOIN stddata_country ON gcd_indicia_publisher.country_id = stddata_country.id
LEFT JOIN stddata_language ON gcd_series.language_id = stddata_language.id
WHERE gcd_issue.id=?
GROUP BY gcd_issue.id; JSON within SQL: SELECT gcd_issue.id AS 'id', gcd_issue.key_date AS 'key_date', gcd_issue.number AS 'number',
gcd_issue.title AS 'issue_title', gcd_issue.series_id AS 'series_id',
gcd_issue.price AS 'price', gcd_issue.valid_isbn AS 'isbn',
gcd_issue.notes AS 'issue_notes', gcd_issue.volume AS 'volume',
gcd_issue.rating AS 'maturity_rating', gcd_story.characters AS 'characters',
stddata_country.name AS 'country', stddata_country.code AS 'country_iso',
stddata_language.name AS 'language', stddata_language.code AS 'language_iso',
(select
json_group_array(json_array(gcd_story.sequence_number,gcd_story.title))
from
gcd_story
where
(
gcd_story.issue_id = gcd_issue.id
and gcd_story.type_id = 19
AND gcd_issue.variant_of_id IS NULL
AND gcd_story.title IS NOT NULL
AND gcd_story.title != ''
)
ORDER BY
gcd_story.sequence_number DESC
) AS 'story_titles',
GROUP_CONCAT(CASE WHEN gcd_story.genre IS NOT NULL AND gcd_story.genre != '' THEN
gcd_story.genre END, ';') AS 'genres',
GROUP_CONCAT(CASE WHEN gcd_story.synopsis IS NOT NULL AND gcd_story.synopsis != '' THEN
gcd_story.synopsis END,'\n\n') AS 'synopses',
GROUP_CONCAT(CASE WHEN gcd_story.id IS NOT NULL AND gcd_story.id != '' THEN
gcd_story.id END, '\n') AS 'story_ids',
(SELECT GROUP_CONCAT(gcd_brand_group.name, '; ')
from gcd_issue
LEFT JOIN gcd_brand ON gcd_issue.brand_id=gcd_brand.id
LEFT JOIN gcd_brand_emblem_group ON gcd_brand.id=gcd_brand_emblem_group.brand_id
LEFT JOIN gcd_brand_group ON gcd_brand_emblem_group.brandgroup_id=gcd_brand_group.id
LEFT JOIN gcd_series ON gcd_issue.series_id=gcd_series.id
LEFT JOIN gcd_publisher ON gcd_series.publisher_id=gcd_publisher.id
WHERE gcd_issue.id=?
and gcd_publisher.name is not gcd_brand_group.name
) as 'imprint'
FROM gcd_issue
LEFT JOIN gcd_story ON gcd_story.issue_id=gcd_issue.id AND gcd_story.type_id=19
LEFT JOIN gcd_indicia_publisher ON gcd_issue.indicia_publisher_id=gcd_indicia_publisher.id
LEFT JOIN gcd_series ON gcd_issue.series_id=gcd_series.id
LEFT JOIN stddata_country ON gcd_indicia_publisher.country_id=stddata_country.id
LEFT JOIN stddata_language ON gcd_series.language_id=stddata_language.id
WHERE gcd_issue.id=?
GROUP BY gcd_issue.id; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Closes #8