Skip to content

Commit

Permalink
Merge pull request #49 from bcgov/WBCAMS-867
Browse files Browse the repository at this point in the history
Update NOC, NOCOccupationGroups and Job Openings tables with LMO 2025 data.
  • Loading branch information
sunanditasahu authored Jan 30, 2025
2 parents 605f080 + 39442ef commit f078945
Show file tree
Hide file tree
Showing 3 changed files with 184 additions and 0 deletions.
77 changes: 77 additions & 0 deletions SSOT/18-UpdateJobOpeningFromLMO2025.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
--Drop the foreign keys and primary keys on Id column in JobOpening table.
ALTER TABLE JobOpening
DROP CONSTRAINT FK_JobOpening_NOC;

--Delete the existing data in Job Openings table.
delete from JobOpening

--Insert the new LMO data in Job Openings table.
--Load file contents into a temp table
Declare @JSON varchar(max)
SELECT @JSON=BulkColumn
FROM OPENROWSET (BULK 'C:\src_cst_new\SSOT\ssot_career_search_openings.json', SINGLE_CLOB) import
SELECT * Into #TempGroups
FROM OPENJSON (@JSON)
WITH
(
[noc_2021] varchar(10),
[job_openings] varchar(255),
[region] varchar(255),
[industry_agg] varchar(255),
[industry_sub] varchar(255)
)

Alter table #TempGroups
Add NOCCodeId varchar(10);

Alter table #TempGroups
Add GeoAreaId int;

Alter table #TempGroups
Add IndustryId int;

Alter table #TempGroups
Add SubIndustryId int;

--Update the region to align with the code.
Update #TempGroups
SET region = 'All'
where region = 'British Columbia'

Update #TempGroups
Set NOCCodeId = n.Id
From #TempGroups t JOIN NOC n
ON t.noc_2021 = n.NOCCode

Update #TempGroups
Set GeoAreaId = g.Id
From #TempGroups t JOIN GeographicArea g
ON t.region = g.Value

Update #TempGroups
Set IndustryId = i.Id
From #TempGroups t JOIN Industry i
ON t.industry_agg = i.Value

Update #TempGroups
Set SubIndustryId = s.Id
From #TempGroups t JOIN SubIndustry s
ON t.industry_sub = s.Value

--Resetting table's id column
DBCC CHECKIDENT ('dbo.JobOpening', RESEED, 0);

--Insert data into JobOpening table from temp table.
INSERT INTO JobOpening(NOCId, GeographicAreaId, JobOpenings, IndustryId, SubIndustryId)
Select NOCCodeId, GeoAreaId, job_openings, IndustryId, SubIndustryId from #TempGroups;

--Delete temp table
Drop table #TempGroups

--Add the constraint back
ALTER TABLE [dbo].[JobOpening] WITH CHECK ADD CONSTRAINT [FK_JobOpening_NOC] FOREIGN KEY([NOCId])
REFERENCES [dbo].[NOC] ([Id])
GO

--Check results
Select * from JobOpening
41 changes: 41 additions & 0 deletions SSOT/19-UpdateNOCWithNewIncomeFromLMO2025.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
--Load file contents into a temp table
Declare @JSON varchar(max)
SELECT @JSON=BulkColumn
FROM OPENROWSET (BULK 'C:\src_cst_new\SSOT\ssot_career_search_openings.json', SINGLE_CLOB) import
SELECT * Into #TempSalary
FROM OPENJSON (@JSON)
WITH
(
[noc_2021] varchar(10),
[calculated_median_annual_salary] varchar(255),
[part_full_time] varchar(255)
)

--Add a column to parse the FullOrPartTimeId int value from the varchar data.
ALTER TABLE #TempSalary ADD part_full_time_id int

--Update #TempSalary with part_full_time as per the data in the dbo. [FullOrPartTime] Id column values.
Update #TempSalary
Set part_full_time_id = case
when #TempSalary.part_full_time = 'Higher chance of part-time' then (Select Id from FullOrPartTime where Value = 'Higher chance of part-time')
when #TempSalary.part_full_time = 'Higher chance of full-time' then (Select Id from FullOrPartTime where Value = 'Higher chance of full-time')
else null
End

--Update #TempSalary with income as int
Update #TempSalary SET calculated_median_annual_salary = CAST((ROUND(CAST (calculated_median_annual_salary AS NUMERIC(20,4)),0)) AS INT)
From #TempSalary

--Update new income and FullOrPartTimeId in NOC table from temp table
Update NOC SET MedianSalary = #TempSalary.calculated_median_annual_salary, FullOrPartTimeId =#TempSalary.part_full_time_id
FROM #TempSalary WHERE NOC.NOCCode = #TempSalary.noc_2021

--Update the null median salary to zero
Update NOC SET MedianSalary = 0
where MedianSalary is null

--Drop temp table
Drop table #TempSalary

--Check results
Select * from NOC
66 changes: 66 additions & 0 deletions SSOT/20-UpdateNOCOccupationGroupFromLMO2025.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
--Drop the foreign keys and primary keys on Id column in NOCOccupationGroup table.
ALTER TABLE NOCOccupationGroup
DROP CONSTRAINT FK_NOCOccupationGroup_NOC;

--Delete the existing data in NOCOccupationGroup table.
delete from NOCOccupationGroup

--Insert the new LMO data in NOCOccupationGroup table.
--Load file contents into a temp table
Declare @JSON varchar(max)
SELECT @JSON=BulkColumn
FROM OPENROWSET (BULK 'C:\src_cst\SSOT\ssot_career_search_groups.json', SINGLE_CLOB) import
SELECT * Into #TempGroups
FROM OPENJSON (@JSON)
WITH
(
[noc] varchar(10),
[occupational_category] varchar(255),
[region] varchar(255)
)

Update #TempGroups
SET region = 'All'
where region = 'British Columbia'

Alter table #TempGroups
Add NOCCodeId varchar(10);

Alter table #TempGroups
Add OccGroupId int;

Alter table #TempGroups
Add OccRegId int;

Update #TempGroups
Set NOCCodeId = n.Id
From #TempGroups t JOIN NOC n
ON t.noc = n.NOCCode

Update #TempGroups
Set OccGroupId = g.Id
From #TempGroups t JOIN OccupationGroup g
ON t.occupational_category = g.Value

Update #TempGroups
Set OccRegId = g.Id
From #TempGroups t JOIN GeographicArea g
ON t.region = g.Value

--Resetting table's id column
DBCC CHECKIDENT ('dbo.NOCOccupationGroup', RESEED, 0);

--Insert data into NOCOccupationGroup table from temp table.
INSERT INTO NOCOccupationGroup(NOCId, OccupationalGroupId, GeographicAreaId)
Select NOCCodeId, OccGroupId, OccRegId from #TempGroups;

--Delete temp table
Drop table #TempGroups

--Add the constraint back
ALTER TABLE [dbo].[NOCOccupationGroup] WITH CHECK ADD CONSTRAINT [FK_NOCOccupationGroup_NOC] FOREIGN KEY([NOCId])
REFERENCES [dbo].[NOC] ([Id])
GO

--Check results
Select * from NOCOccupationGroup

0 comments on commit f078945

Please sign in to comment.