Skip to content

Commit

Permalink
Add data unit SQL
Browse files Browse the repository at this point in the history
  • Loading branch information
seananderson committed Dec 30, 2024
1 parent 869a304 commit 3e0e1f7
Show file tree
Hide file tree
Showing 6 changed files with 437 additions and 0 deletions.
74 changes: 74 additions & 0 deletions sql/FD5046 GFFOS detailed catch.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
SELECT 'GFFOS' AS DATABASE_NAME,
FISHING_YEAR, C.FISHERY_SECTOR, C.TRIP_CATEGORY, C.GEAR, GEAR_SUBTYPE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(RETAINED_ROUND_KG, 0)) AS RETAINED_ROUND_KG,
SUM(ISNULL(RETAINED_COUNT, 0)) AS RETAINED_COUNT,
SUM(ISNULL(LANDED_COUNT, 0)) AS LANDED_COUNT,
SUM(ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_COUNT, 0)) AS TOTAL_RELEASED_COUNT,
SUM(ISNULL(SUBLEGAL_RELEASED_ROUND_KG, 0)) AS SUBLEGAL_RELEASED_ROUND_KG,
SUM(ISNULL(LEGAL_RELEASED_ROUND_KG, 0)) AS LEGAL_RELEASED_ROUND_KG,
SUM(ISNULL(SUBLEGAL_RELEASED_COUNT, 0)) AS SUBLEGAL_RELEASED_COUNT,
SUM(ISNULL(LEGAL_RELEASED_COUNT, 0)) AS LEGAL_RELEASED_COUNT,
SUM(ISNULL(SUBLEGAL_LICED_COUNT, 0)+ISNULL(LEGAL_LICED_COUNT, 0)) AS LICED_COUNT,
SUM(ISNULL(SUBLEGAL_BAIT_COUNT, 0)+ISNULL(LEGAL_BAIT_COUNT, 0)) AS BAIT_COUNT
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
LEFT JOIN (
SELECT TRIP_ID
FROM (
-- Identify trips that are also in PacHarvHL
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvHL.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN' AND OFFLOAD_DATE < '04/01/2006' -- up to cutoff for PHL
UNION ALL
-- Identify trips that are also in PacHarvSable
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvSable.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN'
) H
GROUP BY TRIP_ID
) OL ON OL.TRIP_ID = C.TRIP_ID
WHERE OL.TRIP_ID IS NULL AND SPECIES_CODE = '044' AND YEAR(C.BEST_DATE) > 2004
AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01' AND ISNULL(DFO_STAT_AREA_CODE,0) != 12
/*AND FISHERY_SECTOR != 'ROCKFISH INSIDE' AND FISHERY_SECTOR ! = 'GROUNDFISH TRAWL'*/
AND FISHERY_SECTOR = 'GROUNDFISH TRAWL'
GROUP BY FISHING_YEAR, C.FISHERY_SECTOR, C.TRIP_CATEGORY, C.GEAR, C.GEAR_SUBTYPE
ORDER BY FISHERY_SECTOR, FISHING_YEAR

SELECT 'GFFOS' AS DATABASE_NAME, YEAR(C.BEST_DATE) AS CALENDAR_YEAR, C.FISHERY_SECTOR, C.TRIP_CATEGORY, C.GEAR, C.GEAR_SUBTYPE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(RETAINED_ROUND_KG, 0)) AS RETAINED_ROUND_KG,
SUM(ISNULL(RETAINED_COUNT, 0)) AS RETAINED_COUNT,
SUM(ISNULL(LANDED_COUNT, 0)) AS LANDED_COUNT,
SUM(ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_COUNT, 0)) AS TOTAL_RELEASED_COUNT,
SUM(ISNULL(SUBLEGAL_RELEASED_ROUND_KG, 0)) AS SUBLEGAL_RELEASED_ROUND_KG,
SUM(ISNULL(LEGAL_RELEASED_ROUND_KG, 0)) AS LEGAL_RELEASED_ROUND_KG,
SUM(ISNULL(SUBLEGAL_RELEASED_COUNT, 0)) AS SUBLEGAL_RELEASED_COUNT,
SUM(ISNULL(LEGAL_RELEASED_COUNT, 0)) AS LEGAL_RELEASED_COUNT,
SUM(ISNULL(SUBLEGAL_LICED_COUNT, 0)+ISNULL(LEGAL_LICED_COUNT, 0)) AS LICED_COUNT,
SUM(ISNULL(SUBLEGAL_BAIT_COUNT, 0)+ISNULL(LEGAL_BAIT_COUNT, 0)) AS BAIT_COUNT
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
LEFT JOIN (
SELECT TRIP_ID
FROM (
-- Identify trips that are also in PacHarvHL
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvHL.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN' AND OFFLOAD_DATE < '04/01/2006' -- up to cutoff for PHL
UNION ALL
-- Identify trips that are also in PacHarvSable
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvSable.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN'
) H
GROUP BY TRIP_ID
) OL ON OL.TRIP_ID = C.TRIP_ID
WHERE OL.TRIP_ID IS NULL AND SPECIES_CODE = '044' AND YEAR(C.BEST_DATE) > 2004
AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01' AND ISNULL(DFO_STAT_AREA_CODE,0) != 12
/*AND FISHERY_SECTOR != 'ROCKFISH INSIDE' AND FISHERY_SECTOR ! = 'GROUNDFISH TRAWL'*/
AND FISHERY_SECTOR = 'GROUNDFISH TRAWL'
GROUP BY YEAR(C.BEST_DATE), C.FISHERY_SECTOR, C.TRIP_CATEGORY, C.GEAR, C.GEAR_SUBTYPE
ORDER BY FISHERY_SECTOR, CALENDAR_YEAR
82 changes: 82 additions & 0 deletions sql/FD5046 all line (simple) by calendar year 2001-2024.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
SELECT DATABASE_NAME, CALENDAR_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE,
LANDED_ROUND_KG, TOTAL_RELEASED_ROUND_KG, TOTAL_RELEASED_COUNT, TOTAL_KG
FROM (
SELECT 'PacHarvSable' AS DATABASE_NAME,
YEAR(D.OFFLOAD_DT) AS CALENDAR_YEAR, 'SABLEFISH' AS FISHERY_SECTOR, GEAR, GEAR AS GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED, 0)) AS TOTAL_RELEASED_ROUND_KG,
NULL AS TOTAL_RELEASED_COUNT,
SUM(ISNULL(LANDED, 0)+ISNULL(DISCARDED, 0)) AS TOTAL_KG
FROM PacHarvSable.dbo.D_Official_Catch D
WHERE OFFLOAD_DT > '2001-07-31 00:00:00' AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CDE,0) != 1
AND ISNULL(D.DFO_MGMT_AREA_CDE,0) != '12'
GROUP BY YEAR(D.OFFLOAD_DT), GEAR, SPECIES_CODE

UNION ALL

SELECT 'PacHarHL' AS DATABASE_NAME, D.Calendar_Year AS CALENDAR_YEAR,
FISHERY AS FISHERY_SECTOR,
CASE
WHEN GEAR_TYPE_NME = 'LONGLINE' THEN 'LONGLINE'
WHEN GEAR_TYPE_NME IN ('HANDLINE', 'ROD AND REEL', 'TROLL') THEN 'HOOK AND LINE'
ELSE 'LONGLINE OR HOOK AND LINE' END AS GEAR,
CASE WHEN G.GEAR_TYPE_NME = 'UNKNOWN' THEN 'UNSPECIFIED' ELSE G.GEAR_TYPE_NME END AS GEAR_SUBTYPE,
SPECIES_CODE,
SUM(ISNULL([LANDED/RETAINED],0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED,0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(RELEASED_COUNT,0)) AS TOTAL_RELEASED_COUNT,
SUM(ISNULL([LANDED/RETAINED],0)+ISNULL(DISCARDED,0)) AS TOTAL_KG
FROM PacHarvHL.dbo.D_Official_Catch D
LEFT JOIN (
SELECT C.OBFL_HAIL_IN_NO, OBFL_SET_NO, OBFL_SPECIES_CDE,
SUM(ISNULL(OBFL_EST_WEIGHT,0)) AS RELEASED_KG,
SUM(ISNULL(OBFL_EST_COUNT,0)) AS RELEASED_COUNT
FROM PacHarvHL.dbo.B4_Catches C
INNER JOIN PacHarvHL.dbo.C_Catch_Utilization U ON U.CATCH_UTILIZATION_CDE = C.OBFL_CATCH_UTILIZATION_CDE
WHERE CATCH_UTILIZATION_DISCARD_IND = 1 AND ISNULL(OBFL_EST_WEIGHT,0)+ISNULL(OBFL_EST_COUNT,0)>0
GROUP BY C.OBFL_HAIL_IN_NO, OBFL_SET_NO, OBFL_SPECIES_CDE
) REL ON REL.OBFL_HAIL_IN_NO = D.HAIL_IN_NO AND REL.OBFL_SET_NO = D.SET_NO
AND REL.OBFL_SPECIES_CDE = D.SPECIES_CODE
INNER JOIN PacHarvHL.dbo.C_Gear_Type G ON G.GEAR_TYPE_CDE = D.GEAR_TYPE_CDE
WHERE D.OFFLOAD_DATE < '04/01/2006' AND -- cutoff for PHL data
SPECIES_CODE = '044' AND Fishing_Year > 2000 AND ISNULL(MAJOR_STAT_AREA,0) != 1
AND ISNULL(D.DFO_MGMT_AREA_CDE,0)!= '12'
GROUP BY D.Calendar_Year, FISHERY,
CASE WHEN GEAR_TYPE_NME = 'LONGLINE' THEN 'LONGLINE'
WHEN GEAR_TYPE_NME IN ('HANDLINE', 'ROD AND REEL', 'TROLL') THEN 'HOOK AND LINE'
ELSE 'LONGLINE OR HOOK AND LINE' END,
CASE WHEN G.GEAR_TYPE_NME = 'UNKNOWN' THEN 'UNSPECIFIED' ELSE G.GEAR_TYPE_NME END,
SPECIES_CODE

UNION ALL

SELECT 'GFFOS' AS DATABASE_NAME,
YEAR(BEST_DATE) AS CALENDAR_YEAR, C.FISHERY_SECTOR, C.GEAR, GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
NULL AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_COUNT, 0)) AS TOTAL_RELEASED_COUNT,
NULL AS TOTAL_KG
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
LEFT JOIN (
SELECT TRIP_ID
FROM (
-- Identify trips that are also in PacHarvHL
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvHL.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN' AND OFFLOAD_DATE < '04/01/2006' -- up to cutoff for PHL
UNION ALL
-- Identify trips that are also in PacHarvSable
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvSable.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN'
) H
GROUP BY TRIP_ID
) OL ON OL.TRIP_ID = C.TRIP_ID
WHERE OL.TRIP_ID IS NULL AND FISHERY_SECTOR != 'GROUNDFISH TRAWL' AND FISHERY_SECTOR != 'ROCKFISH INSIDE' AND
YEAR(C.BEST_DATE) > 2004 AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01'
AND ISNULL(DFO_STAT_AREA_CODE,0)!= 12
GROUP BY YEAR(BEST_DATE), C.FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE
) C
ORDER BY FISHERY_SECTOR, CALENDAR_YEAR

86 changes: 86 additions & 0 deletions sql/FD5046 all line (simple) by fishing year 2001-2024.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,86 @@
SELECT DATABASE_NAME, FISHING_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE,
LANDED_ROUND_KG, TOTAL_RELEASED_ROUND_KG, TOTAL_RELEASED_COUNT, TOTAL_KG
FROM (
SELECT 'PacHarvSable' AS DATABASE_NAME,
FISHING_YEAR, 'SABLEFISH' AS FISHERY_SECTOR, GEAR, GEAR AS GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED, 0)) AS TOTAL_RELEASED_ROUND_KG,
NULL AS TOTAL_RELEASED_COUNT,
SUM(ISNULL(LANDED, 0)+ISNULL(DISCARDED, 0)) AS TOTAL_KG
FROM PacHarvSable.dbo.D_Official_Catch D
INNER JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.HAIL_IN_NO = D.HAIL_IN_NO
WHERE OFFLOAD_DT > '2001-07-31 00:00:00' AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CDE,0) != 1
AND ISNULL(D.DFO_MGMT_AREA_CDE,0) != '12'
GROUP BY FISHING_YEAR, GEAR, SPECIES_CODE

UNION ALL

SELECT 'PacHarHL' AS DATABASE_NAME,
CAST(Fishing_Year AS varchar(4))+'-'+CAST(Fishing_Year+1 AS varchar(4)) AS FISHING_YEAR,
FISHERY AS FISHERY_SECTOR,
CASE
WHEN GEAR_TYPE_NME = 'LONGLINE' THEN 'LONGLINE'
WHEN GEAR_TYPE_NME IN ('HANDLINE', 'ROD AND REEL', 'TROLL') THEN 'HOOK AND LINE'
ELSE 'LONGLINE OR HOOK AND LINE' END AS GEAR,
CASE WHEN G.GEAR_TYPE_NME = 'UNKNOWN' THEN 'UNSPECIFIED' ELSE G.GEAR_TYPE_NME END AS GEAR_SUBTYPE,
SPECIES_CODE,
SUM(ISNULL([LANDED/RETAINED],0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED,0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(RELEASED_COUNT,0)) AS TOTAL_RELEASED_COUNT,
SUM(ISNULL([LANDED/RETAINED],0)+ISNULL(DISCARDED,0)) AS TOTAL_KG
FROM PacHarvHL.dbo.D_Official_Catch D
LEFT JOIN (
SELECT C.OBFL_HAIL_IN_NO, OBFL_SET_NO, OBFL_SPECIES_CDE,
SUM(ISNULL(OBFL_EST_WEIGHT,0)) AS RELEASED_KG,
SUM(ISNULL(OBFL_EST_COUNT,0)) AS RELEASED_COUNT
FROM PacHarvHL.dbo.B4_Catches C
INNER JOIN PacHarvHL.dbo.C_Catch_Utilization U ON U.CATCH_UTILIZATION_CDE = C.OBFL_CATCH_UTILIZATION_CDE
WHERE CATCH_UTILIZATION_DISCARD_IND = 1 AND ISNULL(OBFL_EST_WEIGHT,0)+ISNULL(OBFL_EST_COUNT,0)>0
GROUP BY C.OBFL_HAIL_IN_NO, OBFL_SET_NO, OBFL_SPECIES_CDE
) REL ON REL.OBFL_HAIL_IN_NO = D.HAIL_IN_NO AND REL.OBFL_SET_NO = D.SET_NO
AND REL.OBFL_SPECIES_CDE = D.SPECIES_CODE
INNER JOIN PacHarvHL.dbo.C_Gear_Type G ON G.GEAR_TYPE_CDE = D.GEAR_TYPE_CDE
WHERE D.OFFLOAD_DATE < '04/01/2006' AND -- cutoff for PHL data
SPECIES_CODE = '044' AND Fishing_Year > 2000 AND ISNULL(MAJOR_STAT_AREA,0) != 1
AND ISNULL(D.DFO_MGMT_AREA_CDE,0)!= '12'
GROUP BY CAST(Fishing_Year AS varchar(4))+'-'+CAST(Fishing_Year+1 AS varchar(4)), FISHERY,
CASE WHEN GEAR_TYPE_NME = 'LONGLINE' THEN 'LONGLINE'
WHEN GEAR_TYPE_NME IN ('HANDLINE', 'ROD AND REEL', 'TROLL') THEN 'HOOK AND LINE'
ELSE 'LONGLINE OR HOOK AND LINE' END,
CASE WHEN G.GEAR_TYPE_NME = 'UNKNOWN' THEN 'UNSPECIFIED' ELSE G.GEAR_TYPE_NME END,
SPECIES_CODE

UNION ALL

SELECT 'GFFOS' AS DATABASE_NAME,
FISHING_YEAR, C.FISHERY_SECTOR, C.GEAR, GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
NULL AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_COUNT, 0)) AS TOTAL_RELEASED_COUNT,
NULL AS TOTAL_KG
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
LEFT JOIN (
SELECT TRIP_ID
FROM (
-- Identify trips that are also in PacHarvHL
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvHL.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN' AND OFFLOAD_DATE < '04/01/2006' -- up to cutoff for PHL
UNION ALL
-- Identify trips that are also in PacHarvSable
SELECT DISTINCT CAST(H.TRIP_ID AS VARCHAR(50)) AS TRIP_ID FROM GFFOS.dbo.GF_HAIL_NUMBER H
INNER JOIN PacHarvSable.dbo.D_Official_Catch C ON H.HAIL_NUMBER = C.HAIL_IN_NO
WHERE H.HAIL_TYPE = 'IN'
) H
GROUP BY TRIP_ID
) OL ON OL.TRIP_ID = C.TRIP_ID
WHERE OL.TRIP_ID IS NULL AND FISHERY_SECTOR != 'GROUNDFISH TRAWL' AND
YEAR(C.BEST_DATE) > 2004 AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01'
AND ISNULL(DFO_STAT_AREA_CODE,0)!= 12
GROUP BY FISHING_YEAR, C.FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE
) C
ORDER BY FISHERY_SECTOR, FISHING_YEAR



57 changes: 57 additions & 0 deletions sql/FD5046 all trawl (simple) by calendar year 1996-2024.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
SELECT DATABASE_NAME, CALENDAR_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE,
SUM(LANDED_ROUND_KG) AS LANDED_ROUND_KG,
SUM(TOTAL_RELEASED_ROUND_KG) AS TOTAL_RELEASED_ROUND_KG,
SUM(TOTAL_KG) AS TOTAL_KG
FROM (
SELECT 'PacHarvest' AS DATABASE_NAME,
CALENDAR_YEAR, 'GROUNDFISH TRAWL' AS FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(LANDED, 0) + ISNULL(DISCARDED, 0)) AS TOTAL_KG
FROM (
SELECT D.HAIL_IN_NO, YEAR(D.OFFLOAD_DATE) AS CALENDAR_YEAR, D.SET_NO, D.SPECIES_CODE, 'TRAWL' AS GEAR,
CASE
WHEN GS.GEAR_SUBTYPE_NME = 'STANDARD BOTTOM TRAWL' THEN 'BOTTOM TRAWL'
WHEN GS.GEAR_SUBTYPE_NME = 'UNKNOWN TRAWL' THEN 'UNSPECIFIED'
ELSE GS.GEAR_SUBTYPE_NME END AS GEAR_SUBTYPE,
MAJOR_STAT_AREA,
LANDED, DISCARDED
FROM PacHarvest.dbo.D_Official_Catch D
INNER JOIN PacHarvest.dbo.C_Gear_Subtype GS ON
GS.GEAR_TYPE_CDE = D.GEAR_TYPE_CDE AND GS.GEAR_SUBTYPE_CDE = D.GEAR_SUBTYPE_CDE
WHERE D.SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA,'00') != '01'
AND ISNULL(DFO_MGMT_AREA_CDE,0) != 12
) C
GROUP BY CALENDAR_YEAR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE

UNION ALL

SELECT 'GFFOS' AS DATABASE_NAME,
YEAR(C.BEST_DATE) AS CALENDAR_YEAR, C.FISHERY_SECTOR, C.GEAR, GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(LANDED_ROUND_KG, 0)+ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_KG
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
WHERE FISHERY_SECTOR = 'GROUNDFISH TRAWL' AND
YEAR(C.BEST_DATE) > 2005 AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01'
AND ISNULL(DFO_STAT_AREA_CODE,0) != 12
GROUP BY YEAR(C.BEST_DATE), C.FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE

UNION ALL

SELECT 'GFBio' AS DATABASE_NAME,
YEAR(T.TRIP_START_DATE) AS CALENDAR_YEAR,
'GROUNDFISH TRAWL' AS FISHERY_SECTOR, 'TRAWL' AS GEAR, 'MIDWATER TRAWL' AS GEAR_SUBTYPE,
SPECIES_CODE, 0 AS LANDED_ROUND_KG, 0 AS TOTAL_RELEASED_ROUND_KG, SUM(C.CATCH_WEIGHT) AS TOTAL_KG
FROM GFBioSQL.dbo.TRIP T
INNER JOIN GFBioSQL.dbo.FISHING_EVENT F ON F.TRIP_ID = T.TRIP_ID
INNER JOIN GFBioSQL.dbo.FISHING_EVENT_CATCH FEC ON FEC.FISHING_EVENT_ID = F.FISHING_EVENT_ID
INNER JOIN GFBioSQL.dbo.CATCH C ON C.CATCH_ID = FEC.CATCH_ID
WHERE YEAR(T.TRIP_START_DATE) BETWEEN 1996 AND 2006 AND C.SPECIES_CODE = '044'
AND ISNULL(F.MAJOR_STAT_AREA_CODE,'00') != '01' AND ISNULL(F.DFO_STAT_AREA_CODE,0) != 12
AND T.TRIP_SUB_TYPE_CODE = 5
GROUP BY YEAR(T.TRIP_START_DATE), SPECIES_CODE
)C
GROUP BY DATABASE_NAME, CALENDAR_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE
ORDER BY CALENDAR_YEAR
59 changes: 59 additions & 0 deletions sql/FD5046 all trawl (simple) by fishing year 1996-2024.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
SELECT DATABASE_NAME, FISHING_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE,
SUM(LANDED_ROUND_KG) AS LANDED_ROUND_KG,
SUM(TOTAL_RELEASED_ROUND_KG) AS TOTAL_RELEASED_ROUND_KG,
SUM(TOTAL_KG) AS TOTAL_KG
FROM (
SELECT 'PacHarvest' AS DATABASE_NAME,
FISHING_YEAR, 'GROUNDFISH TRAWL' AS FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(DISCARDED, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(LANDED, 0) + ISNULL(DISCARDED, 0)) AS TOTAL_KG
FROM (
SELECT D.HAIL_IN_NO, YEAR(D.OFFLOAD_DATE) AS CALENDAR_YEAR, D.SET_NO, D.SPECIES_CODE, 'TRAWL' AS GEAR,
CASE
WHEN GS.GEAR_SUBTYPE_NME = 'STANDARD BOTTOM TRAWL' THEN 'BOTTOM TRAWL'
WHEN GS.GEAR_SUBTYPE_NME = 'UNKNOWN TRAWL' THEN 'UNSPECIFIED'
ELSE GS.GEAR_SUBTYPE_NME END AS GEAR_SUBTYPE,
MAJOR_STAT_AREA,
LANDED, DISCARDED
FROM PacHarvest.dbo.D_Official_Catch D
INNER JOIN PacHarvest.dbo.C_Gear_Subtype GS ON
GS.GEAR_TYPE_CDE = D.GEAR_TYPE_CDE AND GS.GEAR_SUBTYPE_CDE = D.GEAR_SUBTYPE_CDE
WHERE D.SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA,'00') != '01'
AND ISNULL(DFO_MGMT_AREA_CDE,0) != 12
) C
INNER JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.HAIL_IN_NO = C.HAIL_IN_NO
GROUP BY FISHING_YEAR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE

UNION ALL

SELECT 'GFFOS' AS DATABASE_NAME,
FISHING_YEAR, C.FISHERY_SECTOR, C.GEAR, GEAR_SUBTYPE, SPECIES_CODE,
SUM(ISNULL(LANDED_ROUND_KG, 0)) AS LANDED_ROUND_KG,
SUM(ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_RELEASED_ROUND_KG,
SUM(ISNULL(LANDED_ROUND_KG, 0)+ISNULL(TOTAL_RELEASED_ROUND_KG, 0)) AS TOTAL_KG
FROM GFFOS.dbo.GF_D_OFFICIAL_FE_CATCH C
LEFT JOIN GFDataReq.dbo.GF_FISHING_YEAR_VW FY ON FY.FOS_TRIP_ID = C.TRIP_ID
WHERE FISHERY_SECTOR = 'GROUNDFISH TRAWL' AND
YEAR(C.BEST_DATE) > 2005 AND SPECIES_CODE = '044' AND ISNULL(MAJOR_STAT_AREA_CODE,'00') != '01'
AND ISNULL(DFO_STAT_AREA_CODE,0) != 12
GROUP BY FISHING_YEAR, C.FISHERY_SECTOR, C.GEAR, C.GEAR_SUBTYPE, SPECIES_CODE

UNION ALL

SELECT 'GFBio' AS DATABASE_NAME,
CAST(YEAR(T.TRIP_START_DATE) AS varchar(4))+'-'+CAST(YEAR(T.TRIP_START_DATE)+1 AS varchar(4))
AS FISHING_YEAR,
'GROUNDFISH TRAWL' AS FISHERY_SECTOR, 'TRAWL' AS GEAR, 'MIDWATER TRAWL' AS GEAR_SUBTYPE,
SPECIES_CODE, 0 AS LANDED_ROUND_KG, 0 AS TOTAL_RELEASED_ROUND_KG, SUM(C.CATCH_WEIGHT) AS TOTAL_KG
FROM GFBioSQL.dbo.TRIP T
INNER JOIN GFBioSQL.dbo.FISHING_EVENT F ON F.TRIP_ID = T.TRIP_ID
INNER JOIN GFBioSQL.dbo.FISHING_EVENT_CATCH FEC ON FEC.FISHING_EVENT_ID = F.FISHING_EVENT_ID
INNER JOIN GFBioSQL.dbo.CATCH C ON C.CATCH_ID = FEC.CATCH_ID
WHERE YEAR(T.TRIP_START_DATE) BETWEEN 1996 AND 2006 AND C.SPECIES_CODE = '044'
AND ISNULL(F.MAJOR_STAT_AREA_CODE,'00') != '01' AND ISNULL(F.DFO_STAT_AREA_CODE,0) != 12
AND T.TRIP_SUB_TYPE_CODE = 5
GROUP BY CAST(YEAR(T.TRIP_START_DATE) AS varchar(4))+'-'+CAST(YEAR(T.TRIP_START_DATE)+1 AS varchar(4)), SPECIES_CODE
)C
GROUP BY DATABASE_NAME, FISHING_YEAR, FISHERY_SECTOR, GEAR, GEAR_SUBTYPE
ORDER BY FISHING_YEAR
Loading

0 comments on commit 3e0e1f7

Please sign in to comment.