Project

General

Profile

« Previous | Next » 

Revision 11166

schemas/vegbien.sql: added plot.** subset view of analytical_stem_view, used for VegBank validation

View differences:

schemas/vegbien.my.sql
2750 2750

  
2751 2751

  
2752 2752
--
2753
-- Name: plot.**; Type: VIEW; Schema: public; Owner: -
2754
--
2755

  
2756

  
2757

  
2758

  
2759
--
2753 2760
-- Name: project_project_id_seq; Type: SEQUENCE; Schema: public; Owner: -
2754 2761
--
2755 2762

  
......
7859 7866

  
7860 7867

  
7861 7868
--
7869
-- Name: plot.**; Type: ACL; Schema: public; Owner: -
7870
--
7871

  
7872

  
7873

  
7874

  
7875

  
7876

  
7877

  
7878
--
7862 7879
-- Name: projectcontributor; Type: ACL; Schema: public; Owner: -
7863 7880
--
7864 7881

  
schemas/vegbien.sql
3933 3933

  
3934 3934

  
3935 3935
--
3936
-- Name: plot.**; Type: VIEW; Schema: public; Owner: -
3937
--
3938

  
3939
CREATE VIEW "plot.**" AS
3940
    SELECT source.shortname AS datasource, canon_place.country, canon_place.stateprovince AS "stateProvince", datasource_place.county, location.locationnarrative AS locality, CASE WHEN (coordinates.latitude_deg IS NOT NULL) THEN coordinates.latitude_deg ELSE county_centroids.latitude END AS "decimalLatitude", CASE WHEN (coordinates.latitude_deg IS NOT NULL) THEN coordinates.longitude_deg ELSE county_centroids.longitude END AS "decimalLongitude", CASE WHEN (coordinates.latitude_deg IS NOT NULL) THEN coordinates.coordsaccuracy_m ELSE _km_to_m(county_centroids.error_km) END AS "coordinateUncertaintyInMeters", CASE WHEN (coordinates.latitude_deg IS NOT NULL) THEN 'source data'::coordinatesource WHEN (county_centroids.row_num IS NOT NULL) THEN 'georeferencing'::coordinatesource ELSE NULL::coordinatesource END AS "coordinateSource_bien", CASE WHEN (coordinates.latitude_deg IS NOT NULL) THEN NULL::text WHEN (county_centroids.row_num IS NOT NULL) THEN 'county centroid'::text ELSE NULL::text END AS "georeferenceProtocol_bien", (canon_place.geovalid)::integer AS geovalid_bien, ("newWorldCountries"."isNewWorld")::integer AS "isNewWorld_bien", COALESCE(project.sourceaccessioncode, project.projectname) AS "projectID", COALESCE(location.sourceaccessioncode, NULLIF(pg_catalog.concat_ws('; '::text, COALESCE(parent_location.sourceaccessioncode, parent_location.authorlocationcode), location.authorlocationcode), ''::text)) AS "locationID", COALESCE(parent_location.authorlocationcode, location.authorlocationcode) AS "locationName", CASE WHEN (parent_location.location_id IS NOT NULL) THEN location.authorlocationcode ELSE NULL::text END AS subplot, COALESCE(location.elevation_m, parent_location.elevation_m) AS "elevationInMeters", _m2_to_ha(COALESCE(location.area_m2, parent_location.area_m2)) AS "plotArea_ha", method.name AS "samplingProtocol", COALESCE(locationevent.temperature_c, parent_event.temperature_c) AS "temperature_C", COALESCE(locationevent.precipitation_m, parent_event.precipitation_m) AS precipitation_m, stratum.stratumname AS stratum__name, COALESCE(locationevent__communities__array(locationevent.locationevent_id), locationevent__communities__array(parent_event.locationevent_id)) AS communities, COALESCE(locationevent__contributors__array(locationevent.locationevent_id), locationevent__contributors__array(parent_event.locationevent_id)) AS plot__collectors FROM ((((((((((((((source JOIN location USING (source_id)) LEFT JOIN locationevent USING (location_id)) LEFT JOIN location parent_location ON ((parent_location.location_id = location.parent_id))) LEFT JOIN locationplace ON ((locationplace.location_id = COALESCE(parent_location.location_id, location.location_id)))) LEFT JOIN place datasource_place USING (place_id)) LEFT JOIN place canon_place ON ((canon_place.place_id = datasource_place.canon_place_id))) LEFT JOIN coordinates ON ((coordinates.coordinates_id = canon_place.coordinates_id))) LEFT JOIN "newWorld".iso_code_gadm ON ((iso_code_gadm."*GADM country" = canon_place.country))) LEFT JOIN "newWorld"."newWorldCountries" ON (("newWorldCountries"."*isoCode" = iso_code_gadm."*2-digit iso code"))) LEFT JOIN geoscrub.county_centroids ON ((((canon_place.country = 'United States'::text) AND (county_centroids.state = canon_place.stateprovince)) AND (county_centroids.county = canon_place.county)))) LEFT JOIN locationevent parent_event ON ((parent_event.locationevent_id = locationevent.parent_id))) LEFT JOIN project ON ((project.project_id = COALESCE(locationevent.project_id, parent_event.project_id)))) LEFT JOIN stratum ON ((stratum.stratum_id = COALESCE(locationevent.stratum_id, parent_event.stratum_id)))) LEFT JOIN method ON ((method.method_id = COALESCE(locationevent.method_id, parent_event.method_id)))) ORDER BY source.shortname;
3941

  
3942

  
3943
--
3936 3944
-- Name: project_project_id_seq; Type: SEQUENCE; Schema: public; Owner: -
3937 3945
--
3938 3946

  
......
9227 9235

  
9228 9236

  
9229 9237
--
9238
-- Name: plot.**; Type: ACL; Schema: public; Owner: -
9239
--
9240

  
9241
REVOKE ALL ON TABLE "plot.**" FROM PUBLIC;
9242
REVOKE ALL ON TABLE "plot.**" FROM bien;
9243
GRANT ALL ON TABLE "plot.**" TO bien;
9244
GRANT SELECT ON TABLE "plot.**" TO bien_read;
9245

  
9246

  
9247
--
9230 9248
-- Name: projectcontributor; Type: ACL; Schema: public; Owner: -
9231 9249
--
9232 9250

  

Also available in: Unified diff