-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Further working on the SQL to load raster data (#12)
- Loading branch information
Showing
10 changed files
with
135 additions
and
94 deletions.
There are no files selected for viewing
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,23 @@ | ||
from postgis import connect | ||
|
||
""" | ||
Either create the view, or if the view exists, either | ||
refresh the view if it's a new model value, or do nothing. | ||
I couldn't figure out how to parametize the model string value | ||
using the psycog2 module. So instead I'm just checking that the | ||
value exists as a string in the models table. This should be safe | ||
""" | ||
def create_view(model): | ||
cursor = connect().cursor() | ||
cursor.execute(""" | ||
select 1 where exists ( select * from public.models where name = %s ) | ||
""", (model, )) | ||
exists = not len(cursor.fetchall()) == 0 | ||
|
||
if not exists: | ||
raise Exception('Cannot refresh coordinates for a model that doesn\'t exist') | ||
|
||
with open('cli/load/coordinates/coordinates.sql', 'r') as file: | ||
sql = file.read().replace('%s', "'" + model + "'") # TODO!!! escape properly | ||
cursor = connect().cursor() | ||
cursor.execute(sql) |
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,65 @@ | ||
do $$ | ||
begin | ||
if exists ( | ||
select | ||
1 | ||
from | ||
pg_matviews | ||
where | ||
matviewname = 'coordinates') then | ||
if not exists ( | ||
select | ||
1 | ||
from | ||
coordinates c | ||
join models m on m.id = c.modelid | ||
where | ||
m.name = %s) then | ||
refresh materialized view coordinates; | ||
end if; | ||
else | ||
create materialized view coordinates as | ||
with lon as ( | ||
select | ||
modelid, | ||
geom pixel, | ||
val longitude | ||
from ( select distinct | ||
m.id modelid, | ||
(ST_PixelAsCentroids (rast, 1)).* | ||
from | ||
rasters r | ||
join raster_xref_model rxm on rxm.rasterid = r.rid | ||
join models m on m.id = rxm.modelid | ||
where | ||
filename like '%lon_rho') lon | ||
), | ||
lat as ( | ||
select | ||
modelid, | ||
geom pixel, | ||
val latitude | ||
from ( select distinct | ||
m.id modelid, | ||
(ST_PixelAsCentroids (rast, 1)).* | ||
from | ||
rasters r | ||
left join raster_xref_model rxm on rxm.rasterid = r.rid | ||
left join models m on m.id = rxm.modelid | ||
where | ||
filename like '%lat_rho') lat | ||
) | ||
select | ||
lon.modelid, | ||
lon.pixel, | ||
lon.longitude, | ||
lat.latitude, | ||
st_point (lon.longitude, lat.latitude, 4326) coord | ||
from | ||
lon | ||
join lat on lat.pixel = lon.pixel | ||
and lat.modelid = lon.modelid; | ||
end if; | ||
end | ||
$$; | ||
|
This file was deleted.
Oops, something went wrong.
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,9 @@ | ||
from postgis import connect | ||
|
||
|
||
# Setup view that summarizes models | ||
def create_view(model): | ||
with open('cli/load/metadata/metadata.sql', 'r') as file: | ||
sql = file.read() | ||
cursor = connect().cursor() | ||
cursor.execute(sql) |
File renamed without changes.
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
24 changes: 24 additions & 0 deletions
24
toolkit/cli/load/raster2pgsql/update-raster_xref_model.sql
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,24 @@ | ||
; | ||
|
||
with ref as ( | ||
select | ||
%s filename, | ||
%s model | ||
) | ||
|
||
insert into raster_xref_model (rasterid, modelid) | ||
select | ||
r.rid rasterid, | ||
m.id modelid | ||
from | ||
ref | ||
left join rasters r on r.filename = ref.filename | ||
left join models m on m.name = ref.model | ||
|
||
where not exists ( | ||
select 1 | ||
from raster_xref_model x | ||
where x.rasterid = r.rid and x.modelid = m.id | ||
); | ||
|
||
|
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