From 8bfa9f5dc76d05d8e0390187d6a1f04a354a0b3e Mon Sep 17 00:00:00 2001 From: Your Name Date: Sun, 12 Jul 2020 16:08:49 +0000 Subject: [PATCH] sql --- lib/sql/.gitignore | 9 + lib/sql/.travis.yml | 38 + lib/sql/CONTRIBUTING.md | 73 + lib/sql/LICENSE | 27 + lib/sql/Makefile | 186 ++ lib/sql/NEWS.md | 469 ++++ lib/sql/README.md | 96 + lib/sql/carto-package.json | 11 + lib/sql/cartodb.control.in | 6 + lib/sql/cartodb_version.sql.in | 7 + lib/sql/doc/CDB_ColumnNames.md | 14 + lib/sql/doc/CDB_ColumnType.md | 15 + lib/sql/doc/CDB_EstimateRowCount.md | 25 + lib/sql/doc/CDB_GreatCircle.md | 16 + lib/sql/doc/CDB_HeadsTailsBins.md | 21 + lib/sql/doc/CDB_HexagonGrid.md | 43 + lib/sql/doc/CDB_JenksBins.md | 23 + lib/sql/doc/CDB_MakeHexagon.md | 21 + lib/sql/doc/CDB_Overviews.md | 123 + lib/sql/doc/CDB_QuantileBins.md | 21 + lib/sql/doc/CDB_RectangleGrid.md | 46 + lib/sql/doc/CDB_SetUserQuotaInBytes.md | 11 + lib/sql/doc/CDB_SyncTable.md | 56 + lib/sql/doc/CDB_TransformToWebmercator.md | 44 + lib/sql/doc/CDB_UserTables.md | 15 + lib/sql/doc/CDB_XYZ_Extent.md | 22 + lib/sql/doc/CDB_XYZ_Resolution.md | 20 + lib/sql/doc/CartoDB-PLpgSQL.md | 38 + lib/sql/doc/CartoDB-user-table.rst | 68 + lib/sql/doc/README.md | 23 + lib/sql/doc/cartodbfy-requirements.rst | 63 + lib/sql/expected/test_setup.out | 9 + .../scripts-available/CDB_AnalysisCatalog.sql | 95 + .../scripts-available/CDB_AnalysisCheck.sql | 62 + .../scripts-available/CDB_AnalysisSupport.sql | 55 + .../scripts-available/CDB_CartodbfyTable.sql | 1319 ++++++++++ lib/sql/scripts-available/CDB_ColumnNames.sql | 16 + lib/sql/scripts-available/CDB_ColumnType.sql | 16 + lib/sql/scripts-available/CDB_Conf.sql | 48 + lib/sql/scripts-available/CDB_DDLTriggers.sql | 14 + .../scripts-available/CDB_DateToNumber.sql | 31 + .../scripts-available/CDB_DigitSeparator.sql | 53 + lib/sql/scripts-available/CDB_DistType.sql | 122 + .../scripts-available/CDB_DistinctMeasure.sql | 46 + .../CDB_EqualIntervalBins.sql | 24 + .../CDB_EstimateRowCount.sql | 31 + .../scripts-available/CDB_ExtensionPost.sql | 2 + .../scripts-available/CDB_ExtensionUtils.sql | 20 + .../scripts-available/CDB_ForeignTable.sql | 206 ++ lib/sql/scripts-available/CDB_GhostTables.sql | 123 + lib/sql/scripts-available/CDB_GreatCircle.sql | 26 + lib/sql/scripts-available/CDB_Groups.sql | 252 ++ lib/sql/scripts-available/CDB_Groups_API.sql | 195 ++ .../scripts-available/CDB_HeadsTailsBins.sql | 46 + lib/sql/scripts-available/CDB_Helper.sql | 177 ++ lib/sql/scripts-available/CDB_Hexagon.sql | 148 ++ lib/sql/scripts-available/CDB_JenksBins.sql | 346 +++ lib/sql/scripts-available/CDB_LatLng.sql | 17 + lib/sql/scripts-available/CDB_Math.sql | 27 + .../scripts-available/CDB_Organizations.sql | 171 ++ lib/sql/scripts-available/CDB_Overviews.sql | 1070 ++++++++ .../CDB_OverviewsSupport.sql | 173 ++ .../scripts-available/CDB_QuantileBins.sql | 18 + .../scripts-available/CDB_QueryStatements.sql | 14 + lib/sql/scripts-available/CDB_QueryTables.sql | 75 + lib/sql/scripts-available/CDB_Quota.sql | 155 ++ lib/sql/scripts-available/CDB_RandomTids.sql | 69 + .../scripts-available/CDB_RectangleGrid.sql | 108 + lib/sql/scripts-available/CDB_SearchPath.sql | 24 + lib/sql/scripts-available/CDB_Stats.sql | 53 + .../scripts-available/CDB_StringToDate.sql | 20 + lib/sql/scripts-available/CDB_SyncTable.sql | 167 ++ .../scripts-available/CDB_TableIndexes.sql | 27 + .../scripts-available/CDB_TableMetadata.sql | 146 ++ .../CDB_TransformToWebmercator.sql | 82 + lib/sql/scripts-available/CDB_UserTables.sql | 28 + lib/sql/scripts-available/CDB_Username.sql | 6 + lib/sql/scripts-available/CDB_XYZ.sql | 62 + .../scripts-available/CDB_ZoomFromScale.sql | 36 + .../scripts-enabled/000-CDB_DateToNumber.sql | 1 + .../010-CDB_DigitSeparator.sql | 1 + .../020-CDB_HeadsTailsBins.sql | 1 + lib/sql/scripts-enabled/030-CDB_Hexagon.sql | 1 + lib/sql/scripts-enabled/040-CDB_JenksBins.sql | 1 + lib/sql/scripts-enabled/050-CDB_LatLng.sql | 1 + .../scripts-enabled/060-CDB_QuantileBins.sql | 1 + .../070-CDB_QueryStatements.sql | 1 + .../scripts-enabled/080-CDB_QueryTables.sql | 1 + .../085-CDB_OverviewsSupport.sql | 1 + lib/sql/scripts-enabled/090-CDB_Quota.sql | 1 + .../scripts-enabled/100-CDB_RandomTids.sql | 1 + .../scripts-enabled/110-CDB_RectangleGrid.sql | 1 + .../scripts-enabled/120-CDB_StringToDate.sql | 1 + .../scripts-enabled/130-CDB_TableMetadata.sql | 1 + .../140-CDB_TransformToWebmercator.sql | 1 + .../scripts-enabled/150-CDB_UserTables.sql | 1 + lib/sql/scripts-enabled/160-CDB_XYZ.sql | 1 + .../scripts-enabled/170-CDB_ColumnNames.sql | 1 + .../scripts-enabled/180-CDB_ColumnType.sql | 1 + .../190-CDB_CartodbfyTable.sql | 1 + .../scripts-enabled/200-CDB_TableIndexes.sql | 1 + .../scripts-enabled/210-CDB_Organizations.sql | 1 + lib/sql/scripts-enabled/220-CDB_Math.sql | 1 + .../scripts-enabled/230-CDB_ZoomFromScale.sql | 1 + .../240-CDB_EqualIntervalBins.sql | 1 + .../scripts-enabled/241-CDB_GreatCircle.sql | 1 + lib/sql/scripts-enabled/245-CDB_Overviews.sql | 1 + .../scripts-enabled/250-CDB_ForeignTable.sql | 1 + .../260-CDB_AnalysisCatalog.sql | 1 + .../270-CDB_AnalysisSupport.sql | 1 + .../scripts-enabled/275-CDB_AnalysisCheck.sql | 1 + .../280-CDB_EstimateRowCount.sql | 1 + .../scripts-enabled/290-CDB_GhostTables.sql | 1 + .../scripts-enabled/900-CDB_DDLTriggers.sql | 1 + lib/sql/scripts-enabled/910-CDB_Conf.sql | 1 + lib/sql/scripts-enabled/920-CDB_Username.sql | 1 + lib/sql/scripts-enabled/CDB_DistType.sql | 1 + .../scripts-enabled/CDB_DistinctMeasure.sql | 1 + lib/sql/scripts-enabled/CDB_Groups.sql | 1 + lib/sql/scripts-enabled/CDB_Groups_API.sql | 1 + lib/sql/scripts-enabled/CDB_Stats.sql | 1 + lib/sql/scripts-enabled/CDB_SyncTable.sql | 1 + lib/sql/sql/test_setup.sql | 9 + lib/sql/test/CDB_AnalysisCheckTest.sql | 20 + lib/sql/test/CDB_AnalysisCheckTest_expect | 18 + lib/sql/test/CDB_CartodbfyTableTest.sql | 396 +++ lib/sql/test/CDB_CartodbfyTableTest_expect | 157 ++ lib/sql/test/CDB_DateToNumberTest.sql | 2 + lib/sql/test/CDB_DateToNumberTest_expect | 2 + lib/sql/test/CDB_DigitSeparatorTest.sql | 39 + lib/sql/test/CDB_DigitSeparatorTest_expect | 14 + lib/sql/test/CDB_DistTypeTest.sql | 4 + lib/sql/test/CDB_DistTypeTest_expect | 1 + lib/sql/test/CDB_DistinctMeasureTest.sql | 20 + lib/sql/test/CDB_DistinctMeasureTest_expect | 1 + lib/sql/test/CDB_EqualIntervalBinsTest.sql | 11 + lib/sql/test/CDB_EqualIntervalBinsTest_expect | 14 + lib/sql/test/CDB_EstimateRowCountTest.sql | 10 + lib/sql/test/CDB_EstimateRowCountTest_expect | 9 + lib/sql/test/CDB_GhostTables.sql | 52 + lib/sql/test/CDB_GhostTables_expect | 20 + lib/sql/test/CDB_GreatCircle.sql | 2 + lib/sql/test/CDB_GreatCircle_expect | 2 + lib/sql/test/CDB_HeadsTailsBinsTest.sql | 11 + lib/sql/test/CDB_HeadsTailsBinsTest_expect | 13 + lib/sql/test/CDB_HelperTest.sql | 138 + lib/sql/test/CDB_HelperTest_expect | 67 + lib/sql/test/CDB_HexagonTest.sql | 56 + lib/sql/test/CDB_HexagonTest_expect | 5 + lib/sql/test/CDB_JenksBinsTest.sql | 36 + lib/sql/test/CDB_JenksBinsTest_expect | 18 + lib/sql/test/CDB_MathTest.sql | 4 + lib/sql/test/CDB_MathTest_expect | 3 + lib/sql/test/CDB_OverviewsTest.sql | 44 + lib/sql/test/CDB_OverviewsTest_expect | 49 + lib/sql/test/CDB_QuantileBinsTest.sql | 17 + lib/sql/test/CDB_QuantileBinsTest_expect | 20 + lib/sql/test/CDB_QueryStatementsTest.sql | 66 + lib/sql/test/CDB_QueryStatementsTest_expect | 20 + lib/sql/test/CDB_QueryTablesTest.sql | 41 + lib/sql/test/CDB_QueryTablesTest_expect | 20 + lib/sql/test/CDB_QuotaTest.sql | 47 + lib/sql/test/CDB_QuotaTest_expect | 32 + lib/sql/test/CDB_RectangleTest.sql | 8 + lib/sql/test/CDB_RectangleTest_expect | 3 + lib/sql/test/CDB_StatsTest.sql | 13 + lib/sql/test/CDB_StatsTest_expect | 3 + lib/sql/test/CDB_SyncTableTest.sql | 94 + lib/sql/test/CDB_SyncTableTest_expect | 94 + .../test/CDB_TransformToWebmercatorTest.sql | 28 + .../CDB_TransformToWebmercatorTest_expect | 13 + lib/sql/test/CDB_UserTablesTest.sql | 32 + lib/sql/test/CDB_UserTablesTest_expect | 19 + lib/sql/test/CDB_Username.sql | 23 + lib/sql/test/CDB_Username_expect | 4 + lib/sql/test/CDB_XYZ_ExtentTest.sql | 9 + lib/sql/test/CDB_XYZ_ExtentTest_expect | 21 + lib/sql/test/Makefile | 5 + lib/sql/test/README | 15 + lib/sql/test/extension/test.sh | 615 +++++ lib/sql/test/organization/test.sh | 631 +++++ lib/sql/test/overviews/fixtures.sql | 2249 +++++++++++++++++ lib/sql/test/overviews/gen_points.rb | 43 + lib/sql/test/perf/CDB_HexagonGridPerf.sql | 6 + .../perf/CDB_TransformToWebmercatorPerf.sql | 16 + lib/sql/util/create_from_unpackaged.sh | 77 + lib/sql/util/create_upgrade.sh | 9 + 187 files changed, 13263 insertions(+) create mode 100644 lib/sql/.gitignore create mode 100644 lib/sql/.travis.yml create mode 100644 lib/sql/CONTRIBUTING.md create mode 100644 lib/sql/LICENSE create mode 100644 lib/sql/Makefile create mode 100644 lib/sql/NEWS.md create mode 100644 lib/sql/README.md create mode 100644 lib/sql/carto-package.json create mode 100644 lib/sql/cartodb.control.in create mode 100644 lib/sql/cartodb_version.sql.in create mode 100644 lib/sql/doc/CDB_ColumnNames.md create mode 100644 lib/sql/doc/CDB_ColumnType.md create mode 100644 lib/sql/doc/CDB_EstimateRowCount.md create mode 100644 lib/sql/doc/CDB_GreatCircle.md create mode 100644 lib/sql/doc/CDB_HeadsTailsBins.md create mode 100644 lib/sql/doc/CDB_HexagonGrid.md create mode 100644 lib/sql/doc/CDB_JenksBins.md create mode 100644 lib/sql/doc/CDB_MakeHexagon.md create mode 100644 lib/sql/doc/CDB_Overviews.md create mode 100644 lib/sql/doc/CDB_QuantileBins.md create mode 100644 lib/sql/doc/CDB_RectangleGrid.md create mode 100644 lib/sql/doc/CDB_SetUserQuotaInBytes.md create mode 100644 lib/sql/doc/CDB_SyncTable.md create mode 100644 lib/sql/doc/CDB_TransformToWebmercator.md create mode 100644 lib/sql/doc/CDB_UserTables.md create mode 100644 lib/sql/doc/CDB_XYZ_Extent.md create mode 100644 lib/sql/doc/CDB_XYZ_Resolution.md create mode 100644 lib/sql/doc/CartoDB-PLpgSQL.md create mode 100644 lib/sql/doc/CartoDB-user-table.rst create mode 100644 lib/sql/doc/README.md create mode 100644 lib/sql/doc/cartodbfy-requirements.rst create mode 100644 lib/sql/expected/test_setup.out create mode 100644 lib/sql/scripts-available/CDB_AnalysisCatalog.sql create mode 100644 lib/sql/scripts-available/CDB_AnalysisCheck.sql create mode 100644 lib/sql/scripts-available/CDB_AnalysisSupport.sql create mode 100644 lib/sql/scripts-available/CDB_CartodbfyTable.sql create mode 100644 lib/sql/scripts-available/CDB_ColumnNames.sql create mode 100644 lib/sql/scripts-available/CDB_ColumnType.sql create mode 100644 lib/sql/scripts-available/CDB_Conf.sql create mode 100644 lib/sql/scripts-available/CDB_DDLTriggers.sql create mode 100644 lib/sql/scripts-available/CDB_DateToNumber.sql create mode 100644 lib/sql/scripts-available/CDB_DigitSeparator.sql create mode 100644 lib/sql/scripts-available/CDB_DistType.sql create mode 100644 lib/sql/scripts-available/CDB_DistinctMeasure.sql create mode 100644 lib/sql/scripts-available/CDB_EqualIntervalBins.sql create mode 100644 lib/sql/scripts-available/CDB_EstimateRowCount.sql create mode 100644 lib/sql/scripts-available/CDB_ExtensionPost.sql create mode 100644 lib/sql/scripts-available/CDB_ExtensionUtils.sql create mode 100644 lib/sql/scripts-available/CDB_ForeignTable.sql create mode 100644 lib/sql/scripts-available/CDB_GhostTables.sql create mode 100644 lib/sql/scripts-available/CDB_GreatCircle.sql create mode 100644 lib/sql/scripts-available/CDB_Groups.sql create mode 100644 lib/sql/scripts-available/CDB_Groups_API.sql create mode 100644 lib/sql/scripts-available/CDB_HeadsTailsBins.sql create mode 100644 lib/sql/scripts-available/CDB_Helper.sql create mode 100644 lib/sql/scripts-available/CDB_Hexagon.sql create mode 100644 lib/sql/scripts-available/CDB_JenksBins.sql create mode 100644 lib/sql/scripts-available/CDB_LatLng.sql create mode 100644 lib/sql/scripts-available/CDB_Math.sql create mode 100644 lib/sql/scripts-available/CDB_Organizations.sql create mode 100644 lib/sql/scripts-available/CDB_Overviews.sql create mode 100644 lib/sql/scripts-available/CDB_OverviewsSupport.sql create mode 100644 lib/sql/scripts-available/CDB_QuantileBins.sql create mode 100644 lib/sql/scripts-available/CDB_QueryStatements.sql create mode 100644 lib/sql/scripts-available/CDB_QueryTables.sql create mode 100644 lib/sql/scripts-available/CDB_Quota.sql create mode 100644 lib/sql/scripts-available/CDB_RandomTids.sql create mode 100644 lib/sql/scripts-available/CDB_RectangleGrid.sql create mode 100644 lib/sql/scripts-available/CDB_SearchPath.sql create mode 100644 lib/sql/scripts-available/CDB_Stats.sql create mode 100644 lib/sql/scripts-available/CDB_StringToDate.sql create mode 100644 lib/sql/scripts-available/CDB_SyncTable.sql create mode 100644 lib/sql/scripts-available/CDB_TableIndexes.sql create mode 100644 lib/sql/scripts-available/CDB_TableMetadata.sql create mode 100644 lib/sql/scripts-available/CDB_TransformToWebmercator.sql create mode 100644 lib/sql/scripts-available/CDB_UserTables.sql create mode 100644 lib/sql/scripts-available/CDB_Username.sql create mode 100644 lib/sql/scripts-available/CDB_XYZ.sql create mode 100644 lib/sql/scripts-available/CDB_ZoomFromScale.sql create mode 120000 lib/sql/scripts-enabled/000-CDB_DateToNumber.sql create mode 120000 lib/sql/scripts-enabled/010-CDB_DigitSeparator.sql create mode 120000 lib/sql/scripts-enabled/020-CDB_HeadsTailsBins.sql create mode 120000 lib/sql/scripts-enabled/030-CDB_Hexagon.sql create mode 120000 lib/sql/scripts-enabled/040-CDB_JenksBins.sql create mode 120000 lib/sql/scripts-enabled/050-CDB_LatLng.sql create mode 120000 lib/sql/scripts-enabled/060-CDB_QuantileBins.sql create mode 120000 lib/sql/scripts-enabled/070-CDB_QueryStatements.sql create mode 120000 lib/sql/scripts-enabled/080-CDB_QueryTables.sql create mode 120000 lib/sql/scripts-enabled/085-CDB_OverviewsSupport.sql create mode 120000 lib/sql/scripts-enabled/090-CDB_Quota.sql create mode 120000 lib/sql/scripts-enabled/100-CDB_RandomTids.sql create mode 120000 lib/sql/scripts-enabled/110-CDB_RectangleGrid.sql create mode 120000 lib/sql/scripts-enabled/120-CDB_StringToDate.sql create mode 120000 lib/sql/scripts-enabled/130-CDB_TableMetadata.sql create mode 120000 lib/sql/scripts-enabled/140-CDB_TransformToWebmercator.sql create mode 120000 lib/sql/scripts-enabled/150-CDB_UserTables.sql create mode 120000 lib/sql/scripts-enabled/160-CDB_XYZ.sql create mode 120000 lib/sql/scripts-enabled/170-CDB_ColumnNames.sql create mode 120000 lib/sql/scripts-enabled/180-CDB_ColumnType.sql create mode 120000 lib/sql/scripts-enabled/190-CDB_CartodbfyTable.sql create mode 120000 lib/sql/scripts-enabled/200-CDB_TableIndexes.sql create mode 120000 lib/sql/scripts-enabled/210-CDB_Organizations.sql create mode 120000 lib/sql/scripts-enabled/220-CDB_Math.sql create mode 120000 lib/sql/scripts-enabled/230-CDB_ZoomFromScale.sql create mode 120000 lib/sql/scripts-enabled/240-CDB_EqualIntervalBins.sql create mode 120000 lib/sql/scripts-enabled/241-CDB_GreatCircle.sql create mode 120000 lib/sql/scripts-enabled/245-CDB_Overviews.sql create mode 120000 lib/sql/scripts-enabled/250-CDB_ForeignTable.sql create mode 120000 lib/sql/scripts-enabled/260-CDB_AnalysisCatalog.sql create mode 120000 lib/sql/scripts-enabled/270-CDB_AnalysisSupport.sql create mode 120000 lib/sql/scripts-enabled/275-CDB_AnalysisCheck.sql create mode 120000 lib/sql/scripts-enabled/280-CDB_EstimateRowCount.sql create mode 120000 lib/sql/scripts-enabled/290-CDB_GhostTables.sql create mode 120000 lib/sql/scripts-enabled/900-CDB_DDLTriggers.sql create mode 120000 lib/sql/scripts-enabled/910-CDB_Conf.sql create mode 120000 lib/sql/scripts-enabled/920-CDB_Username.sql create mode 120000 lib/sql/scripts-enabled/CDB_DistType.sql create mode 120000 lib/sql/scripts-enabled/CDB_DistinctMeasure.sql create mode 120000 lib/sql/scripts-enabled/CDB_Groups.sql create mode 120000 lib/sql/scripts-enabled/CDB_Groups_API.sql create mode 120000 lib/sql/scripts-enabled/CDB_Stats.sql create mode 120000 lib/sql/scripts-enabled/CDB_SyncTable.sql create mode 100644 lib/sql/sql/test_setup.sql create mode 100644 lib/sql/test/CDB_AnalysisCheckTest.sql create mode 100644 lib/sql/test/CDB_AnalysisCheckTest_expect create mode 100644 lib/sql/test/CDB_CartodbfyTableTest.sql create mode 100644 lib/sql/test/CDB_CartodbfyTableTest_expect create mode 100644 lib/sql/test/CDB_DateToNumberTest.sql create mode 100644 lib/sql/test/CDB_DateToNumberTest_expect create mode 100644 lib/sql/test/CDB_DigitSeparatorTest.sql create mode 100644 lib/sql/test/CDB_DigitSeparatorTest_expect create mode 100644 lib/sql/test/CDB_DistTypeTest.sql create mode 100644 lib/sql/test/CDB_DistTypeTest_expect create mode 100644 lib/sql/test/CDB_DistinctMeasureTest.sql create mode 100644 lib/sql/test/CDB_DistinctMeasureTest_expect create mode 100644 lib/sql/test/CDB_EqualIntervalBinsTest.sql create mode 100644 lib/sql/test/CDB_EqualIntervalBinsTest_expect create mode 100644 lib/sql/test/CDB_EstimateRowCountTest.sql create mode 100644 lib/sql/test/CDB_EstimateRowCountTest_expect create mode 100644 lib/sql/test/CDB_GhostTables.sql create mode 100644 lib/sql/test/CDB_GhostTables_expect create mode 100644 lib/sql/test/CDB_GreatCircle.sql create mode 100644 lib/sql/test/CDB_GreatCircle_expect create mode 100644 lib/sql/test/CDB_HeadsTailsBinsTest.sql create mode 100644 lib/sql/test/CDB_HeadsTailsBinsTest_expect create mode 100644 lib/sql/test/CDB_HelperTest.sql create mode 100644 lib/sql/test/CDB_HelperTest_expect create mode 100644 lib/sql/test/CDB_HexagonTest.sql create mode 100644 lib/sql/test/CDB_HexagonTest_expect create mode 100644 lib/sql/test/CDB_JenksBinsTest.sql create mode 100644 lib/sql/test/CDB_JenksBinsTest_expect create mode 100644 lib/sql/test/CDB_MathTest.sql create mode 100644 lib/sql/test/CDB_MathTest_expect create mode 100644 lib/sql/test/CDB_OverviewsTest.sql create mode 100644 lib/sql/test/CDB_OverviewsTest_expect create mode 100644 lib/sql/test/CDB_QuantileBinsTest.sql create mode 100644 lib/sql/test/CDB_QuantileBinsTest_expect create mode 100644 lib/sql/test/CDB_QueryStatementsTest.sql create mode 100644 lib/sql/test/CDB_QueryStatementsTest_expect create mode 100644 lib/sql/test/CDB_QueryTablesTest.sql create mode 100644 lib/sql/test/CDB_QueryTablesTest_expect create mode 100644 lib/sql/test/CDB_QuotaTest.sql create mode 100644 lib/sql/test/CDB_QuotaTest_expect create mode 100644 lib/sql/test/CDB_RectangleTest.sql create mode 100644 lib/sql/test/CDB_RectangleTest_expect create mode 100644 lib/sql/test/CDB_StatsTest.sql create mode 100644 lib/sql/test/CDB_StatsTest_expect create mode 100644 lib/sql/test/CDB_SyncTableTest.sql create mode 100644 lib/sql/test/CDB_SyncTableTest_expect create mode 100644 lib/sql/test/CDB_TransformToWebmercatorTest.sql create mode 100644 lib/sql/test/CDB_TransformToWebmercatorTest_expect create mode 100644 lib/sql/test/CDB_UserTablesTest.sql create mode 100644 lib/sql/test/CDB_UserTablesTest_expect create mode 100644 lib/sql/test/CDB_Username.sql create mode 100644 lib/sql/test/CDB_Username_expect create mode 100644 lib/sql/test/CDB_XYZ_ExtentTest.sql create mode 100644 lib/sql/test/CDB_XYZ_ExtentTest_expect create mode 100644 lib/sql/test/Makefile create mode 100644 lib/sql/test/README create mode 100755 lib/sql/test/extension/test.sh create mode 100644 lib/sql/test/organization/test.sh create mode 100644 lib/sql/test/overviews/fixtures.sql create mode 100644 lib/sql/test/overviews/gen_points.rb create mode 100644 lib/sql/test/perf/CDB_HexagonGridPerf.sql create mode 100644 lib/sql/test/perf/CDB_TransformToWebmercatorPerf.sql create mode 100755 lib/sql/util/create_from_unpackaged.sh create mode 100755 lib/sql/util/create_upgrade.sh diff --git a/lib/sql/.gitignore b/lib/sql/.gitignore new file mode 100644 index 0000000..1a2219a --- /dev/null +++ b/lib/sql/.gitignore @@ -0,0 +1,9 @@ +cartodb--*.sql +cartodb_version.sql +cartodb.control +results/ +regression.* +expected/test +sql/test +.idea/* +*.swp diff --git a/lib/sql/.travis.yml b/lib/sql/.travis.yml new file mode 100644 index 0000000..1132fcc --- /dev/null +++ b/lib/sql/.travis.yml @@ -0,0 +1,38 @@ +dist: xenial +language: c +sudo: required + +env: + global: + - PGUSER=postgres + - PGDATABASE=postgres + - PGOPTIONS='-c client_min_messages=NOTICE' + - PGPORT=5432 + - POSTGIS_VERSION="2.5" + + matrix: + - POSTGRESQL_VERSION="9.6" + - POSTGRESQL_VERSION="10" + - POSTGRESQL_VERSION="11" + + +before_install: + - sudo service postgresql stop; + - sudo apt-get remove postgresql* -y + - sudo apt-get install -y --allow-unauthenticated --no-install-recommends --no-install-suggests postgresql-$POSTGRESQL_VERSION postgresql-client-$POSTGRESQL_VERSION postgresql-server-dev-$POSTGRESQL_VERSION postgresql-common + - if [[ $POSTGRESQL_VERSION == '9.6' ]]; then sudo apt-get install -y postgresql-contrib-9.6; fi; + - sudo apt-get install -y --allow-unauthenticated postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION-scripts postgis postgresql-plpython-$POSTGRESQL_VERSION + - sudo pg_dropcluster --stop $POSTGRESQL_VERSION main + - sudo rm -rf /etc/postgresql/$POSTGRESQL_VERSION /var/lib/postgresql/$POSTGRESQL_VERSION + - sudo pg_createcluster -u postgres $POSTGRESQL_VERSION main -- -A trust + - sudo /etc/init.d/postgresql start $POSTGRESQL_VERSION || sudo journalctl -xe + - sudo pip install redis==2.4.9 +script: + - make + - sudo make install + - make installcheck + +after_failure: + - pg_lsclusters + - cat regression.out + - cat regression.diffs diff --git a/lib/sql/CONTRIBUTING.md b/lib/sql/CONTRIBUTING.md new file mode 100644 index 0000000..0d4686a --- /dev/null +++ b/lib/sql/CONTRIBUTING.md @@ -0,0 +1,73 @@ +The development tracker for cartodb-postgresql is on github: +http://github.com/cartodb/cartodb-postgresql/ + +Bug fixes are best reported as pull requests over there. +Features are best discussed on the mailing list: +https://groups.google.com/d/forum/cartodb + +Adding features to the extension +-------------------------------- + +Extension features are coded in scripts found under the +"scripts-available" directory. A feature can be a single function +or a group of function with a specific scope. + +The "scripts-enabled" directory contains symlinks to the scripts +in "scripts-available". Any symlink in that directory is automatically +included in the extension. Numbering can be used to enforce the order +in which those scripts are loaded. + +Scripts would be best coded in a way to be usable both for creation +and upgrade of the objects. This means using CREATE OR REPLACE for +the functions, and whatever it takes to check existence of any previous +version of objects in other cases. + +When adding a new function or modifying an exiting one make sure that the +[VOLATILITY](https://www.postgresql.org/docs/current/static/xfunc-volatility.html) and [PARALLEL](https://www.postgresql.org/docs/9.6/static/parallel-safety.html) categories are updated accordingly. + + +Although the extension will usually be installed in the "cartodb" schema, please +use @extschema@ to fully-qualify internal calls to avoid name clashes. +When you use postgis functions or types, please fully-qualify them by using +@postgisschema@ (it's changed to "public" by the install script) to avoid +pg_upgrade issues. + +Every new feature (as well as bugfixes) should come with a test case, +see the 'Writing testcases' section. + +Writing testcases +----------------- + +Tests reside in the test/ directory. +You can find information about how to write tests in test/README + +Testing changes live +-------------------- + +Testing changes made during development requires upgrading +the extension into your test database. + +During development the cartodb extension version doesn't change with +every commit, so testing latest change requires cheating with PostgreSQL +as to enforce the scripts to reload. To help with cheating, "make install" +also installs migration scripts to go from "V" to "V"next and from "V"next +to "V". Example to upgrade a 0.2.0dev version: + +```sql +ALTER EXTENSION cartodb UPDATE TO '0.2.0next'; +ALTER EXTENSION cartodb UPDATE TO '0.2.0dev'; +``` +Starting with 0.2.0, the in-place reload can be done with an ad-hoc function: + +```sql +SELECT cartodb.cdb_extension_reload(); +``` + +A useful query: +```sql +SELECT * FROM pg_extension_update_paths('cartodb') WHERE path IS NOT NULL AND source = cdb_version(); +``` + +## Submitting Contributions + +* You will need to sign a Contributor License Agreement (CLA) before making a submission. [Learn more here](https://carto.com/contributions). diff --git a/lib/sql/LICENSE b/lib/sql/LICENSE new file mode 100644 index 0000000..91eaff9 --- /dev/null +++ b/lib/sql/LICENSE @@ -0,0 +1,27 @@ +Copyright (c) 2014, Vizzuality +All rights reserved. + +Redistribution and use in source and binary forms, with or without +modification, are permitted provided that the following conditions are met: + +1. Redistributions of source code must retain the above copyright notice, this +list of conditions and the following disclaimer. + +2. Redistributions in binary form must reproduce the above copyright notice, +this list of conditions and the following disclaimer in the documentation +and/or other materials provided with the distribution. + +3. Neither the name of the copyright holder nor the names of its contributors +may be used to endorse or promote products derived from this software without +specific prior written permission. + +THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" +AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE +IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE +DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE +FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL +DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR +SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER +CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, +OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE +OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. diff --git a/lib/sql/Makefile b/lib/sql/Makefile new file mode 100644 index 0000000..82034e5 --- /dev/null +++ b/lib/sql/Makefile @@ -0,0 +1,186 @@ +# cartodb/Makefile + +EXTENSION = cartodb +EXTVERSION = 0.28.1 + +SED = sed +AWK = awk + +CDBSCRIPTS = \ + scripts-enabled/*.sql \ + scripts-available/CDB_SearchPath.sql \ + scripts-available/CDB_ExtensionPost.sql \ + scripts-available/CDB_ExtensionUtils.sql \ + scripts-available/CDB_Helper.sql \ + $(END) + +UPGRADABLE = \ + unpackaged \ + 0.1.0 \ + 0.1.1 \ + 0.2.0 \ + 0.2.1 \ + 0.3.0 \ + 0.3.0dev \ + 0.3.1 \ + 0.3.2 \ + 0.3.3 \ + 0.3.4 \ + 0.3.5 \ + 0.3.6 \ + 0.4.0 \ + 0.4.1 \ + 0.5.0 \ + 0.5.1 \ + 0.5.2 \ + 0.5.3 \ + 0.6.0 \ + 0.7.0 \ + 0.7.1 \ + 0.7.2 \ + 0.7.3 \ + 0.7.4 \ + 0.8.0 \ + 0.8.1 \ + 0.8.2 \ + 0.9.0 \ + 0.9.1 \ + 0.9.2 \ + 0.9.3 \ + 0.9.4 \ + 0.10.0 \ + 0.10.1 \ + 0.10.2 \ + 0.11.0 \ + 0.11.1 \ + 0.11.2 \ + 0.11.3 \ + 0.11.4 \ + 0.11.5 \ + 0.12.0 \ + 0.13.0 \ + 0.13.1 \ + 0.14.0 \ + 0.14.1 \ + 0.14.2 \ + 0.14.3 \ + 0.14.4 \ + 0.15.0 \ + 0.15.1 \ + 0.16.0 \ + 0.16.1 \ + 0.16.2 \ + 0.16.3 \ + 0.16.4 \ + 0.17.0 \ + 0.17.1 \ + 0.18.0 \ + 0.18.1 \ + 0.18.2 \ + 0.18.3 \ + 0.18.4 \ + 0.18.5 \ + 0.19.0 \ + 0.19.1 \ + 0.19.2 \ + 0.20.0 \ + 0.21.0 \ + 0.22.0 \ + 0.22.1 \ + 0.22.2 \ + 0.23.0 \ + 0.23.1 \ + 0.23.2 \ + 0.24.0 \ + 0.24.1 \ + 0.25.0 \ + 0.26.0 \ + 0.26.1 \ + 0.27.0 \ + 0.27.1 \ + 0.27.2 \ + 0.28.0 \ + 0.28.1 \ + $(EXTVERSION)dev \ + $(EXTVERSION)next \ + $(END) + +UPGRADES = \ + $(shell echo $(UPGRADABLE) | \ + $(SED) 's/^/$(EXTENSION)--/' | \ + $(SED) 's/$$/--$(EXTVERSION).sql/' | \ + $(SED) 's/ /--$(EXTVERSION).sql $(EXTENSION)--/g') + +GITDIR=$(shell test -d .git && echo '.git' || cat .git | $(SED) 's/^gitdir: //') + +DATA_built = \ + $(EXTENSION)--$(EXTVERSION).sql \ + $(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql \ + $(UPGRADES) \ + $(EXTENSION).control + +EXTRA_CLEAN = cartodb_version.sql + +DOCS = README.md +REGRESS_OLD = $(wildcard test/*.sql) +REGRESS_LEGACY = $(REGRESS_OLD:.sql=) +REGRESS = test_setup $(REGRESS_LEGACY) + +PG_CONFIG = pg_config +PGXS := $(shell $(PG_CONFIG) --pgxs) +include $(PGXS) + +$(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile + echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@ + cat $(CDBSCRIPTS) | \ + $(SED) -e 's/@extschema@/cartodb/g' \ + -e "s/@postgisschema@/public/g" >> $@ + echo "GRANT USAGE ON SCHEMA cartodb TO public;" >> $@ + cat cartodb_version.sql >> $@ + +$(EXTENSION)--unpackaged--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql util/create_from_unpackaged.sh Makefile + ./util/create_from_unpackaged.sh $(EXTVERSION) + +$(EXTENSION)--%--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql + cp $< $@ + +$(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql: $(EXTENSION)--$(EXTVERSION).sql + cp $< $@ + +$(EXTENSION).control: $(EXTENSION).control.in Makefile + $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' $< > $@ + +cartodb_version.sql: cartodb_version.sql.in Makefile $(GITDIR)/index + $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" $< > $@ + +# Needed for consistent `echo` results with backslashes +SHELL = bash + +legacy_regress: $(REGRESS_OLD) Makefile + mkdir -p sql/test/ + mkdir -p expected/test/ + mkdir -p results/test/ + for f in $(REGRESS_OLD); do \ + tn=`basename $${f} .sql`; \ + of=sql/test/$${tn}.sql; \ + echo '\set ECHO none' > $${of}; \ + echo '\a' >> $${of}; \ + echo '\t' >> $${of}; \ + echo '\set QUIET off' >> $${of}; \ + cat $${f} | \ + $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" >> $${of}; \ + exp=expected/test/$${tn}.out; \ + echo '\set ECHO none' > $${exp}; \ + cat test/$${tn}_expect >> $${exp}; \ + done + +test_organization: + bash test/organization/test.sh + +test_extension_new: + bash test/extension/test.sh + +legacy_tests: legacy_regress + +installcheck: legacy_tests test_extension_new test_organization + diff --git a/lib/sql/NEWS.md b/lib/sql/NEWS.md new file mode 100644 index 0000000..7ddf483 --- /dev/null +++ b/lib/sql/NEWS.md @@ -0,0 +1,469 @@ +0.28.1 (2019-07-04) +* Avoid temporary tables creation in CDB_SyncTable (#366) +* Make CDB_Get_Foreign_Updated_At robust to missing CDB_TableMetadata (#362) + +0.28.0 (2019-07-01) +* New function CDB_SyncTable (#355) + +0.27.2 (2019-06-21) +* Improvements and fixes in Ghost tables functions (#360) + +0.27.1 (2019-06-03) +* Add some qualifications that were left in the previous release. + +0.27.0 (2019-06-03) +* Fully qualify function calls +* Several improvements to bash tests. +* Avoid dropping publicuser in tests. +* Raise minimum requirement to PostgreSQL 9.6. + +0.26.1 (2019-03-19) +* Remove default TIS values from Ghost tables functions + +0.26.0 (2019-03-11) +* Use `ST_ShiftLongitude` instead of `ST_Shift_Longitude`. +* Add Ghost tables functions to install triggers and enqueue the linking process + +0.25.0 (2019-02-22) +* Add `CDB_Username` to get the cartodb username from the current PostgreSQL user + +0.24.1 (2019-01-02) +* Drop functions removed in 0.12 (#341) +* Travis: Test with PostgreSQL 9.5, 10 and 11. + +0.24.0 (2018-09-13) +* Travis: Test with PostgreSQL 9.5 and 10. +* _cdb_estimated_extent: Fix bug with ST_EstimatedExtent interaction. +* Improvements in `CDB_JenksBins`. + * Now it ignores NULLs. + * No longer puts the same value in multiple categories. + * Removes all limits related to size. + * If not set, the number of iterations done is based now on the size of the array. + * Fixed multiple bugs. + * The internal function `CDB_JenksBinsIteration` has changed its signature. + +0.23.2 (2018-07-19) +* Fix `CDB_QueryTablesText` with parenthesized queries (#335) + +0.23.1 (2018-07-19) +* Fix `CDB_EstimateRowCount` parallelizability #333 + +0.23.0 (2018-07-03) +* Add a new helper function `_CDB_Table_Exists(table_name_with_optional_schema TEXT)` #332 + +0.22.2 (2018-05-29) +* Fix: Fix hyphenates usernames in 0.22.1 fix (#331) + +0.22.1 (2018-05-29) +* Fix: Correctly grant permission to all sequences related with table (#330) + +0.22.0 (2018-03-22) +* Fix: allow older ogr2ogr to work in -append mode (#319,#325) +* Refactors CDB_QuantileBins to rely on PostgreSQL function `percentile_disc` #316 + +0.21.0 (2018-02-15) +* Add optional parameter to limit the number of cells in grid-generation functions #322 +* Fix: grant usage on cartodb_id sequence when sharing read write #323 +* Fix: Change sed in-place for tmpfiles 524319 + +0.20.0 (2017-11-08) +* Added VOLATILITY and PARALLEL categories to all functions + +0.19.2 (2017-06-30) +* Improved functions to generate unique identifiers #305 + +0.19.1 (2017-06-05) + +* Fixed a deadlock problem when trying to regenarate overviews #302 + +0.19.0 (2017-04-11) + +* Add new function `CDB_EstimateRowCount` #295 + +0.18.5 (2016-11-30) + +* Add to new overview creation strategies #290 +* Fix tests: race condition with publicuser #157 +* Fix: CDB_Stats divisions by zero #181 +* Better implementation of `CDB_EqualIntervalBins` #244 +* New tests for binning functions #249 + +0.18.4 (2016-11-04) + +* No functional changes; fixes the migration from previous versions #288 + +0.18.3 (2016-11-03) + +* Exclude analysis cache tables from the quota #281 + +0.18.2 (2016-10-20) +------------------- + +* Fix: cleanup inconsistent position of `username` column in analysis catalog after upgrades + [#285](https://github.com/cartodb/cartodb-postgresql/pull/285) + +0.18.1 (2016-10-19) +------------------- + +* Increase analysis limit factor to 2 [#284](https://github.com/CartoDB/cartodb-postgresql/pull/284) + +0.18.0 (2016-10-17) +------------------- + +* Fix: exclude NULL geometries when creating Overviews #269 +* Function to check analysis tables limits #279 + +0.17.1 (2016-08-16) +------------------- + +* Add cache_tables column to cdb_analysis_catalog table #274. + + +0.17.0 (2016-07-04) +------------------- + +* Add export config for cdb_analysis_catalog table #268. +* Add some extra fields to cdb_analysis_catalog table. Track user, error_message for failures, and last entity modifying the node #267. +* Exclude overviews from user data size #262. + + +0.16.4 (2016-05-27) +------------------- + +* Change CDB_ZoomFromScale() to use a formula and raise + maximum overview level from 23 to 29. + [#259](https://github.com/CartoDB/cartodb-postgresql/pull/259) + +* Fix bug in overview creating causing it to fail when `x` or + `y` columns exist with non-integer type. Prevent also + potential integer overflows limiting maximum overview level + to 23. + [#258](https://github.com/CartoDB/cartodb-postgresql/pull/258) + + +0.16.3 (2016-05-09) +------------------- + +* Fix overview creation problem for organization users + with names that require quoting: + [#253](https://github.com/CartoDB/cartodb-postgresql/pull/253) + +0.16.2 (2016-04-27) +------------------- + +* Use the mode to aggregate category columns in overviews + [#246](https://github.com/CartoDB/cartodb-postgresql/pull/246) + +0.16.1 (2016-04-25) +------------------- + +* Optimize column information functions performance + [#238](https://github.com/CartoDB/cartodb-postgresql/pull/238) + +* Adjust overview points to pixel CDB_EqualIntervalBins + [#242](https://github.com/CartoDB/cartodb-postgresql/pull/242) + +* Compute webmercator resolution using full numeric precision + [#243](https://github.com/CartoDB/cartodb-postgresql/pull/243) + + +0.16.0 (2016-04-15) +------------------- +* Adds table for storing camshaft analysis nodes + [#237](https://github.com/CartoDB/cartodb-postgresql/pull/237) + +0.15.1 (2016-04-15) +------------------- +* Fix problems with org users in overviews functions + [#224](https://github.com/CartoDB/cartodb-postgresql/pull/224) +* Add `_feature_count` to overviews + [#227](https://github.com/CartoDB/cartodb-postgresql/pull/227) +* Change point clustering behaviour of overviews + [#228](https://github.com/CartoDB/cartodb-postgresql/pull/228) +* Change default tolerance of overviews + [#230](https://github.com/CartoDB/cartodb-postgresql/pull/230) +* Fix problem with aggregated numerical fields in overviews + [#233](https://github.com/CartoDB/cartodb-postgresql/pull/233) +* Enhance aggregation of text fields in overviews + [#234]https://github.com/CartoDB/cartodb-postgresql/pull/234 + +0.15.0 (2016-04-05) +------------------- +* New function CDB_CreateOverviewsWithToleranceInPixels that adds tolerance parameter for overview creation + [#221](https://github.com/CartoDB/cartodb-postgresql/pull/221) +* New default value for the overviews tolerance in pixels is 2 (used to be 7.5) (also in #221) +* The feature density limit used to choose the reference Z level now depends on the tolerance in pixels (also in #221) +* Tables that require an explicit schema can now be passed to overview functions + [#220](https://github.com/CartoDB/cartodb-postgresql/pull/220) + +0.14.4 (2016-03-29) +------------------- +* Fix creating overviews for tables with boolean columns + [#214](https://github.com/CartoDB/cartodb-postgresql/pull/214) +* Fix tests for some systems [#215](https://github.com/CartoDB/cartodb-postgresql/pull/215) + +0.14.3 (2016-03-17) +------------------- +* Fix for `cartodb_id` bigint casting hardcoded in 0.14.2 to support `cartodb_id` text columns [#210](https://github.com/CartoDB/cartodb-postgresql/pull/210) + +0.14.2 (2016-03-15) +------------------- +* Support text `cartodb_id` columns in `_CDB_Has_Usable_Primary_ID` [#202](https://github.com/CartoDB/cartodb-postgresql/pull/202) + +0.14.1 (2016-03-07) +------------------- +* Fully qualify table names in cache cdb_invalidate_varnish calls [#198](https://github.com/CartoDB/cartodb-postgresql/issues/198) + +0.14.0 (2016-02-14) +------------------- +* Add CDB_ForeignTable.sql to support FDW's [#199](https://github.com/CartoDB/cartodb-postgresql/pull/199) + +0.13.1 (2016-02-01) +------------------- +* Fix migration fron unpackaged. [193](https://github.com/CartoDB/cartodb-postgresql/pull/193) + +0.13.0 (2016-01-29) +------------------- +* Add CDB_CreateOverviews, CDB_DropOverviews and CDB_Overviews for vector overviews support. [185](https://github.com/CartoDB/cartodb-postgresql/pull/185) +* Convert some simple functions from plpgsql to sql. [188](https://github.com/CartoDB/cartodb-postgresql/pull/188) + +0.12.0 (2016-01-27) +------------------- +* Remove schema_triggers extension dependency, to ensure compatibility with PostgreSQL 9.5. [#190](https://github.com/CartoDB/cartodb-postgresql/pull/190) +* Remove DDL trigger functions (unused by CartoDB). + +0.11.5 (2015-11-27) +------------------- +* Disable log invalidation time [#178](https://github.com/CartoDB/cartodb-postgresql/pull/178) + +0.11.4 (2015-11-24) +------------------- +* Fix for existing PK cartodb_id problem [#174](https://github.com/CartoDB/cartodb-postgresql/issues/174) +* Add cartodbfication support for column names with embedded points to fix [#6114](https://github.com/CartoDB/cartodb/issues/6114) +* Add CDB_GreatCircle for creating great circle routes between two points [#171](https://github.com/CartoDB/cartodb-postgresql/pull/171) +* Fix to prevent cartodbfication problems [#155](https://github.com/CartoDB/cartodb-postgresql/issues/155) + +0.11.3 (2015-10-27) +------------------- +* Added CDB_Helper.sql [#173](https://github.com/CartoDB/cartodb-postgresql/pull/173) +* Added `_CDB_Unique_Identifier` for creating UTF8 aware unique identifiers +* Added `_CDB_Unique_Column_Identifier` for creating UTF8 aware unique identifiers for columns +* Added `_CDB_Octet_Truncate` that truncates text to a certain amount of octets. + +0.11.2 (2015-10-19) +------------------- +* Fix schema not being specified on pg_get_serial_sequence [#170](https://github.com/CartoDB/cartodb-postgresql/pull/170) +* Log invalidation function call duration in seconds [#163](https://github.com/CartoDB/cartodb-postgresql/pull/163) + +0.11.1 (2015-10-06) +------------------- +* Added CDB_DateToNumber(timestamp with time zone) [#169](https://github.com/CartoDB/cartodb-postgresql/pull/169) +* cartodbfy now discards cartodb_id candidates that contain nulls [#148](https://github.com/CartoDB/cartodb-postgresql/issues/148) + +0.11.0 (2015-09-dd) +------------------- +* Groups API + +0.10.2 (2015-09-24) +------------------- +* Add back the `DROP FUNCTION IF EXISTS CDB_UserTables(text);` to be able to upgrade from `0.7.3` upward [#160](https://github.com/CartoDB/cartodb-postgresql/issues/160) + +0.10.1 (2015-09-16) +------------------- +* Get back the `update_updated_at` function (still used by old tables) [#143](https://github.com/CartoDB/cartodb-postgresql/pull/143) +* Fix for CDB_StatsTest.sql test failing randomly [#144](https://github.com/CartoDB/cartodb-postgresql/issues/144) +* Fix for table cartodbfy'ed without default seq value [#138](https://github.com/CartoDB/cartodb-postgresql/issues/138) +* Fix for cartodbfy error column `the_geom` already exists [#141](https://github.com/CartoDB/cartodb-postgresql/issues/141) +* Fix for columns with geometry cartodbfy'ed without SRID [#154](https://github.com/CartoDB/cartodb-postgresql/issues/154) + +0.10.0 (2015-09-07) +----------------- +* Quote schema and table names returned by CDB_QueryTables [#134](https://github.com/CartoDB/cartodb-postgresql/pull/134). Use quote_ident to quote schema and table names when necessary. +* Fixed CDB_ColumnNames [#122](https://github.com/CartoDB/cartodb-postgresql/issues/122) and CDB_ColumnType [#130](https://github.com/CartoDB/cartodb-postgresql/issues/130) should honor regclass, returning columns for just the table in the schema and not in any other one [#131](https://github.com/CartoDB/cartodb-postgresql/pull/131). +* Add kurtosis and skewness [#124](https://github.com/CartoDB/cartodb-postgresql/pull/124). +* Removed `DROP FUNCTION IF EXISTS cdb_usertables(text);` [#129](https://github.com/CartoDB/cartodb-postgresql/pull/129). This was needed for upgrading between 0.7.4 to 0.8.0 but is no longer needed. + +0.9.4 (2015-08-28) +------------------ +* Fixed issue with indices when renaming tables [#123](https://github.com/CartoDB/cartodb-postgresql/issues/123) + +0.9.3 (2015-08-27) +------------------ +* Modify sampling of quota trigger [#126](https://github.com/CartoDB/cartodb-postgresql/issues/126) + +0.9.2 (2015-08-24) +------------------ +* Fix for `the_geom` column present but not SRID (EWKT) and other corner cases [#121](https://github.com/CartoDB/cartodb-postgresql/pull/121) + +0.9.1 (2015-08-19) +------------------ +* Fix for transformation to webmercator in corner cases [#116](https://github.com/CartoDB/cartodb-postgresql/issues/116) + +0.9.0 (2015-08-19) +------------------ +* Re-implementation of `CDB_CartodbfyTable` functions + - The signature of the main function changes to + ``` + FUNCTION CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) + RETURNS REGCLASS + ``` + - The `destschema` does not need to match the origin schema of `reloid` + - It returns the `regclass` of the cartodbfy'ed table, if it needs to be rewritten. + - There are many optimizations + - The columns `created_at` and `updated_at` will no longer be added +* Fix for CDB_UserDataSize failing due `ERROR: relation "*" does not exist.` #110 +* Review test to validate permissions in public tables [#112](https://github.com/CartoDB/cartodb-postgresql/pull/112) + +0.8.3 (2015-08-14) +------------------ +* Fixes CDB_UserDataSize failing due `ERROR: relation "*" does not exist.` [#108](https://github.com/CartoDB/cartodb-postgresql/issues/108) + +0.8.2 (2015-07-27) +------------------ +* Fix for CDB_UserTables returning wrong listings when publicuser is used + +0.8.1 (2015-06-30) +------------------ +* Fix for [#95](https://github.com/CartoDB/cartodb-postgresql/issues/95) *cdb_usertables should return public tables when the user is publicuser* + +0.8.0 (2015-06-30) +------------------ +* Adds new function CDB_QueryTablesText that can deal with "schema.table_name" + longer than 63 chars. +* Adds a set of statistical functions: + - CDB_DistType + - CDB_DistinctMeasure + - CDB_EqualIntervalBins +* Fix for CDB_UserTables returns 0 entries for multiuser accounts [#64](https://github.com/CartoDB/cartodb-postgresql/issues/64) + +0.7.4 (2015-06-29) +------------------ +Dummy transitional version. + +0.7.3 (2015-03-03) +------------------ +* Fix upgrade of CDB_StringToDate function +* Add a test for to validate CDB_TableMetadataTouch usage with OID + +0.7.2 (2015-03-03) +------------------ +* Fix conversion of strings to datetime + +0.7.1 (2015-02-27) +------------------ +* Revert quota checks to `pg_total_relation_size` + +0.7.0 (2015-02-19) +------------------ +* Adds CDB_ZoomFromScale function + +0.6.0 (2015-02-19) +------------------ +* Select permission in CDB_TableMetadata no longer granted to public +* New function to upsert the updated_at in CDB_TableMetadata for a regclass + +0.5.3 (2015-02-17) +------------------ +* Fixed security problem related with system tables +* Changed quota checks to use `pg_relation_size` instead of `pg_total_relation_size` + +0.5.2 (2015-01-29) +------------------ +* Improvement: make CDB_UserDataSize functions much faster. + +0.5.1 (2014-11-21) +------------------ +* Bugfix: Quota check and some organization permissions functions were not properly escaping table name. + +0.5.0 (2014-11-03) +------------------ +* Support of raster tables for cartodbfication +* Modified quota functions: vector tables stay the same, raster tables count as full size (as have no + the_geom + the_geom_webmercator combo) and raster overviews are not counted + +0.4.1 (2014-09-21) +------------------ +* Bugfix for Cartodbfication: Set primary key of the table if not already present (e.g. tables created from SQL API) + +0.4.0 (2014-08-27) +------------------ +Added CDB_Math_Mode function +Changes in versioning: no revision is attached so it no longer uses `git describe` for the version. + +0.3.6 (2014-08-11) +------------------ +Dummy release to solve some issues with cdb branch/tag + +0.3.5 (2014-08-11) +------------------ +Inverting priority of CDB_CheckQuota qmax so gies more priority to existing user quota function over parameter value. + +0.3.4 (2014-08-01) +------------------ +Fixes issue with schemas in CDB_QueryTables + +0.3.3 (2014-07-30) +------------------ +* Splitting of CartodbfyTable method in subfunctions to be able to call in fragments and evade timeouts on hot zones + +0.3.2 (2014-07-28) +------------------ +* Make 0.3.0dev version upgradeable + +0.3.1 (2014-07-22) +------------------ +* Dummy version. We start using semantic versioning + +0.3.0 (2014-07-15) +------------------ +* Permission management functions +* Adapt functions to use schemas + +0.2.1 - 2014-06-11 +------------------ + +Enhancements: + + - Do not force re-cartodbfication on CREATE FROM unpackaged + - Drop useless DEFAULT specification in plpgsql variable declarations + - List plpythonu requirement first, to get pg_catalog scanned before public + +Bug fixes: + + - Do not add unique index on cartodb_id if already a primary key (#38) + +0.2.0 - 2014-06-09 +------------------ + +Important changes: + + - This release adds dependency on "plpythonu" extension + - Roles are not created anymore, previously private functions + for table information extraction (CDB_UserTables, CDB_TableIndexes, + CDB_ColumnNames, CDB_ColumnType) will now be callable by anyone while + only returning information about tables over which the calling user + has SELECT privilege (#36) + +Bug fixes: + + - Fix recursive trigger on create table (#32) + - Ensure cartodb_id uses an associated sequence (#33) + - Fully qualify call to cdb_disable_ddl_hooks from cdb_enable_ddl_hooks + - Fully qualify call to CDB_UserDataSize from quota trigger + - Fully qualify call to CDB_TransformToWebmercator from CDB_CartodbfyTable + - Fix potential infinite loop in CDB_CartodbfyTable + - Fix potential infinite loop in CDB_QueryStatements + +Enhancements: + + - Include revision info in cdb_version() output (#34) + +New features: + + - Add a cdb_extension_reload() function + + +0.1.0 - 2014-05-23 +------------------ + +Initial release diff --git a/lib/sql/README.md b/lib/sql/README.md new file mode 100644 index 0000000..a871807 --- /dev/null +++ b/lib/sql/README.md @@ -0,0 +1,96 @@ +cartodb-postgresql +================== + +[![Build Status](http://api.travis-ci.org/CartoDB/cartodb-postgresql.svg?branch=master)](http://travis-ci.org/CartoDB/cartodb-postgresql) + +PostgreSQL extension for CartoDB + +See [the cartodb-postgresql wiki](https://github.com/CartoDB/cartodb-postgresql/wiki). + +Dependencies +------------ + + * PostgreSQL 9.6+ (with plpythonu extension and xml support) + * [PostGIS extension](http://postgis.net) + * Python with [Redis module](https://pypi.org/project/redis/) + +Install +------- + +```sh +make all install +``` + +Test installation +----------------- + +```sh +make installcheck +``` + +NOTE: you need to run the installcheck as a superuser, use PGUSER + env variable if needed, like: PGUSER=postgres make installcheck + +NOTE: the tests need to run against a **clean postgres instance**, if you have some roles already created test will likely fail due `publicuser` not being dropped. + +Enable database +--------------- + +In a database that needs to be turned into a "cartodb" user database, run: + +```sql +CREATE EXTENSION postgis; +CREATE EXTENSION cartodb; +``` + +Migrate existing cartodb database +--------------------------------- + +When upgrading an existing cartodb user database, the cartodb extension +can be migrated from the "unpackaged" version. The procedure will copy +the data from ``public.CDB_TableMetada`` to ``cartodb.CDB_TableMetadata``, +re-cartodbfy all tables using old functions in triggers and drop the +cartodb functions from the 'public' schema. All new cartodb objects will +be in the "cartodb" schema. + +```sql +CREATE EXTENSION postgis FROM unpackaged; +CREATE EXTENSION cartodb FROM unpackaged; +``` + +Update cartodb extension +------------------------ + +Updating the version of cartodb extension installed in a database +is done using ALTER EXTENSION. + +```sql +ALTER EXTENSION cartodb UPDATE TO '0.1.1'; +``` + +The target version needs to be installed on the system first +(see Install section). + +If the "TO 'x.y.z'" part is omitted, the extension will be updated to the +latest installed version, which you can find with the following command: + +```sh +grep default_version `pg_config --sharedir`/extension/cartodb.control +``` + +Updates are performed by PostgreSQL by loading one or more migration scripts +as needed to go from the installed version S to the target version T. +All migration scripts are in the "extension" directory of PostgreSQL: + +```sh +ls `pg_config --sharedir`/extension/cartodb* +``` + +During development the cartodb extension version doesn't change with +every commit, so testing latest change requires special steps documented +in the CONTRIBUTING document, under "Testing changes live". + +Limitations +----------- + +- The main schema of an organization user must have one only owner (the user). diff --git a/lib/sql/carto-package.json b/lib/sql/carto-package.json new file mode 100644 index 0000000..1243b27 --- /dev/null +++ b/lib/sql/carto-package.json @@ -0,0 +1,11 @@ +{ + "name": "carto_postgresql_ext", + "current_version": { + "requires": { + "postgresql": ">=10.0.0", + "postgis": ">=2.4.0.0" + }, + "works_with": { + } + } +} diff --git a/lib/sql/cartodb.control.in b/lib/sql/cartodb.control.in new file mode 100644 index 0000000..a5dcfa0 --- /dev/null +++ b/lib/sql/cartodb.control.in @@ -0,0 +1,6 @@ +default_version = '@@VERSION@@' +comment = 'Turn a database into a cartodb user database.' +superuser = true +relocatable = false +schema = cartodb +requires = 'plpythonu, postgis' diff --git a/lib/sql/cartodb_version.sql.in b/lib/sql/cartodb_version.sql.in new file mode 100644 index 0000000..175dab7 --- /dev/null +++ b/lib/sql/cartodb_version.sql.in @@ -0,0 +1,7 @@ +DO $$ BEGIN IF EXISTS (SELECT * FROM pg_proc p, pg_namespace n WHERE p.proname = 'cdb_transformtowebmercator' AND p.pronamespace = n.oid AND n.nspname = 'public') THEN RAISE EXCEPTION 'Use CREATE EXTENSION cartodb FROM unpackaged'; END IF; END; $$ LANGUAGE 'plpgsql'; -- forbid duplicated extension + +CREATE OR REPLACE FUNCTION @extschema@.CDB_version() +RETURNS text AS $$ + SELECT '@@VERSION@@'::text; +$$ language 'sql' IMMUTABLE STRICT; + diff --git a/lib/sql/doc/CDB_ColumnNames.md b/lib/sql/doc/CDB_ColumnNames.md new file mode 100644 index 0000000..5562440 --- /dev/null +++ b/lib/sql/doc/CDB_ColumnNames.md @@ -0,0 +1,14 @@ +Retrieve all column names in a particular table + +#### Using the function + +```sql +SELECT CDB_ColumnNames('table_name') +--- Returns a set of rows with column names +``` + +#### Arguments + +CDB_ColumnNames(table_name) + +* **table_name** text \ No newline at end of file diff --git a/lib/sql/doc/CDB_ColumnType.md b/lib/sql/doc/CDB_ColumnType.md new file mode 100644 index 0000000..b16fd78 --- /dev/null +++ b/lib/sql/doc/CDB_ColumnType.md @@ -0,0 +1,15 @@ +Returns a column type for any column in a table + +#### Using the function + +```sql +SELECT CDB_ColumnType('column_name','table_name') +--- Returns a set of rows with column types +``` + +#### Arguments + +CDB_ColumnType(column_name, table_name) + +* **column_name** text +* **table_name** text diff --git a/lib/sql/doc/CDB_EstimateRowCount.md b/lib/sql/doc/CDB_EstimateRowCount.md new file mode 100644 index 0000000..e1e9287 --- /dev/null +++ b/lib/sql/doc/CDB_EstimateRowCount.md @@ -0,0 +1,25 @@ +Estimate the number of rows of a query. + + +#### Using the function + +```sql +SELECT CDB_EstimateRowCount($$ + UPDATE addresses SET the_geom = cdb_geocode_street_point(addr, city, state, 'US'); +$$) AS row_count; +``` + +Result: + +``` + row_count +----------- + 5 +(1 row) +``` + +#### Arguments + +CDB_EstimateRowCount(query) + +* **query** text: the SQL query to estimate the row count for. diff --git a/lib/sql/doc/CDB_GreatCircle.md b/lib/sql/doc/CDB_GreatCircle.md new file mode 100644 index 0000000..e32c5b3 --- /dev/null +++ b/lib/sql/doc/CDB_GreatCircle.md @@ -0,0 +1,16 @@ +Based on Paul Ramsey's [blog post](http://blog.cartodb.com/jets-and-datelines/). +#### Using the function + +Creates a great circle line. + +```sql +SELECT CDB_GreatCircle(start_point, end_point) FROM table_name +-- Results a line reprsenting the great circle between the two points +``` + +#### Arguments + +CDB_GreatCircle(start_point, end_point) + +* **start_point** ST_Point indicating the start of the line. +* **end_point** ST_point indicating the end of the line. diff --git a/lib/sql/doc/CDB_HeadsTailsBins.md b/lib/sql/doc/CDB_HeadsTailsBins.md new file mode 100644 index 0000000..305ecc2 --- /dev/null +++ b/lib/sql/doc/CDB_HeadsTailsBins.md @@ -0,0 +1,21 @@ +Find the breaks for N categories in a numerical column based on the [Heads/Tails optimization](http://arxiv.org/pdf/1209.2801v1.pdf). Below, Heads/Tails used to color based on the area of the polygons. + +![headtails](https://f.cloud.github.com/assets/370259/140655/6eebb918-7228-11e2-89fa-149745f25d34.png) + +#### Using the function + +We can determine the 7 most optimal breaks in a column of numerical data as follows, + +```sql +SELECT CDB_HeadsTailsBins(array_agg(numeric_column), 7) FROM table_name +-- Results in an ordered array like, {7824,23492,52696,233857,666089,1001709,1638094} +-- Each break happens up to, and equal, to a number: +-- (bin1 is less than or equal to 7824, bin2 is less than or equal to 23492, etc.) +``` + +#### Arguments + +CDB_HeadsTailsBins(in_array, breaks) + +* **in_array** numeric[]. A NUMERIC array of values. +* **breaks** int. The number of categories you want to create \ No newline at end of file diff --git a/lib/sql/doc/CDB_HexagonGrid.md b/lib/sql/doc/CDB_HexagonGrid.md new file mode 100644 index 0000000..36b0170 --- /dev/null +++ b/lib/sql/doc/CDB_HexagonGrid.md @@ -0,0 +1,43 @@ +Fill given extent with an hexagonal coverage + +#### Using the function + +Create a hexagonal grid from a polygon geometry. For example, take the geometry + +```sql + ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(10000000,-10000000), + ST_MakePoint(-10000000,10000000) + ) + ), + 3857) +``` + +We can create a grid as follows, + +```sql +SELECT CDB_HexagonGrid( + ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(10000000,-10000000), + ST_MakePoint(-10000000,10000000) + ) + ), + 3857), + 1000000) the_geom_webmercator +``` + +Which will look something like this, + +![grid tile](http://i.imgur.com/4rZXGMb.png) + +#### Arguments + +CDB_HexagonGrid(ext, side, origin) + +* **ext** geometry. Extent to fill. Only hexagons with center point falling inside the extent (or at the lower or leftmost edge) will be emitted. The returned hexagons will have the same SRID as this extent. +* **side** float. Side measure for the hexagon. Maximum diameter will be 2 * side. Measure is in the same projection as **ext** +* **origin** OPTIONAL geometry. Optional origin to allow for exact tiling. If omitted the origin will be 0,0. The parameter is checked for having the same SRID as the extent. \ No newline at end of file diff --git a/lib/sql/doc/CDB_JenksBins.md b/lib/sql/doc/CDB_JenksBins.md new file mode 100644 index 0000000..6d8bd9a --- /dev/null +++ b/lib/sql/doc/CDB_JenksBins.md @@ -0,0 +1,23 @@ +Find the breaks for N categories in a numerical column based on the [Jenks optimization](http://en.wikipedia.org/wiki/Jenks_natural_breaks_optimization). Below, Jenks used to color based on the area of the polygons. + +![Jenks](https://f.cloud.github.com/assets/370259/140093/b64a9382-7210-11e2-81a4-c65cce3c885e.png) + +#### Using the function + +We can determine the 7 most optimal breaks in a column of numerical data as follows, + +```sql +SELECT CDB_JenksBins(array_agg(numeric_column), 7) FROM table_name +-- Results in an ordered array like, {0,73,2568,9408,29411,768230,1638094} +-- Each break happens up to, and equal, to a number: +-- (bin1 is less than or equal to 0, bin2 is less than or equal to 73, etc.) +``` + +#### Arguments + +CDB_JenksBins(in_array, breaks, invert) + +* **in_array** numeric[]. A NUMERIC array of values. +* **breaks** int. The number of categories you want to create +* **iterations** OPTIONAL int. The number of iterations used for calculating breaks. +* **invert** OPTIONAL boolean. Flips whether you receive top down breaks or bottom up breaks. Default is top down (so, <=). Bottom up would give you values that define the lower-end start of a bin (so >=). \ No newline at end of file diff --git a/lib/sql/doc/CDB_MakeHexagon.md b/lib/sql/doc/CDB_MakeHexagon.md new file mode 100644 index 0000000..7e76798 --- /dev/null +++ b/lib/sql/doc/CDB_MakeHexagon.md @@ -0,0 +1,21 @@ +Return an Hexagon with given center and side (or maximal radius) + +#### Using the function + +Running the following SQL + +```sql +SELECT CDB_MakeHexagon(ST_MakePoint(0,0),10000000) +``` + +Would give you back a single hexagon geometry, + +![hexagon](http://i.imgur.com/6jeGStb.png) + + +#### Arguments + +CDB_MakeHexagon(center, radius) + +* **center** geometry +* **radius** float. Radius of hexagon measured in same projection as **center** diff --git a/lib/sql/doc/CDB_Overviews.md b/lib/sql/doc/CDB_Overviews.md new file mode 100644 index 0000000..87af5e1 --- /dev/null +++ b/lib/sql/doc/CDB_Overviews.md @@ -0,0 +1,123 @@ +Overviews are tables that represent a *reduced* version of a dataset intended +for efficient rendering at certain zoom levels while preserving the +general visual appearance of the complete dataset. + +The *reduction* consists in havig a fewer number of records +(while each overview record may represent an aggregation of multiple records) +and/or simplified record geometries. + +Overviews are created through the `CDB_CreateOverviews` function. +The statement timeout may need to be adjusted before using this function, +as overview creation for large tables is a time-consuming operation. + +The `CDB_Overviews` function can be used determine what overview tables +exist for a given dataset table and which zoom levels correspond to it. + +The `CDB_DropOverviews` function removes a dataset's existing overviews. + +To know if overview tables exist for some base table, and to obtain +a list of which overview tables are approrpiate for which zoom levels, +the `CDB_Overviews` functions can be used. + +The zoom level we're referring here to are those used +by the tiler: http://wiki.openstreetmap.org/wiki/Zoom_levels + +### CDB_CreateOverviews + +Create overviews for vector dataset. + +#### Using the function + +The table for which overviews will be generated should be +a Cartodbfied dataset with vector geometry. + +```sql +SELECT CDB_CreateOverviews('table_name'); +--- Generates overview tables for the dataset +``` + +#### Arguments + +CDB_CreateOverviews(table_name, ref_z_strategy, reduction_strategy) + +* **table_name** regclass, table for which overviews will be generated +* **ref_z_strategy** regproc, optional function that provides + the Z-scale strategy. + It returns the base Z level for the dataset. + It should have these arguments: + - **table_name** regclass, table to compute the reference Z scale for +* **reduction_strategy** regproc, optional function that provides + the reduction strategy to generate an overview table from a table + for a smaller scale (higher Z number). + It returns the name of the generated table. + It should have these arguments: + - **base_table_name** regclass, base table to be reduced. + - **base_z** integer, base Z level assigned to the base table. + - **overview_z** integer, Z level for which to generate the overview. + +#### Tolerance / level of detail + +The level of detail to be representable by each overview layer can +be specified as a tolerance in pixels (if different from the default of 1 pixel) +with the function `CDB_CreateOverviewsWithToleranceInPixels` +which has as a second additional argument the desired tolerance. + +This tolerance defines the maximum deviation in pixels of the overviews +geometries with respect to the original geometries when overview tables +are used for their intendend zoom level. + +### CDB_Overviews + +Obtain overview metadata for a given table (existing overviews). +The returned relation will be empty if the table has no overviews. + +The function can be applied to a single table: + +```sql +SELECT CDB_Overviews('table_name'); +--- Return existing overview Z levels and corresponding tables +``` + +Or to multiple tables passed as an array; this can be used +to obtain the overviews that can be applied to a query by +combining it with `CDB_QueryTablesText`: + +```sql +SELECT CDB_Overviews(CDB_QueryTablesText('SELECT * FROM table1, table2')); +--- Return existing overview Z levels and corresponding tables +``` + +The result of `CDB_Overviews` has three columns: + +| base_table | z | overview_table | +| ---------- | - | -------------- | +| table1 | 1 | table1_ov1 | +| table1 | 2 | table1_ov2 | +| table1 | 4 | table1_ov4 | +| table2 | 1 | table1_ov1 | +| table2 | 2 | table1_ov2 | + +#### Arguments + +CDB_Overviews(table_name) + +* **table_name** regclass, oid of table to obtain existing overviews for + +CDB_Overviews(table_names) + +* **table_names** regclass[], array of table oids + + +### CDB_DropOverviews + +Remove the overviews of a table, if present. + +```sql +SELECT CDB_DropOverviews('table_name'); +``` + +#### Arguments + +CDB_Overviews(table_name) + +* **table_name** regclass, table for which to drop existing overviews. diff --git a/lib/sql/doc/CDB_QuantileBins.md b/lib/sql/doc/CDB_QuantileBins.md new file mode 100644 index 0000000..26fd855 --- /dev/null +++ b/lib/sql/doc/CDB_QuantileBins.md @@ -0,0 +1,21 @@ +Find the breaks for N categories in a numerical column based on the [Quantile bins]. Below, the quantile method is used to determine color based on the area of the polygons. + +![qunatile](https://f.cloud.github.com/assets/370259/140714/932ed0e6-722b-11e2-9807-ffbd0fddb9ac.png) + +#### Using the function + +We can determine the 7 most optimal breaks in a column of numerical data as follows, + +```sql +SELECT CDB_QuantileBins(array_agg(numeric_column), 7) FROM table_name +-- Results in an ordered array like, {80,2281,7162,17652,39730,91077,1638094} +-- Each break happens up to, and equal, to a number: +-- (bin1 is less than or equal to 80, bin2 is less than or equal to 2281, etc.) +``` + +#### Arguments + +CDB_QuantileBins(in_array, breaks) + +* **in_array** numeric[]. A NUMERIC array of values. +* **breaks** int. The number of categories you want to create \ No newline at end of file diff --git a/lib/sql/doc/CDB_RectangleGrid.md b/lib/sql/doc/CDB_RectangleGrid.md new file mode 100644 index 0000000..221ce87 --- /dev/null +++ b/lib/sql/doc/CDB_RectangleGrid.md @@ -0,0 +1,46 @@ +Fill given extent with a rectangular coverage + +#### Using the function + +Create a rectangular grid from a polygon geometry. For example, take the geometry + +```sql + ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(10000000,-10000000), + ST_MakePoint(-10000000,10000000) + ) + ), + 3857) +``` + +We can create a grid as follows, + +```sql +SELECT CDB_RectangleGrid( + ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(10000000,-10000000), + ST_MakePoint(-10000000,10000000) + ) + ), + 3857), + 1000000, + 1000000 +) the_geom_webmercator +``` + +Which will look something like this, + +![rect grid](http://i.imgur.com/HuhOJRs.png) + +#### Arguments + +CDB_RectangleGrid(ext, width, height, origin) + +* **ext** geometry. Extent to fill. Only rectangles with center point falling inside the extent (or at the lower or leftmost edge) will be emitted. The returned hexagons will have the same SRID as this extent. +* **width** float. Width of each rectangle. Measure is in the same projection as **ext** +* **height** float. Height of each rectangle. Measure is in the same projection as **ext** +* **origin** OPTIONAL geometry. Optional origin to allow for exact tiling. If omitted the origin will be 0,0. The parameter is checked for having the same SRID as the extent. \ No newline at end of file diff --git a/lib/sql/doc/CDB_SetUserQuotaInBytes.md b/lib/sql/doc/CDB_SetUserQuotaInBytes.md new file mode 100644 index 0000000..b43f3b8 --- /dev/null +++ b/lib/sql/doc/CDB_SetUserQuotaInBytes.md @@ -0,0 +1,11 @@ +Sets user quota in bytes (superuser only) + +#### Using the function + +```sql +SELECT CDB_SetUserQuotaInBytes(10485760); +--- Returns the previously set quota. +--- Use 0 to disable quota. +``` + +REF: https://github.com/CartoDB/cartodb-postgresql/blob/master/scripts-available/CDB_Quota.sql diff --git a/lib/sql/doc/CDB_SyncTable.md b/lib/sql/doc/CDB_SyncTable.md new file mode 100644 index 0000000..9447dd0 --- /dev/null +++ b/lib/sql/doc/CDB_SyncTable.md @@ -0,0 +1,56 @@ +Synchronize two tables. This function will synchronize a *destination* table with a *source* table. +The idea is that the *destination* is a replica of *source* and *source* has been subject to +modifications that are to be applied to *destination*. + +This will be achieved by deleting the rows in the destination not present +in the source, inserting rows of the source not in the destination and updating modified rows. +If the destination table does not exist it will be created and all the rows of the source inserted into it. + +Both tables must have a consistent `cartodb_id` primary key column which will be used to match +the source and destination rows. + +Note that both tables do not necessarily become identical after the synchronization, since additional columns +may have been added to the destination; those columns will not be altered by the synchronization. + +In addition some source columns may be skipped by listing them in the optional last argument; such columns +will not be updated in the destination, so if they are present in it their values won't be altered. + + +#### Using the function + +Import some data using COPY FROM into a temporary table, then synchronize a table with the data and +finally delete the temporary table. This could be used import and update some data periodically while +allowing to add columns to the data that will be preserved across updates. + +```sql +CREATE tmp_pois(cartodb_id int, name text, type text, longitude double precision, latitude double precision, rank int); +COPY tmp_pois FROM '/tmp/pois.csv'; +SELECT CDB_SyncTable('tmp_pois', 'public', 'pois'); +DROP TABLE tmp_pois; +``` + +Now we could perform some changes to the `pois` to maintain our own ranking: + +```sql +UPDATE pois SET rank = random()*4 + 1; +``` + +Then, if the source were updated at `/tmp/pois.csv` we could synchronize with it while preserving our `rank` values with: + +```sql +CREATE tmp_pois(cartodb_id int, name text, type text, longitude double precision, latitude double precision, rank int); +COPY tmp_pois FROM '/tmp/pois.csv'; +SELECT CDB_SyncTable('tmp_pois', 'public', 'pois', '{rank}'); +DROP TABLE tmp_pois; +``` + +#### Arguments + +``` +CDB_SyncTable(src_table, dst_schema, dst_table, skip_cols) +``` + +* **src_table** REGCLASS the source data for the synchronization +* **dst_scgena** REGNAMESPACE the destination schema +* **dst_table** NAME the destination table to be updated +* **skip_cols** NAME[] an array of column names, empty by default, which will be skipped diff --git a/lib/sql/doc/CDB_TransformToWebmercator.md b/lib/sql/doc/CDB_TransformToWebmercator.md new file mode 100644 index 0000000..99eab64 --- /dev/null +++ b/lib/sql/doc/CDB_TransformToWebmercator.md @@ -0,0 +1,44 @@ +Function to "safely" transform to webmercator. This function is most useful for rendering custom geometries using the CartoDB tiler. Often, transforming a projection like WGS84 can cause issues with extents beyond what are actually valid in webmercator, this attempts to fix those issues. + +#### Using the function + +Using a box that is nearly the full globe, + +```sql +ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(-180,60), + ST_MakePoint(180,-60) + ) + ), + 4326 +) +``` + +We can then convert it to a renderable webmercator geometry. + +```sql +SELECT CDB_TransformToWebmercator( + ST_SetSRID( + ST_Envelope( + ST_Collect( + ST_MakePoint(-10,60), + ST_MakePoint(300,-60) + ) + ), + 4326 + ) +) +``` + +Would give you back a single valid rectangle in webmercator. Since a longitude of 300 would convert to an unallowed webmercator coordinate, it gets clipped first. Valid extent is WGS84 (-180, -89, 180, 89) + +![valid geom](http://i.imgur.com/EFdXiqt.png) + + +#### Arguments + +CDB_TransformToWebmercator(geom) + +* **geom** geometry \ No newline at end of file diff --git a/lib/sql/doc/CDB_UserTables.md b/lib/sql/doc/CDB_UserTables.md new file mode 100644 index 0000000..7378621 --- /dev/null +++ b/lib/sql/doc/CDB_UserTables.md @@ -0,0 +1,15 @@ +List the name of available tables (only the usable ones) + +#### Using the function + +```sql +--- Returns a row for each table having given permission with the table name. +--- It also returns tables from others users if you've permission to see them. For example, consider the following scenario: +--- User X and User Y at account C. +--- User X has a public table T. +--- User Y will see table T. +--- Currently accepted permissions are: 'public', 'private' or 'all' +SELECT CDB_UserTables(perms) +``` + +REF: https://github.com/CartoDB/cartodb-postgresql/blob/master/scripts-available/CDB_UserTables.sql diff --git a/lib/sql/doc/CDB_XYZ_Extent.md b/lib/sql/doc/CDB_XYZ_Extent.md new file mode 100644 index 0000000..df022f2 --- /dev/null +++ b/lib/sql/doc/CDB_XYZ_Extent.md @@ -0,0 +1,22 @@ +Determine the spatial extent of a tile based on the tile's XYZ coordinate. + +#### Using the function + +Take a common tile with coordinates x=3, y=2, z=2, + +![2/3/2](https://viz2.cartodb.com/tiles/quantile_breaks/2/3/2.png) + +To determine its extent you would run, + +```sql +SELECT CDB_XYZ_Extent(3,2,2) +--- Returns a WKB polygon in Webmercator (SRID 3857) +``` + +#### Arguments + +CDB_XYZ_Extent(x,y,z) + +* **x** integer +* **y** integer +* **z** integer \ No newline at end of file diff --git a/lib/sql/doc/CDB_XYZ_Resolution.md b/lib/sql/doc/CDB_XYZ_Resolution.md new file mode 100644 index 0000000..7bbf75c --- /dev/null +++ b/lib/sql/doc/CDB_XYZ_Resolution.md @@ -0,0 +1,20 @@ +Return pixel resolution of tiles at a given zoom level + +#### Using the function + +Take a common tile with zoom, z=2, + +![2/3/2](https://viz2.cartodb.com/tiles/quantile_breaks/2/3/2.png) + +To determine the resolution of these pixels, + +```sql +SELECT CDB_XYZ_Resolution(2) +--- Returns a float, 39135.7587890625 +``` + +#### Arguments + +CDB_XYZ_Resolution(z) + +* **z** integer \ No newline at end of file diff --git a/lib/sql/doc/CartoDB-PLpgSQL.md b/lib/sql/doc/CartoDB-PLpgSQL.md new file mode 100644 index 0000000..9c5976e --- /dev/null +++ b/lib/sql/doc/CartoDB-PLpgSQL.md @@ -0,0 +1,38 @@ +INTRODUCTION +============ + +CartoDB uses a number of custom [PLpgSQL](http://www.postgresql.org/docs/8.3/static/plpgsql.html) functions to perform a few magical things. Those functions are accessible to users on CartoDB as well, so we would like to document what they are and what they do here. + +## Spatial functions + +[CDB_HexagonGrid](CDB_HexagonGrid) - create hexagonal grid from extent and size + +[CDB_MakeHexagon](CDB_MakeHexagon) - make a hexagon with given center and side + +[CDB_RectangleGrid](CDB_RectangleGrid) - fill given extent with a rectangular coverage + +##### Tile based + +[CDB_XYZ_Extent](CDB_XYZ_Extent) - Find the extent of a tile by XYZ + +[CDB_XYZ_Resolution](CDB_XYZ_Resolution) - Find the pixel resolution of tiles + +[CDB_TransformToWebmercator](CDB_TransformToWebmercator) - Convert a geometry to valid webmercator + +## Statistical functions + +[CDB_JenksBins](CDB_JenksBins) - Find breaks in an array of numbers using Jenks method + +[CDB_HeadsTailsBins](CDB_HeadsTailsBins) - Find breaks in an array of numbers using Heads/Tails method + +[CDB_QuantileBins](CDB_QuantileBins) - Find quantile breaks in an array of numbers + +## System functions + +[CDB_UserTables](CDB_UserTables) - Get a list of all tables in your account + +[[CDB_SetUserQuotaInBytes]] - Set maximum user quota in bytes + +column names - now returned in JSON response + +column types - now returned in JSON response diff --git a/lib/sql/doc/CartoDB-user-table.rst b/lib/sql/doc/CartoDB-user-table.rst new file mode 100644 index 0000000..c1bb569 --- /dev/null +++ b/lib/sql/doc/CartoDB-user-table.rst @@ -0,0 +1,68 @@ +CartoDB User Table +================== + +Introduction +---------- +A CartoDB user table is a table with a well-known set of columns and a well-known set of triggers attached on. + +Columns +---------- +The required columns of a CartoDB table are: + +- ``cartodb_id`` + - This column will be used as the primary key of the table and it has a sequence as default value + - Its values must be integer, non-zero, non-null and unique + - B-Tree indexed +- ``the_geom`` + - This column stores the main geometric features of a table + - The type of the column in the Postgres database is ``geometry(Geometry,4326)``` + - GiST indexed + - geometry, GiST indexed, constrained (see below) +- ``the_geom_webmercator`` + - This column stores the geometries used for rendering purposes + - The type of the column in the Postgres database is ``geometry(Geometry,3857)`` + - GiST indexed + - This column is automatically updated by the system when the ``the_geom`` column is updated or when there is an insertion of a new row into the table (See triggers below) + +The values of ``the_geom`` and ``the_geom_webmercator`` must be two-dimensional Points, MultiLineStrings or MultiPolygons. Different geometric types in a CartoDB table are not supported. + +Described table example +^^^^^^^^^^ +:: + + Column | Type | Modifiers + ----------------------+-------------------------+-------------------------------------------------------- + cartodb_id | bigint | not null default nextval('t_cartodb_id_seq'::regclass) + the_geom | geometry(Geometry,4326) | + the_geom_webmercator | geometry(Geometry,3857) | + Indexes: + "table_name_pkey" PRIMARY KEY, btree (cartodb_id) + "table_name_the_geom_idx" gist (the_geom) + "table_name_the_geom_webmercator_idx" gist (the_geom_webmercator) + +Triggers +---------- +The triggers generated in each CartoDB table are: + +- ``track_updates`` after modifying statement updates ``cdb_tablemetadata`` +- ``test_quota`` before changing statement to forbid if overquota +- ``test_quota_per_row`` before insert ot update row to forbid if overquota (checked on a probabilistic basis) +- ``update_the_geom_webmercator`` before insert or update row to maintain the ``the_geom_webmercator`` updated with the contents in ``the_geom`` + +Described triggers example +^^^^^^^^^^ +:: + + test_quota BEFORE INSERT OR UPDATE ON t FOR EACH STATEMENT EXECUTE PROCEDURE cdb_checkquota('0.1', '-1', 'public') + test_quota_per_row BEFORE INSERT OR UPDATE ON t FOR EACH ROW EXECUTE PROCEDURE cdb_checkquota('0.001', '-1', 'public') + track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON t FOR EACH STATEMENT EXECUTE PROCEDURE cdb_tablemetadata_trigger() + update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON t FOR EACH ROW EXECUTE PROCEDURE _cdb_update_the_geom_webmercator() + + +Further details +---------- + +Some conversions will be attempted to perform upon cartodbfication when certain fields appear: + +- ``cartodb_id``: If found type TEXT will be attempted to cast to integer. If not casteable, an eror will be raised. +- ``the_geom``: If found type TEXT will be attempted to cast to geometry(Geometry,4326). diff --git a/lib/sql/doc/README.md b/lib/sql/doc/README.md new file mode 100644 index 0000000..e18e32c --- /dev/null +++ b/lib/sql/doc/README.md @@ -0,0 +1,23 @@ +# Contents + +* [CartoDB-user-table](CartoDB-user-table.md) +* [CartoDB-PLpgSQL](CartoDB-PLpgSQL.md) +* [CDB_ColumnNames](CDB_ColumnNames.md) +* [CDB_ColumnType](CDB_ColumnType.md) +* [CDB_HeadsTailsBins](CDB_HeadsTailsBins.md) +* [CDB_HexagonGrid](CDB_HexagonGrid.md) +* [CDB_JenksBins](CDB_JenksBins.md) +* [CDB_MakeHexagon](CDB_MakeHexagon.md) +* [CDB_QuantileBins](CDB_QuantileBins.md) +* [CDB_RectangleGrid](CDB_RectangleGrid.md) +* [CDB_SetUserQuotaInBytes](CDB_SetUserQuotaInBytes.md) +* [CDB_TransformToWebmercator](CDB_TransformToWebmercator.md) +* [CDB_UserTables](CDB_UserTables.md) +* [CDB_XYZ_Extent](CDB_XYZ_Extent.md) +* [CDB_XYZ_Resolution](CDB_XYZ_Resolution.md) + +The CartoDB PostgreSQL extension is a module to load into each CartoDB user database to perform cartodb-specific security and functionality checks. + +# Checks + +User tables need to match certain structure criteria (See [[CartoDB-user-table]]) so the extension should provide a mean to enforce such structure everytime an attempt to change structure is encountered. diff --git a/lib/sql/doc/cartodbfy-requirements.rst b/lib/sql/doc/cartodbfy-requirements.rst new file mode 100644 index 0000000..ed5e1eb --- /dev/null +++ b/lib/sql/doc/cartodbfy-requirements.rst @@ -0,0 +1,63 @@ +CartoDBfy Requirements +====================== + +Introduction +------------ + +This document aims at describing what the CartoDBfication is and what its formal requirements are, with the following goals in mind: + +- Clarify what are the expectations of the "cartodbfycation process". +- Define an important part of what should be a stable, public API +- Allow for better testing, which should in turn... +- ...ease modifications and increase quality of the code + + +What is the CartoDBfycation +--------------------------- + +The CartoDBfycation is the process of converting an arbitrary postgres table into a valid CartoDB table, and register it in the system so that it can be used in the CartoDB editor and platform to generate maps and analysis. + +It is performed by running the function ``CDB_CartodbfyTable(reloid REGCLASS)`` over a target table. + +Valid CartoDB tables +-------------------- + +A valid CartoDB table shall meet the following conditions: + +- Have a ``cartodb_id`` column with integer, unique, non-zero and non-null values as primary key with a sequence as default value +- Have a ``the_geom`` column of type ``Geometry`` with SRID 4326 +- Have a ``the_geom_webmercator`` column of type ``Geometry`` with SRID 3857 +- The columns ``the_geom`` and ``the_geom_webmercator`` shall be in sync (task of the ``update_the_geom_webmercator`` trigger) + +Additionally, a CartoDB table can contain other columns. + +See the `CartoDB User Table documentation`_ + +.. _CartoDB User Table documentation: https://github.com/CartoDB/cartodb-postgresql/blob/master/doc/CartoDB-user-table.rst +for further information. + +High level requirements +----------------------- + +Here is a list of high level requirments for the public function ``CDB_CartodbfyTable()``: + +- A call to the function shall modify/rewrite the table and produce a valid CartoDB table with the same name. +- A call to the function shall cause the registration of the table into the platform. +- It shall be idempotent, meaning that successive calls to the function shall not produce any visible effect in the system. +- If there's a column containing a geometry, it shall be used to generate ``the_geom`` and the ``the_geom_webmercator`` columns. +- Exporting and re-importing the same table in CartoDB shall produce equivalent tables, with the same features associated to the same ``cartodb_id``'s. + + +Note that there should be only one geometry per row in the source table. If there's more than one, then which one is used for ``the_geom`` and ``the_geom_webmercator`` fields is not determined. + + +Low-level requirements +---------------------- + +- If the original table contains a valid (integer, unique, non-zero and not null) ``cartodb_id`` column, it shall be used +- If the original table contains a ``the_geom`` column or a ``the_geom_webmercator`` geometric column in the expected projection (EPSG 4326 and EPSG 3857, respectively) they shall be used. +- A modification of a cartodbfy'ed table shall insert or update a row in ``CDB_TableMetadata`` +- A cartodbfy'ed table shall have a ``btree`` index on ``cartodb_id`` +- A cartodbfy'ed table shall have ``gist`` indices on ``the_geom`` and ``the_geom_webmercator`` +- Cartodbfy shall deal with text columns for imports, regarding CartoDB columns (``cartodb_id``, ``the_geom``, ``the_geom_webmercator``) + diff --git a/lib/sql/expected/test_setup.out b/lib/sql/expected/test_setup.out new file mode 100644 index 0000000..cb4d895 --- /dev/null +++ b/lib/sql/expected/test_setup.out @@ -0,0 +1,9 @@ +CREATE EXTENSION postgis; +CREATE EXTENSION plpythonu; +CREATE EXTENSION cartodb; +CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) +RETURNS void AS $$ +BEGIN + RAISE NOTICE 'cdb_invalidate_varnish(%) called', table_name; +END; +$$ LANGUAGE 'plpgsql'; diff --git a/lib/sql/scripts-available/CDB_AnalysisCatalog.sql b/lib/sql/scripts-available/CDB_AnalysisCatalog.sql new file mode 100644 index 0000000..7b65119 --- /dev/null +++ b/lib/sql/scripts-available/CDB_AnalysisCatalog.sql @@ -0,0 +1,95 @@ +-- Table to register analysis nodes from https://github.com/cartodb/camshaft +CREATE TABLE IF NOT EXISTS +@extschema@.cdb_analysis_catalog ( + -- md5 hex hash + node_id char(40) CONSTRAINT cdb_analysis_catalog_pkey PRIMARY KEY, + -- being json allows to do queries like analysis_def->>'type' = 'buffer' + analysis_def json NOT NULL, + -- can reference other nodes in this very same table, allowing recursive queries + input_nodes char(40) ARRAY NOT NULL DEFAULT '{}', + status TEXT NOT NULL DEFAULT 'pending', + CONSTRAINT valid_status CHECK ( + status IN ( 'pending', 'waiting', 'running', 'canceled', 'failed', 'ready' ) + ), + created_at timestamp with time zone NOT NULL DEFAULT now(), + -- should be updated when some operation was performed in the node + -- and anything associated to it might have changed + updated_at timestamp with time zone DEFAULT NULL, + -- should register last time the node was used + used_at timestamp with time zone NOT NULL DEFAULT now(), + -- should register the number of times the node was used + hits NUMERIC DEFAULT 0, + -- should register what was the last node using current node + last_used_from char(40), + -- last job modifying the node + last_modified_by uuid, + -- store error message for failures + last_error_message text, + -- cached tables involved in the analysis + cache_tables regclass[] NOT NULL DEFAULT '{}', + -- useful for multi account deployments + username text +); + +-- This can only be called from an SQL script executed by CREATE EXTENSION +DO LANGUAGE 'plpgsql' $$ +BEGIN + PERFORM pg_catalog.pg_extension_config_dump('@extschema@.cdb_analysis_catalog', ''); +END +$$; + +-- Migrations to add new columns from old versions. +-- IMPORTANT: Those columns will be added in order of creation. To be consistent +-- in column order, ensure that new columns are added at the end and in the same order. + +DO $$ + BEGIN + BEGIN + ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN last_modified_by uuid; + EXCEPTION + WHEN duplicate_column THEN END; + END; +$$; + +DO $$ + BEGIN + BEGIN + ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN last_error_message text; + EXCEPTION + WHEN duplicate_column THEN END; + END; +$$; + +DO $$ + BEGIN + BEGIN + ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN cache_tables regclass[] NOT NULL DEFAULT '{}'; + EXCEPTION + WHEN duplicate_column THEN END; + END; +$$; + +DO $$ + BEGIN + BEGIN + ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN username text; + EXCEPTION + WHEN duplicate_column THEN END; + END; +$$; + +-- We want the "username" column to be moved to the last position if it was on a position from other versions +-- see https://github.com/CartoDB/cartodb-postgresql/issues/276 +DO LANGUAGE 'plpgsql' $$ + DECLARE + column_index int; + BEGIN + SELECT ordinal_position FROM information_schema.columns WHERE table_name='cdb_analysis_catalog' AND table_schema='@extschema@' AND column_name='username' INTO column_index; + IF column_index = 1 OR column_index = 10 THEN + ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN username_final text; + UPDATE @extschema@.cdb_analysis_catalog SET username_final = username; + ALTER TABLE @extschema@.cdb_analysis_catalog DROP COLUMN username; + ALTER TABLE @extschema@.cdb_analysis_catalog RENAME COLUMN username_final TO username; + END IF; + END; +$$; diff --git a/lib/sql/scripts-available/CDB_AnalysisCheck.sql b/lib/sql/scripts-available/CDB_AnalysisCheck.sql new file mode 100644 index 0000000..8645967 --- /dev/null +++ b/lib/sql/scripts-available/CDB_AnalysisCheck.sql @@ -0,0 +1,62 @@ +-- Read configuration parameter analysis_quota_factor, making it +-- accessible to regular users (which don't have access to cdb_conf) +CREATE OR REPLACE FUNCTION @extschema@._CDB_GetConfAnalysisQuotaFactor() +RETURNS float8 AS +$$ +BEGIN + RETURN @extschema@.CDB_Conf_GetConf('analysis_quota_factor')::text::float8; +END; +$$ +LANGUAGE 'plpgsql' STABLE PARALLEL SAFE SECURITY DEFINER; + + +-- Get the factor (fraction of the quota) for Camshaft cached analysis tables +CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisQuotaFactor() +RETURNS float8 AS +$$ +DECLARE + factor float8; +BEGIN + -- We use a floating point cdb_conf parameter + factor := @extschema@._CDB_GetConfAnalysisQuotaFactor(); + -- With a default value + IF factor IS NULL THEN + factor := 2; + END IF; + RETURN factor; +END; +$$ +LANGUAGE 'plpgsql' STABLE PARALLEL SAFE; + +-- This checks the space used up by Camshaft cached analysis tables. +-- An exception will be raised if the limits are exceeded. +-- The name of an analysis table is passed; this, in addition to the +-- db role that executes this function is used to determined which +-- analysis tables will be considered. +CREATE OR REPLACE FUNCTION @extschema@.CDB_CheckAnalysisQuota(table_name TEXT) +RETURNS void AS +$$ +DECLARE + schema_name TEXT; + user_name TEXT; + nominal_quota int8; + cache_size float8; +BEGIN + -- We rely on the search_path to determine the user's schema and + -- check for all analysis tables in that schema. + -- An alternative would be to use cdb_analysis_catalog to + -- select analysis tables (cache_tables) from the same user, analysis or node. + -- For example: + -- SELECT unnest(cache_tables) FROM cdb_analysis_catalog + -- WHERE username IN (SELECT username FROM cdb_analysis_catalog + -- WHERE table_name::regclass = ANY (cache_tables)); + -- At the moment we're not using the provided table_name. + + SELECT current_schema() INTO schema_name; + EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO nominal_quota; + IF nominal_quota * @extschema@._CDB_AnalysisQuotaFactor() < @extschema@._CDB_AnalysisDataSize(schema_name) THEN + -- The limit is defined by a factor applied to the total space quota for the user + RAISE EXCEPTION 'Analysis cache space limits exceeded'; + END IF; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_AnalysisSupport.sql b/lib/sql/scripts-available/CDB_AnalysisSupport.sql new file mode 100644 index 0000000..b5f060d --- /dev/null +++ b/lib/sql/scripts-available/CDB_AnalysisSupport.sql @@ -0,0 +1,55 @@ +-- Internal auxiliar functions to deal with [Camshaft](https://github.com/cartodb/camshaft) cached analysis tables. + +-- This function returns TRUE if a given table name corresponds to a Camshaft cached analysis table +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_IsAnalysisTableName(table_name TEXT) +RETURNS BOOLEAN +AS $$ + BEGIN + RETURN table_name SIMILAR TO '\Aanalysis_[0-9a-f]{10}_[0-9a-f]{40}\Z'; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- This function returns a relation of Camshaft cached analysis tables in the given schema. +-- If the schema name parameter is NULL, then tables from all schemas +-- that may contain user tables are returned. +-- For each table, the regclass, schema name and table name are returned. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisTablesInSchema(schema_name text DEFAULT NULL) +RETURNS TABLE(table_regclass REGCLASS, schema_name TEXT, table_name TEXT) +AS $$ + SELECT * FROM @extschema@._CDB_UserTablesInSchema(schema_name) WHERE @extschema@._CDB_IsAnalysisTableName(table_name); +$$ LANGUAGE 'sql' STABLE PARALLEL SAFE; + +-- This function returns a relation user tables excluding analysis tables +-- If the schema name parameter is NULL, then tables from all schemas +-- that may contain user tables are returned. +-- For each table, the regclass, schema name and table name are returned. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_NonAnalysisTablesInSchema(schema_name text DEFAULT NULL) +RETURNS TABLE(table_regclass REGCLASS, schema_name TEXT, table_name TEXT) +AS $$ + SELECT * FROM @extschema@._CDB_UserTablesInSchema(schema_name) WHERE Not @extschema@._CDB_IsAnalysisTableName(table_name); +$$ LANGUAGE 'sql' STABLE PARALLEL SAFE; + +-- Total spaced used up by Camshaft cached analysis tables in the given schema. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisDataSize(schema_name TEXT DEFAULT NULL) +RETURNS bigint AS +$$ +DECLARE + total_size bigint; +BEGIN + WITH analysis_tables AS ( + SELECT t.schema_name, t.table_name FROM @extschema@._CDB_AnalysisTablesInSchema(schema_name) t + ) + SELECT COALESCE(INT8(SUM(@extschema@._CDB_total_relation_size(analysis_tables.schema_name, analysis_tables.table_name))))::int8 + INTO total_size FROM analysis_tables; + IF total_size IS NOT NULL THEN + RETURN total_size; + ELSE + RETURN 0; + END IF; +END; +$$ +LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_CartodbfyTable.sql b/lib/sql/scripts-available/CDB_CartodbfyTable.sql new file mode 100644 index 0000000..c54baf2 --- /dev/null +++ b/lib/sql/scripts-available/CDB_CartodbfyTable.sql @@ -0,0 +1,1319 @@ +-- Depends on: +-- * CDB_Helper.sql +-- * CDB_ExtensionUtils.sql +-- * CDB_TransformToWebmercator.sql +-- * CDB_TableMetadata.sql +-- * CDB_Quota.sql +-- * _CDB_UserQuotaInBytes() function, installed by rails +-- (user.rebuild_quota_trigger, called by rake task cartodb:db:update_test_quota_trigger) + +-- 1) Required checks before running cartodbfication +-- Either will pass silenty or raise an exception +CREATE OR REPLACE FUNCTION @extschema@._CDB_check_prerequisites(schema_name TEXT, reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF @extschema@.schema_exists(schema_name) = false THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name; + END IF; + + -- TODO: Check that user quota is set ? + BEGIN + EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name::text) INTO sql; + EXCEPTION WHEN undefined_function THEN + RAISE EXCEPTION 'Please set user quota before cartodbfying tables.'; + END; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Drop cartodb triggers (might prevent changing columns) +CREATE OR REPLACE FUNCTION @extschema@._CDB_drop_triggers(reloid REGCLASS) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + -- "track_updates" + sql := Format('DROP TRIGGER IF EXISTS track_updates ON %s', reloid::text); + EXECUTE sql; + + -- "update_the_geom_webmercator" + sql := Format('DROP TRIGGER IF EXISTS update_the_geom_webmercator_trigger ON %s', reloid::text); + EXECUTE sql; + + -- "test_quota" and "test_quota_per_row" + sql := Format('DROP TRIGGER IF EXISTS test_quota ON %s', reloid::text); + EXECUTE sql; + sql := Format('DROP TRIGGER IF EXISTS test_quota_per_row ON %s', reloid::text); + EXECUTE sql; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + +-- Cartodb_id creation & validation or renaming if invalid +CREATE OR REPLACE FUNCTION @extschema@._CDB_create_cartodb_id_column(reloid REGCLASS) + RETURNS void +AS $$ +DECLARE + sql TEXT; + rec RECORD; + rec2 RECORD; + had_column BOOLEAN; + i INTEGER; + new_name TEXT; + cartodb_id_name TEXT; +BEGIN + << cartodb_id_setup >> + LOOP --{ + had_column := FALSE; + BEGIN + sql := Format('ALTER TABLE %s ADD cartodb_id SERIAL NOT NULL UNIQUE', reloid::text); + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + cartodb_id_name := 'cartodb_id'; + EXIT cartodb_id_setup; + EXCEPTION + WHEN duplicate_column THEN + RAISE NOTICE 'Column cartodb_id already exists'; + had_column := TRUE; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + + IF had_column THEN + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Check data type is an integer + SELECT + pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') as seq, + t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a + WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id' + INTO STRICT rec; + + -- 20=int2, 21=int4, 23=int8 + IF rec.oid NOT IN (20,21,23) THEN -- { + RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname; + ELSIF rec.seq IS NULL THEN -- }{ + RAISE NOTICE 'Existing cartodb_id field does not have an associated sequence, renaming'; + ELSE -- }{ + sql := Format('ALTER TABLE %s ALTER COLUMN cartodb_id SET NOT NULL', reloid::text); + IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a + WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid + AND a.attrelid = reloid + AND NOT a.attisdropped + AND a.attname = 'cartodb_id' + AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey + THEN + sql := sql || ', ADD unique(cartodb_id)'; + END IF; + BEGIN + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + cartodb_id_name := 'cartodb_id'; + EXIT cartodb_id_setup; + EXCEPTION + WHEN unique_violation OR not_null_violation THEN + RAISE NOTICE '%, renaming', SQLERRM; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + END IF; -- } + + -- invalid column, need rename and re-create it + i := 0; + << rename_column >> + LOOP --{ + new_name := '_cartodb_id' || i; + BEGIN + sql := Format('ALTER TABLE %s RENAME COLUMN cartodb_id TO %I', reloid::text, new_name); + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXCEPTION + WHEN duplicate_column THEN + i := i+1; + CONTINUE rename_column; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + cartodb_id_name := new_name; + EXIT rename_column; + END LOOP; --} + CONTINUE cartodb_id_setup; + END IF; + END LOOP; -- } + + -- Try to copy data from new name if possible + IF new_name IS NOT NULL THEN + RAISE NOTICE 'Trying to recover data from % column', new_name; + BEGIN + -- Copy existing values to new field + -- NOTE: using ALTER is a workaround to a PostgreSQL bug and is also known to be faster for tables with many rows + -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost + sql := Format('ALTER TABLE %s ALTER cartodb_id TYPE int USING %I::integer', reloid::text, new_name); + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Find max value + sql := Format('SELECT coalesce(max(cartodb_id), 0) as max FROM %s', reloid::text); + RAISE DEBUG 'Running %', sql; + EXECUTE sql INTO rec; + + -- Find sequence name + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Reset sequence name + sql := Format('ALTER SEQUENCE %s RESTART WITH %s', rec2.seq::text, rec.max + 1); + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Drop old column (all went fine if we got here) + sql := Format('ALTER TABLE %s DROP %I', reloid::text, new_name); + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', + SQLERRM, SQLSTATE; + END; + END IF; + + -- Set primary key of the table if not already present (e.g. tables created from SQL API) + IF cartodb_id_name IS NULL THEN + RAISE EXCEPTION 'Cartodbfying % (Didnt get cartodb_id field name)', reloid; + END IF; + BEGIN + sql := Format('ALTER TABLE %s ADD PRIMARY KEY (cartodb_id)', reloid::text); + EXECUTE sql; + EXCEPTION + WHEN others THEN + RAISE DEBUG 'Table % Already had PRIMARY KEY', reloid; + END; + +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + +-- Create all triggers +-- NOTE: drop/create has the side-effect of re-enabling disabled triggers +CREATE OR REPLACE FUNCTION @extschema@._CDB_create_triggers(schema_name TEXT, reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN +-- "track_updates" + sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON ' + || reloid::text + || ' FOR EACH STATEMENT EXECUTE PROCEDURE @extschema@.cdb_tablemetadata_trigger()'; + EXECUTE sql; + +-- "update_the_geom_webmercator" +-- TODO: why _before_ and not after ? + sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE @extschema@._CDB_update_the_geom_webmercator()'; + EXECUTE sql; + +-- "test_quota" and "test_quota_per_row" + + sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' EXECUTE PROCEDURE @extschema@.CDB_CheckQuota(0.1, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; + + sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE @extschema@.CDB_CheckQuota(0.001, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- 8.b) Create all raster triggers +-- NOTE: drop/create has the side-effect of re-enabling disabled triggers +CREATE OR REPLACE FUNCTION @extschema@._CDB_create_raster_triggers(schema_name TEXT, reloid REGCLASS) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN +-- "track_updates" + sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON ' + || reloid::text + || ' FOR EACH STATEMENT EXECUTE PROCEDURE @extschema@.cdb_tablemetadata_trigger()'; + EXECUTE sql; + +-- "test_quota" and "test_quota_per_row" + + sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' EXECUTE PROCEDURE @extschema@.CDB_CheckQuota(1, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; + + sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE @extschema@.CDB_CheckQuota(0.001, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + + +-- Update the_geom_webmercator +CREATE OR REPLACE FUNCTION @extschema@._CDB_update_the_geom_webmercator() + RETURNS trigger +AS $$ +BEGIN + NEW.the_geom_webmercator := @extschema@.CDB_TransformToWebmercator(NEW.the_geom); + RETURN NEW; +END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + +--- Trigger to update the updated_at column. No longer added by default +--- but kept here for compatibility with old tables which still have this behavior +--- and have it added +CREATE OR REPLACE FUNCTION @extschema@._CDB_update_updated_at() + RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at := now(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql VOLATILE; + +-- Auxiliary function +CREATE OR REPLACE FUNCTION @extschema@._CDB_is_raster_table(schema_name TEXT, reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + sql TEXT; + is_raster BOOLEAN; + rel_name TEXT; +BEGIN + IF @extschema@.schema_exists(schema_name) = FALSE THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name; + END IF; + + SELECT relname FROM pg_class WHERE oid=reloid INTO rel_name; + + BEGIN + sql := 'SELECT the_raster_webmercator FROM ' + || quote_ident(schema_name::TEXT) + || '.' + || quote_ident(rel_name::TEXT) + || ' LIMIT 1'; + is_raster = TRUE; + EXECUTE sql; + + EXCEPTION WHEN undefined_column THEN + is_raster = FALSE; + END; + + RETURN is_raster; +END; +$$ LANGUAGE PLPGSQL STABLE PARALLEL UNSAFE; + + + +-- //////////////////////////////////////////////////// + +-- Ensure a table is a "cartodb" table (See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table) + +DROP FUNCTION IF EXISTS CDB_CartodbfyTable(reloid REGCLASS); +CREATE OR REPLACE FUNCTION @extschema@.CDB_CartodbfyTable(reloid REGCLASS) +RETURNS REGCLASS +AS $$ +BEGIN + RETURN @extschema@.CDB_CartodbfyTable('public', reloid); +END; +$$ LANGUAGE PLPGSQL; + + +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= +-- +-- NEW CARTODBFY CODE FROM HERE ON DOWN +-- +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= +-- +-- CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) +-- +-- Main function, calls the following functions, with a little +-- logic before the table re-write to avoid re-writing if the table +-- already has all the necessary columns in place. +-- +-- It returns the destoid of the table. If no rewritting is needed +-- the return value will be equal to reloid. +-- +-- +-- (0) _CDB_check_prerequisites +-- As before, this checks the prerequisites before trying to cartodbfy +-- +-- (1) _CDB_drop_triggers +-- As before, this drops all the metadata and geom sync triggers +-- +-- (2) _CDB_Has_Usable_Primary_ID() +-- Returns TRUE if it can find a unique and not null integer primary key named +-- 'cartodb_id' or can rename an existing key. +-- Returns FALSE otherwise. +-- +-- (3) _CDB_Has_Usable_Geom() +-- Looks for existing EPSG:4326 and EPSG:3857 geometry columns, and +-- renames them to the standard names if it can find them, returning TRUE. +-- If it cannot find both columns in the right EPSG, returns FALSE. +-- +-- (4) _CDB_Rewrite_Table() +-- If table does not have a usable primary key and both usable geom +-- columns it needs to be re-written. Function constructs an appropriate +-- CREATE TABLE AS SELECT... query and executes it. +-- +-- (5) _CDB_Add_Indexes() +-- Checks the primary key column for primary key constraint, adds it if +-- missing. Check geometry columns for GIST indexes and adds them if missing. +-- +-- (6) _CDB_create_triggers() +-- Adds the system metadata and geometry column update triggers back +-- onto the table. +-- +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= + + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Columns(OUT pkey TEXT, OUT geomcol TEXT, OUT mercgeomcol TEXT) +RETURNS record +AS $$ +BEGIN + +pkey := 'cartodb_id'; +geomcol := 'the_geom'; +mercgeomcol := 'the_geom_webmercator'; + +END; +$$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; + + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Error(message TEXT, funcname TEXT DEFAULT '_CDB_Error') +RETURNS void +AS $$ +BEGIN + + RAISE EXCEPTION 'CDB(%): %', funcname, message; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL SAFE; + + +CREATE OR REPLACE FUNCTION @extschema@._CDB_SQL(sql TEXT, funcname TEXT DEFAULT '_CDB_SQL') +RETURNS void +AS $$ +BEGIN + + RAISE DEBUG 'CDB(%): %', funcname, sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE EXCEPTION 'CDB(%:%:%): %', funcname, SQLSTATE, SQLERRM, sql; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +-- DEPRECATED: Use _CDB_Unique_Identifier since it's UTF8 Safe and length +-- aware. Find a unique relation name in the given schema, starting from the +-- template given. If the template is already unique, just return it; +-- otherwise, append an increasing integer until you find a unique variant. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Relation_Name(schemaname TEXT, relationname TEXT) +RETURNS TEXT +AS $$ +DECLARE + rec RECORD; + i INTEGER; + newrelname TEXT; +BEGIN + + RAISE EXCEPTION '_CDB_Unique_Relation_Name is DEPRECATED. Use _CDB_Unique_Identifier(prefix TEXT, relname TEXT, suffix TEXT, schema TEXT DEFAULT NULL)'; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL SAFE; + + +-- DEPRECATED: Use _CDB_Unique_Column_Identifier since it's UTF8 Safe and length +-- aware. Find a unique column name in the given relation, starting from the +-- column name given. If the column name is already unique, just return it; +-- otherwise, append an increasing integer until you find a unique variant. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Column_Name(reloid REGCLASS, columnname TEXT) +RETURNS TEXT +AS $$ +DECLARE + rec RECORD; + i INTEGER; + newcolname TEXT; +BEGIN + + RAISE EXCEPTION '_CDB_Unique_Column_Name is DEPRECATED. Use _CDB_Unique_Column_Identifier(prefix TEXT, relname TEXT, suffix TEXT, reloid REGCLASS DEFAULT NULL)'; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL SAFE; + + +-- Find out if the table already has a usable primary key +-- If the table has both a usable key and usable geometry +-- we can no-op on the table copy and just ensure that the +-- indexes and triggers are in place +DROP FUNCTION IF EXISTS _CDB_Has_Usable_Primary_ID(reloid REGCLASS); +CREATE OR REPLACE FUNCTION @extschema@._CDB_Has_Usable_Primary_ID(reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + rec RECORD; + const RECORD; + i INTEGER; + sql TEXT; + useable_key BOOLEAN = false; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', 'entered function'; + + -- Read in the names of the CartoDB columns + const := @extschema@._CDB_Columns(); + + -- Do we already have a properly named column? + SELECT a.attname, i.indisprimary, i.indisunique, a.attnotnull, a.atttypid + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE c.oid = reloid + AND NOT a.attisdropped + AND a.attname = const.pkey; + + -- Found something named right... + IF FOUND THEN + + -- And it's a unique primary key! Done! + IF (rec.indisprimary OR rec.indisunique) AND rec.attnotnull THEN + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('found good ''%s''', const.pkey); + RETURN true; + + -- Check and see if the column values are unique and not null, + -- if they are, we can use this column... + ELSE + + -- Assume things are OK until proven otherwise... + useable_key := true; + BEGIN + sql := Format('ALTER TABLE %s ADD CONSTRAINT %s_pk PRIMARY KEY (%s)', reloid::text, const.pkey, const.pkey); + sql := sql || ', ' || Format('ADD CONSTRAINT %s_integer CHECK (%s::integer >=0);', const.pkey, const.pkey); + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', sql; + EXECUTE sql; + EXCEPTION + -- Failed unique check... + WHEN unique_violation THEN + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('column %s is not unique', const.pkey); + useable_key := false; + -- Failed not null check... + WHEN not_null_violation THEN + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('column %s contains nulls', const.pkey); + useable_key := false; + -- Failed integer check... + WHEN invalid_text_representation THEN + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('invalid input syntax for integer %s', const.pkey); + useable_key := false; + -- Other fatal error + WHEN others THEN + PERFORM _CDB_Error(sql, Format('_CDB_Has_Usable_Primary_ID: %s', SQLERRM)); + END; + + -- Clean up test constraint + IF useable_key THEN + PERFORM @extschema@._CDB_SQL(Format('ALTER TABLE %s DROP CONSTRAINT %s_pk', reloid::text, const.pkey)); + PERFORM @extschema@._CDB_SQL(Format('ALTER TABLE %s DROP CONSTRAINT %s_integer', reloid::text, const.pkey)); + + -- Move non-valid column out of the way + ELSE + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', + Format('found non-valid ''%s''', const.pkey); + + PERFORM @extschema@._CDB_Error(sql, Format('_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, %s', const.pkey)); + + END IF; + + RETURN useable_key; + + END IF; + + -- There's no column there named pkey + ELSE + + -- Is there another integer suitable primary key already? + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE c.oid = reloid AND NOT a.attisdropped + AND i.indisprimary AND i.indisunique AND a.attnotnull AND a.atttypid IN (20,21,23); + + -- Yes! Ok, rename it. + IF FOUND THEN + PERFORM @extschema@._CDB_SQL(Format('ALTER TABLE %s RENAME COLUMN %s TO %s', reloid::text, rec.attname, const.pkey),'_CDB_Has_Usable_Primary_ID'); + RETURN true; + ELSE + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', + Format('found no useful column for ''%s''', const.pkey); + END IF; + + END IF; + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', 'function complete'; + + -- Didn't find re-usable key, so return FALSE + RETURN false; +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Has_Usable_PK_Sequence(reloid REGCLASS) +RETURNS BOOLEAN +AS $$ +DECLARE + seq TEXT; + const RECORD; + has_sequence BOOLEAN = false; +BEGIN + + const := @extschema@._CDB_Columns(); + + SELECT pg_get_serial_sequence(reloid::text, const.pkey) + INTO STRICT seq; + has_sequence := seq IS NOT NULL; + + RETURN has_sequence; +END; +$$ LANGUAGE 'plpgsql' STABLE PARALLEL SAFE; + +-- Return a set of columns that can be candidates to be the_geom[webmercator] +-- with some extra information to analyze them. +CREATE OR REPLACE FUNCTION @extschema@._cdb_geom_candidate_columns(reloid REGCLASS) +RETURNS TABLE (attname name, srid integer, typname name, desired_attname text, desired_srid integer) +AS $$ +DECLARE + const RECORD; +BEGIN + + const := @extschema@._CDB_Columns(); + + RETURN QUERY + SELECT + a.attname, + CASE WHEN t.typname = 'geometry' THEN @postgisschema@.postgis_typmod_srid(a.atttypmod) ELSE NULL END AS srid, + t.typname, + f.desired_attname, f.desired_srid + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid, + (VALUES (const.geomcol, 4326), (const.mercgeomcol, 3857) ) as f(desired_attname, desired_srid) + WHERE c.oid = reloid + AND a.attnum > 0 + AND NOT a.attisdropped + AND @postgisschema@.postgis_typmod_srid(a.atttypmod) IN (4326, 3857, 0) + ORDER BY t.oid ASC; +END; +$$ LANGUAGE 'plpgsql' STABLE PARALLEL SAFE; + +DO $$ +BEGIN + SET search_path TO @extschema@; + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = '_cdb_has_usable_geom_record') THEN + CREATE TYPE @extschema@._cdb_has_usable_geom_record + AS (has_usable_geoms boolean, + text_geom_column boolean, + text_geom_column_name text, + text_geom_column_srid boolean, + has_geom boolean, + has_geom_name text, + has_mercgeom boolean, + has_mercgeom_name text); + END IF; +END$$; + +DROP FUNCTION IF EXISTS _CDB_Has_Usable_Geom(REGCLASS); +CREATE OR REPLACE FUNCTION @extschema@._CDB_Has_Usable_Geom(reloid REGCLASS) +RETURNS @extschema@._cdb_has_usable_geom_record +AS $$ +DECLARE + r1 RECORD; + r2 RECORD; + rv RECORD; + + const RECORD; + + has_geom BOOLEAN := false; + has_mercgeom BOOLEAN := false; + has_geom_name TEXT; + has_mercgeom_name TEXT; + + -- In case 'the_geom' is a text column + text_geom_column BOOLEAN := false; + text_geom_column_name TEXT := ''; + text_geom_column_srid BOOLEAN := true; + + -- Utility variables + srid INTEGER; + str TEXT; + sql TEXT; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', 'entered function'; + + -- Read in the names of the CartoDB columns + const := @extschema@._CDB_Columns(); + + -- Do we have a column we can use? + FOR r1 IN + SELECT * FROM @extschema@._cdb_geom_candidate_columns(reloid) + LOOP + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('checking column ''%s''', r1.attname); + + -- Name collision: right name (the_geom, the_geomwebmercator?) but wrong type... + IF r1.typname != 'geometry' AND r1.attname = r1.desired_attname THEN + + -- Maybe it's a geometry column hiding in a text column? + IF r1.typname IN ('text','varchar','char') THEN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('column ''%s'' is a text column', r1.attname); + + BEGIN + sql := Format('SELECT Max(@postgisschema@.ST_SRID(%I::@postgisschema@.geometry)) AS srid FROM %I', r1.attname, reloid::text); + EXECUTE sql INTO srid; + -- This gets skipped if EXCEPTION happens + -- Let the table writer know we need to convert from text + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('column ''%s'' can be cast from text to geometry', r1.attname); + text_geom_column := true; + text_geom_column_name := r1.attname; + -- Let the table writer know we need to force an SRID + IF srid = 0 THEN + text_geom_column_srid := false; + END IF; + -- Nope, the text in the column can't be converted into geometry + -- so rename it out of the way + EXCEPTION + WHEN others THEN + IF SQLERRM = 'parse error - invalid geometry' THEN + text_geom_column := false; + str := @extschema@._CDB_Unique_Column_Identifier(NULL, r1.attname, NULL, reloid); + sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Has_Usable_Geom'); + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', + Format('Text column %s is not convertible to geometry, renamed to %s', r1.attname, str); + ELSE + RAISE EXCEPTION 'CDB(_CDB_Has_Usable_Geom) UNEXPECTED ERROR'; + END IF; + END; + + -- Just change its name so we can write a new column into that name. + ELSE + str := @extschema@._CDB_Unique_Column_Identifier(NULL, r1.attname, NULL, reloid); + sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Has_Usable_Geom'); + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', + Format('%s is the wrong type, renamed to %s', r1.attname, str); + END IF; + + -- Found a geometry column! + ELSIF r1.typname = 'geometry' THEN + + -- If it's the right SRID, we can use it in place without + -- transforming it! + IF r1.srid = r1.desired_srid THEN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('found acceptable ''%s''', r1.attname); + + IF r1.desired_attname = const.geomcol THEN + has_geom := true; + has_geom_name := r1.attname; + ELSIF r1.desired_attname = const.mercgeomcol THEN + has_mercgeom := true; + has_mercgeom_name := r1.attname; + END IF; + + -- If it's an unknown SRID, we need to know that too + ELSIF r1.srid = 0 THEN + + -- Unknown SRID, we'll have to fill it in later + text_geom_column_srid := true; + + END IF; + + END IF; + + END LOOP; + + SELECT + -- If table is perfect (no transforms required), return TRUE! + has_geom AND has_mercgeom AS has_usable_geoms, + -- If the geometry column is hiding in a text field, return enough info to deal w/ it. + text_geom_column, text_geom_column_name, text_geom_column_srid, + -- Return enough info to rename geom columns if needed + has_geom, has_geom_name, has_mercgeom, has_mercgeom_name + INTO rv; + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('returning %s', rv); + + RETURN rv; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +-- Create a copy of the table. Assumes that the "Has usable" functions +-- have already been run, so that if there is a 'cartodb_id' column, it is +-- a "good" one, and the same for the geometry columns. If all the required +-- columns are in place already, it no-ops and just renames the table to +-- the destination if necessary. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Rewrite_Table(reloid REGCLASS, destschema TEXT DEFAULT NULL) +RETURNS BOOLEAN +AS $$ +DECLARE + + relname TEXT; + relschema TEXT; + relseq TEXT; + + destoid REGCLASS; + destname TEXT; + destseq TEXT; + destseqmax INTEGER; + + copyname TEXT; + + column_name_sql TEXT; + geom_transform_sql TEXT := NULL; + geom_column_source TEXT := ''; + + rec RECORD; + const RECORD; + gc RECORD; + sql TEXT; + str TEXT; + table_srid INTEGER; + geom_srid INTEGER; + + has_usable_primary_key BOOLEAN; + has_usable_pk_sequence BOOLEAN; + +BEGIN + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', 'entered function'; + + -- Read CartoDB standard column names in + const := @extschema@._CDB_Columns(); + + -- Save the raw schema/table names for later + SELECT n.nspname, c.relname, c.relname + INTO STRICT relschema, relname, destname + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + + -- Default the destination to current schema if unspecified + IF destschema IS NULL THEN + destschema := relschema; + END IF; + + -- See if there is a primary key column we need to carry along to the + -- new table. If this is true, it implies there is an indexed + -- primary key of integer type named (by default) cartodb_id + SELECT @extschema@._CDB_Has_Usable_Primary_ID(reloid) + INTO STRICT has_usable_primary_key; + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_primary_key %', has_usable_primary_key; + + -- See if the candidate primary key column has a sequence for default + -- values. No usable pk implies has_usable_pk_sequence = false. + has_usable_pk_sequence := false; + IF has_usable_primary_key THEN + SELECT _CDB_Has_Usable_PK_Sequence(reloid) + INTO STRICT has_usable_pk_sequence; + END IF; + + -- See if the geometry columns we need are already available + -- on the table. If they are, we don't need to do any bulk + -- transformation of the table, we can just ensure proper + -- indexes are in place and apply a rename + SELECT * + FROM @extschema@._CDB_Has_Usable_Geom(reloid) + INTO STRICT gc; + + -- If geom is the wrong name, just rename it. + IF gc.has_geom AND gc.has_geom_name != const.geomcol THEN + sql := Format('ALTER TABLE %s DROP COLUMN IF EXISTS %I', reloid::text, const.geomcol); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Rewrite_Table'); + sql := Format('ALTER TABLE %s RENAME COLUMN %I TO %I', reloid::text, gc.has_geom_name, const.geomcol); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Rewrite_Table'); + END IF; + + -- If mercgeom is the wrong name, just rename it. + IF gc.has_mercgeom AND gc.has_mercgeom_name != const.mercgeomcol THEN + sql := Format('ALTER TABLE %s DROP COLUMN IF EXISTS %I', reloid::text, const.mercgeomcol); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Rewrite_Table'); + sql := Format('ALTER TABLE %s RENAME COLUMN %I TO %I', reloid::text, gc.has_mercgeom_name, const.mercgeomcol); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Rewrite_Table'); + END IF; + + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_geoms %', gc.has_usable_geoms; + + -- We can only avoid a rewrite if both the key and + -- geometry are usable + + -- No table re-write is required, BUT a rename is required to + -- a destination schema, so do that now + IF has_usable_primary_key AND has_usable_pk_sequence AND gc.has_usable_geoms THEN + IF destschema != relschema THEN + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): perfect table needs to be moved to schema (%)', destschema; + PERFORM @extschema@._CDB_SQL(Format('ALTER TABLE %s SET SCHEMA %I', reloid::text, destschema), '_CDB_Rewrite_Table'); + + ELSE + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): perfect table in the perfect place'; + + END IF; + + RETURN true; + + END IF; + + -- We must rewrite, so here we go... + + -- Our desired PK sequence name + + -- We are going to drop the source table when we're done anyways + -- but it's possible the source PK sequence is living in a name we would like to use + -- so we check to see if that's the case, and rename it out of the way + IF has_usable_primary_key AND has_usable_pk_sequence THEN + -- See if the existing sequence is squatting on our preferred name + destseq := Format('%s_%s_seq', relname, const.pkey); + SELECT pg_catalog.pg_get_serial_sequence(Format('%I.%I', relschema, relname), const.pkey) + INTO relseq; + -- If it's the name we want, then rename it + IF relseq IS NOT NULL AND relseq = Format('%I.%I', destschema, destseq) THEN + PERFORM @extschema@._CDB_SQL(Format('ALTER SEQUENCE %s RENAME TO %I', relseq, Format('tmp_%s', destseq)), '_CDB_Rewrite_Table'); + END IF; + END IF; + + -- Put the primary key sequence in the right schema + -- If the new table is not moving, better ensure the sequence name + -- is unique + destseq := @extschema@._CDB_Unique_Identifier(NULL, relname, '_' || const.pkey || '_seq', destschema); + destseq := Format('%I.%I', destschema, destseq); + PERFORM @extschema@._CDB_SQL(Format('CREATE SEQUENCE %s', destseq), '_CDB_Rewrite_Table'); + + -- Temporary table name if we are re-writing in place + -- Note copyname is already escaped and safe to use as identifier + IF destschema = relschema THEN + copyname := Format('%I.%I', destschema, @extschema@._CDB_Unique_Identifier(NULL, destname, NULL), destschema); + ELSE + copyname := Format('%I.%I', destschema, destname); + END IF; + + -- Start building the SQL! + sql := Format('CREATE TABLE %s AS SELECT ', copyname); + + -- Add cartodb ID! + IF has_usable_primary_key THEN + sql := sql || const.pkey || '::integer '; + ELSE + sql := sql || 'nextval(''' || destseq || ''') AS ' || const.pkey; + END IF; + + -- Add the geometry columns! + IF gc.has_usable_geoms THEN + sql := sql || ',' || const.geomcol || ',' || const.mercgeomcol; + ELSE + + -- Arg, this "geometry" column is actually text!! + -- OK, we tested back in our geometry column research that it could + -- be safely cast to geometry, so let's do that. + IF gc.text_geom_column THEN + + WITH t AS ( + SELECT + a.attname, + CASE WHEN NOT gc.text_geom_column_srid THEN 'ST_SetSRID(' ELSE '' END AS missing_srid_start, + CASE WHEN NOT gc.text_geom_column_srid THEN ',4326)' ELSE '' END AS missing_srid_end + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + WHERE c.oid = reloid + AND t.typname IN ('text','varchar','char') + AND a.attnum > 0 + AND a.attname = gc.text_geom_column_name + AND NOT a.attisdropped + ORDER BY a.attnum + LIMIT 1 + ) + SELECT ', @postgisschema@.ST_Transform(' + || t.missing_srid_start || t.attname || '::geometry' || t.missing_srid_end + || ',4326)::Geometry(GEOMETRY,4326) AS ' + || const.geomcol + || ', @extschema@.CDB_TransformToWebmercator(' + || t.missing_srid_start || t.attname || '::geometry' || t.missing_srid_end + || ')::Geometry(GEOMETRY,3857) AS ' + || const.mercgeomcol, + t.attname + INTO geom_transform_sql, geom_column_source + FROM t; + + IF NOT FOUND THEN + -- We checked that this column existed already, it bloody well + -- better be found. + RAISE EXCEPTION 'CDB(_CDB_Rewrite_Table): Text column % is missing!', gc.text_geom_column_name; + ELSE + sql := sql || geom_transform_sql; + END IF; + + -- There is at least one true geometry column in here, we'll + -- reproject that into the projections we need. + ELSE + + -- Find the column we are going to be working with (the first + -- column with type "geometry") + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + WHERE c.oid = reloid + AND t.typname = 'geometry' + AND a.attnum > 0 + AND NOT a.attisdropped + ORDER BY a.attnum + LIMIT 1; + + -- The SRID could be undeclared at the table level, but still + -- exist in the geometries themselves. We first find our geometry + -- column and read the first SRID off it it, if there is a row + -- to read. + IF FOUND THEN + EXECUTE Format('SELECT @postgisschema@.ST_SRID(%s) AS srid FROM %s LIMIT 1', rec.attname, reloid::text) + INTO geom_srid; + ELSE + geom_srid := 0; + END IF; + + -- The geometry columns weren't in the right projection, + -- so we need to find the first decent geometry column + -- in the table and wrap it in two transforms, one to 4326 + -- and another to 3857. Then remember its name so we can + -- ignore it when we build the list of other columns to + -- add to the output table + WITH t AS ( + SELECT + a.attname, + postgis_typmod_type(a.atttypmod) AS geomtype, + CASE WHEN postgis_typmod_srid(a.atttypmod) = 0 AND srid.srid = 0 THEN '@postgisschema@.ST_SetSRID(' ELSE '' END AS missing_srid_start, + CASE WHEN postgis_typmod_srid(a.atttypmod) = 0 AND srid.srid = 0 THEN ',4326)' ELSE '' END AS missing_srid_end + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid, + ( SELECT geom_srid AS srid ) AS srid + WHERE c.oid = reloid + AND t.typname = 'geometry' + AND a.attnum > 0 + AND NOT a.attisdropped + ORDER BY a.attnum + LIMIT 1 + ) + SELECT ', @postgisschema@.ST_Transform(' + || t.missing_srid_start || t.attname || t.missing_srid_end + || ',4326)::Geometry(GEOMETRY,4326) AS ' + || const.geomcol + || ', @extschema@.CDB_TransformToWebmercator(' + || t.missing_srid_start || t.attname || t.missing_srid_end + || ')::Geometry(GEOMETRY,3857) AS ' + || const.mercgeomcol, + t.attname + INTO geom_transform_sql, geom_column_source + FROM t; + + IF NOT FOUND THEN + -- If there are no geometry columns, we continue making a + -- non-spatial table. This is important for folks who want + -- their tables to invalidate the SQL API + -- cache on update/insert/delete. + geom_column_source := ''; + sql := sql || ',NULL::geometry(Geometry,4326) AS ' || const.geomcol; + sql := sql || ',NULL::geometry(Geometry,3857) AS ' || const.mercgeomcol; + ELSE + sql := sql || geom_transform_sql; + END IF; + + END IF; + + END IF; + + -- Add now add all the rest of the columns + -- by selecting their names into an array and + -- joining the array with a comma + SELECT + ',' || array_to_string(array_agg(Format('%I',a.attname) ORDER BY a.attnum),',') AS column_name_sql, + Count(*) AS count + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + WHERE c.oid = reloid + AND a.attnum > 0 + AND a.attname NOT IN (const.geomcol, const.mercgeomcol, const.pkey, geom_column_source) + AND NOT a.attisdropped; + + + -- No non-cartodb columns? Possible, I guess. + IF rec.count = 0 THEN + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', 'found no extra columns'; + column_name_sql := ''; + ELSE + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', Format('found extra columns columns ''%s''', rec.column_name_sql); + column_name_sql := rec.column_name_sql; + END IF; + + -- Add the source table to the SQL + sql := sql || column_name_sql || ' FROM ' || reloid::text; + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', sql; + + -- Run it! + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- Set up the primary key sequence + -- If we copied the primary key from the original data, we need + -- to set the sequence to the maximum value of that key + EXECUTE Format('SELECT max(%s) FROM %s', + const.pkey, copyname) + INTO destseqmax; + + IF destseqmax IS NOT NULL THEN + PERFORM @extschema@._CDB_SQL(Format('SELECT setval(''%s'', %s)', destseq, destseqmax), '_CDB_Rewrite_Table'); + END IF; + + -- Make the primary key use the sequence as its default value + sql := Format('ALTER TABLE %s ALTER COLUMN %s SET DEFAULT nextval(''%s'')', + copyname, const.pkey, destseq); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- Make the sequence owned by the table, so when the table drops, + -- the sequence does too + sql := Format('ALTER SEQUENCE %s OWNED BY %s.%s', destseq, copyname, const.pkey); + PERFORM @extschema@._CDB_SQL(sql,'_CDB_Rewrite_Table'); + + + -- We just made a copy, so we can drop the original now + sql := Format('DROP TABLE %s', reloid::text); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- If the table is being created by a SECURITY DEFINER function + -- make sure the user is set back to the user who is connected + IF current_user != session_user THEN + sql := Format('ALTER TABLE IF EXISTS %s OWNER TO %s', copyname, session_user); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + sql := Format('ALTER SEQUENCE IF EXISTS %s OWNER TO %s', destseq, session_user); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + END IF; + + -- If we used a temporary destination table + -- we can now rename it into place + IF destschema = relschema THEN + sql := Format('ALTER TABLE %s RENAME TO %I', copyname, destname); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Rewrite_Table'); + END IF; + + RETURN true; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +-- Assumes the table already has the right metadata columns +-- (primary key and two geometry columns) and adds primary key +-- and geometry indexes if necessary. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Add_Indexes(reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + rec RECORD; + const RECORD; + iname TEXT; + sql TEXT; + relname TEXT; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Add_Indexes): %', 'entered function'; + + -- Read CartoDB standard column names in + const := @extschema@._CDB_Columns(); + + -- Extract just the relname to use for the index names + SELECT c.relname + INTO STRICT relname + FROM pg_class c + WHERE c.oid = reloid; + + -- Is there already a primary key on this table for + -- a column other than our chosen primary key? + SELECT ci.relname AS pkey + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON i.indexrelid = ci.oid + WHERE c.oid = reloid + AND NOT a.attisdropped + AND a.attname != const.pkey + AND i.indisprimary; + + -- Yes? Then drop it, we're adding our own PK to the column + -- we prefer. + IF FOUND THEN + RAISE DEBUG 'CDB(_CDB_Add_Indexes): dropping unwanted primary key ''%''', rec.pkey; + sql := Format('ALTER TABLE %s DROP CONSTRAINT IF EXISTS %s', reloid::text, rec.pkey); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Add_Indexes'); + END IF; + + + -- Is the default primary key flagged as primary? + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON ci.oid = i.indexrelid + WHERE attnum > 0 + AND c.oid = reloid + AND a.attname = const.pkey + AND i.indisprimary + AND i.indisunique + AND NOT attisdropped; + + -- No primary key? Add one. + IF NOT FOUND THEN + sql := Format('ALTER TABLE %s ADD PRIMARY KEY (%s)', reloid::text, const.pkey); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Add_Indexes'); + END IF; + + -- Add geometry indexes to all "special geometry columns" that + -- don't have one (either have no index at all, or have a non-GIST index) + FOR rec IN + SELECT a.attname, n.nspname + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + JOIN pg_attribute a ON a.attrelid = c.oid AND attnum > 0 + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE NOT attisdropped + AND a.attname IN (const.geomcol, const.mercgeomcol) + AND c.oid = reloid + AND i.indexrelid IS NULL + UNION + SELECT a.attname, n.nspname + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + JOIN pg_attribute a ON a.attrelid = c.oid AND attnum > 0 + JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON ci.oid = i.indexrelid + JOIN pg_am am ON ci.relam = am.oid + WHERE NOT attisdropped + AND a.attname IN (const.geomcol, const.mercgeomcol) + AND c.oid = reloid + AND am.amname != 'gist' + LOOP + sql := Format('CREATE INDEX ON %s USING GIST (%s)', reloid::text, rec.attname); + PERFORM @extschema@._CDB_SQL(sql, '_CDB_Add_Indexes'); + END LOOP; + + RETURN true; + +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + +DROP FUNCTION IF EXISTS @extschema@.CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS); +CREATE OR REPLACE FUNCTION @extschema@.CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) +RETURNS REGCLASS +AS $$ +DECLARE + + is_raster BOOLEAN; + relname TEXT; + relschema TEXT; + + destoid REGCLASS; + destname TEXT; + + rec RECORD; + +BEGIN + + -- Save the raw schema/table names for later + SELECT n.nspname, c.relname, c.relname + INTO STRICT relschema, relname, destname + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + + PERFORM @extschema@._CDB_check_prerequisites(destschema, reloid); + + -- Check destination schema exists + -- Throws an exception of there is no matching schema + IF destschema IS NOT NULL THEN + + SELECT n.nspname + INTO rec FROM pg_namespace n WHERE n.nspname = destschema; + IF NOT FOUND THEN + RAISE EXCEPTION 'Schema ''%'' does not exist', destschema; + END IF; + + ELSE + destschema := relschema; + END IF; + + -- Drop triggers first + PERFORM @extschema@._CDB_drop_triggers(reloid); + + -- Rasters only get a cartodb_id and a limited selection of triggers + -- underlying assumption is that they are already formed up correctly + SELECT @extschema@._CDB_is_raster_table(destschema, reloid) INTO is_raster; + IF is_raster THEN + + PERFORM @extschema@._CDB_create_cartodb_id_column(reloid); + PERFORM @extschema@._CDB_create_raster_triggers(destschema, reloid); + + ELSE + + -- Rewrite (or rename) the table to the new location + PERFORM @extschema@._CDB_Rewrite_Table(reloid, destschema); + + -- The old regclass might not be valid anymore if we re-wrote the table... + destoid := (destschema || '.' || destname)::regclass; + + -- Add indexes to the destination table, as necessary + PERFORM @extschema@._CDB_Add_Indexes(destoid); + + -- Add triggers to the destination table, as necessary + PERFORM @extschema@._CDB_create_triggers(destschema, destoid); + + END IF; + + RETURN (destschema || '.' || destname)::regclass; +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_ColumnNames.sql b/lib/sql/scripts-available/CDB_ColumnNames.sql new file mode 100644 index 0000000..c7b35a5 --- /dev/null +++ b/lib/sql/scripts-available/CDB_ColumnNames.sql @@ -0,0 +1,16 @@ +-- Function returning the column names of a table +CREATE OR REPLACE FUNCTION @extschema@.CDB_ColumnNames(REGCLASS) +RETURNS SETOF information_schema.sql_identifier +AS $$ + SELECT + a.attname::information_schema.sql_identifier column_name + FROM pg_class c + LEFT JOIN pg_attribute a ON a.attrelid = c.oid + WHERE c.oid = $1::oid + AND a.attstattarget < 0 -- exclude system columns + ORDER BY a.attnum; +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION @extschema@.CDB_ColumnNames(REGCLASS) TO PUBLIC; diff --git a/lib/sql/scripts-available/CDB_ColumnType.sql b/lib/sql/scripts-available/CDB_ColumnType.sql new file mode 100644 index 0000000..82abe6c --- /dev/null +++ b/lib/sql/scripts-available/CDB_ColumnType.sql @@ -0,0 +1,16 @@ +-- Function returning the type of a column +CREATE OR REPLACE FUNCTION @extschema@.CDB_ColumnType(REGCLASS, TEXT) +RETURNS information_schema.character_data +AS $$ + SELECT + format_type(a.atttypid, NULL)::information_schema.character_data data_type + FROM pg_class c + LEFT JOIN pg_attribute a ON a.attrelid = c.oid + WHERE c.oid = $1::oid + AND a.attname = $2 + AND a.attstattarget < 0; -- exclude system columns +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION @extschema@.CDB_ColumnType(REGCLASS, TEXT) TO public; diff --git a/lib/sql/scripts-available/CDB_Conf.sql b/lib/sql/scripts-available/CDB_Conf.sql new file mode 100644 index 0000000..6349965 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Conf.sql @@ -0,0 +1,48 @@ +---------------------------------- +-- CONF MANAGEMENT FUNCTIONS +-- +-- Meant to be used by superadmin user. +-- Functions needing reading configuration should use SECURITY DEFINER. +---------------------------------- + +-- This will trigger NOTICE if @extschema@.CDB_CONF already exists +DO LANGUAGE 'plpgsql' $$ +BEGIN + CREATE TABLE IF NOT EXISTS @extschema@.CDB_CONF ( KEY TEXT PRIMARY KEY, VALUE JSON NOT NULL ); +END +$$; + +-- This can only be called from an SQL script executed by CREATE EXTENSION +DO LANGUAGE 'plpgsql' $$ +BEGIN + PERFORM pg_catalog.pg_extension_config_dump('@extschema@.CDB_CONF', ''); +END +$$; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Conf_SetConf(key text, value JSON) + RETURNS void AS $$ +BEGIN + PERFORM @extschema@.CDB_Conf_RemoveConf(key); + EXECUTE 'INSERT INTO @extschema@.CDB_CONF (KEY, VALUE) VALUES ($1, $2);' USING key, value; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Conf_RemoveConf(key text) + RETURNS void AS $$ +BEGIN + EXECUTE 'DELETE FROM @extschema@.CDB_CONF WHERE KEY = $1;' USING key; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Conf_GetConf(key text) + RETURNS JSON AS $$ +DECLARE + value JSON; +BEGIN + EXECUTE 'SELECT VALUE FROM @extschema@.CDB_CONF WHERE KEY = $1;' INTO value USING key; + RETURN value; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_DDLTriggers.sql b/lib/sql/scripts-available/CDB_DDLTriggers.sql new file mode 100644 index 0000000..8207c59 --- /dev/null +++ b/lib/sql/scripts-available/CDB_DDLTriggers.sql @@ -0,0 +1,14 @@ +-- +-- Legacy file +-- Introduced again to make sure that updates do not leave dangling functions +-- + +DROP FUNCTION IF EXISTS @extschema@.cdb_handle_create_table(); +DROP FUNCTION IF EXISTS @extschema@.cdb_handle_drop_table(); +DROP FUNCTION IF EXISTS @extschema@.cdb_handle_alter_column(); +DROP FUNCTION IF EXISTS @extschema@.cdb_handle_drop_column(); +DROP FUNCTION IF EXISTS @extschema@.cdb_handle_add_column(); +DROP FUNCTION IF EXISTS @extschema@.cdb_disable_ddl_hooks(); +DROP FUNCTION IF EXISTS @extschema@.cdb_enable_ddl_hooks(); + + diff --git a/lib/sql/scripts-available/CDB_DateToNumber.sql b/lib/sql/scripts-available/CDB_DateToNumber.sql new file mode 100644 index 0000000..f841519 --- /dev/null +++ b/lib/sql/scripts-available/CDB_DateToNumber.sql @@ -0,0 +1,31 @@ +-- Convert timestamp to double precision +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_DateToNumber(input timestamp) +RETURNS double precision AS $$ +DECLARE output double precision; +BEGIN + BEGIN + SELECT extract (EPOCH FROM input) INTO output; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN output; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; + +-- Convert timestamp with time zone to double precision +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_DateToNumber(input timestamp with time zone) +RETURNS double precision AS $$ +DECLARE output double precision; +BEGIN + BEGIN + SELECT extract (EPOCH FROM input) INTO output; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN output; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_DigitSeparator.sql b/lib/sql/scripts-available/CDB_DigitSeparator.sql new file mode 100644 index 0000000..6d14493 --- /dev/null +++ b/lib/sql/scripts-available/CDB_DigitSeparator.sql @@ -0,0 +1,53 @@ +-- Find thousand and decimal digits separators +CREATE OR REPLACE FUNCTION @extschema@.CDB_DigitSeparator (rel REGCLASS, fld TEXT, OUT t CHAR, OUT d CHAR) +as $$ +DECLARE + sql TEXT; + rec RECORD; +BEGIN + + -- We're only interested in rows with either "," or '.' + sql := 'SELECT ' || quote_ident(fld) || ' as f FROM ' || rel::text + || ' WHERE ' || quote_ident(fld) || ' ~ ''[,.]'''; + + FOR rec IN EXECUTE sql + LOOP + -- Any separator appearing more than once + -- will be assumed to be thousand separator + IF rec.f ~ ',.*,' THEN + t := ','; d := '.'; + RETURN; + ELSIF rec.f ~ '\..*\.' THEN + t := '.'; d := ','; + RETURN; + END IF; + + -- If both separator are present, rightmost + -- will be assumed to be decimal separator + IF rec.f ~ '\.' AND rec.f ~ ',' THEN + rec.f = reverse(rec.f); + IF strpos(rec.f, ',') < strpos(rec.f, '.') THEN + t := '.'; d := ','; + ELSE + t := ','; d := '.'; + END IF; + RETURN; + END IF; + + -- A separator NOT followed by 3 digits + -- will be assumed to be decimal separator + IF rec.f ~ ',' AND rec.f !~ '(,[0-9]{3}$)|(,[0-9]{3}[,.])' THEN + t := '.'; d := ','; + RETURN; + ELSIF rec.f ~ '\.' AND rec.f !~ '(\.[0-9]{3}$)|(\.[0-9]{3}[,.])' THEN + t := ','; d := '.'; + RETURN; + END IF; + + -- Otherwise continue looking + + END LOOP; + +END +$$ +LANGUAGE 'plpgsql' STABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_DistType.sql b/lib/sql/scripts-available/CDB_DistType.sql new file mode 100644 index 0000000..6b5bc35 --- /dev/null +++ b/lib/sql/scripts-available/CDB_DistType.sql @@ -0,0 +1,122 @@ +-- +-- CDB_DistType classifies the histograms of a column into +-- one of the basic types listed by Galtung: http://druedin.com/2012/12/08/galtungs-ajus-system/ +-- +-- Future improvements: +-- variable number of bins (7 is baked in right now) +-- catch the number of items to ensure that the sample is large enough +-- +-- Refs: +-- 1. width_bucket/histograms: http://tapoueh.org/blog/2014/02/21-PostgreSQL-histogram +-- 2. R implementation: https://github.com/cran/agrmt + +CREATE OR REPLACE FUNCTION @extschema@.CDB_DistType ( in_array NUMERIC[] ) RETURNS text as $$ +DECLARE + element_count INT4; + minv numeric; + maxv numeric; + bins numeric[]; + freqs numeric[]; + ajus INT[]; + freq INT4; + signature text; + i INT := 1; +BEGIN + SELECT min(e), max(e), count(e) INTO minv, maxv, element_count FROM ( SELECT unnest(in_array) e ) x; + + IF abs(maxv - minv) < 1e-7 THEN -- if max and min are nearly equal, call if 'F' (make relative to maxv?) + signature = 'F'; + ELSE + -- Calculate bins and count in bins + EXECUTE 'WITH stats as ( + SELECT min(e) as minv, + max(e) as maxv, + count(e) as total + FROM (SELECT unnest($1) e) x + WHERE e is not null + ), + hist as ( + SELECT width_bucket(e, s.minv, s.maxv, 7) bucket, + count(*) freq + FROM (SELECT unnest($1) e) x, stats s + WHERE e is not null + GROUP BY 1 + ORDER BY 1 + ) + SELECT array_agg(round(100.0 * hist.freq::numeric / stats.total::numeric,1)) freqs, + array_agg(hist.bucket) buckets + FROM hist, stats' + INTO freqs, bins + USING in_array; + + LOOP + IF i < 7 THEN + ajus[i] = CASE WHEN freqs[i] > freqs[i+1] THEN -1 + WHEN abs(freqs[i] - freqs[i+1]) <= 0.05 THEN 0 + ELSE 1 END; + ELSE + EXIT; + END IF; + i := i + 1; + END LOOP; + + signature = @extschema@._CDB_DistTypeClassify(ajus); + END IF; + + RETURN signature; +END; +$$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +-- Classify data into AJUSFL + +CREATE OR REPLACE FUNCTION @extschema@._CDB_DistTypeClassify ( in_array INT[] ) RETURNS text as $$ +DECLARE + element_count INT4; + maxv numeric; + minv numeric; + uniques INT[]; + type text; +BEGIN + SELECT max(e), min(e) INTO maxv, minv FROM ( SELECT unnest(in_array) e ) x; + + IF (maxv = 0 AND minv = 0) THEN + type = 'F'; + ELSIF maxv < 1 THEN + type = 'L'; + ELSIF minv > -1 THEN + type = 'J'; + ELSE + -- Get distinct elements ordered by original position + EXECUTE 'WITH b AS ( + SELECT a + FROM (SELECT unnest($1) a) x + ), + c AS ( + SELECT a, row_number() OVER () r + FROM b + ), + d AS ( + SELECT DISTINCT a + FROM c + ), + e AS ( + SELECT a FROM d ORDER BY ( + SELECT r FROM c WHERE d.a = c.a ORDER BY r ASC LIMIT 1 + ) ASC) + SELECT array_agg(a) FROM e' + INTO uniques + USING in_array; + + -- Decide if it's an A, U, or other + IF (uniques = ARRAY[1,-1] OR uniques = ARRAY[1,0,-1] OR uniques = ARRAY[1,-1,0] OR uniques = ARRAY[0,1,-1]) THEN + type = 'A'; + ELSIF (uniques = ARRAY[-1,1] OR uniques = ARRAY[-1,0,1] OR uniques = ARRAY[-1,1,0] OR uniques = ARRAY[0,-1,1]) THEN + type = 'U'; + ELSE + type = 'S'; + END IF; + END IF; + + RETURN type; +END; +$$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_DistinctMeasure.sql b/lib/sql/scripts-available/CDB_DistinctMeasure.sql new file mode 100644 index 0000000..12a74bb --- /dev/null +++ b/lib/sql/scripts-available/CDB_DistinctMeasure.sql @@ -0,0 +1,46 @@ +-- +-- CDB_DistinctMeasure +-- calculates the fraction of rows in the 10 most common distinct categories +-- returns true if the number of rows in these 10 categories is >= 0.9 * total number of rows +-- +-- + +CREATE OR REPLACE FUNCTION @extschema@.CDB_DistinctMeasure ( in_array text[], threshold numeric DEFAULT null ) RETURNS numeric as $$ +DECLARE + element_count INT4; + maxval numeric; + passes numeric; +BEGIN + SELECT count(e) INTO element_count FROM ( SELECT unnest(in_array) e ) x; + + -- count number of occurrences per bin + -- calculate the normalized cumulative sum + -- return the max value: which corresponds nth entry + -- for n <= 10 depending on # of distinct values + EXECUTE 'WITH a As ( + SELECT + count(*) cnt + FROM + (SELECT * FROM unnest($2) e ) x + WHERE e is not null + GROUP BY e + ORDER BY cnt DESC + ), + b As ( + SELECT + sum(cnt) OVER (ORDER BY cnt DESC) / $1 As cumsum + FROM a + LIMIT 10 + ) + SELECT max(cumsum) maxval FROM b' + INTO maxval + USING element_count, in_array; + IF threshold is null THEN + passes = maxval; + ELSE + passes = CASE WHEN (maxval >= threshold) THEN 1 ELSE 0 END; + END IF; + + RETURN passes; +END; +$$ language plpgsql IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_EqualIntervalBins.sql b/lib/sql/scripts-available/CDB_EqualIntervalBins.sql new file mode 100644 index 0000000..625242c --- /dev/null +++ b/lib/sql/scripts-available/CDB_EqualIntervalBins.sql @@ -0,0 +1,24 @@ +-- +-- Calculate the equal interval bins for a given column +-- +-- @param in_array An array of numbers to determine the best +-- bin boundary +-- +-- @param breaks The number of bins you want to find. +-- +-- +-- Returns: upper edges of bins +-- +-- + +CREATE OR REPLACE FUNCTION @extschema@.CDB_EqualIntervalBins ( in_array anyarray, breaks INT ) RETURNS anyarray as $$ +WITH stats AS ( + SELECT min(e), (max(e)-min(e))/breaks AS del + FROM (SELECT unnest(in_array) e) AS p) +SELECT array_agg(bins) + FROM ( + SELECT min + generate_series(1,breaks)*del AS bins + FROM stats) q; +$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE; + +DROP FUNCTION IF EXISTS @extschema@.CDB_EqualIntervalBins( numeric[], integer); diff --git a/lib/sql/scripts-available/CDB_EstimateRowCount.sql b/lib/sql/scripts-available/CDB_EstimateRowCount.sql new file mode 100644 index 0000000..06e65de --- /dev/null +++ b/lib/sql/scripts-available/CDB_EstimateRowCount.sql @@ -0,0 +1,31 @@ +-- Internal function to generate stats for a table if they don't exist +CREATE OR REPLACE FUNCTION @extschema@._CDB_GenerateStats(reloid REGCLASS) +RETURNS VOID +AS $$ +DECLARE + has_stats BOOLEAN; +BEGIN + SELECT EXISTS ( + SELECT * FROM pg_catalog.pg_statistic WHERE starelid = reloid + ) INTO has_stats; + IF NOT has_stats THEN + EXECUTE Format('ANALYZE %s;', reloid); + END IF; +END +$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE SECURITY DEFINER; + +-- Return a row count estimate of the result of a query using statistics +CREATE OR REPLACE FUNCTION @extschema@.CDB_EstimateRowCount(query text) +RETURNS Numeric +AS $$ +DECLARE + plan JSON; +BEGIN + -- Make sure statistics exist for all the tables of the query + PERFORM @extschema@._CDB_GenerateStats(tabname) FROM unnest(@extschema@.CDB_QueryTablesText(query)) AS tabname; + + -- Use the query planner to obtain an estimate of the number of result rows + EXECUTE 'EXPLAIN (FORMAT JSON) ' || query INTO STRICT plan; + RETURN plan->0->'Plan'->'Plan Rows'; +END +$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_ExtensionPost.sql b/lib/sql/scripts-available/CDB_ExtensionPost.sql new file mode 100644 index 0000000..2b12612 --- /dev/null +++ b/lib/sql/scripts-available/CDB_ExtensionPost.sql @@ -0,0 +1,2 @@ +SELECT pg_catalog.pg_extension_config_dump('@extschema@.cdb_tablemetadata',''); + diff --git a/lib/sql/scripts-available/CDB_ExtensionUtils.sql b/lib/sql/scripts-available/CDB_ExtensionUtils.sql new file mode 100644 index 0000000..88ed8ae --- /dev/null +++ b/lib/sql/scripts-available/CDB_ExtensionUtils.sql @@ -0,0 +1,20 @@ +CREATE OR REPLACE FUNCTION @extschema@.cdb_extension_reload() RETURNS void +AS $$ +DECLARE + ver TEXT; + sql TEXT; +BEGIN + ver := split_part(@extschema@.cdb_version(), ' ', 1); + sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || 'next'''; + EXECUTE sql; + sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || ''''; + EXECUTE sql; +END; +$$ language 'plpgsql' VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE FUNCTION @extschema@.schema_exists(schema_name text) +RETURNS boolean AS +$$ + SELECT EXISTS(SELECT 1 FROM pg_namespace WHERE nspname = schema_name::text); +$$ +language sql STABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_ForeignTable.sql b/lib/sql/scripts-available/CDB_ForeignTable.sql new file mode 100644 index 0000000..f60b043 --- /dev/null +++ b/lib/sql/scripts-available/CDB_ForeignTable.sql @@ -0,0 +1,206 @@ +--------------------------- +-- FDW MANAGEMENT FUNCTIONS +-- +-- All the FDW settings are read from the `cdb_conf.fdws` entry json file. +--------------------------- + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Setup_FDW(fdw_name text, config json) +RETURNS void +AS $$ +DECLARE + row record; + option record; + org_role text; +BEGIN + -- This function tries to be as idempotent as possible, by not creating anything more than once + -- (not even using IF NOT EXIST to avoid throwing warnings) + IF NOT EXISTS ( SELECT * FROM pg_extension WHERE extname = 'postgres_fdw') THEN + CREATE EXTENSION postgres_fdw; + END IF; + -- Create FDW first if it does not exist + IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = fdw_name) + THEN + EXECUTE FORMAT('CREATE SERVER %I FOREIGN DATA WRAPPER postgres_fdw', fdw_name); + END IF; + + -- Set FDW settings + FOR row IN SELECT p.key, p.value from lateral json_each_text(config->'server') p + LOOP + IF NOT EXISTS (WITH a AS (select split_part(unnest(srvoptions), '=', 1) as options from pg_foreign_server where srvname=fdw_name) SELECT * from a where options = row.key) + THEN + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (ADD %I %L)', fdw_name, row.key, row.value); + ELSE + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (SET %I %L)', fdw_name, row.key, row.value); + END IF; + END LOOP; + + -- Create user mappings + FOR row IN SELECT p.key, p.value from lateral json_each(config->'users') p LOOP + -- Check if entry on pg_user_mappings exists + + IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = fdw_name AND usename = row.key ) THEN + EXECUTE FORMAT ('CREATE USER MAPPING FOR %I SERVER %I', row.key, fdw_name); + END IF; + + -- Update user mapping settings + FOR option IN SELECT o.key, o.value from lateral json_each_text(row.value) o LOOP + IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = fdw_name AND usename = row.key) SELECT * from a where options = option.key) THEN + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (ADD %I %L)', row.key, fdw_name, option.key, option.value); + ELSE + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (SET %I %L)', row.key, fdw_name, option.key, option.value); + END IF; + END LOOP; + END LOOP; + + -- Create schema if it does not exist. + IF NOT EXISTS ( SELECT * from pg_namespace WHERE nspname=fdw_name) THEN + EXECUTE FORMAT ('CREATE SCHEMA %I', fdw_name); + END IF; + + -- Give the organization role usage permisions over the schema + SELECT @extschema@.CDB_Organization_Member_Group_Role_Member_Name() INTO org_role; + EXECUTE FORMAT ('GRANT USAGE ON SCHEMA %I TO %I', fdw_name, org_role); + + -- Bring here the remote cdb_tablemetadata + IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname=fdw_name) and relname='cdb_tablemetadata') THEN + EXECUTE FORMAT ('CREATE FOREIGN TABLE %I.cdb_tablemetadata (tabname text, updated_at timestamp with time zone) SERVER %I OPTIONS (table_name ''cdb_tablemetadata_text'', schema_name ''@extschema@'', updatable ''false'')', fdw_name, fdw_name); + END IF; + EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', fdw_name, org_role); + +END +$$ +LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Setup_FDWS() +RETURNS VOID AS +$$ +DECLARE +row record; +BEGIN + FOR row IN SELECT p.key, p.value from lateral json_each(@extschema@.CDB_Conf_GetConf('fdws')) p LOOP + EXECUTE 'SELECT @extschema@._CDB_Setup_FDW($1, $2)' USING row.key, row.value; + END LOOP; + END +$$ +LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Setup_FDW(fdw_name text) + RETURNS void AS +$BODY$ +DECLARE +config json; +BEGIN + SELECT p.value FROM LATERAL json_each(@extschema@.CDB_Conf_GetConf('fdws')) p WHERE p.key = fdw_name INTO config; + EXECUTE 'SELECT @extschema@._CDB_Setup_FDW($1, $2)' USING fdw_name, config; +END +$BODY$ +LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE FUNCTION @extschema@.CDB_Add_Remote_Table(source text, table_name text) + RETURNS void AS +$$ +BEGIN + PERFORM @extschema@._CDB_Setup_FDW(source); + EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', source, table_name, source, source); + --- Grant SELECT to publicuser + EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO publicuser;', source, table_name); +END +$$ +LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE FUNCTION @extschema@.CDB_Get_Foreign_Updated_At(foreign_table regclass) + RETURNS timestamp with time zone AS +$$ +DECLARE + remote_table_name text; + fdw_schema_name text; + time timestamp with time zone; +BEGIN + -- This will turn a local foreign table (referenced as regclass) to its fully qualified text remote table reference. + WITH a AS (SELECT ftoptions FROM pg_foreign_table WHERE ftrelid=foreign_table LIMIT 1), + b as (SELECT (pg_options_to_table(ftoptions)).* FROM a) + SELECT FORMAT('%I.%I', (SELECT option_value FROM b WHERE option_name='schema_name'), (SELECT option_value FROM b WHERE option_name='table_name')) + INTO remote_table_name; + + -- We assume that the remote cdb_tablemetadata is called cdb_tablemetadata and is on the same schema as the queried table. + SELECT nspname FROM pg_class c, pg_namespace n WHERE c.oid=foreign_table AND c.relnamespace = n.oid INTO fdw_schema_name; + BEGIN + EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time; + EXCEPTION + WHEN undefined_table THEN + -- If you add a GET STACKED DIAGNOSTICS text_var = RETURNED_SQLSTATE + -- you get a code 42P01 which corresponds to undefined_table + RAISE NOTICE 'CDB_Get_Foreign_Updated_At: could not find %.cdb_tablemetadata while checking % updated_at, returning NULL timestamp', fdw_schema_name, foreign_table; + END; + RETURN time; +END +$$ +LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + + +CREATE OR REPLACE FUNCTION @extschema@._cdb_dbname_of_foreign_table(reloid oid) +RETURNS TEXT AS $$ + SELECT option_value FROM pg_options_to_table(( + + SELECT fs.srvoptions + FROM pg_foreign_table ft + LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid + WHERE ft.ftrelid = reloid + + )) WHERE option_name='dbname'; +$$ LANGUAGE SQL VOLATILE PARALLEL UNSAFE; + + +-- Return a set of (dbname, schema_name, table_name, updated_at) +-- It is aware of foreign tables +-- It assumes the local (schema_name, table_name) map to the remote ones with the same name +-- Note: dbname is never quoted whereas schema and table names are when needed. +CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTables_Updated_At(query text) +RETURNS TABLE(dbname text, schema_name text, table_name text, updated_at timestamptz) +AS $$ + WITH query_tables AS ( + SELECT unnest(@extschema@.CDB_QueryTablesText(query)) schema_table_name + ), query_tables_oid AS ( + SELECT schema_table_name, schema_table_name::regclass::oid AS reloid + FROM query_tables + ), + fqtn AS ( + SELECT + (CASE WHEN c.relkind = 'f' THEN @extschema@._cdb_dbname_of_foreign_table(query_tables_oid.reloid) + ELSE current_database() + END)::text AS dbname, + quote_ident(n.nspname::text) schema_name, + quote_ident(c.relname::text) table_name, + c.relkind, + query_tables_oid.reloid + FROM query_tables_oid, pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = query_tables_oid.reloid + ) + SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, + (CASE WHEN relkind = 'f' THEN @extschema@.CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM @extschema@.CDB_TableMetadata md WHERE md.tabname = reloid) + END) AS updated_at + FROM fqtn; +$$ LANGUAGE SQL VOLATILE PARALLEL UNSAFE; + + +-- Return the last updated time of a set of tables +-- It is aware of foreign tables +-- It assumes the local (schema_name, table_name) map to the remote ones with the same name +CREATE OR REPLACE FUNCTION @extschema@.CDB_Last_Updated_Time(tables text[]) +RETURNS timestamptz AS $$ + WITH t AS ( + SELECT unnest(tables) AS schema_table_name + ), t_oid AS ( + SELECT (t.schema_table_name)::regclass::oid as reloid FROM t + ), t_updated_at AS ( + SELECT + (CASE WHEN relkind = 'f' THEN @extschema@.CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM @extschema@.CDB_TableMetadata md WHERE md.tabname = reloid) + END) AS updated_at + FROM t_oid + LEFT JOIN pg_catalog.pg_class c ON c.oid = reloid + ) SELECT max(updated_at) FROM t_updated_at; +$$ LANGUAGE SQL VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_GhostTables.sql b/lib/sql/scripts-available/CDB_GhostTables.sql new file mode 100644 index 0000000..dcbb7f9 --- /dev/null +++ b/lib/sql/scripts-available/CDB_GhostTables.sql @@ -0,0 +1,123 @@ +-- Enqueues a job to run Ghost tables linking process for the provided username +CREATE OR REPLACE FUNCTION @extschema@._CDB_LinkGhostTables(username text, db_name text, event_name text) +RETURNS void +AS $$ + if not username: + return + + if 'json' not in GD: + import json + GD['json'] = json + else: + json = GD['json'] + + tis_config = plpy.execute("select @extschema@.CDB_Conf_GetConf('invalidation_service');")[0]['cdb_conf_getconf'] + if not tis_config: + plpy.warning('Invalidation service configuration not found. Skipping Ghost Tables linking.') + return + + tis_config_dict = json.loads(tis_config) + tis_host = tis_config_dict.get('host') + tis_port = tis_config_dict.get('port') + tis_timeout = tis_config_dict.get('timeout', 5) + tis_retry = tis_config_dict.get('retry', 5) + + client = GD.get('invalidation', None) + + while True: + + if not client: + try: + import redis + client = redis.Redis(host=tis_host, port=tis_port, socket_timeout=tis_timeout) + GD['invalidation'] = client + except Exception as err: + error = "client_error - %s" % str(err) + # NOTE: no retries on connection error + plpy.warning('Error trying to connect to Invalidation Service to link Ghost Tables: ' + str(err)) + break + + try: + client.execute_command('DBSCH', db_name, username, event_name) + break + except Exception as err: + error = "request_error - %s" % str(err) + client = GD['invalidation'] = None # force reconnect + if not tis_retry: + plpy.warning('Error calling Invalidation Service to link Ghost Tables: ' + str(err)) + break + tis_retry -= 1 # try reconnecting +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE; + +-- Enqueues a job to run Ghost tables linking process for the current user +CREATE OR REPLACE FUNCTION @extschema@.CDB_LinkGhostTables(event_name text DEFAULT 'USER') +RETURNS void +AS $$ + DECLARE + username TEXT; + db_name TEXT; + BEGIN + EXECUTE 'SELECT @extschema@.CDB_Username();' INTO username; + EXECUTE 'SELECT current_database();' INTO db_name; + + PERFORM @extschema@._CDB_LinkGhostTables(username, db_name, event_name); + RAISE NOTICE '_CDB_LinkGhostTables() called with username=%, event_name=%', username, event_name; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Trigger function to call CDB_LinkGhostTables() +CREATE OR REPLACE FUNCTION @extschema@._CDB_LinkGhostTablesTrigger() +RETURNS trigger +AS $$ + DECLARE + ddl_tag TEXT; + BEGIN + EXECUTE 'DELETE FROM @extschema@.cdb_ddl_execution WHERE txid = txid_current() RETURNING tag;' INTO ddl_tag; + PERFORM @extschema@.CDB_LinkGhostTables(ddl_tag); + RETURN NULL; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Event trigger to save the current transaction in @extschema@.cdb_ddl_execution +CREATE OR REPLACE FUNCTION @extschema@.CDB_SaveDDLTransaction() +RETURNS event_trigger +AS $$ + BEGIN + INSERT INTO @extschema@.cdb_ddl_execution VALUES (txid_current(), tg_tag) ON CONFLICT ON CONSTRAINT cdb_ddl_execution_pkey DO NOTHING; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Creates the trigger on DDL events to link ghost tables +CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableGhostTablesTrigger() +RETURNS void +AS $$ + BEGIN + DROP EVENT TRIGGER IF EXISTS link_ghost_tables; + DROP TRIGGER IF EXISTS check_ddl_update ON @extschema@.cdb_ddl_execution; + + -- Table to store the transaction id from DDL events to avoid multiple executions + CREATE TABLE IF NOT EXISTS @extschema@.cdb_ddl_execution(txid bigint PRIMARY KEY, tag text); + + CREATE CONSTRAINT TRIGGER check_ddl_update + AFTER INSERT ON @extschema@.cdb_ddl_execution + INITIALLY DEFERRED + FOR EACH ROW + EXECUTE PROCEDURE @extschema@._CDB_LinkGhostTablesTrigger(); + + CREATE EVENT TRIGGER link_ghost_tables + ON ddl_command_end + WHEN TAG IN ('CREATE TABLE', 'SELECT INTO', 'DROP TABLE', 'ALTER TABLE', 'CREATE TRIGGER', 'DROP TRIGGER', 'CREATE VIEW', 'DROP VIEW', 'ALTER VIEW', 'CREATE FOREIGN TABLE', 'ALTER FOREIGN TABLE', 'DROP FOREIGN TABLE') + EXECUTE PROCEDURE @extschema@.CDB_SaveDDLTransaction(); + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; + +-- Drops the trigger on DDL events to link ghost tables +CREATE OR REPLACE FUNCTION @extschema@.CDB_DisableGhostTablesTrigger() +RETURNS void +AS $$ + BEGIN + DROP EVENT TRIGGER IF EXISTS link_ghost_tables; + DROP TRIGGER IF EXISTS check_ddl_update ON @extschema@.cdb_ddl_execution; + DROP TABLE IF EXISTS @extschema@.cdb_ddl_execution; + END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_GreatCircle.sql b/lib/sql/scripts-available/CDB_GreatCircle.sql new file mode 100644 index 0000000..a4d6385 --- /dev/null +++ b/lib/sql/scripts-available/CDB_GreatCircle.sql @@ -0,0 +1,26 @@ +-- Great circle point-to-point routes, based on: +-- http://blog.cartodb.com/jets-and-datelines/ +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_GreatCircle(start_point @postgisschema@.geometry, end_point @postgisschema@.geometry, max_segment_length NUMERIC DEFAULT 100000) +RETURNS @postgisschema@.geometry AS $$ +DECLARE + line @postgisschema@.geometry; +BEGIN + line = @postgisschema@.ST_Segmentize( + @postgisschema@.ST_Makeline( + start_point, + end_point + )::geography, + max_segment_length + )::geometry; + + IF @postgisschema@.ST_XMax(line) - @postgisschema@.ST_XMin(line) > 180 THEN + line = @postgisschema@.ST_Difference( + @postgisschema@.ST_ShiftLongitude(line), + @postgisschema@.ST_Buffer(@postgisschema@.ST_GeomFromText('LINESTRING(180 90, 180 -90)', 4326), 0.00001) + ); + END IF; +RETURN line; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_Groups.sql b/lib/sql/scripts-available/CDB_Groups.sql new file mode 100644 index 0000000..e96ce17 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Groups.sql @@ -0,0 +1,252 @@ +---------------------------------- +-- GROUP MANAGEMENT FUNCTIONS +-- +-- Meant to be used by org admin. See CDB_Organization_AddAdmin. +---------------------------------- + +-- Creates a new group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_CreateGroup(group_name text) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + EXECUTE format('CREATE ROLE %I NOLOGIN;', group_role); + PERFORM @extschema@._CDB_Group_CreateGroup_API(group_name, group_role); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Drops group and everything that role owns +-- TODO: LIMITATION: in order to drop a role all its owned objects must be dropped before. +-- Right now this is done with DROP OWNED, which can only be done by a superadmin. +-- Not even the role creator can drop the role and the objects it owns. +-- All group owned objects by the group are permissions. +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_DropGroup(group_name text) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + EXECUTE format('DROP OWNED BY %I', group_role); + EXECUTE format('DROP ROLE IF EXISTS %I', group_role); + PERFORM @extschema@._CDB_Group_DropGroup_API(group_name); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Renames a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_RenameGroup(old_group_name text, new_group_name text) + RETURNS VOID AS $$ +DECLARE + old_group_role TEXT; + new_group_role TEXT; +BEGIN + old_group_role = @extschema@._CDB_Group_GroupRole(old_group_name); + new_group_role = @extschema@._CDB_Group_GroupRole(new_group_name); + EXECUTE format('ALTER ROLE %I RENAME TO %I', old_group_role, new_group_role); + PERFORM @extschema@._CDB_Group_RenameGroup_API(old_group_name, new_group_name, new_group_role); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Adds users to a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_AddUsers(group_name text, usernames text[]) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; + user_role TEXT; + username TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + foreach username in array usernames + loop + user_role := @extschema@._CDB_User_RoleFromUsername(username); + IF(group_role IS NULL OR user_role IS NULL) + THEN + RAISE EXCEPTION 'Group role (%) and user role (%) must be already existing', group_role, user_role; + END IF; + EXECUTE format('GRANT %I TO %I', group_role, user_role); + end loop; + PERFORM @extschema@._CDB_Group_AddUsers_API(group_name, usernames); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Removes users from a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_RemoveUsers(group_name text, usernames text[]) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; + user_role TEXT; + username TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + foreach username in array usernames + loop + user_role := @extschema@._CDB_User_RoleFromUsername(username); + EXECUTE format('REVOKE %I FROM %I', group_role, user_role); + end loop; + PERFORM @extschema@._CDB_Group_RemoveUsers_API(group_name, usernames); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +---------------------------------- +-- TABLE MANAGEMENT FUNCTIONS +-- +-- Meant to be used by table owners. +---------------------------------- + +-- Grants table read permission to a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_Table_GrantRead(group_name text, username text, table_name text) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + PERFORM @extschema@._CDB_Group_Table_GrantRead(group_name, username, table_name, true); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_Table_GrantRead(group_name text, username text, table_name text, sync boolean) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + EXECUTE format('GRANT USAGE ON SCHEMA %I TO %I', username, group_role); + EXECUTE format('GRANT SELECT ON TABLE %I.%I TO %I', username, table_name, group_role ); + IF(sync) THEN + PERFORM @extschema@._CDB_Group_Table_GrantPermission_API(group_name, username, table_name, 'r'); + END IF; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Grants table write permission to a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_Table_GrantReadWrite(group_name text, username text, table_name text) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + PERFORM @extschema@._CDB_Group_Table_GrantReadWrite(group_name, username, table_name, true); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_Table_GrantReadWrite(group_name text, username text, table_name text, sync boolean) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + EXECUTE format('GRANT USAGE ON SCHEMA %I TO %I', username, group_role); + EXECUTE format('GRANT SELECT, INSERT, UPDATE, DELETE ON TABLE %I.%I TO %I', username, table_name, group_role); + PERFORM @extschema@._CDB_Group_TableSequences_Permission(group_name, username, table_name, true); + IF(sync) THEN + PERFORM @extschema@._CDB_Group_Table_GrantPermission_API(group_name, username, table_name, 'w'); + END IF; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Granting and revoking permissions on sequences +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_TableSequences_Permission(group_name text, username text, table_name text, do_grant bool) + RETURNS VOID AS $$ +DECLARE + column_name TEXT; + sequence_name TEXT; + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + FOR column_name IN EXECUTE 'SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_CATALOG = current_database() AND TABLE_SCHEMA = $1 AND TABLE_NAME = $2 AND COLUMN_DEFAULT LIKE ''nextval%''' USING username, table_name + LOOP + EXECUTE format('SELECT PG_GET_SERIAL_SEQUENCE(''%I.%I'', ''%I'')', username, table_name, column_name) INTO sequence_name; + IF sequence_name IS NOT NULL THEN + IF do_grant THEN + -- Here %s is needed since sequence_name has quotes + EXECUTE format('GRANT USAGE, SELECT, UPDATE ON SEQUENCE %s TO %I', sequence_name, group_role); + ELSE + EXECUTE format('REVOKE ALL ON SEQUENCE %s FROM %I', sequence_name, group_role); + END IF; + END IF; + END LOOP; + RETURN; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Revokes all permissions on a table from a group +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Group_Table_RevokeAll(group_name text, username text, table_name text) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + PERFORM @extschema@._CDB_Group_Table_RevokeAll(group_name, username, table_name, true); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_Table_RevokeAll(group_name text, username text, table_name text, sync boolean) + RETURNS VOID AS $$ +DECLARE + group_role TEXT; +BEGIN + group_role := @extschema@._CDB_Group_GroupRole(group_name); + EXECUTE format('REVOKE ALL ON TABLE %I.%I FROM %I', username, table_name, group_role); + PERFORM @extschema@._CDB_Group_TableSequences_Permission(group_name, username, table_name, false); + IF(sync) THEN + PERFORM @extschema@._CDB_Group_Table_RevokeAllPermission_API(group_name, username, table_name); + END IF; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +----------------------- +-- Helper functions +----------------------- +-- Given a group name returns a role. group_name must be a valid PostgreSQL idenfifier. See http://www.postgresql.org/docs/9.2/static/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_GroupRole(group_name text) + RETURNS TEXT AS $$ +DECLARE + group_role TEXT; + prefix TEXT; + max_length constant INTEGER := 63; +BEGIN + prefix = format('%s_g_', @extschema@._CDB_Group_ShortDatabaseName()); + group_role := format('%s%s', prefix, group_name); + IF LENGTH(group_role) > max_length + THEN + RAISE EXCEPTION 'Group name must be shorter. It can''t have more than % characters, but it is longer (%): %', max_length - LENGTH(prefix), length(group_name), group_name; + END IF; + RETURN group_role; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; + +-- Returns the first owner of the schema matching username. Organization user schemas must have one only owner. +CREATE OR REPLACE +FUNCTION @extschema@._CDB_User_RoleFromUsername(username text) + RETURNS TEXT AS $$ +DECLARE + user_role TEXT; +BEGIN + -- This was preferred, but non-superadmins won't get results + -- SELECT SCHEMA_OWNER FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME = $1 LIMIT 1' + SELECT pg_get_userbyid(nspowner) FROM pg_namespace WHERE nspname = username INTO user_role; + RETURN user_role; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; + +-- Database names are too long, we need a shorter version for composing role names +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_ShortDatabaseName() + RETURNS TEXT AS $$ +DECLARE + short_database_name TEXT; +BEGIN + SELECT md5(current_database()) INTO short_database_name; + RETURN short_database_name; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_Groups_API.sql b/lib/sql/scripts-available/CDB_Groups_API.sql new file mode 100644 index 0000000..370e4b8 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Groups_API.sql @@ -0,0 +1,195 @@ +---------------------------------- +-- GROUP METADATA API FUNCTIONS +-- +-- Meant to be used by CDB_Group_* functions to sync data with the editor. +-- Requires configuration parameter. Example: SELECT @extschema@.CDB_Conf_SetConf('groups_api', '{ "host": "127.0.0.1", "port": 3000, "timeout": 10, "username": "extension", "password": "elephant" }'); +---------------------------------- + +-- TODO: delete this development cleanup before final merge +DROP FUNCTION IF EXISTS @extschema@.CDB_Group_AddMember(group_name text, username text); +DROP FUNCTION IF EXISTS @extschema@.CDB_Group_RemoveMember(group_name text, username text); +DROP FUNCTION IF EXISTS @extschema@._CDB_Group_AddMember_API(group_name text, username text); +DROP FUNCTION IF EXISTS @extschema@._CDB_Group_RemoveMember_API(group_name text, username text); + +-- Sends the create group request +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_CreateGroup_API(group_name text, group_role text) + RETURNS VOID AS +$$ + import string + + url = '/api/v1/databases/{0}/groups' + body = '{ "name": "%s", "database_role": "%s" }' % (group_name, group_role) + query = "select @extschema@._CDB_Group_API_Request('POST', '%s', '%s', '{200, 409}') as response_status" % (url, body) + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_DropGroup_API(group_name text) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s' % (urllib.pathname2url(group_name)) + + query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '', '{204, 404}') as response_status" % url + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_RenameGroup_API(old_group_name text, new_group_name text, new_group_role text) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s' % (urllib.pathname2url(old_group_name)) + body = '{ "name": "%s", "database_role": "%s" }' % (new_group_name, new_group_role) + query = "select @extschema@._CDB_Group_API_Request('PUT', '%s', '%s', '{200, 409}') as response_status" % (url, body) + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_AddUsers_API(group_name text, usernames text[]) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s/users' % (urllib.pathname2url(group_name)) + body = "{ \"users\": [\"%s\"] }" % "\",\"".join(usernames) + query = "select @extschema@._CDB_Group_API_Request('POST', '%s', '%s', '{200, 409}') as response_status" % (url, body) + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE SECURITY DEFINER; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_RemoveUsers_API(group_name text, usernames text[]) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s/users' % (urllib.pathname2url(group_name)) + body = "{ \"users\": [\"%s\"] }" % "\",\"".join(usernames) + query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '%s', '{200, 404}') as response_status" % (url, body) + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +DO LANGUAGE 'plpgsql' $$ +BEGIN + -- Needed for dropping type + DROP FUNCTION IF EXISTS @extschema@._CDB_Group_API_Conf(); + DROP TYPE IF EXISTS @extschema@._CDB_Group_API_Params; +END +$$; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_Table_GrantPermission_API(group_name text, username text, table_name text, access text) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s/permission/%s/tables/%s' % (urllib.pathname2url(group_name), username, table_name) + body = '{ "access": "%s" }' % access + query = "select @extschema@._CDB_Group_API_Request('PUT', '%s', '%s', '{200, 409}') as response_status" % (url, body) + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +DO LANGUAGE 'plpgsql' $$ +BEGIN + -- Needed for dropping type + DROP FUNCTION IF EXISTS @extschema@._CDB_Group_API_Conf(); + DROP TYPE IF EXISTS @extschema@._CDB_Group_API_Params; +END +$$; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_Table_RevokeAllPermission_API(group_name text, username text, table_name text) + RETURNS VOID AS +$$ + import string + import urllib + + url = '/api/v1/databases/{0}/groups/%s/permission/%s/tables/%s' % (urllib.pathname2url(group_name), username, table_name) + query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '', '{200, 404}') as response_status" % url + plpy.execute(query) +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +DO LANGUAGE 'plpgsql' $$ +BEGIN + -- Needed for dropping type + DROP FUNCTION IF EXISTS @extschema@._CDB_Group_API_Conf(); + DROP TYPE IF EXISTS @extschema@._CDB_Group_API_Params; +END +$$; + +CREATE TYPE @extschema@._CDB_Group_API_Params AS ( + host text, + port int, + timeout int, + auth text +); + +-- This must be explicitally extracted because "composite types are currently not supported". +-- See http://www.postgresql.org/docs/9.3/static/plpython-database.html. +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_API_Conf() + RETURNS @extschema@._CDB_Group_API_Params AS +$$ + conf = plpy.execute("SELECT @extschema@.CDB_Conf_GetConf('groups_api') conf")[0]['conf'] + if conf is None: + return None + else: + import json + params = json.loads(conf) + auth = 'Basic %s' % plpy.execute("SELECT @extschema@._CDB_Group_API_Auth('%s', '%s') as auth" % (params['username'], params['password']))[0]['auth'] + return { "host": params['host'], "port": params['port'], 'timeout': params['timeout'], 'auth': auth } +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_API_Auth(username text, password text) + RETURNS TEXT AS +$$ + import base64 + return base64.encodestring('%s:%s' % (username, password)).replace('\n', '') +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE; + +-- url must contain a '%s' placeholder that will be replaced by current_database, for security reasons. +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Group_API_Request(method text, url text, body text, valid_return_codes int[]) + RETURNS int AS +$$ + import httplib + + params = plpy.execute("select c.host, c.port, c.timeout, c.auth from @extschema@._CDB_Group_API_Conf() c;")[0] + if params['host'] is None: + return None + + headers = { 'Authorization': params['auth'], 'Content-Type': 'application/json', 'X-Forwarded-Proto': 'https' } + + retry = 3 + + last_err = None + while retry > 0: + try: + client = SD['groups_api_client'] = httplib.HTTPConnection(params['host'], params['port'], False, params['timeout']) + database_name = plpy.execute("select current_database();")[0]['current_database'] + client.request(method, url.format(database_name), body, headers) + response = client.getresponse() + assert response.status in valid_return_codes + return response.status + except Exception as err: + retry -= 1 + last_err = err + plpy.warning('Retrying after: ' + str(err)) + client = SD['groups_api_client'] = None + + if last_err is not None: + plpy.error('Fatal Group API error: ' + str(last_err)) + raise last_err + + return None +$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE; +revoke all on function @extschema@._CDB_Group_API_Request(text, text, text, int[]) from public; diff --git a/lib/sql/scripts-available/CDB_HeadsTailsBins.sql b/lib/sql/scripts-available/CDB_HeadsTailsBins.sql new file mode 100644 index 0000000..d7a178c --- /dev/null +++ b/lib/sql/scripts-available/CDB_HeadsTailsBins.sql @@ -0,0 +1,46 @@ +-- +-- Determine the Heads/Tails classifications from a numeric array +-- +-- @param in_array A numeric array of numbers to determine the best +-- bins based on the Heads/Tails method. +-- +-- @param breaks The number of bins you want to find. +-- +-- + +CREATE OR REPLACE FUNCTION @extschema@.CDB_HeadsTailsBins ( in_array NUMERIC[], breaks INT) RETURNS NUMERIC[] as $$ +DECLARE + element_count INT4; + arr_mean numeric; + i INT := 2; + reply numeric[]; +BEGIN + -- get the total size of our row + element_count := array_upper(in_array, 1) - array_lower(in_array, 1); + -- ensure the ordering of in_array + SELECT array_agg(e) INTO in_array FROM (SELECT unnest(in_array) e ORDER BY e) x; + -- stop if no rows + IF element_count IS NULL THEN + RETURN NULL; + END IF; + -- stop if our breaks are more than our input array size + IF element_count < breaks THEN + RETURN in_array; + END IF; + + -- get our mean value + SELECT avg(v) INTO arr_mean FROM ( SELECT unnest(in_array) as v ) x; + + reply = Array[arr_mean]; + -- slice our bread + LOOP + IF i > breaks THEN EXIT; END IF; + SELECT avg(e) INTO arr_mean FROM ( SELECT unnest(in_array) e) x WHERE e > reply[i-1]; + IF arr_mean IS NOT NULL THEN + reply = array_append(reply, arr_mean); + END IF; + i := i+1; + END LOOP; + RETURN reply; +END; +$$ language plpgsql IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_Helper.sql b/lib/sql/scripts-available/CDB_Helper.sql new file mode 100644 index 0000000..3d275ef --- /dev/null +++ b/lib/sql/scripts-available/CDB_Helper.sql @@ -0,0 +1,177 @@ +-- Create a sequence that belongs to the schema of the extension. +-- It will be used to generate unique identifiers within the + + +-- UTF8 safe and length aware. Find a unique identifier with a given prefix +-- and/or suffix and withing a schema. If a schema is not specified, the identifier +-- is guaranteed to be unique for all schemas. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Identifier(prefix TEXT, relname TEXT, suffix TEXT, schema TEXT DEFAULT NULL) +RETURNS TEXT +AS $$ +DECLARE + maxlen CONSTANT INTEGER := 63; + + rec RECORD; + usedspace INTEGER; + ident TEXT; + origident TEXT; + candrelname TEXT; + + i INTEGER; +BEGIN + -- Accounts for the XXXX incremental suffix in case the identifier is taken + usedspace := 4; + usedspace := usedspace + coalesce(octet_length(prefix), 0); + usedspace := usedspace + coalesce(octet_length(suffix), 0); + + candrelname := @extschema@._CDB_Octet_Truncate(relname, maxlen - usedspace); + + IF candrelname = '' THEN + PERFORM @extschema@._CDB_Error('prefixes are to long to generate a valid identifier', '_CDB_Unique_Identifier'); + END IF; + + ident := coalesce(prefix, '') || candrelname || coalesce(suffix, ''); + + i := 0; + origident := ident; + + WHILE i < 10000 LOOP + IF schema IS NOT NULL THEN + SELECT c.relname, n.nspname + INTO rec + FROM pg_class c + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.relname = ident + AND n.nspname = schema; + ELSE + SELECT c.relname, n.nspname + INTO rec + FROM pg_class c + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.relname = ident; + END IF; + + IF NOT FOUND THEN + RETURN ident; + END IF; + + ident := origident || i; + i := i + 1; + END LOOP; + + PERFORM @extschema@._CDB_Error('looping too far', '_CDB_Unique_Identifier'); +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +-- UTF8 safe and length aware. Find a unique identifier for a column with a given prefix +-- and/or suffix based on colname and within a relation specified via reloid. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Column_Identifier(prefix TEXT, colname TEXT, suffix TEXT, reloid REGCLASS) +RETURNS TEXT +AS $$ +DECLARE + maxlen CONSTANT INTEGER := 63; + + rec RECORD; + candcolname TEXT; + usedspace INTEGER; + ident TEXT; + origident TEXT; + + i INTEGER; +BEGIN + -- Accounts for the XXXX incremental suffix in case the identifier is taken + usedspace := 4; + usedspace := usedspace + coalesce(octet_length(prefix), 0); + usedspace := usedspace + coalesce(octet_length(suffix), 0); + + candcolname := @extschema@._CDB_Octet_Truncate(colname, maxlen - usedspace); + + IF candcolname = '' THEN + PERFORM @extschema@._CDB_Error('prefixes are to long to generate a valid identifier', '_CDB_Unique_Column_Identifier'); + END IF; + + ident := coalesce(prefix, '') || candcolname || coalesce(suffix, ''); + + i := 0; + origident := ident; + + WHILE i < 10000 LOOP + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + WHERE NOT a.attisdropped + AND a.attnum > 0 + AND c.oid = reloid + AND a.attname = ident; + + IF NOT FOUND THEN + RETURN ident; + END IF; + + ident := origident || i; + i := i + 1; + END LOOP; + + PERFORM @extschema@._CDB_Error('looping too far', '_CDB_Unique_Column_Identifier'); +END; +$$ LANGUAGE 'plpgsql' VOLATILE PARALLEL SAFE; + + +-- Truncates a given string to a max_octets octets taking care +-- not to leave characters in half. UTF8 safe. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Octet_Truncate(string TEXT, max_octets INTEGER) +RETURNS TEXT +AS $$ +DECLARE + extcharlen CONSTANT INTEGER := octet_length('ñ'); + + expected INTEGER; + examined INTEGER; + strlen INTEGER; + + i INTEGER; +BEGIN + + IF max_octets <= 0 THEN + RETURN ''; + ELSIF max_octets >= octet_length(string) THEN + RETURN string; + END IF; + + strlen := char_length(string); + + expected := char_length(string); + examined := octet_length(string); + + IF expected = examined THEN + RETURN left(string, max_octets); + END IF; + + i := max_octets / extcharlen; + + WHILE octet_length(left(string, i)) <= max_octets LOOP + i := i + 1; + END LOOP; + + RETURN left(string, (i - 1)); +END; +$$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; + + +-- Checks if a given text representing a qualified or unqualified table name (relation) +-- actually exists in the database. It is meant to be used as a guard for other function/queries. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Table_Exists(table_name_with_optional_schema TEXT) +RETURNS bool +AS $$ +DECLARE + table_exists bool := false; +BEGIN + table_exists := EXISTS(SELECT * FROM pg_class WHERE table_name_with_optional_schema::regclass::oid = oid AND relkind = 'r'); + RETURN table_exists; +EXCEPTION + WHEN invalid_schema_name OR undefined_table THEN + RETURN false; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_Hexagon.sql b/lib/sql/scripts-available/CDB_Hexagon.sql new file mode 100644 index 0000000..f26cba5 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Hexagon.sql @@ -0,0 +1,148 @@ +-- Return an Hexagon with given center and side (or maximal radius) +CREATE OR REPLACE FUNCTION @extschema@.CDB_MakeHexagon(center GEOMETRY, radius FLOAT8) +RETURNS GEOMETRY +AS $$ + SELECT @postgisschema@.ST_MakePolygon(@postgisschema@.ST_MakeLine(geom)) + FROM + ( + SELECT (@postgisschema@.ST_DumpPoints(@postgisschema@.ST_ExteriorRing(@postgisschema@.ST_Buffer($1, $2, 3)))).* + ) as points + WHERE path[1] % 2 != 0 +$$ LANGUAGE 'sql' IMMUTABLE STRICT PARALLEL SAFE; + + +-- In older versions of the extension, CDB_HexagonGrid had a different signature +DROP FUNCTION IF EXISTS @extschema@.CDB_HexagonGrid(GEOMETRY, FLOAT8, GEOMETRY); + +-- +-- Fill given extent with an hexagonal coverage +-- +-- @param ext Extent to fill. Only hexagons with center point falling +-- inside the extent (or at the lower or leftmost edge) will +-- be emitted. The returned hexagons will have the same SRID +-- as this extent. +-- +-- @param side Side measure for the hexagon. +-- Maximum diameter will be 2 * side. +-- +-- @param origin Optional origin to allow for exact tiling. +-- If omitted the origin will be 0,0. +-- The parameter is checked for having the same SRID +-- as the extent. +-- +-- @param maxcells Optional maximum number of grid cells to generate; +-- if the grid requires more cells to cover the extent +-- and exception will occur. +---- +-- DROP FUNCTION IF EXISTS CDB_HexagonGrid(ext GEOMETRY, side FLOAT8); +CREATE OR REPLACE FUNCTION @extschema@.CDB_HexagonGrid(ext GEOMETRY, side FLOAT8, origin GEOMETRY DEFAULT NULL, maxcells INTEGER DEFAULT 512*512) +RETURNS SETOF GEOMETRY +AS $$ +DECLARE + h GEOMETRY; -- hexagon + c GEOMETRY; -- center point + rec RECORD; + hstep FLOAT8; -- horizontal step + vstep FLOAT8; -- vertical step + vstart FLOAT8; + vstartary FLOAT8[]; + vstartidx INTEGER; + hskip BIGINT; + hstart FLOAT8; + hend FLOAT8; + vend FLOAT8; + xoff FLOAT8; + yoff FLOAT8; + xgrd FLOAT8; + ygrd FLOAT8; + srid INTEGER; +BEGIN + + -- | | + -- |hstep| + -- ______ ___ | + -- vstep / \ ___ / + -- ______ \ ___ / \ + -- / \ ___ / + -- + -- + RAISE DEBUG 'Side: %', side; + + vstep := side * sqrt(3); -- x 2 ? + hstep := side * 1.5; + + RAISE DEBUG 'vstep: %', vstep; + RAISE DEBUG 'hstep: %', hstep; + + srid := ST_SRID(ext); + + xoff := 0; + yoff := 0; + + IF origin IS NOT NULL THEN + IF @postgisschema@.ST_SRID(origin) != srid THEN + RAISE EXCEPTION 'SRID mismatch between extent (%) and origin (%)', srid, ST_SRID(origin); + END IF; + xoff := @postgisschema@.ST_X(origin); + yoff := @postgisschema@.ST_Y(origin); + END IF; + + RAISE DEBUG 'X offset: %', xoff; + RAISE DEBUG 'Y offset: %', yoff; + + xgrd := side * 0.5; + ygrd := ( side * sqrt(3) ) / 2.0; + RAISE DEBUG 'X grid size: %', xgrd; + RAISE DEBUG 'Y grid size: %', ygrd; + + -- Tweak horizontal start on hstep*2 grid from origin + hskip := ceil((@postgisschema@.ST_XMin(ext)-xoff)/hstep); + RAISE DEBUG 'hskip: %', hskip; + hstart := xoff + hskip*hstep; + RAISE DEBUG 'hstart: %', hstart; + + -- Tweak vertical start on hstep grid from origin + vstart := yoff + ceil((@postgisschema@.ST_Ymin(ext)-yoff)/vstep)*vstep; + RAISE DEBUG 'vstart: %', vstart; + + hend := @postgisschema@.ST_XMax(ext); + vend := @postgisschema@.ST_YMax(ext); + + IF vstart - (vstep/2.0) < @postgisschema@.ST_YMin(ext) THEN + vstartary := ARRAY[ vstart + (vstep/2.0), vstart ]; + ELSE + vstartary := ARRAY[ vstart - (vstep/2.0), vstart ]; + END IF; + + If maxcells IS NOT NULL AND maxcells > 0 THEN + IF CEIL((CEIL((vend-vstart)/(vstep/2.0)) * CEIL((hend-hstart)/(hstep*2.0/3.0)))/3.0)::integer > maxcells THEN + RAISE EXCEPTION 'The requested grid is too big to be rendered'; + END IF; + END IF; + + vstartidx := abs(hskip)%2; + + RAISE DEBUG 'vstartary: % : %', vstartary[1], vstartary[2]; + RAISE DEBUG 'vstartidx: %', vstartidx; + + c := @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(hstart, vstartary[vstartidx+1]), srid); + h := @postgisschema@.ST_SnapToGrid(@extschema@.CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); + vstartidx := (vstartidx + 1) % 2; + WHILE @postgisschema@.ST_X(c) < hend LOOP -- over X + --RAISE DEBUG 'X loop starts, center point: %', ST_AsText(c); + WHILE @postgisschema@.ST_Y(c) < vend LOOP -- over Y + --RAISE DEBUG 'Center: %', ST_AsText(c); + --h := ST_SnapToGrid(CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); + RETURN NEXT h; + h := @postgisschema@.ST_SnapToGrid(ST_Translate(h, 0, vstep), xoff, yoff, xgrd, ygrd); + c := @postgisschema@.ST_Translate(c, 0, vstep); -- TODO: drop ? + END LOOP; + -- TODO: translate h direcly ... + c := @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(ST_X(c)+hstep, vstartary[vstartidx+1]), srid); + h := @postgisschema@.ST_SnapToGrid(@extschema@.CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); + vstartidx := (vstartidx + 1) % 2; + END LOOP; + + RETURN; +END +$$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_JenksBins.sql b/lib/sql/scripts-available/CDB_JenksBins.sql new file mode 100644 index 0000000..81ead54 --- /dev/null +++ b/lib/sql/scripts-available/CDB_JenksBins.sql @@ -0,0 +1,346 @@ +-- +-- Determine the Jenks classifications from a numeric array +-- +-- @param in_array A numeric array of numbers to determine the best +-- bins based on the Jenks method. +-- +-- @param breaks The number of bins you want to find. +-- +-- @param iterations The number of different starting positions to test. +-- +-- @param invert Optional wheter to return the top of each bin (default) +-- or the bottom. BOOLEAN, default=FALSE. +-- +-- + +CREATE OR REPLACE FUNCTION @extschema@.CDB_JenksBins(in_array NUMERIC[], breaks INT, iterations INT DEFAULT 0, invert BOOLEAN DEFAULT FALSE) +RETURNS NUMERIC[] as +$$ +DECLARE + in_matrix NUMERIC[][]; + in_unique_count BIGINT; + + shuffles INT; + arr_mean NUMERIC; + sdam NUMERIC; + + i INT; + bot INT; + top INT; + + tops INT[]; + classes INT[][]; + j INT := 1; + curr_result NUMERIC[]; + best_result NUMERIC[]; + seedtarget TEXT; + +BEGIN + -- We clean the input array (remove NULLs) and create 2 arrays + -- [1] contains the unique values in in_array + -- [2] contains the number of appearances of those unique values + SELECT ARRAY[array_agg(value), array_agg(count)] FROM + ( + SELECT value, count(1)::numeric as count + FROM unnest(in_array) AS value + WHERE value is NOT NULL + GROUP BY value + ORDER BY value + ) __clean_array_q INTO in_matrix; + + -- Get the number of unique values + in_unique_count := array_length(in_matrix[1:1], 2); + + IF in_unique_count IS NULL THEN + RETURN NULL; + END IF; + + IF in_unique_count <= breaks THEN + -- There isn't enough distinct values for the requested breaks + RETURN ARRAY(Select unnest(in_matrix[1:1])) _a; + END IF; + + -- If not declated explicitly we iterate based on the length of the array + IF iterations < 1 THEN + -- This is based on a 'looks fine' heuristic + iterations := log(in_unique_count)::integer + 1; + END IF; + + -- We set the number of shuffles per iteration as the number of unique values but + -- this is just another 'looks fine' heuristic + shuffles := in_unique_count; + + -- Get the mean value of the whole vector (already ignores NULLs) + SELECT avg(v) INTO arr_mean FROM ( SELECT unnest(in_array) as v ) x; + + -- Calculate the sum of squared deviations from the array mean (SDAM). + SELECT sum(((arr_mean - v)^2) * w) INTO sdam FROM ( + SELECT unnest(in_matrix[1:1]) as v, unnest(in_matrix[2:2]) as w + ) x; + + -- To start, we create ranges with approximately the same amount of different values + top := 0; + i := 1; + LOOP + bot := top + 1; + top := ROUND(i * in_unique_count::numeric / breaks::NUMERIC); + + IF i = 1 THEN + classes = ARRAY[ARRAY[bot,top]]; + ELSE + classes = ARRAY_CAT(classes, ARRAY[bot,top]); + END IF; + + i := i + 1; + IF i > breaks THEN EXIT; END IF; + END LOOP; + + best_result = @extschema@.CDB_JenksBinsIteration(in_matrix, breaks, classes, invert, sdam, shuffles); + + --set the seed so we can ensure the same results + SELECT setseed(0.4567) INTO seedtarget; + --loop through random starting positions + LOOP + IF j > iterations-1 THEN EXIT; END IF; + i = 1; + tops = ARRAY[in_unique_count]; + LOOP + IF i = breaks THEN EXIT; END IF; + SELECT array_agg(distinct e) INTO tops FROM ( + SELECT unnest(array_cat(tops, ARRAY[trunc(random() * in_unique_count::float8)::int + 1])) as e ORDER BY e + ) x; + i = array_length(tops, 1); + END LOOP; + top := 0; + i = 1; + LOOP + bot := top + 1; + top = tops[i]; + IF i = 1 THEN + classes = ARRAY[ARRAY[bot,top]]; + ELSE + classes = ARRAY_CAT(classes, ARRAY[bot,top]); + END IF; + + i := i+1; + IF i > breaks THEN EXIT; END IF; + END LOOP; + + curr_result = @extschema@.CDB_JenksBinsIteration(in_matrix, breaks, classes, invert, sdam, shuffles); + + IF curr_result[1] > best_result[1] THEN + best_result = curr_result; + END IF; + + j = j+1; + END LOOP; + + RETURN (best_result)[2:array_upper(best_result, 1)]; +END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL RESTRICTED; + + +-- +-- Perform a single iteration of the Jenks classification +-- +-- Returns an array with: +-- - First element: gvf +-- - Second to 2+n: Category limits +DROP FUNCTION IF EXISTS @extschema@.CDB_JenksBinsIteration ( in_matrix NUMERIC[], breaks INT, classes INT[], invert BOOLEAN, element_count INT4, arr_mean NUMERIC, max_search INT); -- Old signature + +CREATE OR REPLACE FUNCTION @extschema@.CDB_JenksBinsIteration ( in_matrix NUMERIC[], breaks INT, classes INT[], invert BOOLEAN, sdam NUMERIC, max_search INT DEFAULT 50) RETURNS NUMERIC[] as $$ +DECLARE + i INT; + iterations INT = 0; + + side INT := 2; + + gvf numeric := 0.0; + new_gvf numeric; + arr_gvf numeric[]; + arr_avg numeric[]; + class_avg numeric; + class_dev numeric; + + class_max_i INT = 0; + class_min_i INT = 0; + dev_max numeric; + dev_min numeric; + + best_classes INT[] = classes; + best_gvf numeric[]; + best_avg numeric[]; + move_elements INT = 1; + + reply numeric[]; + +BEGIN + + -- We fill the arrays with the initial values + i = 0; + LOOP + IF i = breaks THEN EXIT; END IF; + i = i + 1; + + -- Get class mean + SELECT (sum(v * w) / sum(w)) INTO class_avg FROM ( + SELECT unnest(in_matrix[1:1][classes[i][1]:classes[i][2]]) as v, + unnest(in_matrix[2:2][classes[i][1]:classes[i][2]]) as w + ) x; + + -- Get class deviation + SELECT sum((class_avg - v)^2 * w) INTO class_dev FROM ( + SELECT unnest(in_matrix[1:1][classes[i][1]:classes[i][2]]) as v, + unnest(in_matrix[2:2][classes[i][1]:classes[i][2]]) as w + ) x; + + + IF i = 1 THEN + arr_avg = ARRAY[class_avg]; + arr_gvf = ARRAY[class_dev]; + ELSE + arr_avg = array_append(arr_avg, class_avg); + arr_gvf = array_append(arr_gvf, class_dev); + END IF; + END LOOP; + + -- We copy the values to avoid recalculation when a failure happens + best_avg = arr_avg; + best_gvf = arr_gvf; + + iterations = 0; + LOOP + IF iterations = max_search THEN EXIT; END IF; + iterations = iterations + 1; + + -- calculate our new GVF + SELECT sdam - sum(e) INTO new_gvf FROM ( SELECT unnest(arr_gvf) as e ) x; + + -- Check if any improvement was made + IF new_gvf <= gvf THEN + -- If we were moving too many elements, go back and move less + IF move_elements <= 2 OR class_max_i = class_min_i THEN + EXIT; + END IF; + + move_elements = GREATEST(move_elements / 8, 1); + + -- Rollback from saved statuses + classes = best_classes; + new_gvf = gvf; + + i = class_min_i; + LOOP + arr_avg[i] = best_avg[i]; + arr_gvf[i] = best_gvf[i]; + + IF i = class_max_i THEN EXIT; END IF; + i = i + 1; + END LOOP; + END IF; + + -- We search for the classes with the min and max deviation + i = 1; + class_min_i = 1; + class_max_i = 1; + dev_max = arr_gvf[1]; + dev_min = arr_gvf[1]; + LOOP + IF i = breaks THEN EXIT; END IF; + i = i + 1; + + IF arr_gvf[i] < dev_min THEN + dev_min = arr_gvf[i]; + class_min_i = i; + ELSE + IF arr_gvf[i] > dev_max THEN + dev_max = arr_gvf[i]; + class_max_i = i; + END IF; + END IF; + END LOOP; + + + -- Save best values for comparison and output + gvf = new_gvf; + best_classes = classes; + + -- Limit the moved elements as to not remove everything from class_max_i + move_elements = LEAST(move_elements, classes[class_max_i][2] - classes[class_max_i][1]); + + -- Move `move_elements` from class_max_i to class_min_i + IF class_min_i < class_max_i THEN + i := class_min_i; + LOOP + IF i = class_max_i THEN EXIT; END IF; + classes[i][2] = classes[i][2] + move_elements; + i := i + 1; + END LOOP; + + i := class_max_i; + LOOP + IF i = class_min_i THEN EXIT; END IF; + classes[i][1] = classes[i][1] + move_elements; + i := i - 1; + END LOOP; + ELSE + i := class_min_i; + LOOP + IF i = class_max_i THEN EXIT; END IF; + classes[i][1] = classes[i][1] - move_elements; + i := i - 1; + END LOOP; + + i := class_max_i; + LOOP + IF i = class_min_i THEN EXIT; END IF; + classes[i][2] = classes[i][2] - move_elements; + i := i + 1; + END LOOP; + END IF; + + -- Recalculate avg and deviation ONLY for the affected classes + i = LEAST(class_min_i, class_max_i); + class_max_i = GREATEST(class_min_i, class_max_i); + class_min_i = i; + LOOP + SELECT (sum(v * w) / sum(w)) INTO class_avg FROM ( + SELECT unnest(in_matrix[1:1][classes[i][1]:classes[i][2]]) as v, + unnest(in_matrix[2:2][classes[i][1]:classes[i][2]]) as w + ) x; + + SELECT sum((class_avg - v)^2 * w) INTO class_dev FROM ( + SELECT unnest(in_matrix[1:1][classes[i][1]:classes[i][2]]) as v, + unnest(in_matrix[2:2][classes[i][1]:classes[i][2]]) as w + ) x; + + -- Save status (in case it's needed for rollback) and store the new one + best_avg[i] = arr_avg[i]; + arr_avg[i] = class_avg; + + best_gvf[i] = arr_gvf[i]; + arr_gvf[i] = class_dev; + + IF i = class_max_i THEN EXIT; END IF; + i = i + 1; + END LOOP; + + move_elements = move_elements * 2; + + END LOOP; + + i = 1; + LOOP + IF invert = TRUE THEN + side = 1; --default returns bottom side of breaks, invert returns top side + END IF; + reply = array_append(reply, unnest(in_matrix[1:1][best_classes[i][side]:best_classes[i][side]])); + i = i+1; + IF i > breaks THEN EXIT; END IF; + END LOOP; + + reply = array_prepend(gvf, reply); + RETURN reply; + +END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_LatLng.sql b/lib/sql/scripts-available/CDB_LatLng.sql new file mode 100644 index 0000000..06ef7bb --- /dev/null +++ b/lib/sql/scripts-available/CDB_LatLng.sql @@ -0,0 +1,17 @@ +-- +-- Create a valid GEOMETRY in 4326 from a lat/lng pair +-- +-- @param lat A numeric latitude value. +-- +-- @param lng A numeric longitude value. +-- +-- + +CREATE OR REPLACE FUNCTION @extschema@.CDB_LatLng (lat NUMERIC, lng NUMERIC) RETURNS @postgisschema@.geometry as $$ + SELECT @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(lng,lat), 4326); +$$ language SQL IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION @extschema@.CDB_LatLng (lat FLOAT8, lng FLOAT8) RETURNS @postgisschema@.geometry as $$ + SELECT @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(lng,lat), 4326); +$$ language SQL IMMUTABLE PARALLEL SAFE; + diff --git a/lib/sql/scripts-available/CDB_Math.sql b/lib/sql/scripts-available/CDB_Math.sql new file mode 100644 index 0000000..abd470f --- /dev/null +++ b/lib/sql/scripts-available/CDB_Math.sql @@ -0,0 +1,27 @@ +-- CartoDB Math SQL functions + + +-- Mode +-- https://wiki.postgresql.org/wiki/Aggregate_Mode + +CREATE OR REPLACE FUNCTION @extschema@._CDB_Math_final_mode(anyarray) + RETURNS anyelement AS +$BODY$ + SELECT a + FROM unnest($1) a + GROUP BY 1 + ORDER BY COUNT(1) DESC, 1 + LIMIT 1; +$BODY$ +LANGUAGE 'sql' IMMUTABLE PARALLEL SAFE; + +DROP AGGREGATE IF EXISTS @extschema@.CDB_Math_Mode(anyelement); + +CREATE AGGREGATE @extschema@.CDB_Math_Mode(anyelement) ( + SFUNC=array_append, + STYPE=anyarray, + FINALFUNC=@extschema@._CDB_Math_final_mode, + PARALLEL = SAFE, + INITCOND='{}' +); + diff --git a/lib/sql/scripts-available/CDB_Organizations.sql b/lib/sql/scripts-available/CDB_Organizations.sql new file mode 100644 index 0000000..c97208e --- /dev/null +++ b/lib/sql/scripts-available/CDB_Organizations.sql @@ -0,0 +1,171 @@ +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Member_Group_Role_Member_Name() + RETURNS TEXT +AS $$ + SELECT 'cdb_org_member'::text || '_' || md5(current_database()); +$$ +LANGUAGE SQL STABLE PARALLEL SAFE; + +DO LANGUAGE 'plpgsql' $$ +DECLARE + cdb_org_member_role_name TEXT; +BEGIN + cdb_org_member_role_name := @extschema@.CDB_Organization_Member_Group_Role_Member_Name(); + IF NOT EXISTS ( SELECT * FROM pg_roles WHERE rolname= cdb_org_member_role_name ) + THEN + EXECUTE 'CREATE ROLE "' || cdb_org_member_role_name || '" NOLOGIN;'; + END IF; +END +$$; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Create_Member(role_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'GRANT "' || @extschema@.CDB_Organization_Member_Group_Role_Member_Name() || '" TO "' || role_name || '"'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +------------------------------------------------------------------------------- +-- Administrator +------------------------------------------------------------------------------- +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Organization_Admin_Role_Name() + RETURNS TEXT +AS $$ + SELECT current_database() || '_a'::text; +$$ +LANGUAGE SQL STABLE PARALLEL SAFE; + +-- Administrator role creation on extension install +DO LANGUAGE 'plpgsql' $$ +DECLARE + cdb_org_admin_role_name TEXT; +BEGIN + cdb_org_admin_role_name := @extschema@._CDB_Organization_Admin_Role_Name(); + IF NOT EXISTS ( SELECT * FROM pg_roles WHERE rolname= cdb_org_admin_role_name ) + THEN + EXECUTE format('CREATE ROLE %I CREATEROLE NOLOGIN;', cdb_org_admin_role_name); + END IF; +END +$$; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_AddAdmin(username text) + RETURNS void +AS $$ +DECLARE + cdb_user_role TEXT; + cdb_admin_role TEXT; +BEGIN + cdb_admin_role := @extschema@._CDB_Organization_Admin_Role_Name(); + cdb_user_role := @extschema@._CDB_User_RoleFromUsername(username); + EXECUTE format('GRANT %I TO %I WITH ADMIN OPTION', cdb_admin_role, cdb_user_role); + -- CREATEROLE is not inherited, and is needed for user creation + EXECUTE format('ALTER ROLE %I CREATEROLE', cdb_user_role); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_RemoveAdmin(username text) + RETURNS void +AS $$ +DECLARE + cdb_user_role TEXT; + cdb_admin_role TEXT; +BEGIN + cdb_admin_role := @extschema@._CDB_Organization_Admin_Role_Name(); + cdb_user_role := @extschema@._CDB_User_RoleFromUsername(username); + EXECUTE format('ALTER ROLE %I NOCREATEROLE', cdb_user_role); + EXECUTE format('REVOKE %I FROM %I', cdb_admin_role, cdb_user_role); +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +------------------------------------------------------------------------------- +-- Sharing tables +------------------------------------------------------------------------------- +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Add_Table_Read_Permission(from_schema text, table_name text, to_role_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'GRANT USAGE ON SCHEMA "' || from_schema || '" TO "' || to_role_name || '"'; + EXECUTE 'GRANT SELECT ON "' || from_schema || '"."' || table_name || '" TO "' || to_role_name || '"'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Add_Table_Organization_Read_Permission(from_schema text, table_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'SELECT @extschema@.CDB_Organization_Add_Table_Read_Permission(''' || from_schema || ''', ''' || table_name || ''', ''' || @extschema@.CDB_Organization_Member_Group_Role_Member_Name() || ''');'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@._CDB_Organization_Get_Table_Sequences(from_schema text, table_name text) + RETURNS SETOF TEXT +AS $$ +BEGIN + RETURN QUERY EXECUTE 'SELECT + quote_ident(n.nspname) || ''.'' || quote_ident(c.relname) + FROM + pg_depend d + JOIN pg_class c ON d.objid = c.oid + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE + d.refobjsubid > 0 AND + d.classid = ''pg_class''::regclass AND + c.relkind = ''S''::"char" AND + d.refobjid = (''' || quote_ident(from_schema) || '.' || quote_ident(table_name) ||''')::regclass'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Add_Table_Read_Write_Permission(from_schema text, table_name text, to_role_name text) + RETURNS void +AS $$ +DECLARE + sequence_name TEXT; +BEGIN + EXECUTE 'GRANT USAGE ON SCHEMA "' || from_schema || '" TO "' || to_role_name || '"'; + EXECUTE 'GRANT SELECT, INSERT, UPDATE, DELETE ON "' || from_schema || '"."' || table_name || '" TO "' || to_role_name || '"'; + + FOR sequence_name IN SELECT * FROM @extschema@._CDB_Organization_Get_Table_Sequences(from_schema, table_name) LOOP + EXECUTE 'GRANT USAGE, SELECT ON SEQUENCE ' || sequence_name || ' TO "' || to_role_name || '"'; + END LOOP; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Add_Table_Organization_Read_Write_Permission(from_schema text, table_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'SELECT @extschema@.CDB_Organization_Add_Table_Read_Write_Permission(''' || from_schema || ''', ''' || table_name || ''', ''' || @extschema@.CDB_Organization_Member_Group_Role_Member_Name() || ''');'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Remove_Access_Permission(from_schema text, table_name text, to_role_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'REVOKE ALL PRIVILEGES ON TABLE "' || from_schema || '"."' || table_name || '" FROM "' || to_role_name || '"'; + -- EXECUTE 'REVOKE USAGE ON SCHEMA ' || from_schema || ' FROM "' || to_role_name || '"'; + -- We need to revoke usage on schema only if we are revoking privileges from the last table where to_role_name has + -- any permission granted within the schema from_schema +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +CREATE OR REPLACE +FUNCTION @extschema@.CDB_Organization_Remove_Organization_Access_Permission(from_schema text, table_name text) + RETURNS void +AS $$ +BEGIN + EXECUTE 'SELECT @extschema@.CDB_Organization_Remove_Access_Permission(''' || from_schema || ''', ''' || table_name || ''', ''' || @extschema@.CDB_Organization_Member_Group_Role_Member_Name() || ''');'; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_Overviews.sql b/lib/sql/scripts-available/CDB_Overviews.sql new file mode 100644 index 0000000..216c294 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Overviews.sql @@ -0,0 +1,1070 @@ +-- Remove a dataset's existing overview tables. +-- Scope: public +-- Parameters: +-- reloid: oid of the table. +CREATE OR REPLACE FUNCTION @extschema@.CDB_DropOverviews(reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + row record; + schema_name TEXT; + table_name TEXT; +BEGIN + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, table_name; + FOR row IN + SELECT * FROM @extschema@.CDB_Overviews(reloid) + LOOP + EXECUTE Format('DROP TABLE %s;', row.overview_table); + RAISE NOTICE 'Dropped overview for level %: %', row.z, row.overview_table; + END LOOP; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + + + +-- Return existing overviews (if any) for a given dataset table +-- Scope: public +-- Parameters +-- reloid: oid of the input table. +-- Return relation of overviews for the table with +-- the base table oid, +-- z level of the overview and overview table oid, ordered by z. +CREATE OR REPLACE FUNCTION @extschema@.CDB_Overviews(reloid REGCLASS) +RETURNS TABLE(base_table REGCLASS, z integer, overview_table REGCLASS) +AS $$ + DECLARE + schema_name TEXT; + base_table_name TEXT; + BEGIN + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, base_table_name; + RETURN QUERY SELECT + reloid AS base_table, + @extschema@._CDB_OverviewTableZ(table_name) AS z, + table_regclass AS overview_table + FROM @extschema@._CDB_UserTablesInSchema(schema_name) + WHERE @extschema@._CDB_IsOverviewTableOf((SELECT relname FROM pg_class WHERE oid=reloid), table_name) + ORDER BY z; + END +$$ LANGUAGE PLPGSQL STABLE PARALLEL RESTRICTED; + +-- Return existing overviews (if any) for multiple dataset tables. +-- Scope: public +-- Parameters +-- tables: Array of input tables oids +-- Return relation of overviews for the table with +-- the base table oid, +-- z level of the overview and overview table oid, ordered by z. +-- Note: CDB_Overviews can be applied to the result of CDB_QueryTablesText +-- to obtain the overviews applicable to a query. +CREATE OR REPLACE FUNCTION @extschema@.CDB_Overviews(tables regclass[]) +RETURNS TABLE(base_table REGCLASS, z integer, overview_table REGCLASS) +AS $$ + SELECT + base_table::regclass AS base_table, + @extschema@._CDB_OverviewTableZ(table_name) AS z, + table_regclass AS overview_table + FROM + @extschema@._CDB_UserTablesInSchema(), unnest(tables) base_table + WHERE + schema_name = @extschema@._cdb_schema_name(base_table) + AND @extschema@._CDB_IsOverviewTableOf((SELECT relname FROM pg_class WHERE oid=base_table), table_name) + ORDER BY base_table, z; +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +-- Calculate the estimated extent of a cartodbfy'ed table. +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. +-- Return value A box2d extent in 3857. +CREATE OR REPLACE FUNCTION @extschema@._cdb_estimated_extent(reloid REGCLASS) +RETURNS @postgisschema@.box2d +AS $$ + DECLARE + ext @postgisschema@.box2d; + ext_query text; + table_id record; + BEGIN + + SELECT n.nspname AS schema_name, c.relname table_name INTO STRICT table_id + FROM pg_class c JOIN pg_namespace n on n.oid = c.relnamespace WHERE c.oid = reloid::oid; + + ext_query = format( + 'SELECT @postgisschema@.ST_EstimatedExtent(''%1$s'', ''%2$s'', ''%3$s'');', + table_id.schema_name, table_id.table_name, 'the_geom_webmercator' + ); + + EXECUTE ext_query INTO ext; + IF ext IS NULL THEN + -- Get stats and execute again + EXECUTE format('ANALYZE %1$s', reloid); + + -- We check the geometry type in case the error is due to empty geometries + IF @extschema@._CDB_GeometryTypes(reloid) IS NULL THEN + RETURN NULL; + END IF; + + EXECUTE ext_query INTO ext; + END IF; + + RETURN ext; + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Determine the max feature density of a given dataset. +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- nz: number of zoom levels to consider from z0 upward. +-- Return value: feature density (num_features / webmercator_squared_meters). +CREATE OR REPLACE FUNCTION @extschema@._CDB_Feature_Density(reloid REGCLASS, nz integer) +RETURNS FLOAT8 +AS $$ + DECLARE + fd FLOAT8; + min_features TEXT; + n integer = 4; + c FLOAT8; + BEGIN + -- TODO: for small total count or extents we could just: + -- EXECUTE 'SELECT Count(*)/ST_Area(ST_Extent(the_geom_webmercator)) FROM ' || reloid::text || ';' INTO fd; + + -- min_features is a SQL subexpression which can depend on z and represents + -- the minimum number of features to recursively consider a tile. + -- We can either use a fixed minimum number of features per tile + -- or a minimum feature density by dividing the number of features by + -- the area of tiles at level Z: c*c*power(2, -2*z) + -- with c = CDB_XYZ_Resolution(-8) (earth circumference) + min_features = '500'; + SELECT @extschema@.CDB_XYZ_Resolution(-8) INTO c; + + -- We first compute a set of *seed* tiles, of the minimum Z level, z0, such that + -- they cover the extent of the table and we have at least n of them in each + -- linear dimension (i.e. at least n*n tiles cover the extent). + -- We compute the number of features in these tiles, and recursively in + -- subtiles up to level z0 + nz. Then we compute the maximum of the feature + -- density (per tile area in webmercator squared meters) for all the + -- considered tiles. + EXECUTE Format(' + WITH RECURSIVE t(x, y, z, e) AS ( + WITH ext AS (SELECT @extschema@._cdb_estimated_extent(%6$s) as g), + base AS ( + SELECT + least( + -floor(log(2, (greatest(@postgisschema@.ST_XMax(ext.g)-@postgisschema@.ST_XMin(ext.g), @postgisschema@.ST_YMax(ext.g)-@postgisschema@.ST_YMin(ext.g))/(%4$s*%5$s))::numeric)), + @extschema@._CDB_MaxOverviewLevel()+1 + )::integer z + FROM ext + ), + lim AS ( + SELECT + FLOOR((@postgisschema@.ST_XMin(ext.g)+@extschema@.CDB_XYZ_Resolution(0)*128)/(@extschema@.CDB_XYZ_Resolution(base.z)*256))::integer x0, + FLOOR((@postgisschema@.ST_XMax(ext.g)+@extschema@.CDB_XYZ_Resolution(0)*128)/(@extschema@.CDB_XYZ_Resolution(base.z)*256))::integer x1, + FLOOR((@extschema@.CDB_XYZ_Resolution(0)*128-@postgisschema@.ST_YMin(ext.g))/(@extschema@.CDB_XYZ_Resolution(base.z)*256))::integer y1, + FLOOR((@extschema@.CDB_XYZ_Resolution(0)*128-@postgisschema@.ST_YMax(ext.g))/(@extschema@.CDB_XYZ_Resolution(base.z)*256))::integer y0 + FROM ext, base + ), + seed AS ( + SELECT xt, yt, base.z, ( + SELECT count(*) FROM %1$s + WHERE the_geom_webmercator && @extschema@.CDB_XYZ_Extent(xt, yt, base.z) + ) e + FROM base, lim, generate_series(lim.x0, lim.x1) xt, generate_series(lim.y0, lim.y1) yt + ) + SELECT * from seed + UNION ALL + SELECT x*2 + xx, y*2 + yy, t.z+1, ( + SELECT count(*) FROM %1$s + WHERE the_geom_webmercator && @extschema@.CDB_XYZ_Extent(t.x*2 + c.xx, t.y*2 + c.yy, t.z+1) + ) + FROM t, base, (VALUES (0, 0), (0, 1), (1, 1), (1, 0)) AS c(xx, yy) + WHERE t.e > %2$s AND t.z < least(base.z + %3$s, _CDB_MaxZoomLevel()) + ) + SELECT MAX(e/@postgisschema@.ST_Area(@extschema@.CDB_XYZ_Extent(x,y,z))) FROM t where e > 0; + ', reloid::text, min_features, nz, n, c, reloid::oid) + INTO fd; + RETURN fd; + END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Experimental default strategy to assign a reference base Z level +-- to a cartodbfied table. The resulting Z level represents the +-- minimum scale level at which the table data can be rendered +-- without overcrowded results or loss of detail. +-- Parameters: +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- Return value: Z level as an integer +CREATE OR REPLACE FUNCTION @extschema@._CDB_Feature_Density_Ref_Z_Strategy(reloid REGCLASS, tolerance_px FLOAT8 DEFAULT NULL) +RETURNS INTEGER +AS $$ + DECLARE + lim FLOAT8; + nz integer := 4; + fd FLOAT8; + c FLOAT8; + BEGIN + IF (tolerance_px IS NULL) OR tolerance_px = 0 THEN + lim := 500; + ELSE + lim := floor(power(256/tolerance_px, 2))/2; + END IF; + + -- Compute fd as an estimation of the (maximum) number + -- of features per unit of tile area (in webmercator squared meters) + SELECT @extschema@._CDB_Feature_Density(reloid, nz) INTO fd; + -- lim maximum number of (desiderable) features per tile + -- we have c = 2*Pi*R = CDB_XYZ_Resolution(-8) (earth circumference) + -- ta(z): tile area = power(c*power(2,-z), 2) = c*c*power(2,-2*z) + -- => fd*ta(z) is the average number of features per tile at level z + -- find minimum z so that fd*ta(z) <= lim + -- compute a rough 'feature density' value + SELECT @extschema@.CDB_XYZ_Resolution(-8) INTO c; + RETURN least(@extschema@._CDB_MaxOverviewLevel()+1, ceil(log(2.0, (c*c*fd/lim)::numeric)/2)); + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Overview table name for a given Z level and base dataset or overview table +-- Scope: private. +-- Parameters: +-- ref reference table (can be the base table of the dataset or an existing +-- overview) from which the overview is being generated. +-- ref_z Z level of the reference table +-- overview_z Z level of the overview to be named, must be smaller than ref_z +-- Return value: the name to be used for the overview. The name is always +-- unqualified (does not include a schema name). +CREATE OR REPLACE FUNCTION @extschema@._CDB_Overview_Name(ref REGCLASS, ref_z INTEGER, overview_z INTEGER) +RETURNS TEXT +AS $$ + DECLARE + schema_name TEXT; + base TEXT; + suffix TEXT; + is_overview BOOLEAN; + BEGIN + SELECT * FROM @extschema@._cdb_split_table_name(ref) INTO schema_name, base; + SELECT @extschema@._CDB_OverviewBaseTableName(base) INTO base; + RETURN @extschema@._CDB_OverviewTableName(base, overview_z); + END +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Sampling reduction method. +-- Valid for any kind of geometry. +-- Scope: private. +-- reloid original table (can be the base table of the dataset or an existing +-- overview) from which the overview is being generated. +-- ref_z Z level assigned to the original table +-- overview_z Z level of the overview to be generated, must be smaller than ref_z +-- Return value: Name of the generated overview table +CREATE OR REPLACE FUNCTION @extschema@._CDB_Sampling_Reduce_Strategy(reloid REGCLASS, ref_z INTEGER, overview_z INTEGER, tolerance_px FLOAT8 DEFAULT NULL, has_overview_created BOOLEAN DEFAULT FALSE) +RETURNS REGCLASS +AS $$ + DECLARE + overview_rel TEXT; + fraction FLOAT8; + base_name TEXT; + class_info RECORD; + num_samples INTEGER; + schema_name TEXT; + table_name TEXT; + overview_table_name TEXT; + creation_clause TEXT; + BEGIN + overview_rel := @extschema@._CDB_Overview_Name(reloid, ref_z, overview_z); + -- TODO: compute fraction from tolerance_px if not NULL + fraction := power(2, 2*(overview_z - ref_z)); + + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, table_name; + + overview_table_name := Format('%I.%I', schema_name, overview_rel); + IF has_overview_created THEN + RAISE NOTICE 'Sampling reduce stategy deleting and inserting because % has overviews', overview_table_name; + EXECUTE Format('DELETE FROM %s;', overview_table_name); + creation_clause := Format('INSERT INTO %s', overview_table_name); + ELSE + RAISE NOTICE 'Sampling reduce stategy creating a new table overview %', overview_table_name; + creation_clause := Format('CREATE TABLE %s AS', overview_table_name); + END IF; + + -- Estimate number of rows + SELECT reltuples, relpages FROM pg_class INTO STRICT class_info + WHERE oid = reloid::oid; + + IF class_info.relpages < 2 OR fraction > 0.5 THEN + -- We'll avoid possible CDB_RandomTids problems + EXECUTE Format(' + %s SELECT * FROM %s WHERE random() < %s; + ', creation_clause, reloid, fraction); + ELSE + num_samples := ceil(class_info.reltuples*fraction); + EXECUTE Format(' + %1$s SELECT * FROM %2$s + WHERE ctid = ANY ( + ARRAY[ + (SELECT @extschema@.CDB_RandomTids(''%2$s'', %3$s)) + ] + ); + ', creation_clause, reloid, num_samples); + END IF; + + RETURN Format('%s', overview_table_name)::regclass; + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Register new overview table (post-creation chores) +-- Scope: private +-- Parameters: +-- dataset: oid of the input dataset table, It must be a cartodbfy'ed table. +-- overview_table: oid of the overview table to be registered. +-- overview_z: intended Z level for the overview table +-- This function is declared SECURITY DEFINER so it executes with the privileges +-- of the function creator to have a chance to alter the privileges of the +-- overview table to match those of the dataset. It will only perform any change +-- if the overview table belgons to the same scheme as the dataset and it +-- matches the scheme naming for overview tables. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Register_Overview(dataset REGCLASS, overview_table REGCLASS, overview_z INTEGER) +RETURNS VOID +AS $$ + DECLARE + sql TEXT; + table_owner TEXT; + dataset_scheme TEXT; + dataset_name TEXT; + overview_scheme TEXT; + overview_name TEXT; + BEGIN + -- This function will only register a table as an overview table if it matches + -- the overviews naming scheme for the dataset and z level and the table belongs + -- to the same scheme as the the dataset + SELECT * FROM @extschema@._cdb_split_table_name(dataset) INTO dataset_scheme, dataset_name; + SELECT * FROM @extschema@._cdb_split_table_name(overview_table) INTO overview_scheme, overview_name; + IF dataset_scheme = overview_scheme AND + overview_name = @extschema@._CDB_OverviewTableName(dataset_name, overview_z) THEN + + -- preserve the owner of the base table + SELECT u.usename + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_user u ON (c.relowner=u.usesysid) + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = dataset_name::text AND n.nspname = dataset_scheme + INTO table_owner; + + EXECUTE Format('ALTER TABLE IF EXISTS %s OWNER TO %I;', overview_table::text, table_owner); + + -- preserve the table privileges + UPDATE pg_class c_to + SET relacl = c_from.relacl + FROM pg_class c_from + WHERE c_from.oid = dataset + AND c_to.oid = overview_table; + + PERFORM @extschema@._CDB_Add_Indexes(overview_table); + + -- TODO: If metadata about existing overviews is to be stored + -- it should be done here (CDB_Overviews would consume such metadata) + END IF; + END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- Dataset attributes (column names other than the +-- CartoDB primary key and geometry columns) which should be aggregated +-- in aggregated overviews. +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- Return value: set of attribute names +CREATE OR REPLACE FUNCTION @extschema@._CDB_Aggregable_Attributes(reloid REGCLASS) +RETURNS SETOF information_schema.sql_identifier +AS $$ + SELECT c FROM @extschema@.CDB_ColumnNames(reloid) c, @extschema@._CDB_Columns() cdb + WHERE c NOT IN ( + cdb.pkey, cdb.geomcol, cdb.mercgeomcol + ) +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +-- List of dataset attributes to be aggregated in aggregated overview +-- as a comma-separated SQL expression. +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- Return value: SQL subexpression as text +CREATE OR REPLACE FUNCTION @extschema@._CDB_Aggregable_Attributes_Expression(reloid REGCLASS) +RETURNS TEXT +AS $$ +DECLARE + attr_list TEXT; +BEGIN + SELECT string_agg(s.c, ',') FROM ( + SELECT * FROM @extschema@._CDB_Aggregable_Attributes(reloid) c + ) AS s INTO attr_list; + + RETURN attr_list; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; + +-- Check if a column of a table is of an unlimited-length text type +CREATE OR REPLACE FUNCTION @extschema@._cdb_unlimited_text_column(reloid REGCLASS, col_name TEXT) +RETURNS BOOLEAN +AS $$ + SELECT EXISTS ( + SELECT a.attname + FROM pg_class c + LEFT JOIN pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_type t ON t.oid = a.atttypid + WHERE c.oid = reloid + AND a.attname = col_name + AND format_type(a.atttypid, NULL) IN ('text', 'character varying', 'character') + AND format_type(a.atttypid, NULL) = format_type(a.atttypid, a.atttypmod) + ); +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION @extschema@._cdb_categorical_column(reloid REGCLASS, col_name TEXT) +RETURNS BOOLEAN +AS $$ +DECLARE + schema_name TEXT; + table_name TEXT; + available BOOLEAN; + categorical BOOLEAN; +BEGIN + SELECT * FROM _cdb_split_table_name(reloid) INTO schema_name, table_name; + SELECT n_distinct IS NOT NULL + FROM pg_stats + WHERE pg_stats.schemaname = schema_name + AND pg_stats.tablename = table_name + AND pg_stats.attname = col_name + INTO available; + IF available IS NULL OR NOT available THEN + EXECUTE Format('ANALYZE %s;', reloid); + END IF; + SELECT n_distinct > 0 AND n_distinct <= 20 + FROM pg_stats + WHERE pg_stats.schemaname = schema_name + AND pg_stats.tablename = table_name + AND pg_stats.attname = col_name + INTO categorical; + RETURN categorical; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL RESTRICTED; + +CREATE OR REPLACE FUNCTION @extschema@._cdb_mode_of_array(anyarray) + RETURNS anyelement AS +$$ + SELECT a + FROM unnest($1) a + GROUP BY 1 + ORDER BY COUNT(1) DESC, 1 + LIMIT 1; +$$ +LANGUAGE SQL IMMUTABLE PARALLEL SAFE; + +DROP AGGREGATE IF EXISTS @extschema@._cdb_mode(anyelement); +CREATE AGGREGATE @extschema@._cdb_mode(anyelement) ( + SFUNC=array_append, + STYPE=anyarray, + FINALFUNC=@extschema@._cdb_mode_of_array, + PARALLEL = SAFE, + INITCOND='{}' +); + +-- SQL Aggregation expression for a datase attribute +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- column_name: column to be aggregated +-- table_alias: (optional) table qualifier for the column to be aggregated +-- Return SQL subexpression as text with aggregated attribute aliased +-- with its original name. +CREATE OR REPLACE FUNCTION @extschema@._CDB_Attribute_Aggregation_Expression(reloid REGCLASS, column_name TEXT, table_alias TEXT DEFAULT '') +RETURNS TEXT +AS $$ +DECLARE + column_type TEXT; + qualified_column TEXT; + has_counter_column BOOLEAN; + feature_count TEXT; + total_feature_count TEXT; + base_table REGCLASS; +BEGIN + IF table_alias <> '' THEN + qualified_column := Format('%I.%I', table_alias, column_name); + ELSE + qualified_column := Format('%I', column_name); + END IF; + + column_type := @extschema@.CDB_ColumnType(reloid, column_name); + + SELECT EXISTS ( + SELECT * FROM @extschema@.CDB_ColumnNames(reloid) as colname WHERE colname = '_feature_count' + ) INTO has_counter_column; + IF has_counter_column THEN + feature_count := '_feature_count'; + total_feature_count := 'SUM(_feature_count)'; + ELSE + feature_count := '1'; + total_feature_count := 'count(*)'; + END IF; + + base_table := @extschema@._CDB_OverviewBaseTable(reloid); + + CASE column_type + WHEN 'double precision', 'real', 'integer', 'bigint', 'numeric' THEN + IF column_name = '_feature_count' THEN + RETURN 'SUM(_feature_count)'; + ELSE + IF column_type = 'integer' AND @extschema@._cdb_categorical_column(base_table, column_name) THEN + RETURN Format('CDB_Math_Mode(%s)::', qualified_column) || column_type; + ELSE + RETURN Format('SUM(%s*%s)/%s::' || column_type, qualified_column, feature_count, total_feature_count); + END IF; + END IF; + WHEN 'text', 'character varying', 'character' THEN + IF @extschema@._cdb_categorical_column(base_table, column_name) THEN + RETURN Format('_cdb_mode(%s)::', qualified_column) || column_type; + ELSE + IF @extschema@._cdb_unlimited_text_column(base_table, column_name) THEN + -- TODO: this should not be applied to columns containing largish text; + -- it is intended only to short names/identifiers + RETURN 'CASE WHEN count(distinct ' || qualified_column || ') = 1 THEN MIN(' || qualified_column || ') WHEN ' || total_feature_count || ' < 5 THEN string_agg(distinct ' || qualified_column || ','' / '') ELSE ''*'' END::' || column_type; + ELSE + RETURN 'CASE count(*) WHEN 1 THEN MIN(' || qualified_column || ') ELSE NULL END::' || column_type; + END IF; + END IF; + WHEN 'boolean' THEN + RETURN 'CASE count(*) WHEN 1 THEN BOOL_AND(' || qualified_column || ') ELSE NULL END::' || column_type; + ELSE + RETURN 'CASE count(*) WHEN 1 THEN MIN(' || qualified_column || ') ELSE NULL END::' || column_type; + END CASE; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL RESTRICTED; + +-- List of dataset aggregated attributes as a comma-separated SQL expression. +-- Scope: private. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- table_alias: (optional) table qualifier for the columns to be aggregated +-- Return value: SQL subexpression as text +CREATE OR REPLACE FUNCTION @extschema@._CDB_Aggregated_Attributes_Expression(reloid REGCLASS, table_alias TEXT DEFAULT '') +RETURNS TEXT +AS $$ +DECLARE + attr_list TEXT; +BEGIN + SELECT string_agg(@extschema@._CDB_Attribute_Aggregation_Expression(reloid, s.c, table_alias) || Format(' AS %s', s.c), ',') + FROM ( + SELECT * FROM @extschema@._CDB_Aggregable_Attributes(reloid) c + ) AS s INTO attr_list; + + RETURN attr_list; +END +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL RESTRICTED; + +-- Array of geometry types detected in a cartodbfied table +-- For effciency only look at a limited number of rwos. +-- Parameters +-- reloid: oid of the input table. It must be a cartodbfy'ed table. +-- Return value: array of geometry type names +CREATE OR REPLACE FUNCTION @extschema@._CDB_GeometryTypes(reloid REGCLASS) +RETURNS TEXT[] +AS $$ +DECLARE + gtypes TEXT[]; +BEGIN + EXECUTE Format(' + SELECT array_agg(DISTINCT @postgisschema@.ST_GeometryType(the_geom)) FROM ( + SELECT the_geom FROM %s + WHERE (the_geom is not null) LIMIT 10 + ) as geom_types + ', reloid) + INTO gtypes; + RETURN gtypes; +END +$$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; + +-- Experimental Overview reduction method for point datasets. +-- It clusters the points using a grid, then aggregates the point in each +-- cluster into a point at the centroid of the clustered records. +-- Scope: private. +-- Parameters: +-- reloid original table (can be the base table of the dataset or an existing +-- overview) from which the overview is being generated. +-- ref_z Z level assigned to the original table +-- overview_z Z level of the overview to be generated, must be smaller than ref_z +-- Return value: Name of the generated overview table +CREATE OR REPLACE FUNCTION @extschema@._CDB_GridCluster_Reduce_Strategy(reloid REGCLASS, ref_z INTEGER, overview_z INTEGER, grid_px FLOAT8 DEFAULT NULL, has_overview_created BOOLEAN DEFAULT FALSE) +RETURNS REGCLASS +AS $$ + DECLARE + overview_rel TEXT; + reduction FLOAT8; + base_name TEXT; + pixel_m FLOAT8; + grid_m FLOAT8; + offset_m FLOAT8; + offset_x TEXT; + offset_y TEXT; + cell_x TEXT; + cell_y TEXT; + aggr_attributes TEXT; + attributes TEXT; + columns TEXT; + gtypes TEXT[]; + schema_name TEXT; + table_name TEXT; + point_geom TEXT; + overview_table_name TEXT; + creation_clause TEXT; + BEGIN + SELECT @extschema@._CDB_GeometryTypes(reloid) INTO gtypes; + IF gtypes IS NULL OR array_upper(gtypes, 1) <> 1 OR gtypes[1] <> 'ST_Point' THEN + -- This strategy only supports datasets with point geomety + RETURN NULL; + END IF; + + --TODO: check applicability: geometry type, minimum number of points... + + overview_rel := @extschema@._CDB_Overview_Name(reloid, ref_z, overview_z); + + -- Grid size in pixels at Z level overview_z + IF grid_px IS NULL THEN + grid_px := 1.0; + END IF; + + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, table_name; + + -- pixel_m: size of a pixel in webmercator units (meters) + SELECT @extschema@.CDB_XYZ_Resolution(overview_z) INTO pixel_m; + -- grid size in meters + grid_m = grid_px * pixel_m; + + attributes := @extschema@._CDB_Aggregable_Attributes_Expression(reloid); + aggr_attributes := @extschema@._CDB_Aggregated_Attributes_Expression(reloid); + IF attributes <> '' THEN + attributes := ', ' || attributes; + END IF; + IF aggr_attributes <> '' THEN + aggr_attributes := aggr_attributes || ', '; + END IF; + + -- Center of each cell: + cell_x := Format('gx*%1$s + %2$s', grid_m, grid_m/2); + cell_y := Format('gy*%1$s + %2$s', grid_m, grid_m/2); + + -- Displacement to the nearest pixel center: + IF MOD(grid_px::numeric, 1.0::numeric) = 0 THEN + offset_m := pixel_m/2 - MOD((grid_m/2)::numeric, pixel_m::numeric)::float8; + offset_x := Format('%s', offset_m); + offset_y := Format('%s', offset_m); + ELSE + offset_x := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_x, pixel_m); + offset_y := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_y, pixel_m); + END IF; + + point_geom := Format('ST_SetSRID(ST_MakePoint(%1$s + %3$s, %2$s + %4$s), 3857)', cell_x, cell_y, offset_x, offset_y); + + -- compute the resulting columns in the same order as in the base table + WITH cols AS ( + SELECT + CASE c + WHEN 'cartodb_id' THEN 'cartodb_id' + WHEN 'the_geom' THEN + Format('@postgisschema@.ST_Transform(%s, 4326) AS the_geom', point_geom) + WHEN 'the_geom_webmercator' THEN + Format('%s AS the_geom_webmercator', point_geom) + ELSE c + END AS column + FROM @extschema@.CDB_ColumnNames(reloid) c + ) + SELECT string_agg(s.column, ',') FROM ( + SELECT * FROM cols + ) AS s INTO columns; + + IF NOT columns LIKE '%_feature_count%' THEN + columns := columns || ', n AS _feature_count'; + END IF; + + overview_table_name := Format('%I.%I', schema_name, overview_rel); + IF has_overview_created THEN + RAISE NOTICE 'Grid cluster strategy deleting and inserting because % has overviews', overview_table_name; + EXECUTE Format('DELETE FROM %s;', overview_table_name); + creation_clause := Format('INSERT INTO %s', overview_table_name); + ELSE + RAISE NOTICE 'Grid cluster strategy creating a new table overview %', overview_table_name; + creation_clause := Format('CREATE TABLE %s AS', overview_table_name); + END IF; + + -- Now we cluster the data using a grid of size grid_m + -- and selecte the centroid (average coordinates) of each cluster. + -- If we had a selected numeric attribute of interest we could use it + -- as a weight for the average coordinates. + EXECUTE Format(' + %3$s + WITH clusters AS ( + SELECT + %5$s + count(*) AS n, + Floor(@postgisschema@.ST_X(f.the_geom_webmercator)/%2$s)::int AS gx, + Floor(@postgisschema@.ST_Y(f.the_geom_webmercator)/%2$s)::int AS gy, + MIN(cartodb_id) AS cartodb_id + FROM %1$s f + WHERE f.the_geom_webmercator IS NOT NULL + GROUP BY gx, gy + ) + SELECT %6$s FROM clusters + ', reloid::text, grid_m, creation_clause, attributes, aggr_attributes, columns); + + RETURN Format('%s', overview_table_name)::regclass; + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- This strategy places the aggregation of each cluster at the centroid of the cluster members. +CREATE OR REPLACE FUNCTION @extschema@._CDB_GridClusterCentroid_Reduce_Strategy(reloid REGCLASS, ref_z INTEGER, overview_z INTEGER, grid_px FLOAT8 DEFAULT NULL, has_overview_created BOOLEAN DEFAULT FALSE) +RETURNS REGCLASS +AS $$ + DECLARE + overview_rel TEXT; + reduction FLOAT8; + base_name TEXT; + pixel_m FLOAT8; + grid_m FLOAT8; + offset_m FLOAT8; + offset_x TEXT; + offset_y TEXT; + cell_x TEXT; + cell_y TEXT; + aggr_attributes TEXT; + attributes TEXT; + columns TEXT; + gtypes TEXT[]; + schema_name TEXT; + table_name TEXT; + point_geom TEXT; + overview_table_name TEXT; + creation_clause TEXT; + BEGIN + SELECT @extschema@._CDB_GeometryTypes(reloid) INTO gtypes; + IF gtypes IS NULL OR array_upper(gtypes, 1) <> 1 OR gtypes[1] <> 'ST_Point' THEN + -- This strategy only supports datasets with point geomety + RETURN NULL; + END IF; + + --TODO: check applicability: geometry type, minimum number of points... + + overview_rel := @extschema@._CDB_Overview_Name(reloid, ref_z, overview_z); + + -- Grid size in pixels at Z level overview_z + IF grid_px IS NULL THEN + grid_px := 1.0; + END IF; + + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, table_name; + + -- pixel_m: size of a pixel in webmercator units (meters) + SELECT @extschema@.CDB_XYZ_Resolution(overview_z) INTO pixel_m; + -- grid size in meters + grid_m = grid_px * pixel_m; + + attributes := @extschema@._CDB_Aggregable_Attributes_Expression(reloid); + aggr_attributes := @extschema@._CDB_Aggregated_Attributes_Expression(reloid); + IF attributes <> '' THEN + attributes := ', ' || attributes; + END IF; + IF aggr_attributes <> '' THEN + aggr_attributes := aggr_attributes || ', '; + END IF; + + -- Center of each cell: + cell_x := Format('gx*%1$s + %2$s', grid_m, grid_m/2); + cell_y := Format('gy*%1$s + %2$s', grid_m, grid_m/2); + + -- Displacement to the nearest pixel center: + IF MOD(grid_px::numeric, 1.0::numeric) = 0 THEN + offset_m := pixel_m/2 - MOD((grid_m/2)::numeric, pixel_m::numeric)::float8; + offset_x := Format('%s', offset_m); + offset_y := Format('%s', offset_m); + ELSE + offset_x := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_x, pixel_m); + offset_y := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_y, pixel_m); + END IF; + + point_geom := Format('@postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(%1$s + %3$s, %2$s + %4$s), 3857)', cell_x, cell_y, offset_x, offset_y); + + -- compute the resulting columns in the same order as in the base table + WITH cols AS ( + SELECT + CASE c + WHEN 'cartodb_id' THEN 'cartodb_id' + WHEN 'the_geom' THEN + '@postgisschema@.ST_Transform(@postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(_sum_of_x/n, _sum_of_y/n), 3857), 4326) AS the_geom' + WHEN 'the_geom_webmercator' THEN + '@postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(_sum_of_x/n, _sum_of_y/n), 3857) AS the_geom_webmercator' + ELSE c + END AS column + FROM CDB_ColumnNames(reloid) c + ) + SELECT string_agg(s.column, ',') FROM ( + SELECT * FROM cols + ) AS s INTO columns; + + IF NOT columns LIKE '%_feature_count%' THEN + columns := columns || ', n AS _feature_count'; + END IF; + + overview_table_name := Format('%I.%I', schema_name, overview_rel); + IF has_overview_created THEN + RAISE NOTICE 'Grid cluster centroid strategy deleting and inserting because % has overviews', overview_table_name; + EXECUTE Format('DELETE FROM %s;', overview_table_name); + creation_clause := Format('INSERT INTO %s', overview_table_name); + ELSE + RAISE NOTICE 'Grid cluster centroid strategy creating a new table overview %', overview_table_name; + creation_clause := Format('CREATE TABLE %s AS', overview_table_name); + END IF; + + -- Now we cluster the data using a grid of size grid_m + -- and selecte the centroid (average coordinates) of each cluster. + -- If we had a selected numeric attribute of interest we could use it + -- as a weight for the average coordinates. + EXECUTE Format(' + %3$s + WITH clusters AS ( + SELECT + %5$s + count(*) AS n, + SUM(@postgisschema@.ST_X(f.the_geom_webmercator)) AS _sum_of_x, + SUM(@postgisschema@.ST_Y(f.the_geom_webmercator)) AS _sum_of_y, + Floor(@postgisschema@.ST_Y(f.the_geom_webmercator)/%2$s)::int AS gy, + Floor(@postgisschema@.ST_X(f.the_geom_webmercator)/%2$s)::int AS gx, + MIN(cartodb_id) AS cartodb_id + FROM %1$s f + GROUP BY gx, gy + ) + SELECT %6$s FROM clusters + ', reloid::text, grid_m, creation_clause, attributes, aggr_attributes, columns); + + RETURN Format('%s', overview_table_name)::regclass; + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- This strategy places the aggregation of each cluster at the position of one of the cluster members. +CREATE OR REPLACE FUNCTION @extschema@._CDB_GridClusterSample_Reduce_Strategy(reloid REGCLASS, ref_z INTEGER, overview_z INTEGER, grid_px FLOAT8 DEFAULT NULL, has_overview_created BOOLEAN DEFAULT FALSE) +RETURNS REGCLASS +AS $$ + DECLARE + overview_rel TEXT; + reduction FLOAT8; + base_name TEXT; + pixel_m FLOAT8; + grid_m FLOAT8; + offset_m FLOAT8; + offset_x TEXT; + offset_y TEXT; + cell_x TEXT; + cell_y TEXT; + aggr_attributes TEXT; + attributes TEXT; + columns TEXT; + gtypes TEXT[]; + schema_name TEXT; + table_name TEXT; + point_geom TEXT; + overview_table_name TEXT; + creation_clause TEXT; + BEGIN + SELECT @extschema@._CDB_GeometryTypes(reloid) INTO gtypes; + IF gtypes IS NULL OR array_upper(gtypes, 1) <> 1 OR gtypes[1] <> 'ST_Point' THEN + -- This strategy only supports datasets with point geomety + RETURN NULL; + END IF; + + --TODO: check applicability: geometry type, minimum number of points... + + overview_rel := @extschema@._CDB_Overview_Name(reloid, ref_z, overview_z); + + -- Grid size in pixels at Z level overview_z + IF grid_px IS NULL THEN + grid_px := 1.0; + END IF; + + SELECT * FROM @extschema@._cdb_split_table_name(reloid) INTO schema_name, table_name; + + -- pixel_m: size of a pixel in webmercator units (meters) + SELECT @extschema@.CDB_XYZ_Resolution(overview_z) INTO pixel_m; + -- grid size in meters + grid_m = grid_px * pixel_m; + + attributes := @extschema@._CDB_Aggregable_Attributes_Expression(reloid); + aggr_attributes := @extschema@._CDB_Aggregated_Attributes_Expression(reloid); + IF attributes <> '' THEN + attributes := ', ' || attributes; + END IF; + IF aggr_attributes <> '' THEN + aggr_attributes := aggr_attributes || ', '; + END IF; + + -- Center of each cell: + cell_x := Format('gx*%1$s + %2$s', grid_m, grid_m/2); + cell_y := Format('gy*%1$s + %2$s', grid_m, grid_m/2); + + -- Displacement to the nearest pixel center: + IF MOD(grid_px::numeric, 1.0::numeric) = 0 THEN + offset_m := pixel_m/2 - MOD((grid_m/2)::numeric, pixel_m::numeric)::float8; + offset_x := Format('%s', offset_m); + offset_y := Format('%s', offset_m); + ELSE + offset_x := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_x, pixel_m); + offset_y := Format('%2$s/2 - MOD((%1$s)::numeric, (%2$s)::numeric)::float8', cell_y, pixel_m); + END IF; + + point_geom := Format('@postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(%1$s + %3$s, %2$s + %4$s), 3857)', cell_x, cell_y, offset_x, offset_y); + + -- compute the resulting columns in the same order as in the base table + WITH cols AS ( + SELECT + CASE c + WHEN 'cartodb_id' THEN 'cartodb_id' + ELSE c + END AS column + FROM @extschema@.CDB_ColumnNames(reloid) c + ) + SELECT string_agg(s.column, ',') FROM ( + SELECT * FROM cols + ) AS s INTO columns; + + IF NOT columns LIKE '%_feature_count%' THEN + columns := columns || ', n AS _feature_count'; + END IF; + + overview_table_name := Format('%I.%I', schema_name, overview_rel); + IF has_overview_created THEN + RAISE NOTICE 'Grid cluster sampling strategy deleting and inserting because % has overviews', overview_table_name; + EXECUTE Format('DELETE FROM %s;', overview_table_name); + creation_clause := Format('INSERT INTO %s', overview_table_name); + ELSE + RAISE NOTICE 'Grid cluster sampling strategy creating a new table overview %', overview_table_name; + creation_clause := Format('CREATE TABLE %s AS', overview_table_name); + END IF; + + -- Now we cluster the data using a grid of size grid_m + -- and select the centroid (average coordinates) of each cluster. + -- If we had a selected numeric attribute of interest we could use it + -- as a weight for the average coordinates. + EXECUTE Format(' + %3$s + WITH clusters AS ( + SELECT + %5$s + count(*) AS n, + Floor(@postgisschema@.ST_X(_f.the_geom_webmercator)/%2$s)::int AS gx, + Floor(@postgisschema@.ST_Y(_f.the_geom_webmercator)/%2$s)::int AS gy, + MIN(cartodb_id) AS cartodb_id + FROM %1$s _f + GROUP BY gx, gy + ), + cluster_geom AS ( + SELECT the_geom, the_geom_webmercator, clusters.* + FROM clusters INNER JOIN %1$s _g ON (clusters.cartodb_id = _g.cartodb_id) + ) + SELECT %6$s FROM cluster_geom + ', reloid::text, grid_m, creation_clause, attributes, aggr_attributes, columns); + + RETURN Format('%s', overview_table_name)::regclass; + END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Create overview tables for a dataset. +-- Scope: public +-- Parameters: +-- reloid: oid of the input table. It must be a cartodbfy'ed table with +-- vector features. +-- refscale_strategy: function that computes the reference Z of the dataset +-- reduce_strategy: function that generates overviews from a base table +-- or higher level overview. The overview tables +-- created by the strategy must have the same columns +-- as the base table and in the same order. +-- Return value: Array with the names of the generated overview tables +CREATE OR REPLACE FUNCTION @extschema@.CDB_CreateOverviews(reloid REGCLASS, refscale_strategy regproc DEFAULT '@extschema@._CDB_Feature_Density_Ref_Z_Strategy(REGCLASS,FLOAT8)'::regprocedure, reduce_strategy regproc DEFAULT '@extschema@._CDB_GridCluster_Reduce_Strategy(REGCLASS,INTEGER,INTEGER,FLOAT8,BOOLEAN)'::regprocedure) +RETURNS text[] +AS $$ +DECLARE + tolerance_px FLOAT8; +BEGIN + -- Use the default tolerance + tolerance_px := 1.0; + RETURN @extschema@.CDB_CreateOverviewsWithToleranceInPixels(reloid, tolerance_px, refscale_strategy, reduce_strategy); +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Create overviews with additional parameter to define the desired detail/tolerance in pixels +CREATE OR REPLACE FUNCTION @extschema@.CDB_CreateOverviewsWithToleranceInPixels(reloid REGCLASS, tolerance_px FLOAT8, refscale_strategy regproc DEFAULT '@extschema@._CDB_Feature_Density_Ref_Z_Strategy(REGCLASS,FLOAT8)'::regprocedure, reduce_strategy regproc DEFAULT '@extschema@._CDB_GridCluster_Reduce_Strategy(REGCLASS,INTEGER,INTEGER,FLOAT8,BOOLEAN)'::regprocedure) +RETURNS text[] +AS $$ +DECLARE + ref_z integer; + overviews_z integer[]; + base_z integer; + base_rel REGCLASS; + overview_z integer; + overview_tables REGCLASS[]; + overviews_step integer := 1; + has_counter_column boolean; + has_overviews_for_z boolean; +BEGIN + -- Determine the referece zoom level + EXECUTE 'SELECT ' || quote_ident(refscale_strategy::text) || Format('(''%s'', %s);', reloid, tolerance_px) INTO ref_z; + + IF ref_z < 0 OR ref_z IS NULL THEN + RETURN NULL; + END IF; + + -- Determine overlay zoom levels + -- TODO: should be handled by the refscale_strategy? + overview_z := ref_z - 1; + WHILE overview_z >= 0 LOOP + SELECT array_append(overviews_z, overview_z) INTO overviews_z; + overview_z := overview_z - overviews_step; + END LOOP; + + -- TODO Check for non-used overview to delete them but we have to be aware that the + -- current queries, for example from a tiler, are been used with the old overviews + -- so if we remove the overviews in the process this could lead to errors + + -- Create or reganerate overlay tables + base_z := ref_z; + base_rel := reloid; + FOREACH overview_z IN ARRAY overviews_z LOOP + SELECT CASE WHEN count(*) > 0 THEN TRUE ELSE FALSE END from CDB_Overviews(reloid) WHERE z = overview_z INTO has_overviews_for_z; + EXECUTE 'SELECT ' || quote_ident(reduce_strategy::text) || Format('(''%s'', %s, %s, %s, ''%s'');', base_rel, base_z, overview_z, tolerance_px, has_overviews_for_z) INTO base_rel; + IF base_rel IS NULL THEN + EXIT; + END IF; + base_z := overview_z; + IF NOT has_overviews_for_z THEN + RAISE NOTICE 'Registering overview: %', base_rel; + PERFORM _CDB_Register_Overview(reloid, base_rel, base_z); + END IF; + SELECT array_append(overview_tables, base_rel) INTO overview_tables; + END LOOP; + + IF overview_tables IS NOT NULL AND array_length(overview_tables, 1) > 0 THEN + SELECT EXISTS ( + SELECT * FROM @extschema@.CDB_ColumnNames(reloid) as colname WHERE colname = '_feature_count' + ) INTO has_counter_column; + IF NOT has_counter_column THEN + EXECUTE Format(' + ALTER TABLE %s ADD COLUMN _feature_count integer DEFAULT 1; + ', reloid); + END IF; + END IF; + + RETURN overview_tables; +END; +$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + +-- Here are some older signatures of these functions, no longer in use. +-- They must be droped here, after the (new) definition of the function `CDB_CreateOverviews` +-- because that function used to contain references to them in the default argument values. +DROP FUNCTION IF EXISTS @extschema@._CDB_Feature_Density_Ref_Z_Strategy(REGCLASS); +DROP FUNCTION IF EXISTS @extschema@._CDB_GridCluster_Reduce_Strategy(REGCLASS,INTEGER,INTEGER); +DROP FUNCTION IF EXISTS @extschema@._CDB_GridCluster_Reduce_Strategy(REGCLASS,INTEGER,INTEGER,FLOAT8); +DROP FUNCTION IF EXISTS @extschema@._CDB_GridClusterCentroid_Reduce_Strategy(REGCLASS, INTEGER, INTEGER, FLOAT8); +DROP FUNCTION IF EXISTS @extschema@._CDB_GridClusterSample_Reduce_Strategy(REGCLASS, INTEGER, INTEGER, FLOAT8); +DROP FUNCTION IF EXISTS @extschema@._CDB_Sampling_Reduce_Strategy(REGCLASS,INTEGER,INTEGER); +DROP FUNCTION IF EXISTS @extschema@._CDB_Sampling_Reduce_Strategy(REGCLASS,INTEGER,INTEGER,FLOAT8); diff --git a/lib/sql/scripts-available/CDB_OverviewsSupport.sql b/lib/sql/scripts-available/CDB_OverviewsSupport.sql new file mode 100644 index 0000000..f5d8a9c --- /dev/null +++ b/lib/sql/scripts-available/CDB_OverviewsSupport.sql @@ -0,0 +1,173 @@ +-- Auxiliary overviews FUNCTIONS + +-- Maximum zoom level for which overviews may be created +CREATE OR REPLACE FUNCTION @extschema@._CDB_MaxOverviewLevel() +RETURNS INTEGER +AS $$ + BEGIN + -- Zoom level will be limited so that both tile coordinates + -- and gridding coordinates within a tile up to 1px + -- (i.e. tile coordinates / 256) + -- can be stored in a 32-bit signed integer. + -- We have 31 bits por positive numbers + -- For zoom level Z coordinates range from 0 to 2^Z-1, so they + -- need Z bits, and need 8 bits more to address pixels within a tile + -- (gridding), so we'll limit Z to a maximum of 31 - 8 + RETURN 23; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Maximum zoom level usable with integer coordinates +CREATE OR REPLACE FUNCTION @extschema@._CDB_MaxZoomLevel() +RETURNS INTEGER +AS $$ + BEGIN + RETURN 31; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Information about tables in a schema. +-- If the schema name parameter is NULL, then tables from all schemas +-- that may contain user tables are returned. +-- For each table, the regclass, schema name and table name are returned. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_UserTablesInSchema(schema_name text DEFAULT NULL) +RETURNS TABLE(table_regclass REGCLASS, schema_name TEXT, table_name TEXT) +AS $$ + SELECT + c.oid::regclass AS table_regclass, + n.nspname::text AS schema_name, + c.relname::text AS table_relname + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relkind = 'r' + AND c.relname NOT IN ('cdb_tablemetadata', 'cdb_analysis_catalog', 'cdb_conf', 'spatial_ref_sys') + AND CASE WHEN schema_name IS NULL + THEN n.nspname NOT IN ('pg_catalog', 'information_schema', 'topology', '@extschema@') + ELSE n.nspname = schema_name + END; +$$ LANGUAGE 'sql' STABLE PARALLEL SAFE; + +-- Pattern that can be used to detect overview tables and Extract +-- the intended zoom level from the table name. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewTableDiscriminator() +RETURNS TEXT +AS $$ + BEGIN + RETURN '\A_vovw_(\d+)_'; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; +-- substring(tablename from _CDB_OverviewTableDiscriminator()) + + +-- Pattern matched by the overview tables of a given base table name. +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewTablePattern(base_table TEXT) +RETURNS TEXT +AS $$ + BEGIN + RETURN @extschema@._CDB_OverviewTableDiscriminator() || base_table; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; +-- tablename SIMILAR TO _CDB_OverviewTablePattern(base_table) + +-- Name of an overview table, given the base table name and the Z level +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewTableName(base_table TEXT, z INTEGER) +RETURNS TEXT +AS $$ + BEGIN + RETURN '_vovw_' || z::text || '_' || base_table; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Condition to check if a tabla is an overview table of some base table +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_IsOverviewTableOf(base_table TEXT, otable TEXT) +RETURNS BOOLEAN +AS $$ + BEGIN + RETURN otable SIMILAR TO @extschema@._CDB_OverviewTablePattern(base_table); + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Extract the Z level from an overview table name +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewTableZ(otable TEXT) +RETURNS INTEGER +AS $$ + BEGIN + RETURN substring(otable from @extschema@._CDB_OverviewTableDiscriminator())::integer; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Name of the base table corresponding to an overview table +-- Scope: private. +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewBaseTableName(overview_table TEXT) +RETURNS TEXT +AS $$ + BEGIN + IF @extschema@._CDB_OverviewTableZ(overview_table) IS NULL THEN + RETURN overview_table; + ELSE + RETURN regexp_replace(overview_table, @extschema@._CDB_OverviewTableDiscriminator(), ''); + END IF; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION @extschema@._CDB_OverviewBaseTable(overview_table REGCLASS) +RETURNS REGCLASS +AS $$ + DECLARE + table_name TEXT; + schema_name TEXT; + base_name TEXT; + base_table REGCLASS; + BEGIN + SELECT * FROM @extschema@._cdb_split_table_name(overview_table) INTO schema_name, table_name; + base_name := @extschema@._CDB_OverviewBaseTableName(table_name); + IF base_name != table_name THEN + base_table := Format('%I.%I', schema_name, base_name)::regclass; + ELSE + base_table := overview_table; + END IF; + RETURN base_table; + END; +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Schema and relation names of a table given its reloid +-- Scope: private. +-- Parameters +-- reloid: oid of the table. +-- Return (schema_name, table_name) +-- note that returned names will be quoted if necessary +CREATE OR REPLACE FUNCTION @extschema@._cdb_split_table_name(reloid REGCLASS, OUT schema_name TEXT, OUT table_name TEXT) +AS $$ + BEGIN + SELECT n.nspname, c.relname + INTO STRICT schema_name, table_name + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + END +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; + +-- Schema and relation names of a table given its reloid +-- Scope: private. +-- Parameters +-- reloid: oid of the table. +-- Return (schema_name, table_name) +-- note that returned names will be quoted if necessary +CREATE OR REPLACE FUNCTION @extschema@._cdb_schema_name(reloid REGCLASS) +RETURNS TEXT +AS $$ + DECLARE + schema_name TEXT; + BEGIN + SELECT n.nspname + INTO STRICT schema_name + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + RETURN schema_name; + END +$$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_QuantileBins.sql b/lib/sql/scripts-available/CDB_QuantileBins.sql new file mode 100644 index 0000000..bbda6aa --- /dev/null +++ b/lib/sql/scripts-available/CDB_QuantileBins.sql @@ -0,0 +1,18 @@ +-- +-- Determine the Quantile classifications from a numeric array +-- +-- @param in_array A numeric array of numbers to determine the best +-- bins based on the Quantile method. +-- +-- @param breaks The number of bins you want to find. +-- +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_QuantileBins(in_array numeric[], breaks int) +RETURNS numeric[] +AS $$ + SELECT + percentile_disc(Array(SELECT generate_series(1, breaks) / breaks::numeric)) + WITHIN GROUP (ORDER BY x ASC) AS p + FROM + unnest(in_array) AS x; +$$ language SQL IMMUTABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_QueryStatements.sql b/lib/sql/scripts-available/CDB_QueryStatements.sql new file mode 100644 index 0000000..54b7115 --- /dev/null +++ b/lib/sql/scripts-available/CDB_QueryStatements.sql @@ -0,0 +1,14 @@ +-- Return an array of statements found in the given query text +-- +-- Regexp curtesy of Hubert Lubaczewski (depesz) +-- Implemented in plpython for performance reasons +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryStatements(query text) +RETURNS SETOF TEXT AS $$ + import re + pat = re.compile( r'''((?:[^'"$;]+|"[^"]*"|'[^']*'|(\$[^$]*\$).*?\2)+)''', re.DOTALL ) + for match in pat.findall(query): + cleaned = match[0].strip() + if ( cleaned ): + yield cleaned +$$ language 'plpythonu' IMMUTABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_QueryTables.sql b/lib/sql/scripts-available/CDB_QueryTables.sql new file mode 100644 index 0000000..8cf9d06 --- /dev/null +++ b/lib/sql/scripts-available/CDB_QueryTables.sql @@ -0,0 +1,75 @@ +-- Return an array of table names scanned by a given query +-- +-- Requires PostgreSQL 9.x+ +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTablesText(query text) +RETURNS text[] +AS $$ +DECLARE + exp XML; + tables text[]; + rec RECORD; + rec2 RECORD; +BEGIN + + tables := '{}'; + + FOR rec IN SELECT @extschema@.CDB_QueryStatements(query) q LOOP + BEGIN + EXECUTE 'EXPLAIN (FORMAT XML, VERBOSE) ' || rec.q INTO STRICT exp; + EXCEPTION WHEN syntax_error THEN + -- We can get a syntax error if the user tries to EXPLAIN a DDL + CONTINUE; + WHEN others THEN + -- TODO: if error is 'relation "xxxxxx" does not exist', take xxxxxx as + -- the affected table ? + RAISE WARNING 'CDB_QueryTables cannot explain query: % (%: %)', rec.q, SQLSTATE, SQLERRM; + RAISE EXCEPTION '%', SQLERRM; + CONTINUE; + END; + + -- Now need to extract all values of + + -- RAISE DEBUG 'Explain: %', exp; + + FOR rec2 IN WITH + inp AS ( + SELECT + xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x, + xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s + ) + SELECT unnest(x)::text as p, unnest(s)::text as sc from inp + LOOP + -- RAISE DEBUG 'tab: %', rec2.p; + -- RAISE DEBUG 'sc: %', rec2.sc; + tables := array_append(tables, format('%s.%s', quote_ident(rec2.sc), quote_ident(rec2.p))); + END LOOP; + + -- RAISE DEBUG 'Tables: %', tables; + + END LOOP; + + -- RAISE DEBUG 'Tables: %', tables; + + -- Remove duplicates and sort by name + IF array_upper(tables, 1) > 0 THEN + WITH dist as ( SELECT DISTINCT unnest(tables)::text as p ORDER BY p ) + SELECT array_agg(p) from dist into tables; + END IF; + + --RAISE DEBUG 'Tables: %', tables; + + return tables; +END +$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; + + +-- Keep CDB_QueryTables with same signature for backwards compatibility. +-- It should probably be removed in the future. +CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTables(query text) +RETURNS name[] +AS $$ +BEGIN + RETURN @extschema@.CDB_QueryTablesText(query)::name[]; +END +$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_Quota.sql b/lib/sql/scripts-available/CDB_Quota.sql new file mode 100644 index 0000000..d3dc983 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Quota.sql @@ -0,0 +1,155 @@ +CREATE OR REPLACE FUNCTION @extschema@._CDB_total_relation_size(_schema_name TEXT, _table_name TEXT) +RETURNS bigint AS +$$ +DECLARE relation_size bigint := 0; +BEGIN + BEGIN + SELECT pg_total_relation_size(format('"%s"."%s"', _schema_name, _table_name)) INTO relation_size; + EXCEPTION + WHEN undefined_table OR OTHERS THEN + RAISE NOTICE '@extschema@._CDB_total_relation_size(''%'', ''%'') caught error: % (%)', _schema_name, _table_name, SQLERRM, SQLSTATE; + END; + RETURN relation_size; +END; +$$ +LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + +-- Return the estimated size of user data. Used for quota checking. +CREATE OR REPLACE FUNCTION @extschema@.CDB_UserDataSize(schema_name TEXT) +RETURNS bigint AS +$$ +DECLARE + total_size INT8; +BEGIN + WITH raster_tables AS ( + SELECT o_table_name, r_table_name FROM raster_overviews + WHERE o_table_schema = schema_name AND o_table_catalog = current_database() + ), + user_tables AS ( + SELECT table_name FROM @extschema@._CDB_NonAnalysisTablesInSchema(schema_name) + ), + table_cat AS ( + SELECT + table_name, + ( + EXISTS(select * from raster_tables where o_table_name = table_name) + OR table_name SIMILAR TO @extschema@._CDB_OverviewTableDiscriminator() || '[\w\d]*' + ) AS is_overview, + EXISTS(SELECT * FROM raster_tables WHERE r_table_name = table_name) AS is_raster + FROM user_tables + ), + sizes AS ( + SELECT COALESCE(INT8(SUM(@extschema@._CDB_total_relation_size(schema_name, table_name)))) table_size, + CASE + WHEN is_overview THEN 0 + WHEN is_raster THEN 1 + ELSE 0.5 -- Division by 2 is for not counting the_geom_webmercator + END AS multiplier FROM table_cat GROUP BY is_overview, is_raster + ) + SELECT sum(table_size*multiplier)::int8 INTO total_size FROM sizes; + + IF total_size IS NOT NULL THEN + RETURN total_size; + ELSE + RETURN 0; + END IF; +END; +$$ +LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +-- Return the estimated size of user data. Used for quota checking. +-- Implicit schema version for backwards compatibility +CREATE OR REPLACE FUNCTION @extschema@.CDB_UserDataSize() +RETURNS bigint AS +$$ + SELECT @extschema@.CDB_UserDataSize('public'); +$$ +LANGUAGE 'sql' VOLATILE PARALLEL UNSAFE; + +-- Triggers cannot have declared arguments: pbfact float8, qmax int8, schema_name text +CREATE OR REPLACE FUNCTION @extschema@.CDB_CheckQuota() +RETURNS trigger AS +$$ +DECLARE + pbfact float8; + qmax int8; + schema_name text; + dice float8; + quota float8; +BEGIN + IF TG_NARGS = 3 THEN + schema_name := TG_ARGV[2]; + IF @extschema@.schema_exists(schema_name) = false THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name; + END IF; + ELSE + schema_name := 'public'; + END IF; + + -- By default try to use quota function, and if not present then rely on the one specified by params + BEGIN + EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO qmax; + EXCEPTION WHEN undefined_function THEN + BEGIN + IF TG_NARGS >= 2 AND TG_ARGV[1] <> '-1' THEN + qmax := TG_ARGV[1]; + ELSE + RAISE EXCEPTION 'Missing "%"._CDB_UserQuotaInBytes()', schema_name; + END IF; + END; + END; + + pbfact := TG_ARGV[0]; + + dice := random(); + + IF dice < pbfact THEN + RAISE DEBUG 'Checking quota on table % (dice:%, needed:<%)', TG_RELID::text, dice, pbfact; + + IF qmax = 0 THEN + RETURN NEW; + END IF; + + SELECT @extschema@.CDB_UserDataSize(schema_name) INTO quota; + IF quota > qmax THEN + RAISE EXCEPTION 'Quota exceeded by %KB', (quota-qmax)/1024; + ELSE RAISE DEBUG 'User quota in bytes: % < % (max allowed)', quota, qmax; + END IF; + END IF; + + RETURN NEW; +END; +$$ +LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; + + +CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUserQuotaInBytes(schema_name text, bytes int8) +RETURNS int8 AS +$$ +DECLARE + sql text; +BEGIN + IF @extschema@.schema_exists(schema_name::text) = false THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name::text; + END IF; + + sql := 'CREATE OR REPLACE FUNCTION "' || schema_name::text || '"._CDB_UserQuotaInBytes() ' + || 'RETURNS int8 AS $X$ SELECT ' || bytes + || '::int8 $X$ LANGUAGE sql IMMUTABLE'; + EXECUTE sql; + + return bytes; +END +$$ +LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; + + +CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUserQuotaInBytes(bytes int8) +RETURNS int8 AS +$$ +BEGIN + return @extschema@.CDB_SetUserQuotaInBytes('public', bytes); +END; +$$ +LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_RandomTids.sql b/lib/sql/scripts-available/CDB_RandomTids.sql new file mode 100644 index 0000000..d35ced8 --- /dev/null +++ b/lib/sql/scripts-available/CDB_RandomTids.sql @@ -0,0 +1,69 @@ + +-- { +-- +-- Return random TIDs in a table. +-- +-- You can use like this: +-- +-- SELECT * FROM lots_of_points WHERE ctid = ANY ( +-- ARRAY[ (SELECT CDB_RandomTids('lots_of_points', 100000)) ] +-- ); +-- +-- NOTE: +-- It currently doesn't really do it random, but in a +-- equally-distributed way among all tuples. +-- +-- +-- }{ +CREATE OR REPLACE FUNCTION @extschema@.CDB_RandomTids(in_table regclass, in_nsamples integer) + RETURNS tid[] +AS $$ +DECLARE + class_info RECORD; + tuples_per_page INTEGER; + needed_pages INTEGER; + skip_pages INTEGER; + tidlist TID[]; + pnrec RECORD; +BEGIN + + -- (#) estimate pages and tuples-per-page + -- HINT: pg_class.relpages, pg_class.reltuples + SELECT relpages, reltuples + FROM pg_class WHERE oid = in_table + INTO class_info; + + RAISE DEBUG 'Table % has % pages and % tuples', + in_table::text, class_info.relpages, class_info.reltuples; + + IF in_nsamples > class_info.reltuples THEN + RAISE WARNING 'Table has less tuples than requested'; + -- should just perform a sequencial scan here... + END IF; + + tuples_per_page := floor(class_info.reltuples/class_info.relpages); + needed_pages := ceil(in_nsamples::real/tuples_per_page); + + RAISE DEBUG '% tuples per page, we need % pages for % tuples', + tuples_per_page, needed_pages, in_nsamples; + + -- (#) select random pages + -- TODO: see how good this is first + + skip_pages := floor( (class_info.relpages-needed_pages)/(needed_pages+1) ); + + RAISE DEBUG 'we are going to skip % pages at each iteration', + skip_pages; + + SELECT array_agg(t) FROM ( + SELECT '(' || pn || ',' || tn || ')' as t + FROM generate_series(1, tuples_per_page) x(tn), + generate_series(skip_pages+1, class_info.relpages, skip_pages) y(pn) ) f + INTO tidlist; + + RETURN tidlist; + +END +$$ LANGUAGE 'plpgsql' STABLE STRICT PARALLEL SAFE; +-- } + diff --git a/lib/sql/scripts-available/CDB_RectangleGrid.sql b/lib/sql/scripts-available/CDB_RectangleGrid.sql new file mode 100644 index 0000000..14cb58e --- /dev/null +++ b/lib/sql/scripts-available/CDB_RectangleGrid.sql @@ -0,0 +1,108 @@ +-- In older versions of the extension, CDB_RectangleGrid had a different signature +DROP FUNCTION IF EXISTS @extschema@.CDB_RectangleGrid(GEOMETRY, FLOAT8, FLOAT8, GEOMETRY); + +-- +-- Fill given extent with a rectangular coverage +-- +-- @param ext Extent to fill. Only rectangles with center point falling +-- inside the extent (or at the lower or leftmost edge) will +-- be emitted. The returned hexagons will have the same SRID +-- as this extent. +-- +-- @param width Width of each rectangle +-- +-- @param height Height of each rectangle +-- +-- @param origin Optional origin to allow for exact tiling. +-- If omitted the origin will be 0,0. +-- The parameter is checked for having the same SRID +-- as the extent. +-- +-- @param maxcells Optional maximum number of grid cells to generate; +-- if the grid requires more cells to cover the extent +-- and exception will occur. +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_RectangleGrid(ext GEOMETRY, width FLOAT8, height FLOAT8, origin GEOMETRY DEFAULT NULL, maxcells INTEGER DEFAULT 512*512) +RETURNS SETOF GEOMETRY +AS $$ +DECLARE + h GEOMETRY; -- rectangle cell + hstep FLOAT8; -- horizontal step + vstep FLOAT8; -- vertical step + hw FLOAT8; -- half width + hh FLOAT8; -- half height + vstart FLOAT8; + hstart FLOAT8; + hend FLOAT8; + vend FLOAT8; + xoff FLOAT8; + yoff FLOAT8; + xgrd FLOAT8; + ygrd FLOAT8; + x FLOAT8; + y FLOAT8; + srid INTEGER; +BEGIN + + srid := @postgisschema@.ST_SRID(ext); + + xoff := 0; + yoff := 0; + + IF origin IS NOT NULL THEN + IF @postgisschema@.ST_SRID(origin) != srid THEN + RAISE EXCEPTION 'SRID mismatch between extent (%) and origin (%)', srid, ST_SRID(origin); + END IF; + xoff := @postgisschema@.ST_X(origin); + yoff := @postgisschema@.ST_Y(origin); + END IF; + + --RAISE DEBUG 'X offset: %', xoff; + --RAISE DEBUG 'Y offset: %', yoff; + + hw := width/2.0; + hh := height/2.0; + + xgrd := hw; + ygrd := hh; + --RAISE DEBUG 'X grid size: %', xgrd; + --RAISE DEBUG 'Y grid size: %', ygrd; + + hstep := width; + vstep := height; + + -- Tweak horizontal start on hstep grid from origin + hstart := xoff + ceil((@postgisschema@.ST_XMin(ext)-xoff)/hstep)*hstep; + --RAISE DEBUG 'hstart: %', hstart; + + -- Tweak vertical start on vstep grid from origin + vstart := yoff + ceil((@postgisschema@.ST_Ymin(ext)-yoff)/vstep)*vstep; + --RAISE DEBUG 'vstart: %', vstart; + + hend := ST_XMax(ext); + vend := ST_YMax(ext); + + --RAISE DEBUG 'hend: %', hend; + --RAISE DEBUG 'vend: %', vend; + + If maxcells IS NOT NULL AND maxcells > 0 THEN + IF ((hend - hstart)/hstep * (vend - vstart)/vstep)::integer > maxcells THEN + RAISE EXCEPTION 'The requested grid is too big to be rendered'; + END IF; + END IF; + + x := hstart; + WHILE x < hend LOOP -- over X + y := vstart; + h := @postgisschema@.ST_MakeEnvelope(x-hw, y-hh, x+hw, y+hh, srid); + WHILE y < vend LOOP -- over Y + RETURN NEXT h; + h := @postgisschema@.ST_Translate(h, 0, vstep); + y := yoff + round(((y + vstep)-yoff)/ygrd)*ygrd; -- round to grid + END LOOP; + x := xoff + round(((x + hstep)-xoff)/xgrd)*xgrd; -- round to grid + END LOOP; + + RETURN; +END +$$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_SearchPath.sql b/lib/sql/scripts-available/CDB_SearchPath.sql new file mode 100644 index 0000000..236e281 --- /dev/null +++ b/lib/sql/scripts-available/CDB_SearchPath.sql @@ -0,0 +1,24 @@ +---- Make sure '@extschema@' is in database search path +DO +$$ +DECLARE + var_result text; + var_cur_search_path text; +BEGIN + SELECT reset_val INTO var_cur_search_path + FROM pg_settings WHERE name = 'search_path'; + + IF var_cur_search_path LIKE '%@extschema@%' THEN + RAISE DEBUG '"@extschema@" already in database search_path'; + ELSE + var_cur_search_path := var_cur_search_path || ', "@extschema@"'; + EXECUTE 'ALTER DATABASE ' || quote_ident(current_database()) || + ' SET search_path = ' || var_cur_search_path; + RAISE DEBUG '"@extschema@" has been added to end of database search_path'; + END IF; + + -- Reset search_path + EXECUTE 'SET search_path = ' || var_cur_search_path; + +END +$$ LANGUAGE 'plpgsql'; diff --git a/lib/sql/scripts-available/CDB_Stats.sql b/lib/sql/scripts-available/CDB_Stats.sql new file mode 100644 index 0000000..103a2f4 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Stats.sql @@ -0,0 +1,53 @@ +-- +-- Calculate basic statistics of a given dataset +-- +-- @param in_array A numeric array of numbers +-- +-- Returns: statistical quantity chosen +-- +-- References: http://www.itl.nist.gov/div898/handbook/eda/section3/eda35b.htm +-- + +-- Calculate kurtosis +CREATE OR REPLACE FUNCTION @extschema@.CDB_Kurtosis ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ +DECLARE + a numeric; + c numeric; + k numeric; +BEGIN + SELECT AVG(e), COUNT(e)::numeric * power(stddev(e),4) INTO a, c FROM ( SELECT unnest(in_array) e ) x; + + IF c=0 THEN + RETURN 0; + ELSE + + EXECUTE 'SELECT sum(power($1 - e, 4)) / ($2 ) - 3 + FROM (SELECT unnest($3) e ) x' + INTO k + USING a, c, in_array; + + RETURN k; + END IF; +END; +$$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +-- Calculate skewness +CREATE OR REPLACE FUNCTION @extschema@.CDB_Skewness ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ +DECLARE + a numeric; + c numeric; + sk numeric; +BEGIN + SELECT AVG(e), COUNT(e)::numeric * power(stddev(e),3) INTO a, c FROM ( SELECT unnest(in_array) e ) x; + IF c=0 THEN + RETURN 0; + ELSE + EXECUTE 'SELECT sum(power($1 - e, 3)) / ( $2 ) + FROM (SELECT unnest($3) e ) x' + INTO sk + USING a, c, in_array; + + RETURN sk; + END IF; +END; +$$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; diff --git a/lib/sql/scripts-available/CDB_StringToDate.sql b/lib/sql/scripts-available/CDB_StringToDate.sql new file mode 100644 index 0000000..1a536fc --- /dev/null +++ b/lib/sql/scripts-available/CDB_StringToDate.sql @@ -0,0 +1,20 @@ +-- Convert string to date +-- +DROP FUNCTION IF EXISTS @extschema@.CDB_StringToDate(character varying); +CREATE OR REPLACE FUNCTION @extschema@.CDB_StringToDate(input character varying) +RETURNS TIMESTAMP AS $$ +DECLARE output TIMESTAMP; +BEGIN + BEGIN + output := input::date; + EXCEPTION WHEN OTHERS THEN + BEGIN + SELECT to_timestamp(input::integer) INTO output; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; + END; +RETURN output; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_SyncTable.sql b/lib/sql/scripts-available/CDB_SyncTable.sql new file mode 100644 index 0000000..9d35788 --- /dev/null +++ b/lib/sql/scripts-available/CDB_SyncTable.sql @@ -0,0 +1,167 @@ +/* + Gets the column names of a given table. + + Sample usage: + + SELECT @extschema@._CDB_GetColumns('public.films'); +*/ +CREATE OR REPLACE FUNCTION @extschema@._CDB_GetColumns(src_table REGCLASS) +RETURNS SETOF NAME +AS $$ + SELECT + a.attname as "colname" + FROM + pg_catalog.pg_attribute a + WHERE + a.attnum > 0 + AND NOT a.attisdropped + AND a.attrelid = ( + SELECT c.oid + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.oid = src_table::oid + AND pg_catalog.pg_table_is_visible(c.oid) + ) + ORDER BY a.attnum; +$$ LANGUAGE sql STABLE PARALLEL UNSAFE; + + +/* + Given an array of quoted column names, it generates an UPDATE SET + clause with the following form: + + the_geom = changed.the_geom, + id = changed.id, + elevation = changed.elevation + + Example of usage: + + SELECT @extschema@.__CDB_GetUpdateSetClause('{the_geom, id, elevation}', 'changed'); +*/ +CREATE OR REPLACE FUNCTION @extschema@.__CDB_GetUpdateSetClause(colnames TEXT[], update_source TEXT) +RETURNS TEXT +AS $$ +DECLARE + set_clause_list TEXT[]; + col TEXT; +BEGIN + FOREACH col IN ARRAY colnames + LOOP + set_clause_list := array_append(set_clause_list, format('%1$s = %2$s.%1$s', col, update_source)); + END lOOP; + RETURN array_to_string(set_clause_list, ', '); +END; +$$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE; + + +/* + Given a prefix, generate a safe unique NAME for a temp table. + + Example of usage: + + SELECT @extschema@.__CDB_GenerateUniqueName('src_sync'); --> src_sync_718794_120106 + +*/ +CREATE OR REPLACE FUNCTION @extschema@.__CDB_GenerateUniqueName(prefix TEXT) +RETURNS NAME +AS $$ + SELECT format('%s_%s_%s', prefix, txid_current(), (random()*1000000)::int)::NAME; +$$ LANGUAGE sql VOLATILE PARALLEL UNSAFE; + +/* + Given a table name and an array of column names, + return array of column names qualified with the table name and quoted when necessary + tablename and colnames should be properly quoted, and for this reason the type NAME is not + used for them (with quotes they could exceed the maximum identifier length) + + Example of usage: + + SELECT @extschema@.__CDB_QualifyColumns('t', ARRAY['a','"b-1"']); --> ARRAY['t.a','t."b-1"'] + +*/ +CREATE OR REPLACE FUNCTION @extschema@.__CDB_QualifyColumns(tablename NAME, colnames NAME[]) RETURNS TEXT[] AS +$$ + SELECT array_agg(tablename || '.' || _colname) from unnest(colnames) _colname; +$$ LANGUAGE sql IMMUTABLE PARALLEL SAFE; + +/* + A Table Syncer + + Assumptions: + - Both tables contain a consistent cartodb_id column + - Destination table has all columns of the source or does not exist + + Sample usage: + + SELECT CDB_SyncTable('radar_stations', 'public', 'syncdest'); + SELECT CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest', '{the_geom, the_geom_webmercator}'); + +*/ +CREATE OR REPLACE FUNCTION @extschema@.CDB_SyncTable(src_table REGCLASS, dst_schema REGNAMESPACE, dst_table NAME, skip_cols NAME[] = '{}') +RETURNS void +AS $$ +DECLARE + fq_dest_table TEXT; + + colnames TEXT[]; + dst_colnames TEXT; + src_colnames TEXT; + + update_set_clause TEXT; + + num_rows BIGINT; + err_context text; + + t timestamptz; +BEGIN + -- If the destination table does not exist, just copy the source table + fq_dest_table := format('%s.%I', dst_schema, dst_table); + EXECUTE format('CREATE TABLE IF NOT EXISTS %s as TABLE %s', fq_dest_table, src_table); + GET DIAGNOSTICS num_rows = ROW_COUNT; + IF num_rows > 0 THEN + RAISE NOTICE 'INSERTED % row(s)', num_rows; + RETURN; + END IF; + + skip_cols := skip_cols || '{cartodb_id}'; + + -- Get the list of columns from the source table, excluding skip_cols + SELECT ARRAY(SELECT quote_ident(c) FROM @extschema@._CDB_GetColumns(src_table) as c EXCEPT SELECT unnest(skip_cols)) INTO colnames; + + -- Deal with deleted rows: ids in dest but not in source + t := clock_timestamp(); + EXECUTE format( + 'DELETE FROM %1$s _dst WHERE NOT EXISTS (SELECT * FROM %2$s _src WHERE _src.cartodb_id=_dst.cartodb_id)', + fq_dest_table, src_table); + GET DIAGNOSTICS num_rows = ROW_COUNT; + RAISE NOTICE 'DELETED % row(s)', num_rows; + RAISE DEBUG 'DELETE time (s): %', clock_timestamp() - t; + + -- Deal with inserted rows: ids in source but not in dest + t := clock_timestamp(); + EXECUTE format(' + INSERT INTO %1$s(cartodb_id, %2$s) + SELECT cartodb_id, %2$s FROM %3$s _src WHERE NOT EXISTS (SELECT * FROM %1$s _dst WHERE _src.cartodb_id=_dst.cartodb_id) + ', fq_dest_table, array_to_string(colnames, ','), src_table); + GET DIAGNOSTICS num_rows = ROW_COUNT; + RAISE NOTICE 'INSERTED % row(s)', num_rows; + RAISE DEBUG 'INSERT time (s): %', clock_timestamp() - t; + + -- Deal with modified rows: ids in source and dest but different hashes + t := clock_timestamp(); + update_set_clause := @extschema@.__CDB_GetUpdateSetClause(colnames, '_changed'); + dst_colnames := array_to_string(@extschema@.__CDB_QualifyColumns('_dst', colnames), ','); + src_colnames := array_to_string(@extschema@.__CDB_QualifyColumns('_src', colnames), ','); + EXECUTE format(' + UPDATE %1$s _update SET %2$s + FROM ( + SELECT _src.* FROM %3$s _src JOIN %1$s _dst ON (_dst.cartodb_id = _src.cartodb_id) + WHERE md5(ROW(%4$s)::text) <> md5(ROW(%5$s)::text) + ) _changed + WHERE _update.cartodb_id = _changed.cartodb_id; + ', fq_dest_table, update_set_clause, src_table, dst_colnames, src_colnames); + GET DIAGNOSTICS num_rows = ROW_COUNT; + RAISE NOTICE 'MODIFIED % row(s)', num_rows; + RAISE DEBUG 'UPDATE time (s): %', clock_timestamp() - t; +END; +$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_TableIndexes.sql b/lib/sql/scripts-available/CDB_TableIndexes.sql new file mode 100644 index 0000000..533cbe9 --- /dev/null +++ b/lib/sql/scripts-available/CDB_TableIndexes.sql @@ -0,0 +1,27 @@ +-- Function returning indexes for a table +CREATE OR REPLACE FUNCTION @extschema@.CDB_TableIndexes(REGCLASS) +RETURNS TABLE(index_name name, index_unique bool, index_primary bool, index_keys text array) +AS $$ + + SELECT pg_class.relname as index_name, + idx.indisunique as index_unique, + idx.indisprimary as index_primary, + ARRAY( + SELECT pg_get_indexdef(idx.indexrelid, k + 1, true) + FROM generate_subscripts(idx.indkey, 1) as k + ORDER BY k + ) as index_keys + FROM pg_indexes, + pg_index as idx + JOIN pg_class + ON pg_class.oid = idx.indexrelid + WHERE pg_indexes.tablename = '' || $1 || '' + AND '' || $1 || '' IN (SELECT CDB_UserTables()) + AND pg_class.relname=pg_indexes.indexname + ; + +$$ LANGUAGE SQL STABLE PARALLEL SAFE; + +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION @extschema@.CDB_TableIndexes(REGCLASS) TO public; diff --git a/lib/sql/scripts-available/CDB_TableMetadata.sql b/lib/sql/scripts-available/CDB_TableMetadata.sql new file mode 100644 index 0000000..4d68831 --- /dev/null +++ b/lib/sql/scripts-available/CDB_TableMetadata.sql @@ -0,0 +1,146 @@ + +CREATE TABLE IF NOT EXISTS + @extschema@.CDB_TableMetadata ( + tabname regclass not null primary key, + updated_at timestamp with time zone not null default now() + ); + +CREATE OR REPLACE VIEW @extschema@.CDB_TableMetadata_Text AS + SELECT FORMAT('%I.%I', n.nspname::text, c.relname::text) tabname, updated_at + FROM @extschema@.CDB_TableMetadata m JOIN pg_catalog.pg_class c ON m.tabname::oid = c.oid + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid; + +-- No one can see this +-- Updates are only possible trough the security definer trigger +-- GRANT SELECT ON @extschema@.CDB_TableMetadata TO public; + +-- +-- Trigger logging updated_at in the CDB_TableMetadata +-- and notifying cdb_tabledata_update with table name as payload. +-- +-- Attach to tables like this: +-- +-- CREATE trigger track_updates +-- AFTER INSERT OR UPDATE OR TRUNCATE OR DELETE ON +-- FOR EACH STATEMENT +-- EXECUTE PROCEDURE cdb_tablemetadata_trigger(); +-- +-- NOTE: _never_ attach to CDB_TableMetadata ... +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_TableMetadata_Trigger() +RETURNS trigger AS +$$ +BEGIN + -- Guard against infinite loop + IF TG_RELID = '@extschema@.CDB_TableMetadata'::regclass::oid THEN + RETURN NULL; + END IF; + + -- Cleanup stale entries + DELETE FROM @extschema@.CDB_TableMetadata + WHERE NOT EXISTS ( + SELECT oid FROM pg_class WHERE oid = tabname + ); + + WITH nv as ( + SELECT TG_RELID as tabname, NOW() as t + ), updated as ( + UPDATE @extschema@.CDB_TableMetadata x SET updated_at = nv.t + FROM nv WHERE x.tabname = nv.tabname + RETURNING x.tabname + ) + INSERT INTO @extschema@.CDB_TableMetadata SELECT nv.* + FROM nv LEFT JOIN updated USING(tabname) + WHERE updated.tabname IS NULL; + + RETURN NULL; +END; +$$ +LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +-- +-- Trigger invalidating varnish whenever CDB_TableMetadata +-- record change. +-- +CREATE OR REPLACE FUNCTION @extschema@._CDB_TableMetadata_Updated() +RETURNS trigger AS +$$ +DECLARE + tabname regclass; + rec RECORD; + found BOOL; + schema_name TEXT; + table_name TEXT; +BEGIN + + IF TG_OP = 'UPDATE' or TG_OP = 'INSERT' THEN + tabname = NEW.tabname; + ELSE + tabname = OLD.tabname; + END IF; + + -- Notify table data update + -- This needs a little bit more of research regarding security issues + -- see https://github.com/CartoDB/cartodb/pull/241 + -- PERFORM pg_notify('cdb_tabledata_update', tabname); + + --RAISE NOTICE 'Table % was updated', tabname; + + -- This will be needed until we'll have someone listening + -- on the event we just broadcasted: + -- + -- LISTEN cdb_tabledata_update; + -- + + -- Call the first varnish invalidation function owned + -- by a superuser found in @extschema@ or public schema + -- (in that order) + found := false; + FOR rec IN SELECT u.usesuper, u.usename, n.nspname, p.proname + FROM pg_proc p, pg_namespace n, pg_user u + WHERE p.proname = 'cdb_invalidate_varnish' + AND p.pronamespace = n.oid + AND n.nspname IN ('public', '@extschema@') + AND u.usesysid = p.proowner + AND u.usesuper + ORDER BY n.nspname + LOOP + SELECT n.nspname, c.relname FROM pg_class c, pg_namespace n WHERE c.oid=tabname AND c.relnamespace = n.oid INTO schema_name, table_name; + EXECUTE 'SELECT ' || quote_ident(rec.nspname) || '.' + || quote_ident(rec.proname) + || '(' || quote_literal(quote_ident(schema_name) || '.' || quote_ident(table_name)) || ')'; + found := true; + EXIT; + END LOOP; + IF NOT found THEN RAISE WARNING 'Missing cdb_invalidate_varnish()'; END IF; + + RETURN NULL; +END; +$$ +LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER; + +DROP TRIGGER IF EXISTS table_modified ON @extschema@.CDB_TableMetadata; +-- NOTE: on DELETE we would be unable to convert the table +-- oid (regclass) to its name +CREATE TRIGGER table_modified AFTER INSERT OR UPDATE +ON @extschema@.CDB_TableMetadata FOR EACH ROW EXECUTE PROCEDURE + @extschema@._CDB_TableMetadata_Updated(); + + +-- similar to TOUCH(1) in unix filesystems but for table in cdb_tablemetadata +CREATE OR REPLACE FUNCTION @extschema@.CDB_TableMetadataTouch(tablename regclass) + RETURNS void AS + $$ + BEGIN + WITH upsert AS ( + UPDATE @extschema@.cdb_tablemetadata + SET updated_at = NOW() + WHERE tabname = tablename + RETURNING * + ) + INSERT INTO @extschema@.cdb_tablemetadata (tabname, updated_at) + SELECT tablename, NOW() + WHERE NOT EXISTS (SELECT * FROM upsert); + END; + $$ +LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_TransformToWebmercator.sql b/lib/sql/scripts-available/CDB_TransformToWebmercator.sql new file mode 100644 index 0000000..b61e8da --- /dev/null +++ b/lib/sql/scripts-available/CDB_TransformToWebmercator.sql @@ -0,0 +1,82 @@ +-- +-- Function to "safely" transform to webmercator +-- +-- This function works around the existance of a valid range +-- for web mercator by "clipping" anything outside to the valid +-- range. +-- +CREATE OR REPLACE FUNCTION @extschema@.CDB_TransformToWebmercator(geom @postgisschema@.geometry) +RETURNS @postgisschema@.geometry +AS +$$ +DECLARE + valid_extent @postgisschema@.GEOMETRY; + latlon_input @postgisschema@.GEOMETRY; + clipped_input @postgisschema@.GEOMETRY; + to_webmercator @postgisschema@.GEOMETRY; + ret @postgisschema@.GEOMETRY; +BEGIN + + IF @postgisschema@.ST_Srid(geom) = 3857 THEN + RETURN geom; + END IF; + + -- This is the valid web mercator extent + -- + -- NOTE: some sources set the valid latitude range + -- to -85.0511 to 85.0511 but as long as proj + -- does not complain we are happy + -- + valid_extent := @postgisschema@.ST_MakeEnvelope(-180, -89, 180, 89, 4326); + + -- Then we transform to WGS84 latlon, which is + -- where we have known coordinates for the clipping + -- + latlon_input := @postgisschema@.ST_Transform(geom, 4326); + + -- Don't bother clipping if the geometry boundary doesn't + -- go outside the valid extent. + IF latlon_input @ valid_extent THEN + BEGIN + RETURN @postgisschema@.ST_Transform(latlon_input, 3857); + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; + END IF; + + -- Since we're going to use ST_Intersection on input + -- we'd better ensure the input is valid + -- TODO: only do this if the first ST_Intersection fails ? + IF @postgisschema@.ST_Dimension(geom) != 0 AND + -- See http://trac.osgeo.org/postgis/ticket/1719 + @postgisschema@.GeometryType(geom) != 'GEOMETRYCOLLECTION' + THEN + BEGIN + latlon_input := @postgisschema@.ST_MakeValid(latlon_input); + EXCEPTION + WHEN OTHERS THEN + -- See http://github.com/Vizzuality/cartodb/issues/931 + RAISE WARNING 'Could not clean input geometry: %', SQLERRM; + RETURN NULL; + END; + latlon_input := @postgisschema@.ST_CollectionExtract(latlon_input, ST_Dimension(geom)+1); + END IF; + + -- Then we clip, trying to retain the input type + -- TODO: catch exceptions here too ? + clipped_input := @postgisschema@.ST_Intersection(latlon_input, valid_extent); + + -- We transform to web mercator + to_webmercator := @postgisschema@.ST_Transform(clipped_input, 3857); + + -- Finally we convert EMPTY to NULL + -- See https://github.com/Vizzuality/cartodb/issues/706 + -- And retain "multi" status + ret := CASE WHEN @postgisschema@.ST_IsEmpty(to_webmercator) THEN NULL::@postgisschema@.geometry + WHEN @postgisschema@.GeometryType(geom) LIKE 'MULTI%' THEN @postgisschema@.ST_Multi(to_webmercator) + ELSE to_webmercator + END; + + RETURN ret; +END +$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; diff --git a/lib/sql/scripts-available/CDB_UserTables.sql b/lib/sql/scripts-available/CDB_UserTables.sql new file mode 100644 index 0000000..ee76e1d --- /dev/null +++ b/lib/sql/scripts-available/CDB_UserTables.sql @@ -0,0 +1,28 @@ +-- Function returning list of cartodb user tables +-- +-- The optional argument restricts the result to tables +-- of the specified access type. +-- +-- Currently accepted permissions are: 'public', 'private' or 'all' +-- +DROP FUNCTION IF EXISTS @extschema@.CDB_UserTables(text); +CREATE OR REPLACE FUNCTION @extschema@.CDB_UserTables(perm text DEFAULT 'all') +RETURNS SETOF name +AS $$ + +SELECT c.relname +FROM pg_class c +JOIN pg_namespace n ON n.oid = c.relnamespace +WHERE c.relkind = 'r' +AND c.relname NOT IN ('cdb_tablemetadata', 'cdb_analysis_catalog', 'cdb_conf', 'spatial_ref_sys') +AND n.nspname NOT IN ('pg_catalog', 'information_schema', 'topology', '@extschema@') +AND CASE WHEN perm = 'public' THEN has_table_privilege('publicuser', c.oid, 'SELECT') + WHEN perm = 'private' THEN has_table_privilege(current_user, c.oid, 'SELECT') AND NOT has_table_privilege('publicuser', c.oid, 'SELECT') + WHEN perm = 'all' THEN has_table_privilege(current_user, c.oid, 'SELECT') OR has_table_privilege('publicuser', c.oid, 'SELECT') + ELSE false END; + +$$ LANGUAGE 'sql' STABLE PARALLEL SAFE; + +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION @extschema@.CDB_UserTables(text) TO public; diff --git a/lib/sql/scripts-available/CDB_Username.sql b/lib/sql/scripts-available/CDB_Username.sql new file mode 100644 index 0000000..adc1427 --- /dev/null +++ b/lib/sql/scripts-available/CDB_Username.sql @@ -0,0 +1,6 @@ +-- Returns the cartodb username of the current PostgreSQL session +CREATE OR REPLACE FUNCTION @extschema@.CDB_Username() +RETURNS text +AS $$ + SELECT @extschema@.CDB_Conf_GetConf(CONCAT('api_keys_', session_user))->>'username'; +$$ LANGUAGE SQL STABLE PARALLEL SAFE SECURITY DEFINER; diff --git a/lib/sql/scripts-available/CDB_XYZ.sql b/lib/sql/scripts-available/CDB_XYZ.sql new file mode 100644 index 0000000..d07ce46 --- /dev/null +++ b/lib/sql/scripts-available/CDB_XYZ.sql @@ -0,0 +1,62 @@ +-- { +-- Return pixel resolution at the given zoom level +-- }{ +CREATE OR REPLACE FUNCTION @extschema@.CDB_XYZ_Resolution(z INTEGER) +RETURNS FLOAT8 +AS $$ + -- circumference divided by 256 is z0 resolution, then divide by 2^z + SELECT 6378137.0*2.0*pi() / 256.0 / power(2.0, z); +$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE STRICT; +-- } + +-- { +-- Returns a polygon representing the bounding box of a given XYZ tile +-- +-- SRID of the returned polygon is forceably 3857 +-- +-- }{ +CREATE OR REPLACE FUNCTION @extschema@.CDB_XYZ_Extent(x INTEGER, y INTEGER, z INTEGER) +RETURNS GEOMETRY +AS $$ +DECLARE + origin_shift FLOAT8; + initial_resolution FLOAT8; + tile_geo_size FLOAT8; + pixres FLOAT8; + xmin FLOAT8; + ymin FLOAT8; + xmax FLOAT8; + ymax FLOAT8; + earth_circumference FLOAT8; + tile_size INTEGER; +BEGIN + + -- Size of each tile in pixels (1:1 aspect ratio) + tile_size := 256; + + initial_resolution := @extschema@.CDB_XYZ_Resolution(0); + --RAISE DEBUG 'Initial resolution: %', initial_resolution; + + origin_shift := (initial_resolution * tile_size) / 2.0; + -- RAISE DEBUG 'Origin shift (after): %', origin_shift; + + pixres := initial_resolution / (power(2,z)); + --RAISE DEBUG 'Pixel resolution: %', pixres; + + tile_geo_size = tile_size * pixres; + --RAISE DEBUG 'Tile_geo_size: %', tile_geo_size; + + xmin := -origin_shift + x*tile_geo_size; + xmax := -origin_shift + (x+1)*tile_geo_size; + --RAISE DEBUG 'xmin: %', xmin; + --RAISE DEBUG 'xmax: %', xmax; + + ymin := origin_shift - y*tile_geo_size; + ymax := origin_shift - (y+1)*tile_geo_size; + --RAISE DEBUG 'ymin: %', ymin; + --RAISE DEBUG 'ymax: %', ymax; + + RETURN @postgisschema@.ST_MakeEnvelope(xmin, ymin, xmax, ymax, 3857); +END +$$ LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL SAFE; +-- } diff --git a/lib/sql/scripts-available/CDB_ZoomFromScale.sql b/lib/sql/scripts-available/CDB_ZoomFromScale.sql new file mode 100644 index 0000000..0866f51 --- /dev/null +++ b/lib/sql/scripts-available/CDB_ZoomFromScale.sql @@ -0,0 +1,36 @@ +-- Maximum supported zoom level +CREATE OR REPLACE FUNCTION @extschema@._CDB_MaxSupportedZoom() +RETURNS int +LANGUAGE SQL +IMMUTABLE PARALLEL SAFE +AS $$ + -- The maximum zoom level has to be limited for various reasons, + -- e.g. zoom levels greater than 31 would require tile coordinates + -- that would not fit in an INTEGER (which is signed, 32 bits long). + -- We'll choose 20 as a limit which is safe also when the JavaScript shift + -- operator (<<) is used for computing powers of two. + SELECT 29; +$$; + +CREATE OR REPLACE FUNCTION @extschema@.CDB_ZoomFromScale(scaleDenominator numeric) +RETURNS int +LANGUAGE SQL +IMMUTABLE PARALLEL SAFE +AS $$ + SELECT + CASE + WHEN scaleDenominator > 600000000 THEN + -- Scale is smaller than zoom level 0 + NULL + WHEN scaleDenominator = 0 THEN + -- Actual zoom level would be infinite + @extschema@._CDB_MaxSupportedZoom() + ELSE + CAST ( + LEAST( + ROUND(LOG(2, 559082264.028/scaleDenominator)), + @extschema@._CDB_MaxSupportedZoom() + ) + AS INTEGER) + END; +$$; diff --git a/lib/sql/scripts-enabled/000-CDB_DateToNumber.sql b/lib/sql/scripts-enabled/000-CDB_DateToNumber.sql new file mode 120000 index 0000000..6c5d30b --- /dev/null +++ b/lib/sql/scripts-enabled/000-CDB_DateToNumber.sql @@ -0,0 +1 @@ +../scripts-available/CDB_DateToNumber.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/010-CDB_DigitSeparator.sql b/lib/sql/scripts-enabled/010-CDB_DigitSeparator.sql new file mode 120000 index 0000000..da031d8 --- /dev/null +++ b/lib/sql/scripts-enabled/010-CDB_DigitSeparator.sql @@ -0,0 +1 @@ +../scripts-available/CDB_DigitSeparator.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/020-CDB_HeadsTailsBins.sql b/lib/sql/scripts-enabled/020-CDB_HeadsTailsBins.sql new file mode 120000 index 0000000..388c618 --- /dev/null +++ b/lib/sql/scripts-enabled/020-CDB_HeadsTailsBins.sql @@ -0,0 +1 @@ +../scripts-available/CDB_HeadsTailsBins.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/030-CDB_Hexagon.sql b/lib/sql/scripts-enabled/030-CDB_Hexagon.sql new file mode 120000 index 0000000..a8a27a4 --- /dev/null +++ b/lib/sql/scripts-enabled/030-CDB_Hexagon.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Hexagon.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/040-CDB_JenksBins.sql b/lib/sql/scripts-enabled/040-CDB_JenksBins.sql new file mode 120000 index 0000000..9d0d5f8 --- /dev/null +++ b/lib/sql/scripts-enabled/040-CDB_JenksBins.sql @@ -0,0 +1 @@ +../scripts-available/CDB_JenksBins.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/050-CDB_LatLng.sql b/lib/sql/scripts-enabled/050-CDB_LatLng.sql new file mode 120000 index 0000000..f8a546a --- /dev/null +++ b/lib/sql/scripts-enabled/050-CDB_LatLng.sql @@ -0,0 +1 @@ +../scripts-available/CDB_LatLng.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/060-CDB_QuantileBins.sql b/lib/sql/scripts-enabled/060-CDB_QuantileBins.sql new file mode 120000 index 0000000..a81f510 --- /dev/null +++ b/lib/sql/scripts-enabled/060-CDB_QuantileBins.sql @@ -0,0 +1 @@ +../scripts-available/CDB_QuantileBins.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/070-CDB_QueryStatements.sql b/lib/sql/scripts-enabled/070-CDB_QueryStatements.sql new file mode 120000 index 0000000..bc5ecb6 --- /dev/null +++ b/lib/sql/scripts-enabled/070-CDB_QueryStatements.sql @@ -0,0 +1 @@ +../scripts-available/CDB_QueryStatements.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/080-CDB_QueryTables.sql b/lib/sql/scripts-enabled/080-CDB_QueryTables.sql new file mode 120000 index 0000000..758bef3 --- /dev/null +++ b/lib/sql/scripts-enabled/080-CDB_QueryTables.sql @@ -0,0 +1 @@ +../scripts-available/CDB_QueryTables.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/085-CDB_OverviewsSupport.sql b/lib/sql/scripts-enabled/085-CDB_OverviewsSupport.sql new file mode 120000 index 0000000..571319b --- /dev/null +++ b/lib/sql/scripts-enabled/085-CDB_OverviewsSupport.sql @@ -0,0 +1 @@ +../scripts-available/CDB_OverviewsSupport.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/090-CDB_Quota.sql b/lib/sql/scripts-enabled/090-CDB_Quota.sql new file mode 120000 index 0000000..c4cbdd7 --- /dev/null +++ b/lib/sql/scripts-enabled/090-CDB_Quota.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Quota.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/100-CDB_RandomTids.sql b/lib/sql/scripts-enabled/100-CDB_RandomTids.sql new file mode 120000 index 0000000..ea359d4 --- /dev/null +++ b/lib/sql/scripts-enabled/100-CDB_RandomTids.sql @@ -0,0 +1 @@ +../scripts-available/CDB_RandomTids.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/110-CDB_RectangleGrid.sql b/lib/sql/scripts-enabled/110-CDB_RectangleGrid.sql new file mode 120000 index 0000000..95f90da --- /dev/null +++ b/lib/sql/scripts-enabled/110-CDB_RectangleGrid.sql @@ -0,0 +1 @@ +../scripts-available/CDB_RectangleGrid.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/120-CDB_StringToDate.sql b/lib/sql/scripts-enabled/120-CDB_StringToDate.sql new file mode 120000 index 0000000..89a4411 --- /dev/null +++ b/lib/sql/scripts-enabled/120-CDB_StringToDate.sql @@ -0,0 +1 @@ +../scripts-available/CDB_StringToDate.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/130-CDB_TableMetadata.sql b/lib/sql/scripts-enabled/130-CDB_TableMetadata.sql new file mode 120000 index 0000000..507fda7 --- /dev/null +++ b/lib/sql/scripts-enabled/130-CDB_TableMetadata.sql @@ -0,0 +1 @@ +../scripts-available/CDB_TableMetadata.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/140-CDB_TransformToWebmercator.sql b/lib/sql/scripts-enabled/140-CDB_TransformToWebmercator.sql new file mode 120000 index 0000000..85650af --- /dev/null +++ b/lib/sql/scripts-enabled/140-CDB_TransformToWebmercator.sql @@ -0,0 +1 @@ +../scripts-available/CDB_TransformToWebmercator.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/150-CDB_UserTables.sql b/lib/sql/scripts-enabled/150-CDB_UserTables.sql new file mode 120000 index 0000000..2ef6405 --- /dev/null +++ b/lib/sql/scripts-enabled/150-CDB_UserTables.sql @@ -0,0 +1 @@ +../scripts-available/CDB_UserTables.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/160-CDB_XYZ.sql b/lib/sql/scripts-enabled/160-CDB_XYZ.sql new file mode 120000 index 0000000..2b5d9d8 --- /dev/null +++ b/lib/sql/scripts-enabled/160-CDB_XYZ.sql @@ -0,0 +1 @@ +../scripts-available/CDB_XYZ.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/170-CDB_ColumnNames.sql b/lib/sql/scripts-enabled/170-CDB_ColumnNames.sql new file mode 120000 index 0000000..3c3bf4f --- /dev/null +++ b/lib/sql/scripts-enabled/170-CDB_ColumnNames.sql @@ -0,0 +1 @@ +../scripts-available/CDB_ColumnNames.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/180-CDB_ColumnType.sql b/lib/sql/scripts-enabled/180-CDB_ColumnType.sql new file mode 120000 index 0000000..4122629 --- /dev/null +++ b/lib/sql/scripts-enabled/180-CDB_ColumnType.sql @@ -0,0 +1 @@ +../scripts-available/CDB_ColumnType.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/190-CDB_CartodbfyTable.sql b/lib/sql/scripts-enabled/190-CDB_CartodbfyTable.sql new file mode 120000 index 0000000..2385162 --- /dev/null +++ b/lib/sql/scripts-enabled/190-CDB_CartodbfyTable.sql @@ -0,0 +1 @@ +../scripts-available/CDB_CartodbfyTable.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/200-CDB_TableIndexes.sql b/lib/sql/scripts-enabled/200-CDB_TableIndexes.sql new file mode 120000 index 0000000..1997db4 --- /dev/null +++ b/lib/sql/scripts-enabled/200-CDB_TableIndexes.sql @@ -0,0 +1 @@ +../scripts-available/CDB_TableIndexes.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/210-CDB_Organizations.sql b/lib/sql/scripts-enabled/210-CDB_Organizations.sql new file mode 120000 index 0000000..3f2d48a --- /dev/null +++ b/lib/sql/scripts-enabled/210-CDB_Organizations.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Organizations.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/220-CDB_Math.sql b/lib/sql/scripts-enabled/220-CDB_Math.sql new file mode 120000 index 0000000..613e0d8 --- /dev/null +++ b/lib/sql/scripts-enabled/220-CDB_Math.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Math.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/230-CDB_ZoomFromScale.sql b/lib/sql/scripts-enabled/230-CDB_ZoomFromScale.sql new file mode 120000 index 0000000..c53ee7e --- /dev/null +++ b/lib/sql/scripts-enabled/230-CDB_ZoomFromScale.sql @@ -0,0 +1 @@ +../scripts-available/CDB_ZoomFromScale.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/240-CDB_EqualIntervalBins.sql b/lib/sql/scripts-enabled/240-CDB_EqualIntervalBins.sql new file mode 120000 index 0000000..88c35b5 --- /dev/null +++ b/lib/sql/scripts-enabled/240-CDB_EqualIntervalBins.sql @@ -0,0 +1 @@ +../scripts-available/CDB_EqualIntervalBins.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/241-CDB_GreatCircle.sql b/lib/sql/scripts-enabled/241-CDB_GreatCircle.sql new file mode 120000 index 0000000..8bec24c --- /dev/null +++ b/lib/sql/scripts-enabled/241-CDB_GreatCircle.sql @@ -0,0 +1 @@ +../scripts-available/CDB_GreatCircle.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/245-CDB_Overviews.sql b/lib/sql/scripts-enabled/245-CDB_Overviews.sql new file mode 120000 index 0000000..7f1a650 --- /dev/null +++ b/lib/sql/scripts-enabled/245-CDB_Overviews.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Overviews.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/250-CDB_ForeignTable.sql b/lib/sql/scripts-enabled/250-CDB_ForeignTable.sql new file mode 120000 index 0000000..4154d35 --- /dev/null +++ b/lib/sql/scripts-enabled/250-CDB_ForeignTable.sql @@ -0,0 +1 @@ +../scripts-available/CDB_ForeignTable.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/260-CDB_AnalysisCatalog.sql b/lib/sql/scripts-enabled/260-CDB_AnalysisCatalog.sql new file mode 120000 index 0000000..3b75542 --- /dev/null +++ b/lib/sql/scripts-enabled/260-CDB_AnalysisCatalog.sql @@ -0,0 +1 @@ +../scripts-available/CDB_AnalysisCatalog.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/270-CDB_AnalysisSupport.sql b/lib/sql/scripts-enabled/270-CDB_AnalysisSupport.sql new file mode 120000 index 0000000..d586e3e --- /dev/null +++ b/lib/sql/scripts-enabled/270-CDB_AnalysisSupport.sql @@ -0,0 +1 @@ +../scripts-available/CDB_AnalysisSupport.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/275-CDB_AnalysisCheck.sql b/lib/sql/scripts-enabled/275-CDB_AnalysisCheck.sql new file mode 120000 index 0000000..978dc35 --- /dev/null +++ b/lib/sql/scripts-enabled/275-CDB_AnalysisCheck.sql @@ -0,0 +1 @@ +../scripts-available/CDB_AnalysisCheck.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/280-CDB_EstimateRowCount.sql b/lib/sql/scripts-enabled/280-CDB_EstimateRowCount.sql new file mode 120000 index 0000000..9d6120a --- /dev/null +++ b/lib/sql/scripts-enabled/280-CDB_EstimateRowCount.sql @@ -0,0 +1 @@ +../scripts-available/CDB_EstimateRowCount.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/290-CDB_GhostTables.sql b/lib/sql/scripts-enabled/290-CDB_GhostTables.sql new file mode 120000 index 0000000..9be6429 --- /dev/null +++ b/lib/sql/scripts-enabled/290-CDB_GhostTables.sql @@ -0,0 +1 @@ +../scripts-available/CDB_GhostTables.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/900-CDB_DDLTriggers.sql b/lib/sql/scripts-enabled/900-CDB_DDLTriggers.sql new file mode 120000 index 0000000..3e15289 --- /dev/null +++ b/lib/sql/scripts-enabled/900-CDB_DDLTriggers.sql @@ -0,0 +1 @@ +../scripts-available/CDB_DDLTriggers.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/910-CDB_Conf.sql b/lib/sql/scripts-enabled/910-CDB_Conf.sql new file mode 120000 index 0000000..19578a9 --- /dev/null +++ b/lib/sql/scripts-enabled/910-CDB_Conf.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Conf.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/920-CDB_Username.sql b/lib/sql/scripts-enabled/920-CDB_Username.sql new file mode 120000 index 0000000..8c0abca --- /dev/null +++ b/lib/sql/scripts-enabled/920-CDB_Username.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Username.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_DistType.sql b/lib/sql/scripts-enabled/CDB_DistType.sql new file mode 120000 index 0000000..64ff8c2 --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_DistType.sql @@ -0,0 +1 @@ +../scripts-available/CDB_DistType.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_DistinctMeasure.sql b/lib/sql/scripts-enabled/CDB_DistinctMeasure.sql new file mode 120000 index 0000000..e78b435 --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_DistinctMeasure.sql @@ -0,0 +1 @@ +../scripts-available/CDB_DistinctMeasure.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_Groups.sql b/lib/sql/scripts-enabled/CDB_Groups.sql new file mode 120000 index 0000000..63d80a7 --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_Groups.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Groups.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_Groups_API.sql b/lib/sql/scripts-enabled/CDB_Groups_API.sql new file mode 120000 index 0000000..2a80d8e --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_Groups_API.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Groups_API.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_Stats.sql b/lib/sql/scripts-enabled/CDB_Stats.sql new file mode 120000 index 0000000..37abd7b --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_Stats.sql @@ -0,0 +1 @@ +../scripts-available/CDB_Stats.sql \ No newline at end of file diff --git a/lib/sql/scripts-enabled/CDB_SyncTable.sql b/lib/sql/scripts-enabled/CDB_SyncTable.sql new file mode 120000 index 0000000..c258915 --- /dev/null +++ b/lib/sql/scripts-enabled/CDB_SyncTable.sql @@ -0,0 +1 @@ +../scripts-available/CDB_SyncTable.sql \ No newline at end of file diff --git a/lib/sql/sql/test_setup.sql b/lib/sql/sql/test_setup.sql new file mode 100644 index 0000000..cb4d895 --- /dev/null +++ b/lib/sql/sql/test_setup.sql @@ -0,0 +1,9 @@ +CREATE EXTENSION postgis; +CREATE EXTENSION plpythonu; +CREATE EXTENSION cartodb; +CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) +RETURNS void AS $$ +BEGIN + RAISE NOTICE 'cdb_invalidate_varnish(%) called', table_name; +END; +$$ LANGUAGE 'plpgsql'; diff --git a/lib/sql/test/CDB_AnalysisCheckTest.sql b/lib/sql/test/CDB_AnalysisCheckTest.sql new file mode 100644 index 0000000..1f85e7a --- /dev/null +++ b/lib/sql/test/CDB_AnalysisCheckTest.sql @@ -0,0 +1,20 @@ +SET client_min_messages TO error; +\set VERBOSITY terse + +SELECT CDB_SetUserQuotaInBytes(1000000); +SELECT _CDB_AnalysisTablesInSchema('public'); +SELECT _CDB_AnalysisDataSize('public'); +CREATE TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5(id int); +CREATE TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94(id int); +CREATE TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da9(id int); +SELECT _CDB_AnalysisTablesInSchema('public') t ORDER BY t; +SELECT _CDB_AnalysisDataSize('public'); +SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); +SELECT CDB_SetUserQuotaInBytes(1); +SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); +INSERT INTO analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5(id) VALUES (1),(2),(3),(4),(5); +SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); +DROP TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5; +DROP TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94; +DROP TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da9; +DROP FUNCTION "public"._CDB_UserQuotaInBytes(); diff --git a/lib/sql/test/CDB_AnalysisCheckTest_expect b/lib/sql/test/CDB_AnalysisCheckTest_expect new file mode 100644 index 0000000..9769356 --- /dev/null +++ b/lib/sql/test/CDB_AnalysisCheckTest_expect @@ -0,0 +1,18 @@ +SET +1000000 +0 +CREATE TABLE +CREATE TABLE +CREATE TABLE +(analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5,public,analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5) +(analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94,public,analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94) +0 + +1 + +INSERT 0 5 +ERROR: Analysis cache space limits exceeded +DROP TABLE +DROP TABLE +DROP TABLE +DROP FUNCTION diff --git a/lib/sql/test/CDB_CartodbfyTableTest.sql b/lib/sql/test/CDB_CartodbfyTableTest.sql new file mode 100644 index 0000000..3e5658e --- /dev/null +++ b/lib/sql/test/CDB_CartodbfyTableTest.sql @@ -0,0 +1,396 @@ +SET client_min_messages TO error; +\set VERBOSITY terse + +CREATE OR REPLACE FUNCTION CDB_CartodbfyTableCheck(tabname regclass, label text) +RETURNS text AS +$$ +DECLARE + sql TEXT; + id INTEGER; + rec RECORD; + lag INTERVAL; + tmp INTEGER; + ogc_geom geometry_columns; -- old the_geom record in geometry_columns + ogc_merc geometry_columns; -- old the_geom_webmercator record in geometry_columns + tabtext TEXT; +BEGIN + + -- Save current constraints on geometry columns, if any + ogc_geom = ('','','','',0,0,'GEOMETRY'); + ogc_merc = ogc_geom; + sql := 'SELECT gc.* FROM geometry_columns gc, pg_class c, pg_namespace n ' + || 'WHERE c.oid = ' || tabname::oid || ' AND n.oid = c.relnamespace' + || ' AND gc.f_table_schema = n.nspname AND gc.f_table_name = c.relname' + || ' AND gc.f_geometry_column IN ( ' || quote_literal('the_geom') + || ',' || quote_literal('the_geom_webmercator') || ')'; + FOR rec IN EXECUTE sql LOOP + IF rec.f_geometry_column = 'the_geom' THEN + ogc_geom := rec; + ELSE + ogc_merc := rec; + END IF; + END LOOP; + + tabtext := Format('%s.%s','public',tabname); + RAISE NOTICE 'CARTODBFYING % !!!!', tabtext; + PERFORM CDB_CartodbfyTable('public', tabname); + tabname := tabtext::regclass; + + sql := 'INSERT INTO ' || tabname::text || '(the_geom) values ( CDB_LatLng(2,1) ) RETURNING cartodb_id'; + EXECUTE sql INTO STRICT id; + sql := 'SELECT the_geom_webmercator FROM ' + || tabname::text || ' WHERE cartodb_id = ' || id; + EXECUTE sql INTO STRICT rec; + + -- Check the_geom_webmercator trigger + IF round(st_x(rec.the_geom_webmercator)) != 111319 THEN + RAISE EXCEPTION 'the_geom_webmercator X is % (expecting 111319)', round(st_x(rec.the_geom_webmercator)); + END IF; + IF round(st_y(rec.the_geom_webmercator)) != 222684 THEN + RAISE EXCEPTION 'the_geom_webmercator Y is % (expecting 222684)', round(st_y(rec.the_geom_webmercator)); + END IF; + + -- Check CDB_TableMetadata entry + sql := 'SELECT * FROM CDB_TableMetadata WHERE tabname = ' || tabname::oid; + EXECUTE sql INTO STRICT rec; + lag = rec.updated_at - now(); + IF lag > '1 second' THEN + RAISE EXCEPTION 'updated_at in CDB_TableMetadata not set to now() after insert [ valued % ago ]', lag; + END IF; + + -- Check geometry_columns entries + tmp := 0; + FOR rec IN + SELECT + CASE WHEN gc.f_geometry_column = 'the_geom' THEN 4326 + ELSE 3857 END as expsrid, + CASE WHEN gc.f_geometry_column = 'the_geom' THEN ogc_geom.type + ELSE ogc_merc.type END as exptype, gc.* + FROM geometry_columns gc, pg_class c, pg_namespace n + WHERE c.oid = tabname::oid AND n.oid = c.relnamespace + AND gc.f_table_schema = n.nspname AND gc.f_table_name = c.relname + AND gc.f_geometry_column IN ( 'the_geom', 'the_geom_webmercator') + LOOP + tmp := tmp + 1; + -- Check SRID constraint + IF rec.srid != rec.expsrid THEN + RAISE EXCEPTION 'SRID of % in geometry_columns is %, expected %', + rec.f_geometry_column, rec.srid, rec.expsrid; + END IF; + -- Check TYPE constraint didn't change + IF (rec.type != 'GEOMETRY') AND (rec.type != 'POINT') THEN + RAISE EXCEPTION 'type of % in geometry_columns is %, expected %', + rec.f_geometry_column, rec.type, rec.exptype; + END IF; + -- check coord_dimension ? + END LOOP; + IF tmp != 2 THEN + RAISE EXCEPTION '% entries found for table % in geometry_columns, expected 2', tmp, tabname; + END IF; + + -- Check GiST index + sql := 'SELECT a.attname, count(ri.relname) FROM' + || ' pg_index i, pg_class c, pg_class ri, pg_attribute a, pg_opclass o' + || ' WHERE i.indrelid = c.oid AND ri.oid = i.indexrelid' + || ' AND a.attrelid = ri.oid AND o.oid = i.indclass[0]' + || ' AND a.attname IN ( ' || quote_literal('the_geom') + || ',' || quote_literal('the_geom_webmercator') || ')' + || ' AND ri.relnatts = 1 AND o.opcname = ' + || quote_literal('gist_geometry_ops_2d') + || ' AND c.oid = ' || tabname::oid + || ' GROUP BY a.attname'; + RAISE NOTICE 'sql: %', sql; + EXECUTE sql; + GET DIAGNOSTICS tmp = ROW_COUNT; + IF tmp != 2 THEN + RAISE EXCEPTION '% gist indices found on the_geom and the_geom_webmercator, expected 2', tmp; + END IF; + + -- Check null constraint on cartodb_id, created_at, updated_at + SELECT count(*) FROM pg_attribute a, pg_class c WHERE c.oid = tabname::oid + AND a.attrelid = c.oid AND NOT a.attisdropped AND a.attname in + ( 'cartodb_id' ) + AND NOT a.attnotnull INTO strict tmp; + IF tmp > 0 THEN + RAISE EXCEPTION 'cartodb_id is missing not-null constraint'; + END IF; + + -- Cleanup + sql := 'DELETE FROM ' || tabname::text || ' WHERE cartodb_id = ' || id; + EXECUTE sql; + + RETURN label || ' cartodbfied fine'; +END; +$$ +LANGUAGE 'plpgsql'; + +-- check cartodbfytable idempotence +CREATE TABLE t AS SELECT 1::int as a; +SELECT CDB_CartodbfyTable('public', 't'); -- should fail +SELECT CDB_SetUserQuotaInBytes(0); -- Set user quota to infinite +SELECT CDB_CartodbfyTableCheck('t', 'single non-geometrical column'); +DROP TABLE t; + +-- table with single non-geometrical column +CREATE TABLE t AS SELECT ST_SetSRID(ST_MakePoint(-1,-1),4326) as the_geom, 1::int as cartodb_id, 'this is a sentence' as description; +SELECT CDB_CartodbfyTableCheck('t', 'check function idempotence'); +SELECT * FROM t; +SELECT CDB_CartodbfyTableCheck('t', 'check function idempotence'); +SELECT * FROM t; +DROP TABLE t; + +-- table with existing srid-unconstrained (but type-constrained) the_geom +CREATE TABLE t AS SELECT ST_SetSRID(ST_MakePoint(0,0),4326)::geometry(point) as the_geom; +SELECT CDB_CartodbfyTableCheck('t', 'srid-unconstrained the_geom'); +DROP TABLE t; + +-- table with mixed-srid the_geom values +CREATE TABLE t AS SELECT ST_SetSRID(ST_MakePoint(-1,-1),4326) as the_geom +UNION ALL SELECT ST_SetSRID(ST_MakePoint(0,0),3857); +SELECT CDB_CartodbfyTableCheck('t', 'mixed-srid the_geom'); +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; +DROP TABLE t; + +-- table with wrong srid-constrained the_geom values +CREATE TABLE t AS SELECT 'SRID=3857;LINESTRING(222638.981586547 222684.208505545, 111319.490793274 111325.142866385)'::geometry(geometry,3857) as the_geom; +SELECT CDB_CartodbfyTableCheck('t', 'wrong srid-constrained the_geom'); +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)),ST_Extent(ST_SnapToGrid(the_geom_webmercator,1)) FROM t; +DROP TABLE t; + +-- table with wrong srid-constrained the_geom_webmercator values (and no the_geom!) +CREATE TABLE t AS SELECT 'SRID=4326;LINESTRING(1 1,2 2)'::geometry(geometry,4326) as the_geom_webmercator; +SELECT CDB_CartodbfyTableCheck('t', 'wrong srid-constrained the_geom_webmercator'); +-- expect the_geom to be populated from the_geom_webmercator +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; +DROP TABLE t; + +-- table with existing triggered the_geom +CREATE TABLE t AS SELECT 'SRID=4326;LINESTRING(1 1,2 2)'::geometry(geometry) as the_geom; +CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE UPDATE OF the_geom ON t + FOR EACH ROW EXECUTE PROCEDURE _CDB_update_the_geom_webmercator(); +SELECT CDB_CartodbfyTableCheck('t', 'trigger-protected the_geom'); +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; +DROP TABLE t; + +-- table with existing cartodb_id field of type text +CREATE TABLE t AS SELECT 10::text as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text cartodb_id'); +select cartodb_id/2 FROM t; +DROP TABLE t; + +-- table with existing cartodb_id field of type text not casting +CREATE TABLE t AS SELECT 'nan'::text as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'uncasting text cartodb_id'); +DROP TABLE t; + +-- table with empty cartodb_id field of type text +CREATE TABLE t AS SELECT null::text as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'empty text cartodb_id'); +SELECT cartodb_id from t; +DROP TABLE t; + +-- table with existing cartodb_id field of type int4 not sequenced +CREATE TABLE t AS SELECT 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'unsequenced cartodb_id'); +SELECT cartodb_id FROM t; +DROP TABLE t; + +-- table with text geometry column +CREATE TABLE t AS SELECT 'SRID=4326;POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column'); +SELECT cartodb_id FROM t; +DROP TABLE t; + +-- table with text geometry column, no SRS +CREATE TABLE t AS SELECT 'POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, no srs'); +SELECT cartodb_id FROM t; +DROP TABLE t; + +-- table with text geometry column, unusual SRS +CREATE TABLE t AS SELECT 'SRID=26910;POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, srs = 26819'); +SELECT cartodb_id FROM t; +DROP TABLE t; + +-- table with text unparseable geometry column +CREATE TABLE t AS SELECT 'SRID=26910;PONT(1 1)'::text AS the_geom, 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, unparseable content'); +SELECT cartodb_id FROM t; +DROP TABLE t; + +-- table with existing cartodb_id serial primary key +CREATE TABLE t ( cartodb_id serial primary key ); +SELECT CDB_CartodbfyTableCheck('t', 'cartodb_id serial primary key'); +SELECT c.conname, a.attname FROM pg_constraint c, pg_attribute a +WHERE c.conrelid = 't'::regclass and a.attrelid = c.conrelid +AND c.conkey[1] = a.attnum AND NOT a.attisdropped; +DROP TABLE t; + +-- tables can be renamed and there's no index name clashing #123 +CREATE TABLE original(); +SELECT CDB_CartodbfyTable('original'); +ALTER TABLE original RENAME TO original_renamed; +CREATE TABLE original(); +SELECT CDB_CartodbfyTable('original'); +DROP TABLE original_renamed; +DROP TABLE original; + +-- Table always have a default seq value after cartodbfy #138 +CREATE TABLE bug_empty_table_no_seq ( + cartodb_id integer, + the_geom geometry(Geometry,4326), + the_geom_webmercator geometry(Geometry,3857), + name text, + description text +); +SELECT CDB_CartodbfyTableCheck('bug_empty_table_no_seq', 'Table always have a default seq value after cartodbfy #138'); +INSERT INTO bug_empty_table_no_seq DEFAULT VALUES; +DROP TABLE bug_empty_table_no_seq; + +-- Existing cartodb_id values are respected +CREATE table existing_cartodb_id ( + cartodb_id integer, + the_geom geometry(Geometry,4326), + the_geom_webmercator geometry(Geometry,3857), + name text, + description text +); +INSERT INTO existing_cartodb_id (cartodb_id, description) VALUES + (10, 'a'), + (20, 'b'), + (30, 'c'); +SELECT CDB_CartodbfyTableCheck('existing_cartodb_id', 'Existing cartodb_id values are respected #138'); +SELECT cartodb_id,the_geom,the_geom_webmercator,description,name from existing_cartodb_id; +DROP TABLE existing_cartodb_id; + +-- Table with both the_geom and wkb_geometry +CREATE TABLE many_geometry_columns ( + the_geom geometry, + wkb_geometry geometry(MultiPoint,4326), + description varchar +); +INSERT INTO many_geometry_columns (the_geom, wkb_geometry) VALUES + ('0104000020E61000000100000001010000007108B023698052C03CEEA53A2E5D4440', '0104000020E61000000100000001010000007108B023698052C03CEEA53A2E5D4440'), + ('0104000020E6100000010000000101000000864C9E57618052C0994F0C7F3C5B4440', '0104000020E6100000010000000101000000864C9E57618052C0994F0C7F3C5B4440'); +SELECT CDB_CartodbfyTableCheck('many_geometry_columns', 'Table with both the_geom and wkb_geometry #141'); +SELECT * FROM many_geometry_columns; +DROP TABLE many_geometry_columns; + +-- Many colliding geom columns +CREATE TABLE many_colliding_columns ( + the_geom varchar, + the_geom_webmercator varchar, + my_geom geometry, + my_mercgeom geometry(Point, 3857), + cartodb_id varchar, + my_pk integer primary key +); +INSERT INTO many_colliding_columns VALUES ( + 'foo', 'bar', 'SRID=4326;POINT(0 0)', 'SRID=3857;POINT(0 0)', 'nerf', 1 +); +SELECT CDB_CartodbfyTableCheck('many_colliding_columns', 'Many colliding columns #141'); +DROP TABLE many_colliding_columns; + +-- Table with null cartodb_id +CREATE TABLE test ( + cartodb_id integer +); +INSERT INTO test VALUES + (1), + (2), + (NULL), + (3); +SELECT CDB_CartodbfyTableCheck('test', 'Table with null cartodb_id #148'); +SELECT cartodb_id from test; +DROP TABLE test; + +-- Table with non unique cartodb_id +CREATE TABLE test ( + cartodb_id integer +); +INSERT INTO test VALUES + (1), + (2), + (2); +SELECT CDB_CartodbfyTableCheck('test', 'Table with non unique cartodb_id #148'); +SELECT cartodb_id from test; +DROP TABLE test; + +-- Table with non unique and null cartodb_id +CREATE TABLE test ( + cartodb_id integer +); +INSERT INTO test VALUES + (1), + (2), + (NULL), + (2); +SELECT CDB_CartodbfyTableCheck('test', 'Table with non unique and null cartodb_id #148'); +SELECT cartodb_id from test; +DROP TABLE test; + +CREATE TABLE test ( + cartodb_id integer +); +CREATE UNIQUE INDEX "test_cartodb_id_key" ON test (cartodb_id); +CREATE UNIQUE INDEX "test_cartodb_id_pkey" ON test (cartodb_id); +ALTER TABLE test ADD CONSTRAINT "test_pkey" PRIMARY KEY USING INDEX test_cartodb_id_pkey; +INSERT INTO test VALUES + (1), + (2), + (3); +SELECT CDB_CartodbfyTableCheck('test', 'Table with primary key and unique index on it #174'); +SELECT cartodb_id from test; +DROP TABLE test; + +CREATE TABLE test ( + name varchar, + "first.value" integer, + "second.value" integer +); +INSERT INTO test VALUES ('one', 1, 2), ('two', 3, 4); +SELECT CDB_CartodbfyTableCheck('test', 'Table with dots in name columns (cartodb #6114)'); +SELECT name, "first.value" from test; +DROP TABLE test; + +SET client_min_messages TO notice; +-- _CDB_create_cartodb_id_column with cartodb_id integer already present +CREATE TABLE test (cartodb_id integer); + +SELECT _CDB_Create_Cartodb_ID_Column('test'::regclass); +SELECT column_name FROM information_schema.columns WHERE table_name = 'test' AND column_name = '_cartodb_id0'; + +DROP TABLE test; + +-- _CDB_create_cartodb_id_column with cartodb_id text already present +CREATE TABLE test (cartodb_id text); + +SELECT _CDB_Create_Cartodb_ID_Column('test'::regclass); +SELECT column_name FROM information_schema.columns WHERE table_name = 'test' AND column_name = '_cartodb_id0'; + +DROP TABLE test; +SET client_min_messages TO error; + +-- Unique identifier generation can break CDB_CartodbfyTable #305 +BEGIN; + DO $$ + BEGIN + FOR i IN 1..150 LOOP + EXECUTE 'CREATE TABLE untitled_table();'; + EXECUTE $query$SELECT CDB_CartodbfyTable('untitled_table');$query$; + EXECUTE 'ALTER TABLE untitled_table RENAME TO my_renamed_table_' || i; + END LOOP; + END; + $$; +ROLLBACK; + +-- Long table name could cause possible sequence rename collision #325 +CREATE TABLE "wadus_table_9473e8f6-2da1-11e8-8bca-0204e4dfe4d8" ( cartodb_id serial primary key ); +SELECT CDB_CartodbfyTableCheck('wadus_table_9473e8f6-2da1-11e8-8bca-0204e4dfe4d8'::REGCLASS, 'Long table name could cause sequence collision while renaming #325'); +DROP TABLE "wadus_table_9473e8f6-2da1-11e8-8bca-0204e4dfe4d8"; + +-- TODO: table with existing custom-triggered the_geom + +DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text); +DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/lib/sql/test/CDB_CartodbfyTableTest_expect b/lib/sql/test/CDB_CartodbfyTableTest_expect new file mode 100644 index 0000000..9939598 --- /dev/null +++ b/lib/sql/test/CDB_CartodbfyTableTest_expect @@ -0,0 +1,157 @@ +SET +CREATE FUNCTION +SELECT 1 +ERROR: Please set user quota before cartodbfying tables. +0 +single non-geometrical column cartodbfied fine +DROP TABLE +SELECT 1 +check function idempotence cartodbfied fine +1|0101000020E6100000000000000000F0BF000000000000F0BF|0101000020110F0000DB0B4ADA772DFBC077432E49D22DFBC0|this is a sentence +check function idempotence cartodbfied fine +1|0101000020E6100000000000000000F0BF000000000000F0BF|0101000020110F0000DB0B4ADA772DFBC077432E49D22DFBC0|this is a sentence +DROP TABLE +SELECT 1 +srid-unconstrained the_geom cartodbfied fine +DROP TABLE +SELECT 2 +mixed-srid the_geom cartodbfied fine +extent|BOX(-1 -1,0 0) +DROP TABLE +SELECT 1 +wrong srid-constrained the_geom cartodbfied fine +extent|BOX(1 1,2 2)|BOX(111319 111325,222639 222684) +DROP TABLE +SELECT 1 +wrong srid-constrained the_geom_webmercator cartodbfied fine +extent|BOX(1 1,2 2) +DROP TABLE +SELECT 1 +CREATE TRIGGER +trigger-protected the_geom cartodbfied fine +extent|BOX(1 1,2 2) +DROP TABLE +SELECT 1 +text cartodb_id cartodbfied fine +5 +DROP TABLE +SELECT 1 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, cartodb_id): ALTER TABLE t ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); +DROP TABLE +SELECT 1 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, cartodb_id): ALTER TABLE t ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); + +DROP TABLE +SELECT 1 +unsequenced cartodb_id cartodbfied fine +1 +DROP TABLE +SELECT 1 +text the_geom column cartodbfied fine +1 +DROP TABLE +SELECT 1 +text the_geom column, no srs cartodbfied fine +1 +DROP TABLE +SELECT 1 +text the_geom column, srs = 26819 cartodbfied fine +1 +DROP TABLE +SELECT 1 +text the_geom column, unparseable content cartodbfied fine +1 +DROP TABLE +CREATE TABLE +cartodb_id serial primary key cartodbfied fine +t_pkey|cartodb_id +DROP TABLE +CREATE TABLE +original +ALTER TABLE +CREATE TABLE +original +DROP TABLE +DROP TABLE +CREATE TABLE +Table always have a default seq value after cartodbfy #138 cartodbfied fine +INSERT 0 1 +DROP TABLE +CREATE TABLE +INSERT 0 3 +Existing cartodb_id values are respected #138 cartodbfied fine +10|||a| +20|||b| +30|||c| +DROP TABLE +CREATE TABLE +INSERT 0 2 +Table with both the_geom and wkb_geometry #141 cartodbfied fine +1|0104000020E61000000100000001010000007108B023698052C03CEEA53A2E5D4440|0104000020110F00000100000001010000004A9F662B456D5FC11392690DC3F75241| +2|0104000020E6100000010000000101000000864C9E57618052C0994F0C7F3C5B4440|0104000020110F00000100000001010000002858E0EC376D5FC1CAE8DB4B95F55241| +DROP TABLE +CREATE TABLE +INSERT 0 1 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: multiple primary keys for table "many_colliding_columns" are not allowed): ALTER TABLE many_colliding_columns ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); +DROP TABLE +CREATE TABLE +INSERT 0 4 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, cartodb_id): ALTER TABLE test ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); +1 +2 + +3 +DROP TABLE +CREATE TABLE +INSERT 0 3 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, cartodb_id): ALTER TABLE test ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); +1 +2 +2 +DROP TABLE +CREATE TABLE +INSERT 0 4 +ERROR: CDB(_CDB_Has_Usable_Primary_ID: Error: invalid cartodb_id, cartodb_id): ALTER TABLE test ADD CONSTRAINT cartodb_id_pk PRIMARY KEY (cartodb_id), ADD CONSTRAINT cartodb_id_integer CHECK (cartodb_id::integer >=0); +1 +2 + +2 +DROP TABLE +CREATE TABLE +CREATE INDEX +CREATE INDEX +ALTER TABLE +INSERT 0 3 +Table with primary key and unique index on it #174 cartodbfied fine +1 +2 +3 +DROP TABLE +CREATE TABLE +INSERT 0 2 +Table with dots in name columns (cartodb #6114) cartodbfied fine +one|1 +two|3 +DROP TABLE +SET +CREATE TABLE +NOTICE: Column cartodb_id already exists +NOTICE: Existing cartodb_id field does not have an associated sequence, renaming +NOTICE: Trying to recover data from _cartodb_id0 column + +DROP TABLE +CREATE TABLE +NOTICE: Column cartodb_id already exists +NOTICE: Existing cartodb_id field is of invalid type text (need int2, int4 or int8), renaming +NOTICE: Trying to recover data from _cartodb_id0 column + +DROP TABLE +SET +BEGIN +DO +ROLLBACK +CREATE TABLE +Long table name could cause sequence collision while renaming #325 cartodbfied fine +DROP TABLE +DROP FUNCTION +DROP FUNCTION diff --git a/lib/sql/test/CDB_DateToNumberTest.sql b/lib/sql/test/CDB_DateToNumberTest.sql new file mode 100644 index 0000000..0c1051c --- /dev/null +++ b/lib/sql/test/CDB_DateToNumberTest.sql @@ -0,0 +1,2 @@ +SELECT * FROM CDB_DateToNumber('1999-01-08 00:00:00'::timestamp); +SELECT * FROM CDB_DateToNumber('1999-01-08 00:00:00+05'::timestamp with time zone); diff --git a/lib/sql/test/CDB_DateToNumberTest_expect b/lib/sql/test/CDB_DateToNumberTest_expect new file mode 100644 index 0000000..bd3d3b0 --- /dev/null +++ b/lib/sql/test/CDB_DateToNumberTest_expect @@ -0,0 +1,2 @@ +915753600 +915735600 diff --git a/lib/sql/test/CDB_DigitSeparatorTest.sql b/lib/sql/test/CDB_DigitSeparatorTest.sql new file mode 100644 index 0000000..3c6cff7 --- /dev/null +++ b/lib/sql/test/CDB_DigitSeparatorTest.sql @@ -0,0 +1,39 @@ +BEGIN; +CREATE TEMP TABLE "_CDB_DigitSeparatorTest" ( + none text, + only_com_dec text, + only_dot_dec text, + only_com_tho text, + only_dot_tho text, + both_com_dec text, + both_dot_dec text, + "only_com_AMB" text, + "only_dot_AMB" text +); +COPY "_CDB_DigitSeparatorTest" FROM STDIN; +123456 123,1235 123.12345 1,234,231 1.234.234 1.234,23 1,234.23 1,123 1.123 +123456 123,12 123.12 231 234 1.121.234,230 3,111,234.230 123,123 123.123 +123456 123,12 123.12 231 234 1.121.234,2 3,111,234.230 123,123 123.123 +\. + +SELECT 'none', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'none'); +SELECT 'only_com_dec', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_dec'); +SELECT 'only_dot_dec', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_dec'); +SELECT 'only_com_tho', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_tho'); +SELECT 'only_dot_tho', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_tho'); +SELECT 'both_com_dec', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_com_dec'); +SELECT 'both_dot_dec', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_dot_dec'); +SELECT 'only_com_AMB', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_AMB'); +SELECT 'only_dot_AMB', * FROM + CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_AMB'); + +DROP TABLE "_CDB_DigitSeparatorTest"; +COMMIT; diff --git a/lib/sql/test/CDB_DigitSeparatorTest_expect b/lib/sql/test/CDB_DigitSeparatorTest_expect new file mode 100644 index 0000000..e7b3aea --- /dev/null +++ b/lib/sql/test/CDB_DigitSeparatorTest_expect @@ -0,0 +1,14 @@ +BEGIN +CREATE TABLE +COPY 3 +none|| +only_com_dec|.|, +only_dot_dec|,|. +only_com_tho|,|. +only_dot_tho|.|, +both_com_dec|.|, +both_dot_dec|,|. +only_com_AMB|| +only_dot_AMB|| +DROP TABLE +COMMIT diff --git a/lib/sql/test/CDB_DistTypeTest.sql b/lib/sql/test/CDB_DistTypeTest.sql new file mode 100644 index 0000000..efe1804 --- /dev/null +++ b/lib/sql/test/CDB_DistTypeTest.sql @@ -0,0 +1,4 @@ +WITH data AS ( + SELECT pow(x,3)::numeric x FROM generate_series(-100,100) x + ) +SELECT CDB_DistType(array_agg(x)) FROM data diff --git a/lib/sql/test/CDB_DistTypeTest_expect b/lib/sql/test/CDB_DistTypeTest_expect new file mode 100644 index 0000000..f70f10e --- /dev/null +++ b/lib/sql/test/CDB_DistTypeTest_expect @@ -0,0 +1 @@ +A diff --git a/lib/sql/test/CDB_DistinctMeasureTest.sql b/lib/sql/test/CDB_DistinctMeasureTest.sql new file mode 100644 index 0000000..1eb3a74 --- /dev/null +++ b/lib/sql/test/CDB_DistinctMeasureTest.sql @@ -0,0 +1,20 @@ +-- a - j add up to 89%, k-m add up to 11% +WITH a As ( + SELECT ( + repeat('a',12) || + repeat('b',11) || + repeat('c',11) || + repeat('d',10) || + repeat('e',10) || + repeat('f',9) || + repeat('g',8) || + repeat('h',7) || + repeat('i',6) || + repeat('j',5) || + repeat('k',4) || + repeat('l',4) || + repeat('m',3) + )::text AS x + ) + +SELECT CDB_DistinctMeasure(string_to_array(x,null),0.90) from a diff --git a/lib/sql/test/CDB_DistinctMeasureTest_expect b/lib/sql/test/CDB_DistinctMeasureTest_expect new file mode 100644 index 0000000..573541a --- /dev/null +++ b/lib/sql/test/CDB_DistinctMeasureTest_expect @@ -0,0 +1 @@ +0 diff --git a/lib/sql/test/CDB_EqualIntervalBinsTest.sql b/lib/sql/test/CDB_EqualIntervalBinsTest.sql new file mode 100644 index 0000000..eebd51e --- /dev/null +++ b/lib/sql/test/CDB_EqualIntervalBinsTest.sql @@ -0,0 +1,11 @@ +WITH data AS ( + SELECT array_agg(x::numeric) s FROM generate_series(1,300) x + WHERE x % 5 != 0 AND x % 7 != 0 + ) +SELECT round(unnest(CDB_EqualIntervalBins(s, 7)),7) FROM data; + +WITH data_nulls AS ( + SELECT array_agg(CASE WHEN x % 2 != 0 THEN x ELSE NULL END::numeric) s FROM generate_series(1,100) x + WHERE x % 5 != 0 AND x % 7 != 0 + ) +SELECT round(unnest(CDB_EqualIntervalBins(s, 7)),7) FROM data_nulls; diff --git a/lib/sql/test/CDB_EqualIntervalBinsTest_expect b/lib/sql/test/CDB_EqualIntervalBinsTest_expect new file mode 100644 index 0000000..9b724fa --- /dev/null +++ b/lib/sql/test/CDB_EqualIntervalBinsTest_expect @@ -0,0 +1,14 @@ +43.5714286 +86.1428571 +128.7142857 +171.2857143 +213.8571429 +256.4285714 +299.0000000 +15.0000000 +29.0000000 +43.0000000 +57.0000000 +71.0000000 +85.0000000 +99.0000000 diff --git a/lib/sql/test/CDB_EstimateRowCountTest.sql b/lib/sql/test/CDB_EstimateRowCountTest.sql new file mode 100644 index 0000000..4659bfa --- /dev/null +++ b/lib/sql/test/CDB_EstimateRowCountTest.sql @@ -0,0 +1,10 @@ +SET client_min_messages TO error; +\set VERBOSITY terse +CREATE TABLE tmptab1(id INT); +INSERT INTO tmptab1(id) VALUES (1), (2), (3); +CREATE TABLE tmptab2(id INT, value NUMERIC); +INSERT INTO tmptab2(id, value) VALUES (1, 10.0), (2, 20.0); +SELECT CDB_EstimateRowCount('SELECT SUM(value) FROM tmptab1 INNER JOIN tmptab2 ON (tmptab1.id = tmptab2.id);') AS row_count; +SELECT CDB_EstimateRowCount('UPDATE tmptab2 SET value = 30 WHERE id=2;') AS row_count; +DROP TABLE tmptab2; +DROP TABLE tmptab1; diff --git a/lib/sql/test/CDB_EstimateRowCountTest_expect b/lib/sql/test/CDB_EstimateRowCountTest_expect new file mode 100644 index 0000000..b5f3893 --- /dev/null +++ b/lib/sql/test/CDB_EstimateRowCountTest_expect @@ -0,0 +1,9 @@ +SET +CREATE TABLE +INSERT 0 3 +CREATE TABLE +INSERT 0 2 +1 +1 +DROP TABLE +DROP TABLE diff --git a/lib/sql/test/CDB_GhostTables.sql b/lib/sql/test/CDB_GhostTables.sql new file mode 100644 index 0000000..1741f01 --- /dev/null +++ b/lib/sql/test/CDB_GhostTables.sql @@ -0,0 +1,52 @@ +-- Create user and enable Ghost tables trigger +\set QUIET on +SET client_min_messages TO error; +SELECT CDB_EnableGhostTablesTrigger(); +CREATE ROLE "fulano" LOGIN; +GRANT ALL ON SCHEMA cartodb TO "fulano"; +GRANT SELECT ON cartodb.cdb_ddl_execution TO "fulano"; +GRANT EXECUTE ON FUNCTION CDB_Username() TO "fulano"; +GRANT EXECUTE ON FUNCTION CDB_LinkGhostTables(text) TO "fulano"; +SELECT cartodb.CDB_Conf_SetConf('api_keys_fulano', '{"username": "fulanito", "permissions":[]}'); +DELETE FROM cdb_conf WHERE key = 'invalidation_service'; +SET SESSION AUTHORIZATION "fulano"; +SET client_min_messages TO notice; +\set QUIET off + +SELECT CDB_LinkGhostTables(); -- _CDB_LinkGhostTables called (configuration not found) + +-- Add TIS configuration +\set QUIET on +SET SESSION AUTHORIZATION postgres; +SELECT cartodb.CDB_Conf_SetConf('invalidation_service', '{"host": "fake-tis-host", "port": 3142}'); +SET SESSION AUTHORIZATION "fulano"; +\set QUIET off + +SELECT CDB_LinkGhostTables(); -- _CDB_LinkGhostTables called + +BEGIN; +SELECT to_regclass('cartodb.cdb_ddl_execution'); -- exists +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 0 +CREATE TABLE tmp(id INT); +SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 1 +END; -- _CDB_LinkGhostTables called + +-- Disable Ghost tables trigger +\set QUIET on +SET SESSION AUTHORIZATION postgres; +SELECT CDB_DisableGhostTablesTrigger(); +SET SESSION AUTHORIZATION "fulano"; +\set QUIET off + +SELECT to_regclass('cartodb.cdb_ddl_execution'); -- not exists +DROP TABLE tmp; -- _CDB_LinkGhostTables not called + +-- Cleanup +\set QUIET on +SET SESSION AUTHORIZATION postgres; +REVOKE EXECUTE ON FUNCTION CDB_LinkGhostTables(text) FROM "fulano"; +REVOKE EXECUTE ON FUNCTION CDB_Username() FROM "fulano"; +REVOKE ALL ON SCHEMA cartodb FROM "fulano"; +DROP ROLE "fulano"; +DELETE FROM cdb_conf WHERE key = 'api_keys_fulano' OR key = 'invalidation_service'; +\set QUIET off diff --git a/lib/sql/test/CDB_GhostTables_expect b/lib/sql/test/CDB_GhostTables_expect new file mode 100644 index 0000000..01156f7 --- /dev/null +++ b/lib/sql/test/CDB_GhostTables_expect @@ -0,0 +1,20 @@ + + +WARNING: Invalidation service configuration not found. Skipping Ghost Tables linking. +NOTICE: _CDB_LinkGhostTables() called with username=fulanito, event_name=USER + + +WARNING: Error calling Invalidation Service to link Ghost Tables: Error -2 connecting fake-tis-host:3142. Name or service not known. +NOTICE: _CDB_LinkGhostTables() called with username=fulanito, event_name=USER + +BEGIN +cdb_ddl_execution +0 +CREATE TABLE +1 +WARNING: Error calling Invalidation Service to link Ghost Tables: Error -2 connecting fake-tis-host:3142. Name or service not known. +NOTICE: _CDB_LinkGhostTables() called with username=fulanito, event_name=CREATE TABLE +COMMIT + + +DROP TABLE diff --git a/lib/sql/test/CDB_GreatCircle.sql b/lib/sql/test/CDB_GreatCircle.sql new file mode 100644 index 0000000..32b9aa2 --- /dev/null +++ b/lib/sql/test/CDB_GreatCircle.sql @@ -0,0 +1,2 @@ +select ST_AsText(CDB_GreatCircle(CDB_LatLng(55.8580,4.2590), CDB_LatLng(40.7127,74.0059))); +select ST_AsText(CDB_GreatCircle(CDB_LatLng(55.8580,4.2590), CDB_LatLng(40.7127,74.0059), 50000)); diff --git a/lib/sql/test/CDB_GreatCircle_expect b/lib/sql/test/CDB_GreatCircle_expect new file mode 100644 index 0000000..8d7eb15 --- /dev/null +++ b/lib/sql/test/CDB_GreatCircle_expect @@ -0,0 +1,2 @@ +LINESTRING(4.259 55.858,5.53349240387128 56.0006659105918,6.81698919498694 56.130094578525,8.10870381314147 56.2461317260662,9.40781156033233 56.3486370295466,10.7134527044527 56.4374849223869,12.0247359780093 56.5125653297878,13.3407424424749 56.573784325367,14.660529681225 56.6210647008095,15.9831362768927 56.654346440595,17.307586522649 56.67358709506,18.6328953115992 56.6787620464102,19.9580731443722 56.6698646638042,21.282131192215 56.6469063452276,22.6040863516019 56.6099164455407,23.922966226566 56.5589420917603,25.2378139766594 56.4940478882858,26.5476929715805 56.4153155163602,27.8516911979552 56.3228432335229,29.1489253693643 56.2167452801302,30.4385446972665 56.0971512011646,31.7197342877491 55.9642050924945,32.9917181368037 55.8180647814723,34.2537617048216 55.6589009522625,35.5051740589896 55.4868962265697,36.7453095800251 55.3022442104976,37.9735692370026 55.1051485181267,39.1894014407465 54.8958217820713,40.3923024922398 54.6744846607816,41.5818166476476 54.4413648517294,42.757535825811 54.1966961188706,43.919098987406 53.9407173419567,45.0661912174019 53.673671594382,46.198542544017 53.3958052553427,47.3159265281308 53.1073671611612,48.4181586571351 52.8086077997244,49.5050945765883 52.499778551104,50.5766281918714 52.1811309766006,51.6326896704254 51.8529161576737,52.673243373185 51.5153840855177,53.6982857415906 51.1687831014009,54.7078431641625 50.8133593873253,55.7019698441171 50.4493565060761,56.6807456869812 50.0770149893128,57.6442742246566 49.6965719720156,58.5926805899637 49.3082608713202,59.5261095533829 48.9123111075629,60.4447236315382 48.5089478652008,61.3487012749643 48.0983918911668,62.2382351408597 47.6808593281578,63.1135304548766 47.2565615803358,63.9748034645285 46.8257052089336,64.822279985501 46.3884918552974,65.6561940410346 45.9451181889661,66.476786593589 45.4957758784676,67.284304367196 45.0406515826125,68.0789987582454 44.5799269601738,68.8611248319107 44.1137786959568,69.6309404010034 43.6423785413868,70.388705183725 43.1658933678633,71.1346800365587 42.6844852312539,71.8691262583921 42.1983114460249,72.5923049618788 41.7075246676227,73.3044765080245 41.2122729818388,74.0059 40.7127) +LINESTRING(4.259 55.858,4.89507305967085 55.930977446384,5.53349240387128 56.0006659105918,6.17416348361598 56.0670448594645,6.81698919498694 56.130094578525,7.46186995983655 56.1897961993418,8.10870381314147 56.2461317260662,8.75738649688733 56.2990840610623,9.40781156033233 56.3486370295466,10.0598704664666 56.3947754031591,10.7134527044527 56.4374849223869,11.3684459078018 56.4767523177655,12.0247359780093 56.5125653297878,12.6822072133468 56.5449127274491,13.3407424424749 56.573784325367,14.0002231625192 56.5991709994144,14.660529681225 56.6210647008095,15.3215412627822 56.6394584686143,15.9831362768927 56.654346440595,16.6451923506331 56.6657238624055,17.307586522649 56.67358709506,17.9701953992046 56.677933620668,18.6328953115992 56.6787620464102,19.2955624744544 56.6760721067401,19.9580731443722 56.6698646638042,20.6203037784591 56.6601417060788,21.282131192215 56.6469063452276,21.943432716288 56.6301628111935,22.6040863516019 56.6099164455407,23.2639709223762 56.5861736930735,23.922966226566 56.5589420917603,24.5809531832687 56.5282302610022,25.2378139766594 56.4940478882858,25.8934321960358 56.4564057142701,26.5476929715805 56.4153155163602,27.2004831054654 56.3707900908252,27.8516911979552 56.3228432335229,28.5012077681911 56.2714897192993,29.1489253693643 56.2167452801302,29.7947386980206 56.1586265820819,30.4385446972665 56.0971512011646,31.0802426536785 56.0323375981587,31.7197342877491 55.9642050924945,32.3569238377352 55.8927738352675,32.9917181368037 55.8180647814723,33.6240266834038 55.74009966154,34.2537617048216 55.6589009522625,34.8808382139074 55.5744918471876,35.5051740589896 55.4868962265697,36.1266899670207 55.3961386269571,36.7453095800251 55.3022442104976,37.3609594849451 55.2052387340427,37.9735692370026 55.1051485181267,38.5830713767178 55.0020004158976,39.1894014407465 54.8958217820713,39.7924979667135 54.7866404419798,40.3923024922398 54.6744846607816,40.9887595483734 54.5593831128969,41.5818166476476 54.4413648517294,42.1714242670021 54.3204592797319,42.757535825811 54.1966961188706,43.3401076592708 54.0701053815371,43.919098987406 53.9407173419567,44.4944718799548 53.8085625081347,45.0661912174019 53.673671594382,45.6342246484243 53.5360754944551,46.198542544017 53.3958052553427,46.7591179485663 53.2528920517295,47.3159265281308 53.1073671611612,47.8689465161932 52.9592619399335,48.4181586571351 52.8086077997244,48.9635461476859 52.6554361849853,49.5050945765883 52.499778551104,50.0427918627159 52.3416663433486,50.5766281918714 52.1811309766006,51.1065959524853 52.0182038158815,51.6326896704254 51.8529161576737,52.1549059431199 51.6852992120372,52.673243373185 51.5153840855177,53.1877025017413 51.3432017648431,53.6982857415906 51.1687831014009,54.2049973104167 50.9921587964881,54.7078431641625 50.8133593873253,55.2068309307272 50.6324152338211,55.7019698441171 50.4493565060761,56.1932706791714 50.2642131726125,56.6807456869812 50.0770149893128,57.1644085311015 49.8877914890534,57.6442742246566 49.6965719720156,58.1203590684218 49.5033854966561,58.5926805899637 49.3082608713202,59.0612574839055 49.1112266464775,59.5261095533829 48.9123111075629,59.9872576527434 48.7115422684016,60.4447236315382 48.5089478652008,60.8985302798459 48.3045553510865,61.3487012749643 48.0983918911668,61.7952611294973 47.8904843581013,62.2382351408597 47.6808593281578,62.6776493422177 47.4695430777354,63.1135304548766 47.2565615803358,63.5459058421237 47.0419405039633,63.9748034645285 46.8257052089336,64.4002518367009 46.6078807460742,64.822279985501 46.3884918552974,65.2409174096934 46.1675629645276,65.6561940410346 45.9451181889661,66.0681402067793 45.7211813306754,66.476786593589 45.4957758784676,66.8821642128236 45.2689250080781,67.284304367196 45.0406515826125,67.6832386187654 44.8109781532476,68.0789987582454 44.5799269601738,68.4716167756018 44.3475199337644,68.8611248319107 44.1137786959568,69.2475552324516 43.878724561833,69.6309404010034 43.6423785413868,70.0113128553159 43.4047613414637,70.388705183725 43.1658933678633,70.7631500228809 42.925794727592,71.1346800365587 42.6844852312539,71.5033278955199 42.4419843955718,71.8691262583921 42.1983114460249,72.2321077535378 41.953485319597,72.5923049618788 41.7075246676227,72.9497504006463 41.4604478587259,73.3044765080245 41.2122729818388,73.6565156286596 40.963017849297,74.0059 40.7127) diff --git a/lib/sql/test/CDB_HeadsTailsBinsTest.sql b/lib/sql/test/CDB_HeadsTailsBinsTest.sql new file mode 100644 index 0000000..1c71f7e --- /dev/null +++ b/lib/sql/test/CDB_HeadsTailsBinsTest.sql @@ -0,0 +1,11 @@ +WITH data AS ( + SELECT array_agg(x::numeric) s FROM generate_series(1,100) x + WHERE x % 5 != 0 AND x % 7 != 0 + ) +SELECT round(unnest(CDB_HeadsTailsBins(s, 7)),2) FROM data; + +WITH data_nulls AS ( + SELECT array_agg(CASE WHEN x % 2 != 0 THEN x ELSE NULL END::numeric) s FROM generate_series(1,100) x + WHERE x % 5 != 0 AND x % 7 != 0 + ) +SELECT round(unnest(CDB_HeadsTailsBins(s, 7)),2) FROM data_nulls; diff --git a/lib/sql/test/CDB_HeadsTailsBinsTest_expect b/lib/sql/test/CDB_HeadsTailsBinsTest_expect new file mode 100644 index 0000000..4c204d0 --- /dev/null +++ b/lib/sql/test/CDB_HeadsTailsBinsTest_expect @@ -0,0 +1,13 @@ +49.56 +74.44 +87.50 +93.50 +96.50 +98.00 +99.00 +49.76 +74.65 +88.50 +94.50 +98.00 +99.00 diff --git a/lib/sql/test/CDB_HelperTest.sql b/lib/sql/test/CDB_HelperTest.sql new file mode 100644 index 0000000..f33c2c7 --- /dev/null +++ b/lib/sql/test/CDB_HelperTest.sql @@ -0,0 +1,138 @@ +-- Test unique identifier creation with normal length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'relname', NULL); + +-- Test unique identifier creation with prefix with normal length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'relname', NULL); + +-- Test unique identifier creation with suffix with normal length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'relname', '_suffix'); + +-- Test unique identifier creation with long length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL); + +-- Test unique identifier creation with prefix with long length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL); + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE prefix_largolargolargolargolargolargolargolargolargolargola (name text); +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL); +DROP TABLE prefix_largolargolargolargolargolargolargolargolargolargola; + +-- Test unique identifier creation with suffix with long length normal relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', '_suffix'); + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE largolargolargolargolargolargolargolargolargolargola_suffix (name text); +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', '_suffix'); +DROP TABLE largolargolargolargolargolargolargolargolargolargola_suffix; + +-- Test unique identifier creation with normal length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'piraña', NULL); + +-- Test unique identifier creation with prefix with normal length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'piraña', NULL); + +-- Test unique identifier creation with suffix with normal length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'piraña', '_suffix'); + +-- Test unique identifier creation with long length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL); + +-- Test unique identifier creation with prefix with long length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL); + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi (name text); +SELECT * FROM cartodb._CDB_Unique_Identifier('prefix_', 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL); +DROP TABLE prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi; + +-- Test unique identifier creation with suffix with long length UTF8 relname +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', '_suffix'); + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix (name text); +SELECT * FROM cartodb._CDB_Unique_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', '_suffix'); +DROP TABLE piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix; + +CREATE TABLE test (name text); +-- Test unique identifier creation with normal length normal colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'colname', NULL, 'test'::regclass); + +-- Test unique identifier creation with prefix with normal length normal colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'colname', NULL, 'test'::regclass); + +-- Test unique identifier creation with suffix with normal length normal colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'colname', '_suffix', 'test'::regclass); + +-- Test unique identifier creation with long length normal colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL, 'test'::regclass); + +-- Test unique identifier creation with prefix with long length normal colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL, 'test'::regclass); +DROP TABLE test; + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE test (prefix_largolargolargolargolargolargolargolargolargolargola text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'largolargolargolargolargolargolargolargolargolargolargolargolar', NULL, 'test'::regclass); +DROP TABLE test; + +-- Test unique identifier creation with suffix with long length normal colname +CREATE TABLE test (name text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', '_suffix', 'test'::regclass); +DROP TABLE test; + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE test (largolargolargolargolargolargolargolargolargolargola_suffix text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'largolargolargolargolargolargolargolargolargolargolargolargolar', '_suffix', 'test'::regclass); +DROP TABLE test; + +CREATE TABLE test (name text); +-- Test unique identifier creation with normal length UTF8 colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'piraña', NULL, 'test'::regclass); + +-- Test unique identifier creation with prefix with normal length UTF8 colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'piraña', NULL, 'test'::regclass); + +-- Test unique identifier creation with suffix with normal length UTF8 colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'piraña', '_suffix', 'test'::regclass); + +-- Test unique identifier creation with long length UTF8 colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL, 'test'::regclass); + +-- Test unique identifier creation with prefix with long length UTF8 colname +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL, 'test'::regclass); +DROP TABLE test; + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE test (prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier('prefix_', 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', NULL, 'test'::regclass); +DROP TABLE test; + +-- Test unique identifier creation with suffix with long length UTF8 colname +CREATE TABLE test (name text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', '_suffix', 'test'::regclass); +DROP TABLE test; + +-- Test new identifier is found when name is taken from previous case +CREATE TABLE test (piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix text); +SELECT * FROM cartodb._CDB_Unique_Column_Identifier(NULL, 'piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaácidpin', '_suffix', 'test'::regclass); +DROP TABLE test; + +-- Test _CDB_Octet_Truncate simple case +SELECT * FROM cartodb._CDB_Octet_Truncate('piraña', 5); + +-- Test _CDB_Octet_Truncate UTF8 case +SELECT * FROM cartodb._CDB_Octet_Truncate('piraña', 6); + +-- Test _CDB_Octet_Truncate UTF8 case +SELECT * FROM cartodb._CDB_Octet_Truncate('piraña', 7); + +-- Test _CDB_Table_Exists +CREATE TABLE public.this_table_exists(); +SELECT cartodb._CDB_Table_Exists('this_table_does_not_exist'); +SELECT cartodb._CDB_Table_Exists('this_schema_does_not_exist.this_table_does_not_exist'); +SELECT cartodb._CDB_Table_Exists('this_table_exists'); +SELECT cartodb._CDB_Table_Exists('public.this_table_exists'); +SELECT cartodb._CDB_Table_Exists('raster_overviews'); -- view created by postgis +SELECT cartodb._CDB_Table_Exists('public.raster_overviews'); +DROP TABLE public.this_table_exists diff --git a/lib/sql/test/CDB_HelperTest_expect b/lib/sql/test/CDB_HelperTest_expect new file mode 100644 index 0000000..5ef82e5 --- /dev/null +++ b/lib/sql/test/CDB_HelperTest_expect @@ -0,0 +1,67 @@ +relname +prefix_relname +relname_suffix +largolargolargolargolargolargolargolargolargolargolargolarg +prefix_largolargolargolargolargolargolargolargolargolargola +CREATE TABLE +prefix_largolargolargolargolargolargolargolargolargolargola0 +DROP TABLE +largolargolargolargolargolargolargolargolargolargola_suffix +CREATE TABLE +largolargolargolargolargolargolargolargolargolargola_suffix0 +DROP TABLE +piraña +prefix_piraña +piraña_suffix +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaáci +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi +CREATE TABLE +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi0 +DROP TABLE +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix +CREATE TABLE +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix0 +DROP TABLE +CREATE TABLE +colname +prefix_colname +colname_suffix +largolargolargolargolargolargolargolargolargolargolargolarg +prefix_largolargolargolargolargolargolargolargolargolargola +DROP TABLE +CREATE TABLE +prefix_largolargolargolargolargolargolargolargolargolargola0 +DROP TABLE +CREATE TABLE +largolargolargolargolargolargolargolargolargolargola_suffix +DROP TABLE +CREATE TABLE +largolargolargolargolargolargolargolargolargolargola_suffix0 +DROP TABLE +CREATE TABLE +piraña +prefix_piraña +piraña_suffix +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaáci +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi +DROP TABLE +CREATE TABLE +prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi0 +DROP TABLE +CREATE TABLE +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix +DROP TABLE +CREATE TABLE +piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix0 +DROP TABLE +pira +pirañ +piraña +CREATE TABLE +f +f +t +t +f +f +DROP TABLE diff --git a/lib/sql/test/CDB_HexagonTest.sql b/lib/sql/test/CDB_HexagonTest.sql new file mode 100644 index 0000000..038540d --- /dev/null +++ b/lib/sql/test/CDB_HexagonTest.sql @@ -0,0 +1,56 @@ +set client_min_messages to error; +\set VERBOSITY TERSE + +-- Check correctness of an hexagons grid +-- +-- Cells must have no overlaps and have a number of +-- intersections with other cells between 2 and 6 +-- + +WITH + params AS ( SELECT ST_MakeEnvelope(10, 10, 20, 20) as env, 2 as radius ), + grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params), + igrid AS ( SELECT row_number() over (), cell from grid ) + + SELECT count(row_number) as r1, sum(st_npoints(cell)) as r2, 'count / npoints' as err + FROM igrid g1 + +UNION ALL + + SELECT g1.row_number as r1, g2.row_number as r2, 'overlap' as err + FROM igrid g1, igrid g2 + WHERE g2.row_number > g1.row_number AND + ST_Overlaps(g1.cell, g2.cell) + +UNION ALL + + SELECT g1.row_number, count(g2.row_number) as r2, 'n intersections' as err + FROM igrid g1, igrid g2 + WHERE g1.row_number != g2.row_number AND + ST_Intersects(g1.cell, g2.cell) + GROUP BY g1.row_number + HAVING count(g2.row_number) > 6 OR count(g2.row_number) < 2 + +UNION ALL + + SELECT g1.row_number, null::integer, 'centroid out of extent' as err + FROM igrid g1, params + WHERE NOT ST_Intersects(ST_Centroid(g1.cell), params.env) + + ; + + +-- Check robustness of HexagonGrid generation + +WITH + params AS ( SELECT + ST_MakeEnvelope(-20037508.5,20037507,-20037508,20037507.5) as env, + 0.002 as radius ), + grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params) +SELECT '#160', count(cell) > 23000 from grid; + +-- Check small grids are generated... +SELECT COUNT(*) FROM cartodb.CDB_HexagonGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 10); + +-- But large grids produce an error +SELECT COUNT(*) FROM cartodb.CDB_HexagonGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 1); diff --git a/lib/sql/test/CDB_HexagonTest_expect b/lib/sql/test/CDB_HexagonTest_expect new file mode 100644 index 0000000..42c7fec --- /dev/null +++ b/lib/sql/test/CDB_HexagonTest_expect @@ -0,0 +1,5 @@ +SET +9|63|count / npoints +#160|t +3886 +ERROR: The requested grid is too big to be rendered diff --git a/lib/sql/test/CDB_JenksBinsTest.sql b/lib/sql/test/CDB_JenksBinsTest.sql new file mode 100644 index 0000000..8b55b0b --- /dev/null +++ b/lib/sql/test/CDB_JenksBinsTest.sql @@ -0,0 +1,36 @@ +WITH data AS ( + SELECT Array[0.99, 1.0, 1.01, + 4.99, 5.01, + 10.01, 10.01, + 15.01, 14.99, + 20.1, 19.9]::numeric[] AS s +) +SELECT unnest(CDB_JenksBins(s, 5)) FROM data; + + +WITH data_nulls AS ( + SELECT Array[0.99, 1.0, 1.01, + 4.99, 5.01, + null, null, + 10.01, 10.01, + 15.01, 14.99, + null, null, + 20.1, 19.9]::numeric[] AS s +) +SELECT unnest(CDB_JenksBins(s, 5)) FROM data_nulls; + + +WITH data_inverse AS ( + SELECT Array[0.99, 1.0, 1.01, + 4.99, 5.01, + 10.01, 10.01, + 15.01, 14.99, + 20.1, 19.9]::numeric[] AS s +) +SELECT unnest(CDB_JenksBins(s, 5, 0, true)) FROM data_inverse; + + +WITH data_small AS ( + SELECT Array[0.99, 1.0, 10.01, 10.01, 10.01, 10.01]::numeric[] AS s +) +SELECT unnest(CDB_JenksBins(s, 4)) FROM data_small; diff --git a/lib/sql/test/CDB_JenksBinsTest_expect b/lib/sql/test/CDB_JenksBinsTest_expect new file mode 100644 index 0000000..0dfaa43 --- /dev/null +++ b/lib/sql/test/CDB_JenksBinsTest_expect @@ -0,0 +1,18 @@ +1.01 +5.01 +10.01 +15.01 +20.1 +1.01 +5.01 +10.01 +15.01 +20.1 +0.99 +4.99 +10.01 +14.99 +19.9 +0.99 +1.0 +10.01 diff --git a/lib/sql/test/CDB_MathTest.sql b/lib/sql/test/CDB_MathTest.sql new file mode 100644 index 0000000..5a6d752 --- /dev/null +++ b/lib/sql/test/CDB_MathTest.sql @@ -0,0 +1,4 @@ + +SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,2,3]) a; +SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,3]) a; +SELECT cdb_math_mode(a) from unnest(ARRAY[1]) a; diff --git a/lib/sql/test/CDB_MathTest_expect b/lib/sql/test/CDB_MathTest_expect new file mode 100644 index 0000000..afe234b --- /dev/null +++ b/lib/sql/test/CDB_MathTest_expect @@ -0,0 +1,3 @@ +2 +1 +1 diff --git a/lib/sql/test/CDB_OverviewsTest.sql b/lib/sql/test/CDB_OverviewsTest.sql new file mode 100644 index 0000000..71b427f --- /dev/null +++ b/lib/sql/test/CDB_OverviewsTest.sql @@ -0,0 +1,44 @@ +SET client_min_messages TO error; +\set VERBOSITY default + +\i test/overviews/fixtures.sql +vacuum ANALYZE; -- Make sure there are metrics for ST_EstimatedExtent + +SELECT _CDB_Aggregable_Attributes_Expression('base_bare_t'::regclass); +SELECT _CDB_Aggregated_Attributes_Expression('base_bare_t'::regclass); +SELECT _CDB_Aggregated_Attributes_Expression('base_bare_t'::regclass, 'tab'); + +SELECT CDB_CreateOverviews('base_bare_t'::regclass); +SELECT count(*) FROM _vovw_2_base_bare_t; + + +SELECT _CDB_Aggregable_Attributes_Expression('base_t'::regclass); +SELECT _CDB_Aggregated_Attributes_Expression('base_t'::regclass); +SELECT _CDB_Aggregated_Attributes_Expression('base_t'::regclass, 'tab'); + +SELECT CDB_CreateOverviews('base_t'::regclass); +SELECT count(*) FROM _vovw_2_base_t; + +SELECT CDB_CreateOverviews('polyg_t'::regclass); + +SELECT CDB_CreateOverviews('column_types_t'::regclass); + +SELECT CDB_Overviews('base_t'::regclass); +SELECT CDB_Overviews('"public"."base_t"'::regclass); +SELECT CDB_Overviews(ARRAY['base_t'::regclass, 'base_bare_t'::regclass]); +SELECT CDB_Overviews('polyg_t'::regclass); +SELECT CDB_Overviews('column_types_t'::regclass); + +SELECT CDB_DropOverviews('column_types_t'::regclass); +SELECT CDB_DropOverviews('base_bare_t'::regclass); +SELECT CDB_DropOverviews('base_t'::regclass); +SELECT count(*) FROM _vovw_2_base_t; + +SELECT CDB_CreateOverviewsWithToleranceInPixels('base_t'::regclass, 7.5); +SELECT count(*) FROM _vovw_2_base_t; +SELECT CDB_DropOverviews('base_t'::regclass); + +DROP TABLE column_types_t; +DROP TABLE base_bare_t; +DROP TABLE base_t; +DROP TABLE polyg_t; diff --git a/lib/sql/test/CDB_OverviewsTest_expect b/lib/sql/test/CDB_OverviewsTest_expect new file mode 100644 index 0000000..4d7e979 --- /dev/null +++ b/lib/sql/test/CDB_OverviewsTest_expect @@ -0,0 +1,49 @@ +SET +CREATE TABLE +INSERT 0 1114 +CREATE TABLE +INSERT 0 1114 +CREATE TABLE +INSERT 0 5 +SELECT 1114 +VACUUM + + + +{_vovw_2_base_bare_t,_vovw_1_base_bare_t,_vovw_0_base_bare_t} +126 +number,int_number,name,start +SUM(number*1)/count(*)::double precision AS number,SUM(int_number*1)/count(*)::integer AS int_number,CASE WHEN count(distinct name) = 1 THEN MIN(name) WHEN count(*) < 5 THEN string_agg(distinct name,' / ') ELSE '*' END::text AS name,CASE count(*) WHEN 1 THEN MIN(start) ELSE NULL END::date AS start +SUM(tab.number*1)/count(*)::double precision AS number,SUM(tab.int_number*1)/count(*)::integer AS int_number,CASE WHEN count(distinct tab.name) = 1 THEN MIN(tab.name) WHEN count(*) < 5 THEN string_agg(distinct tab.name,' / ') ELSE '*' END::text AS name,CASE count(*) WHEN 1 THEN MIN(tab.start) ELSE NULL END::date AS start +{_vovw_2_base_t,_vovw_1_base_t,_vovw_0_base_t} +126 + +{_vovw_2_column_types_t,_vovw_1_column_types_t,_vovw_0_column_types_t} +(base_t,0,_vovw_0_base_t) +(base_t,1,_vovw_1_base_t) +(base_t,2,_vovw_2_base_t) +(base_t,0,_vovw_0_base_t) +(base_t,1,_vovw_1_base_t) +(base_t,2,_vovw_2_base_t) +(base_bare_t,0,_vovw_0_base_bare_t) +(base_bare_t,1,_vovw_1_base_bare_t) +(base_bare_t,2,_vovw_2_base_bare_t) +(base_t,0,_vovw_0_base_t) +(base_t,1,_vovw_1_base_t) +(base_t,2,_vovw_2_base_t) +(column_types_t,0,_vovw_0_column_types_t) +(column_types_t,1,_vovw_1_column_types_t) +(column_types_t,2,_vovw_2_column_types_t) + + + +ERROR: relation "_vovw_2_base_t" does not exist +LINE 1: SELECT count(*) FROM _vovw_2_base_t; + ^ +{_vovw_5_base_t,_vovw_4_base_t,_vovw_3_base_t,_vovw_2_base_t,_vovw_1_base_t,_vovw_0_base_t} +38 + +DROP TABLE +DROP TABLE +DROP TABLE +DROP TABLE diff --git a/lib/sql/test/CDB_QuantileBinsTest.sql b/lib/sql/test/CDB_QuantileBinsTest.sql new file mode 100644 index 0000000..342122d --- /dev/null +++ b/lib/sql/test/CDB_QuantileBinsTest.sql @@ -0,0 +1,17 @@ +WITH data AS ( + SELECT array_agg(x::numeric) AS s + FROM generate_series(0, 99) AS x + ) +SELECT unnest(CDB_QuantileBins(s, 10)) + FROM data; + +WITH data_nulls AS ( + SELECT array_agg(x::numeric) AS s + FROM ( + SELECT x FROM generate_series(0, 99) AS x + UNION ALL + SELECT null AS x FROM generate_series(1, 10) AS x + ) _wrap + ) +SELECT unnest(CDB_QuantileBins(s, 10)) + FROM data_nulls; diff --git a/lib/sql/test/CDB_QuantileBinsTest_expect b/lib/sql/test/CDB_QuantileBinsTest_expect new file mode 100644 index 0000000..fbb4b0e --- /dev/null +++ b/lib/sql/test/CDB_QuantileBinsTest_expect @@ -0,0 +1,20 @@ +9 +19 +29 +39 +49 +59 +69 +79 +89 +99 +9 +19 +29 +39 +49 +59 +69 +79 +89 +99 diff --git a/lib/sql/test/CDB_QueryStatementsTest.sql b/lib/sql/test/CDB_QueryStatementsTest.sql new file mode 100644 index 0000000..e85bc2a --- /dev/null +++ b/lib/sql/test/CDB_QueryStatementsTest.sql @@ -0,0 +1,66 @@ +SET client_min_messages TO error; +\set VERBOSITY terse + +WITH q AS ( SELECT CDB_QueryStatements(' +SELECT * FROM geometry_columns; +') as statement ) +SELECT '1', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements(' +SELECT * FROM geometry_columns +') as statement ) +SELECT '2', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements(' +;;;SELECT * FROM geometry_columns +') as statement ) +SELECT '3', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +CREATE table "my'tab;le" ("$" int); +SELECT '1','$$', '$hello$', "$" FROM "my'tab;le"; +CREATE function "hi'there" ("'" text default '$') returns void as $h$ declare a int; b text; begin b='hi'; return; end; $h$ language 'plpgsql'; +SELECT 5; +$the_param$) as statement ) +SELECT '4', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +INSER INTO "my''""t" values ('''','""'';;'); +SELECT $qu;oted$ hi $qu;oted$; +$the_param$) as statement ) +SELECT '5', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +SELECT +1 ; SELECT +2 +$the_param$) as statement ) +SELECT '6', row_number() over (), statement FROM q; + +-- This is an insane input, illegal sql +-- we are really only testing that it does not +-- take forever to process.. +-- The actual result is not correct, so if the function +-- ever gets fixed check if it's better +WITH q AS ( SELECT CDB_QueryStatements($the_param$ + + + + + + + + + /a + $b$ + $c$d + ; +$the_param$) as statement ) +SELECT '7', row_number() over (), statement FROM q; + + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +SELECT $quoted$ hi +$quoted$; +$the_param$) as statement ) +SELECT '8', row_number() over (), statement FROM q; diff --git a/lib/sql/test/CDB_QueryStatementsTest_expect b/lib/sql/test/CDB_QueryStatementsTest_expect new file mode 100644 index 0000000..085e3eb --- /dev/null +++ b/lib/sql/test/CDB_QueryStatementsTest_expect @@ -0,0 +1,20 @@ +SET +1|1|SELECT * FROM geometry_columns +2|1|SELECT * FROM geometry_columns +3|1|SELECT * FROM geometry_columns +4|1|CREATE table "my'tab;le" ("$" int) +4|2|SELECT '1','$$', '$hello$', "$" FROM "my'tab;le" +4|3|CREATE function "hi'there" ("'" text default '$') returns void as $h$ declare a int; b text; begin b='hi'; return; end; $h$ language 'plpgsql' +4|4|SELECT 5 +5|1|INSER INTO "my''""t" values ('''','""'';;') +5|2|SELECT $qu;oted$ hi $qu;oted$ +6|1|SELECT +1 +6|2|SELECT +2 +7|1|/a +7|2|b +7|3|c +7|4|d +8|1|SELECT $quoted$ hi +$quoted$ diff --git a/lib/sql/test/CDB_QueryTablesTest.sql b/lib/sql/test/CDB_QueryTablesTest.sql new file mode 100644 index 0000000..101bf57 --- /dev/null +++ b/lib/sql/test/CDB_QueryTablesTest.sql @@ -0,0 +1,41 @@ +SET client_min_messages TO warning; +\set VERBOSITY terse + +WITH inp AS ( select 'SELECT * FROM geometry_columns'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select $quote$CREATE table "my'tab;le" as select 1$quote$::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'SELECT a.oid, b.oid FROM pg_class a, pg_class b'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'SELECT 1 as col1; select 2 as col2'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'select 1 from nonexistant'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'begin; select * from pg_class; commit;'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'create table test (a int); insert into test values (1); select * from test;'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +WITH inp AS ( select 'WITH a AS (select * from pg_class) select * from a'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; + +CREATE SCHEMA sc; +create table sc.test (a int); +insert into sc.test values (1); +WITH inp AS ( select 'select * from sc.test'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; +DROP TABLE sc.test; +DROP SCHEMA sc; + +WITH inp AS ( select 'SELECT +* FROM geometry_columns'::text as q ) + SELECT q, CDB_QueryTables(q) from inp; diff --git a/lib/sql/test/CDB_QueryTablesTest_expect b/lib/sql/test/CDB_QueryTablesTest_expect new file mode 100644 index 0000000..417b988 --- /dev/null +++ b/lib/sql/test/CDB_QueryTablesTest_expect @@ -0,0 +1,20 @@ +SET +SELECT * FROM geometry_columns|{pg_catalog.pg_attribute,pg_catalog.pg_class,pg_catalog.pg_constraint,pg_catalog.pg_namespace,pg_catalog.pg_type} +SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)|{pg_catalog.pg_attribute,pg_catalog.pg_class} +CREATE table "my'tab;le" as select 1|{} +SELECT a.oid, b.oid FROM pg_class a, pg_class b|{pg_catalog.pg_class} +SELECT 1 as col1; select 2 as col2|{} +WARNING: CDB_QueryTables cannot explain query: select 1 from nonexistant (42P01: relation "nonexistant" does not exist) +ERROR: relation "nonexistant" does not exist +begin; select * from pg_class; commit;|{pg_catalog.pg_class} +WARNING: CDB_QueryTables cannot explain query: insert into test values (1) (42P01: relation "test" does not exist) +ERROR: relation "test" does not exist +WITH a AS (select * from pg_class) select * from a|{pg_catalog.pg_class} +CREATE SCHEMA +CREATE TABLE +INSERT 0 1 +select * from sc.test|{sc.test} +DROP TABLE +DROP SCHEMA +SELECT +* FROM geometry_columns|{pg_catalog.pg_attribute,pg_catalog.pg_class,pg_catalog.pg_constraint,pg_catalog.pg_namespace,pg_catalog.pg_type} diff --git a/lib/sql/test/CDB_QuotaTest.sql b/lib/sql/test/CDB_QuotaTest.sql new file mode 100644 index 0000000..92b65d1 --- /dev/null +++ b/lib/sql/test/CDB_QuotaTest.sql @@ -0,0 +1,47 @@ +set client_min_messages to error; +\set VERBOSITY TERSE + +-- See the dice +SELECT setseed(0.5); + +CREATE TABLE big(a int); +-- Try the legacy interface +-- See https://github.com/CartoDB/cartodb-postgresql/issues/13 +CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big + EXECUTE PROCEDURE CDB_CheckQuota(1, 1, 'public'); +INSERT INTO big VALUES (1); -- allowed, check runs before +INSERT INTO big VALUES (2); -- disallowed, quota exceeds before +SELECT CDB_SetUserQuotaInBytes(0); +SELECT CDB_CartodbfyTable('big'); +INSERT INTO big SELECT generate_series(2049,4096); +INSERT INTO big SELECT generate_series(4097,6144); +INSERT INTO big SELECT generate_series(6145,8192); +-- Test for #108: https://github.com/CartoDB/cartodb-postgresql/issues/108 +SELECT CDB_UserDataSize(); +SELECT cartodb._CDB_total_relation_size('public', 'big'); +SELECT cartodb._CDB_total_relation_size('public', 'nonexistent_table_name'); +-- END Test for #108 +SELECT setseed(0.9); +SELECT CDB_SetUserQuotaInBytes(2); +INSERT INTO big VALUES (8193); +SELECT CDB_SetUserQuotaInBytes(0); +INSERT INTO big VALUES (8194); +DROP TABLE big; + + +--analysis tables should be excluded from quota: +CREATE TABLE big(a int); +CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big + EXECUTE PROCEDURE CDB_CheckQuota(1, 1, 'public'); +SELECT CDB_SetUserQuotaInBytes(1); +CREATE TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4(id int); +INSERT INTO analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4(id) VALUES (1),(2),(3),(4),(5); +INSERT INTO big VALUES (1); -- allowed, check runs before +DROP TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4; +INSERT INTO big VALUES (2); -- disallowed, quota exceeds before +DROP TABLE big; +SELECT CDB_SetUserQuotaInBytes(0); + + +set client_min_messages to NOTICE; +DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/lib/sql/test/CDB_QuotaTest_expect b/lib/sql/test/CDB_QuotaTest_expect new file mode 100644 index 0000000..9204514 --- /dev/null +++ b/lib/sql/test/CDB_QuotaTest_expect @@ -0,0 +1,32 @@ +SET + +CREATE TABLE +CREATE TRIGGER +INSERT 0 1 +ERROR: Quota exceeded by 3.9990234375KB +0 +big +INSERT 0 2048 +INSERT 0 2048 +INSERT 0 2048 +454656 +909312 +0 + +2 +ERROR: Quota exceeded by 443.998046875KB +0 +INSERT 0 1 +DROP TABLE +CREATE TABLE +CREATE TRIGGER +1 +CREATE TABLE +INSERT 0 5 +INSERT 0 1 +DROP TABLE +ERROR: Quota exceeded by 3.9990234375KB +DROP TABLE +0 +SET +DROP FUNCTION diff --git a/lib/sql/test/CDB_RectangleTest.sql b/lib/sql/test/CDB_RectangleTest.sql new file mode 100644 index 0000000..a16b7fa --- /dev/null +++ b/lib/sql/test/CDB_RectangleTest.sql @@ -0,0 +1,8 @@ +set client_min_messages to error; +\set VERBOSITY TERSE + +-- Check small grids are generated... +SELECT COUNT(*) FROM cartodb.CDB_RectangleGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 10, 10); + +-- But large grids produce an error +SELECT COUNT(*) FROM cartodb.CDB_RectangleGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 1, 1); diff --git a/lib/sql/test/CDB_RectangleTest_expect b/lib/sql/test/CDB_RectangleTest_expect new file mode 100644 index 0000000..cc1c961 --- /dev/null +++ b/lib/sql/test/CDB_RectangleTest_expect @@ -0,0 +1,3 @@ +SET +10000 +ERROR: The requested grid is too big to be rendered diff --git a/lib/sql/test/CDB_StatsTest.sql b/lib/sql/test/CDB_StatsTest.sql new file mode 100644 index 0000000..1ba6f94 --- /dev/null +++ b/lib/sql/test/CDB_StatsTest.sql @@ -0,0 +1,13 @@ +-- continuous uniform distribution has kurtosis = -6/5, skewness = 0.0 +-- http://mathworld.wolfram.com/UniformDistribution.html +set client_min_messages to ERROR; + +WITH dist AS ( + SELECT generate_series(0,10000)::numeric / 10000.0 i +) +SELECT + abs(CDB_Kurtosis(array_agg(i)) + 1.2) < 1e-3 AS kurtosis, + abs(CDB_Skewness(array_agg(i))) < 1e-3 AS skewness +FROM dist; + +set client_min_messages to NOTICE; diff --git a/lib/sql/test/CDB_StatsTest_expect b/lib/sql/test/CDB_StatsTest_expect new file mode 100644 index 0000000..fdc125d --- /dev/null +++ b/lib/sql/test/CDB_StatsTest_expect @@ -0,0 +1,3 @@ +SET +t|t +SET diff --git a/lib/sql/test/CDB_SyncTableTest.sql b/lib/sql/test/CDB_SyncTableTest.sql new file mode 100644 index 0000000..fc2711e --- /dev/null +++ b/lib/sql/test/CDB_SyncTableTest.sql @@ -0,0 +1,94 @@ +-- Setup: create and populate a table to test the syncs +\set QUIET on +BEGIN; +SET client_min_messages TO error; +CREATE TABLE test_sync_source ( + cartodb_id bigint, + lat double precision, + lon double precision, + name text +); +INSERT INTO test_sync_source VALUES + (1, 1.0, 1.0, 'foo'), + (2, 2.0, 2.0, 'bar'), + (3, 3.0, 3.0, 'patata'), + (4, 4.0, 4.0, 'melon'); +SET client_min_messages TO notice; +\set QUIET off + + +\echo 'First table sync: it should be simply just copied to the destination' +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); + +\echo 'Next table sync: there shall be no changes' +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); + +\echo 'Remove a row from the source and check it is deleted from the dest table' +DELETE FROM test_sync_source WHERE cartodb_id = 3; +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); + +\echo 'Insert a new row and check that it is inserted in the dest table' +INSERT INTO test_sync_source VALUES (5, 5.0, 5.0, 'sandia'); +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); + +\echo 'Modify row and check that it is modified in the dest table' +UPDATE test_sync_source SET name = 'cantaloupe' WHERE cartodb_id = 4; +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); + +\echo 'Sanity check: the end result is the same source table' +SELECT * FROM test_sync_source ORDER BY cartodb_id; +SELECT * FROM test_sync_dest ORDER BY cartodb_id; + + +\echo 'It shall exclude geom columns if instructed to do so' +\set QUIET on +SET client_min_messages TO error; +SELECT cartodb.CDB_SetUserQuotaInBytes(0); -- Set user quota to infinite +SELECT cartodb.CDB_CartodbfyTable('test_sync_source'); +SELECT cartodb.CDB_CartodbfyTable('test_sync_dest'); +UPDATE test_sync_dest SET the_geom = cartodb.CDB_LatLng(lat, lon); -- A "gecoding" +\set QUIET off +SET client_min_messages TO notice; +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest', '{the_geom, the_geom_webmercator}'); +SELECT * FROM test_sync_source ORDER BY cartodb_id; +SELECT * FROM test_sync_dest ORDER BY cartodb_id; + +\echo 'It will work with schemas that need quoting' +\set QUIET on +SET client_min_messages TO error; +CREATE SCHEMA "sch-ema"; +CREATE TABLE "test_sync_source2" AS SELECT * FROM test_sync_source; +\set QUIET off +SELECT cartodb.CDB_SyncTable('test_sync_source2', 'sch-ema', 'test_sync_dest'); +INSERT INTO test_sync_source2(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); +DELETE FROM test_sync_source2 WHERE cartodb_id = 4; +UPDATE test_sync_source2 SET lat = 2.5 WHERE cartodb_id = 2; +SET client_min_messages TO notice; +SELECT cartodb.CDB_SyncTable('test_sync_source2', 'sch-ema', 'test_sync_dest'); + +\echo 'It will work with table names that need quoting' +\set QUIET on +SET client_min_messages TO error; +CREATE TABLE "test-sync-source" AS SELECT * FROM test_sync_source; +\set QUIET off +SELECT cartodb.CDB_SyncTable('test-sync-source', 'public', 'test-sync-dest'); +INSERT INTO "test-sync-source"(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); +DELETE FROM "test-sync-source" WHERE cartodb_id = 4; +UPDATE "test-sync-source" SET lat = 2.5 WHERE cartodb_id = 2; +SET client_min_messages TO notice; +SELECT cartodb.CDB_SyncTable('test-sync-source', 'public', 'test-sync-dest'); + +\echo 'It will work with column names that need quoting' +\set QUIET on +SET client_min_messages TO error; +ALTER TABLE test_sync_source ADD COLUMN "a-column" int; +\set QUIET off +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest2'); +INSERT INTO test_sync_source(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); +DELETE FROM test_sync_source WHERE cartodb_id = 4; +UPDATE test_sync_source SET lat = 2.5 WHERE cartodb_id = 2; +SET client_min_messages TO notice; +SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest2'); + +-- Cleanup +ROLLBACK; diff --git a/lib/sql/test/CDB_SyncTableTest_expect b/lib/sql/test/CDB_SyncTableTest_expect new file mode 100644 index 0000000..01cb358 --- /dev/null +++ b/lib/sql/test/CDB_SyncTableTest_expect @@ -0,0 +1,94 @@ +First table sync: it should be simply just copied to the destination +NOTICE: INSERTED 4 row(s) + +Next table sync: there shall be no changes +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: DELETED 0 row(s) +NOTICE: INSERTED 0 row(s) +NOTICE: MODIFIED 0 row(s) + +Remove a row from the source and check it is deleted from the dest table +DELETE 1 +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: DELETED 1 row(s) +NOTICE: INSERTED 0 row(s) +NOTICE: MODIFIED 0 row(s) + +Insert a new row and check that it is inserted in the dest table +INSERT 0 1 +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: DELETED 0 row(s) +NOTICE: INSERTED 1 row(s) +NOTICE: MODIFIED 0 row(s) + +Modify row and check that it is modified in the dest table +UPDATE 1 +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: DELETED 0 row(s) +NOTICE: INSERTED 0 row(s) +NOTICE: MODIFIED 1 row(s) + +Sanity check: the end result is the same source table +1|1|1|foo +2|2|2|bar +4|4|4|cantaloupe +5|5|5|sandia +1|1|1|foo +2|2|2|bar +4|4|4|cantaloupe +5|5|5|sandia +It shall exclude geom columns if instructed to do so +0 +test_sync_source +test_sync_dest +SET +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called +NOTICE: DELETED 0 row(s) +NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called +NOTICE: INSERTED 0 row(s) +NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called +NOTICE: MODIFIED 0 row(s) + +1|||1|1|foo +2|||2|2|bar +4|||4|4|cantaloupe +5|||5|5|sandia +1|0101000020E6100000000000000000F03F000000000000F03F|0101000020110F0000DB0B4ADA772DFB402B432E49D22DFB40|1|1|foo +2|0101000020E610000000000000000000400000000000000040|0101000020110F00003C0C4ADA772D0B4177F404ABE12E0B41|2|2|bar +4|0101000020E610000000000000000010400000000000001040|0101000020110F00003C0C4ADA772D1B4160AB497020331B41|4|4|cantaloupe +5|0101000020E610000000000000000014400000000000001440|0101000020110F000099476EE86AFC20413E7EB983F2012141|5|5|sandia +It will work with schemas that need quoting + +INSERT 0 1 +DELETE 1 +UPDATE 1 +SET +NOTICE: relation "test_sync_dest" already exists, skipping +NOTICE: DELETED 1 row(s) +NOTICE: INSERTED 1 row(s) +NOTICE: MODIFIED 1 row(s) + +It will work with table names that need quoting + +INSERT 0 1 +DELETE 1 +UPDATE 1 +SET +NOTICE: relation "test-sync-dest" already exists, skipping +NOTICE: DELETED 1 row(s) +NOTICE: INSERTED 1 row(s) +NOTICE: MODIFIED 1 row(s) + +It will work with column names that need quoting + +INSERT 0 1 +DELETE 1 +UPDATE 1 +SET +NOTICE: relation "test_sync_dest2" already exists, skipping +NOTICE: DELETED 1 row(s) +NOTICE: INSERTED 1 row(s) +NOTICE: MODIFIED 1 row(s) + +ROLLBACK diff --git a/lib/sql/test/CDB_TransformToWebmercatorTest.sql b/lib/sql/test/CDB_TransformToWebmercatorTest.sql new file mode 100644 index 0000000..2d349f6 --- /dev/null +++ b/lib/sql/test/CDB_TransformToWebmercatorTest.sql @@ -0,0 +1,28 @@ +BEGIN; +SET client_min_messages TO error; + +-- Run psql with -tA switches and expect +-- CDB_TransformToWebmercatorTest_expect +select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;LINESTRING(90 90, 0 80)'), 1)); +select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;LINESTRING(90 90, 0 90)'), 1)); +select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;POINT(0 90)'), 1)); +select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1)); +select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTIPOINT(10 3)'), 1)); +select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1)); +select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;POINT(5 3)'), 1)); +-- See https://github.com/Vizzuality/cartodb/issues/901 +select '8', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;POLYGON((100 0, -100 -100, 100 -100, -100 0, 100 00))'), 1)); +-- See https://github.com/Vizzuality/cartodb/issues/931 +select '9', CDB_TransformToWebmercator( + '0106000020E61000000100000001030000000100000007000000010000000000F87F9CDFD01E32095341010000000000F87F193B6F0A30095341010000000000F87FA10FBF4C1D095341010000000000F87F38E258111C095341010000000000F87F5196BAFF17095341010000000000F87F4F0550911B095341010000000000F87F9CDFD01E32095341'::geometry); +-- Already in webmercator, doun't touch, even if out of valid bounds +select '10', ST_AsEWKT(CDB_TransformToWebmercator('SRID=3857;POINT(-20037510 -30240972)'::geometry)); +END; diff --git a/lib/sql/test/CDB_TransformToWebmercatorTest_expect b/lib/sql/test/CDB_TransformToWebmercatorTest_expect new file mode 100644 index 0000000..0d83617 --- /dev/null +++ b/lib/sql/test/CDB_TransformToWebmercatorTest_expect @@ -0,0 +1,13 @@ +BEGIN +SET +1|SRID=3857;LINESTRING(9016879 30240972,0 15538711) +2| +3| +4|SRID=3857;MULTIPOINT(0 445640,1113195 334111) +5|SRID=3857;MULTIPOINT(1113195 334111) +6|SRID=3857;MULTILINESTRING((0 445640,-445278 557305)) +7|SRID=3857;POINT(556597 334111) +8|SRID=3857;MULTIPOLYGON(((0 -6446276,8682920 -30240972,-8682920 -30240972,0 -6446276)),((11131949 0,0 -6446276,-11131949 0,11131949 0))) +9| +10|SRID=3857;POINT(-20037510 -30240972) +COMMIT diff --git a/lib/sql/test/CDB_UserTablesTest.sql b/lib/sql/test/CDB_UserTablesTest.sql new file mode 100644 index 0000000..3e16c1b --- /dev/null +++ b/lib/sql/test/CDB_UserTablesTest.sql @@ -0,0 +1,32 @@ +SET client_min_messages TO ERROR; +DO +$do$ +BEGIN + IF NOT EXISTS ( + SELECT * + FROM pg_catalog.pg_user + WHERE usename = 'publicuser') THEN + + CREATE ROLE publicuser LOGIN; + END IF; +END +$do$; +SET client_min_messages TO NOTICE; + +CREATE TABLE pub(a int); +CREATE TABLE prv(a int); +GRANT SELECT ON TABLE pub TO publicuser; +REVOKE SELECT ON TABLE prv FROM publicuser; +SELECT CDB_UserTables() ORDER BY 1; +SELECT 'all',CDB_UserTables('all') ORDER BY 2; +SELECT 'public',CDB_UserTables('public') ORDER BY 2; +SELECT 'private',CDB_UserTables('private') ORDER BY 2; +SELECT '--unsupported--',CDB_UserTables('--unsupported--') ORDER BY 2; +-- now tests with public user +\c contrib_regression publicuser +SELECT 'all_publicuser',CDB_UserTables('all') ORDER BY 2; +SELECT 'public_publicuser',CDB_UserTables('public') ORDER BY 2; +SELECT 'private_publicuser',CDB_UserTables('private') ORDER BY 2; +\c contrib_regression postgres +DROP TABLE pub; +DROP TABLE prv; diff --git a/lib/sql/test/CDB_UserTablesTest_expect b/lib/sql/test/CDB_UserTablesTest_expect new file mode 100644 index 0000000..dc7fc63 --- /dev/null +++ b/lib/sql/test/CDB_UserTablesTest_expect @@ -0,0 +1,19 @@ +SET +DO +SET +CREATE TABLE +CREATE TABLE +GRANT +REVOKE +prv +pub +all|prv +all|pub +public|pub +private|prv +You are now connected to database "contrib_regression" as user "publicuser". +all_publicuser|pub +public_publicuser|pub +You are now connected to database "contrib_regression" as user "postgres". +DROP TABLE +DROP TABLE diff --git a/lib/sql/test/CDB_Username.sql b/lib/sql/test/CDB_Username.sql new file mode 100644 index 0000000..55bd01c --- /dev/null +++ b/lib/sql/test/CDB_Username.sql @@ -0,0 +1,23 @@ +SELECT session_user; -- postgres +SELECT CDB_Username(); -- (NULL) + +-- Add the role fulano with api_key and connect with it +\set QUIET on +CREATE ROLE fulano LOGIN; +GRANT USAGE ON SCHEMA cartodb TO fulano; +GRANT EXECUTE ON FUNCTION CDB_Username() TO fulano; +INSERT INTO cdb_conf (key, value) VALUES ('api_keys_fulano', '{"username": "fulanito", "permissions":[]}'); +SET SESSION AUTHORIZATION fulano; +\set QUIET off + +SELECT session_user; -- fulano +SELECT CDB_Username(); -- fulanito + +-- Remove fulano +\set QUIET on +SET SESSION AUTHORIZATION postgres; +REVOKE USAGE ON SCHEMA cartodb FROM fulano; +REVOKE EXECUTE ON FUNCTION CDB_Username() FROM fulano; +DROP ROLE fulano; +DELETE FROM cdb_conf WHERE key = 'api_keys_fulano'; +\set QUIET off \ No newline at end of file diff --git a/lib/sql/test/CDB_Username_expect b/lib/sql/test/CDB_Username_expect new file mode 100644 index 0000000..fe1ea5b --- /dev/null +++ b/lib/sql/test/CDB_Username_expect @@ -0,0 +1,4 @@ +postgres + +fulano +fulanito diff --git a/lib/sql/test/CDB_XYZ_ExtentTest.sql b/lib/sql/test/CDB_XYZ_ExtentTest.sql new file mode 100644 index 0000000..6f080fe --- /dev/null +++ b/lib/sql/test/CDB_XYZ_ExtentTest.sql @@ -0,0 +1,9 @@ + +WITH zoom AS ( select generate_series(0,2) as Z ), +range AS ( select z, generate_series(0, pow(2,z)::int-1) as r FROM zoom), +inp AS ( select z0.z, r1.r as x, r2.r as y FROM zoom z0, range r1, range r2 WHERE z0.z = r1.z and r1.z = r2.z ), +ext AS ( select x,y,z,CDB_XYZ_Extent(x,y,z) as g from inp ) +select X::text || ',' || Y::text || ',' || Z::text as xyz, + round(st_xmin(g)), round(st_xmax(g)), round(st_ymin(g)), round(st_ymax(g)) + from ext order by xyz; + diff --git a/lib/sql/test/CDB_XYZ_ExtentTest_expect b/lib/sql/test/CDB_XYZ_ExtentTest_expect new file mode 100644 index 0000000..3e83e69 --- /dev/null +++ b/lib/sql/test/CDB_XYZ_ExtentTest_expect @@ -0,0 +1,21 @@ +0,0,0|-20037508|20037508|-20037508|20037508 +0,0,1|-20037508|0|0|20037508 +0,0,2|-20037508|-10018754|10018754|20037508 +0,1,1|-20037508|0|-20037508|0 +0,1,2|-20037508|-10018754|0|10018754 +0,2,2|-20037508|-10018754|-10018754|0 +0,3,2|-20037508|-10018754|-20037508|-10018754 +1,0,1|0|20037508|0|20037508 +1,0,2|-10018754|0|10018754|20037508 +1,1,1|0|20037508|-20037508|0 +1,1,2|-10018754|0|0|10018754 +1,2,2|-10018754|0|-10018754|0 +1,3,2|-10018754|0|-20037508|-10018754 +2,0,2|0|10018754|10018754|20037508 +2,1,2|0|10018754|0|10018754 +2,2,2|0|10018754|-10018754|0 +2,3,2|0|10018754|-20037508|-10018754 +3,0,2|10018754|20037508|10018754|20037508 +3,1,2|10018754|20037508|0|10018754 +3,2,2|10018754|20037508|-10018754|0 +3,3,2|10018754|20037508|-20037508|-10018754 diff --git a/lib/sql/test/Makefile b/lib/sql/test/Makefile new file mode 100644 index 0000000..95c8cb8 --- /dev/null +++ b/lib/sql/test/Makefile @@ -0,0 +1,5 @@ +all: + @echo "Try make check" + +check: + bundle exec rspec ../../../spec/lib/sql_test_spec.rb diff --git a/lib/sql/test/README b/lib/sql/test/README new file mode 100644 index 0000000..6dcf328 --- /dev/null +++ b/lib/sql/test/README @@ -0,0 +1,15 @@ +Adding tests consists in adding 2 files in this directory: one file +containing the sql code and another containing the expected output. + +Example, to add a test for CDB_Something function, you'd add: + + - CDB_SomethingTest.sql + - CDB_SomethingTest_expect + +To easy the generation of the expected file you can initially omit it, +then run "make -C .. installcheck" from the top-level dir and copy +../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping +off the first line: + + make -C .. installcheck + tail -n +2 ../results/test/CDB_SomethingTest.out > CDB_SomethingTest_expect diff --git a/lib/sql/test/extension/test.sh b/lib/sql/test/extension/test.sh new file mode 100755 index 0000000..1d9e7ee --- /dev/null +++ b/lib/sql/test/extension/test.sh @@ -0,0 +1,615 @@ +#!/bin/sh + +# +# Tests for the extension since version 0.5.0. They don't replace SQL based ones, for now need to run both +# + +# It is expected that you run this script as a PostgreSQL superuser, for example: +# +# PGUSER=postgres bash ./test.sh +# + +DATABASE=test_extension +CMD='echo psql' +CMD=psql +SED=sed + +OK=0 +PARTIALOK=0 + +function set_failed() { + OK=1 + PARTIALOK=1 +} + + +function clear_partial_result() { + PARTIALOK=0 +} + + +function sql() { + local ROLE + local QUERY + if [[ $# -ge 2 ]] + then + ROLE="$1" + QUERY="$2" + else + QUERY="$1" + fi + + if [ -n "${ROLE}" ]; then + log_debug "Executing query '${QUERY}' as ${ROLE}" + RESULT=`${CMD} -U "${ROLE}" ${DATABASE} -c "${QUERY}" -A -t` + else + log_debug "Executing query '${QUERY}'" + RESULT=`${CMD} ${DATABASE} -c "${QUERY}" -A -t` + fi + CODERESULT=$? + + echo ${RESULT} + echo + + if [[ ${CODERESULT} -ne 0 ]] + then + echo -n "FAILED TO EXECUTE QUERY: " + log_warning "${QUERY}" + if [[ "$3" != "fails" ]] + then + log_error "${QUERY}" + set_failed + fi + else + if [[ "$3" == "fails" ]] + then + log_error "QUERY: '${QUERY}' was expected to fail and it did not fail" + set_failed + fi + fi + + if [[ "$3" == "should" ]] + then + if [[ "${RESULT}" != "$4" ]] + then + log_error "QUERY '${QUERY}' expected result '${4}' but got '${RESULT}'" + set_failed + fi + fi + + if [[ "$3" == "should-not" ]] + then + if [[ "${RESULT}" == "$4" ]] + then + log_error "QUERY '${QUERY}' did not expect '${RESULT}'" + set_failed + fi + fi +} + + +function log_info() +{ + echo + echo + echo + _log "1;34m" "$1" +} + +function log_error() { + _log "1;31m" "$1" +} + +function log_debug() { + _log "1;32m" "> $1" +} + +function log_warning() { + _log "0;33m" "$1" +} + +function _log() { + echo -e "\033[$1$2\033[0m" +} + +# '############################ HELPERS #############################' +function create_role_and_schema() { + local ROLE=$1 + sql "CREATE ROLE ${ROLE} LOGIN;" + sql "GRANT CONNECT ON DATABASE \"${DATABASE}\" TO ${ROLE};" + sql "CREATE SCHEMA ${ROLE} AUTHORIZATION ${ROLE};" + sql "GRANT USAGE ON SCHEMA cartodb TO ${ROLE};" + sql "SELECT cartodb.CDB_Organization_Create_Member('${ROLE}');" + sql "ALTER ROLE ${ROLE} SET search_path TO ${ROLE},cartodb,public;" +} + + +function drop_role_and_schema() { + local ROLE=$1 + sql "REVOKE USAGE ON SCHEMA cartodb FROM ${ROLE};" + sql "DROP SCHEMA \"${ROLE}\" CASCADE;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM \"${ROLE}\";" + sql "DROP ROLE \"${ROLE}\";" +} + + +function create_table() { + if [[ $# -ne 2 ]] + then + log_error "create_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + sql ${ROLE} "CREATE TABLE ${ROLE}.${TABLENAME} ( a int );" +} + + +function create_raster_table() { + if [[ $# -ne 2 ]] + then + log_error "create_raster_table requires two arguments: role and table_name" + exit 1 + fi + local RASTER_COL="the_raster_webmercator" + local ROLE="$1" + local TABLENAME="$2" + local OVERVIEW_TABLENAME="o_2_${TABLENAME}" + sql ${ROLE} "CREATE TABLE ${ROLE}.${TABLENAME} (rid serial PRIMARY KEY, ${RASTER_COL} raster);" + + sql ${ROLE} "CREATE TABLE ${ROLE}.${OVERVIEW_TABLENAME} (rid serial PRIMARY KEY, ${RASTER_COL} raster);" + + sql ${ROLE} "SELECT AddOverviewConstraints('${ROLE}','${OVERVIEW_TABLENAME}','${RASTER_COL}','${ROLE}','${TABLENAME}','${RASTER_COL}',2);" +} + +function drop_raster_table() { + if [[ $# -ne 2 ]] + then + log_error "drop_raster_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + local OVERVIEW_TABLENAME="o_2_${TABLENAME}" + + sql ${ROLE} "DROP TABLE ${ROLE}.${OVERVIEW_TABLENAME};" + sql ${ROLE} "DROP TABLE ${ROLE}.${TABLENAME};" +} + +function setup_database() { + ${CMD} -c "CREATE DATABASE ${DATABASE}" + sql "CREATE EXTENSION postgis;" + sql postgres "DO +\$\$ +BEGIN + IF substring(postgis_lib_version() FROM 1 FOR 1) = '3' THEN + CREATE EXTENSION postgis_raster; + END IF; +END +\$\$;" + sql "CREATE EXTENSION cartodb CASCADE;" + ${CMD} -c "ALTER DATABASE ${DATABASE} SET search_path = public, cartodb;" +} + +function setup() { + setup_database + + log_info "############################# SETUP #############################" + create_role_and_schema cdb_testmember_1 + create_role_and_schema cdb_testmember_2 + + create_table cdb_testmember_1 foo + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (1), (2), (3), (4), (5), (6);' + sql cdb_testmember_1 'SELECT * FROM cdb_testmember_1.foo;' + + create_table cdb_testmember_2 bar + sql cdb_testmember_2 'INSERT INTO bar VALUES (1), (2), (3);' + sql cdb_testmember_2 'SELECT * FROM cdb_testmember_2.bar;' +} + + +function tear_down_database() { + ${CMD} -c "DROP DATABASE ${DATABASE}" +} +function tear_down() { + log_info "########################### USER TEAR DOWN ###########################" + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2');" + sql cdb_testmember_2 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_2', 'bar', 'cdb_testmember_1');" + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.foo;' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.bar;' + + sql "DROP SCHEMA cartodb CASCADE" + + log_info "########################### TEAR DOWN ###########################" + sql 'DROP SCHEMA cdb_testmember_1 CASCADE;' + sql 'DROP SCHEMA cdb_testmember_2 CASCADE;' + + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_1;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_2;" + + sql 'DROP ROLE cdb_testmember_1;' + sql 'DROP ROLE cdb_testmember_2;' + + tear_down_database +} + + +function run_tests() { + local FAILED_TESTS=() + + local TESTS + if [[ $# -ge 1 ]] + then + if [[ $# -eq 1 ]] + then + TESTS=`cat $0 | grep -o "$1[^\(]*"` + else + TESTS="$@" + fi + else + TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'` + fi + setup + for t in ${TESTS} + do + echo "####################################################################" + echo "#" + echo "# Running: ${t}" + echo "#" + echo "####################################################################" + + clear_partial_result + eval ${t} + if [[ ${PARTIALOK} -ne 0 ]] + then + FAILED_TESTS+=(${t}) + fi + done + tear_down + if [[ ${OK} -ne 0 ]] + then + echo + log_error "The following tests are failing:" + printf -- '\t%s\n' "${FAILED_TESTS[@]}" + fi +} + + +#################################################### TESTS GO HERE #################################################### + + +# Tests quota checking taking into account both geom and raster tables +function test_quota_for_each_user() { + # Normal tables add 4096 bytes + # Raster tables no longer add anything so also count as 4096 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 4096 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 4096 + + create_raster_table cdb_testmember_1 raster_1 + create_raster_table cdb_testmember_2 raster_2 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 20480 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 20480 + + create_raster_table cdb_testmember_1 raster_3 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 36864 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 20480 + + drop_raster_table cdb_testmember_1 raster_1 + drop_raster_table cdb_testmember_2 raster_2 + drop_raster_table cdb_testmember_1 raster_3 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 4096 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 4096 +} + +function test_cdb_tablemetadatatouch() { + sql postgres "CREATE TABLE touch_example (a int)" + sql postgres "SELECT updated_at FROM CDB_TableMetadata WHERE tabname = 'touch_example'::regclass;" should '' + sql postgres "SELECT CDB_TableMetadataTouch('touch_example');" + sql postgres "SELECT updated_at FROM CDB_TableMetadata WHERE tabname = 'touch_example'::regclass;" should-not '' + + # Another call doesn't fail + sql postgres "SELECT CDB_TableMetadataTouch('touch_example');" + sql postgres "SELECT updated_at FROM CDB_TableMetadata WHERE tabname = 'touch_example'::regclass;" should-not '' + + # Works with qualified tables + sql postgres "SELECT CDB_TableMetadataTouch('public.touch_example');" + sql postgres "SELECT CDB_TableMetadataTouch('public.\"touch_example\"');" + sql postgres "SELECT CDB_TableMetadataTouch('\"public\".touch_example');" + sql postgres "SELECT CDB_TableMetadataTouch('\"public\".\"touch_example\"');" + + # Works with OID + sql postgres "SELECT tabname from CDB_TableMetadata;" should 'touch_example' + sql postgres "SELECT count(*) from CDB_TableMetadata;" should 1 + TABLE_OID=`${CMD} -U postgres ${DATABASE} -c "SELECT attrelid FROM pg_attribute WHERE attrelid = 'touch_example'::regclass limit 1;" -A -t` + + # quoted OID works + sql postgres "SELECT CDB_TableMetadataTouch('${TABLE_OID}');" + sql postgres "SELECT tabname from CDB_TableMetadata;" should 'touch_example' + sql postgres "SELECT count(*) from CDB_TableMetadata;" should 1 + + # non quoted OID works + sql postgres "SELECT CDB_TableMetadataTouch(${TABLE_OID});" + sql postgres "SELECT tabname from CDB_TableMetadata;" should 'touch_example' + sql postgres "SELECT count(*) from CDB_TableMetadata;" should 1 + + #### test tear down + sql postgres 'DROP TABLE touch_example;' +} + +function test_cdb_tablemetadatatouch_fails_for_unexistent_table() { + sql cdb_testmember_1 "SELECT CDB_TableMetadataTouch('unexistent_example');" fails +} + +function test_cdb_tablemetadatatouch_fails_from_user_without_permission() { + sql postgres "CREATE TABLE touch_example (a int);" + sql postgres "SELECT CDB_TableMetadataTouch('touch_example');" + + sql cdb_testmember_1 "SELECT CDB_TableMetadataTouch('touch_example');" fails + + sql postgres "GRANT ALL ON CDB_TableMetadata TO cdb_testmember_1;" + sql cdb_testmember_1 "SELECT CDB_TableMetadataTouch('touch_example');" + + sql postgres "REVOKE ALL ON CDB_TableMetadata FROM cdb_testmember_1;" + + #### test tear down + sql postgres 'DROP TABLE touch_example;' +} + +function test_cdb_tablemetadatatouch_fully_qualifies_names() { + sql postgres "CREATE TABLE touch_invalidations (table_name text);" + sql postgres "create or replace function cartodb.cdb_invalidate_varnish(table_name text) returns void as \$\$ begin insert into touch_invalidations select table_name; end; \$\$ language 'plpgsql';" + + #default schema + sql "CREATE TABLE touch_example (a int);" + sql postgres "SELECT CDB_TableMetadataTouch('touch_example');" + sql postgres "SELECT table_name FROM touch_invalidations" should "public.touch_example" + sql postgres "TRUNCATE TABLE touch_invalidations" + sql postgres "DROP TABLE touch_example" + + #setup different schema + sql postgres "CREATE SCHEMA test_schema;" + sql postgres "CREATE TABLE test_schema.touch_example (a int);" + + #different schema outside search_path + sql postgres "SELECT CDB_TableMetadataTouch('test_schema.touch_example');" + sql postgres "SELECT table_name FROM touch_invalidations" should "test_schema.touch_example" + sql postgres "TRUNCATE TABLE touch_invalidations" + + #different schema in default search_path + sql postgres "SET search_path=test_schema,public,cartodb; SELECT CDB_TableMetadataTouch('test_schema.touch_example');" + sql postgres "SELECT table_name FROM touch_invalidations" should "test_schema.touch_example" + sql postgres "TRUNCATE TABLE touch_invalidations" + + #teardown different schema + sql postgres 'DROP TABLE test_schema.touch_example;' + sql postgres 'DROP SCHEMA test_schema;' + + + + sql postgres 'DROP FUNCTION cartodb.cdb_invalidate_varnish(table_name text);' + sql postgres 'DROP TABLE touch_invalidations' +} + +function test_cdb_tablemetadata_text() { + + #create and touch tables + sql postgres "CREATE TABLE touch_ex_a (id int);" + sql postgres "CREATE TABLE touch_ex_b (id int);" + sql postgres "CREATE TABLE touch_ex_c (id int);" + sql postgres "SELECT CDB_TableMetadataTouch('touch_ex_a');" + sql postgres "SELECT CDB_TableMetadataTouch('touch_ex_b');" + sql postgres "SELECT CDB_TableMetadataTouch('touch_ex_c');" + + #ensure there is 1 record per table + QUERY="SELECT COUNT(1) FROM (SELECT 1 FROM cdb_tablemetadata_text " + QUERY+="GROUP BY tabname HAVING COUNT(1) > 1) s;" + sql postgres "$QUERY" should "0" + + #ensure timestamps are distinct and properly ordered + QUERY="SELECT (SELECT updated_at FROM CDB_TableMetadata_Text WHERE tabname='public.touch_ex_a')" + QUERY+=" < (SELECT updated_at FROM CDB_TableMetadata_Text WHERE tabname='public.touch_ex_b');" + sql postgres "$QUERY" should "t" + QUERY="SELECT (SELECT updated_at FROM CDB_TableMetadata_Text WHERE tabname='public.touch_ex_b')" + QUERY+=" < (SELECT updated_at FROM CDB_TableMetadata_Text WHERE tabname='public.touch_ex_c');" + sql postgres "$QUERY" should "t" + + #cleanup + sql postgres "DROP TABLE touch_ex_a;" + sql postgres "DROP TABLE touch_ex_b;" + sql postgres "DROP TABLE touch_ex_c;" + +} + +function test_cdb_column_names() { + sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_cnames(c int, a int, r int, t int, o int);' + sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_cnames(d int, b int);' + + sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "carto" + sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "db" + + sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames'::regclass) c) as s" should "carto" + sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_2.table_cnames') c) as s" should "db" + + # Using schema from owner + sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" should "carto" + + ## it's not possible to get column names from a table where you don't have permissions + sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" fails + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_cnames' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_cnames' +} + +function test_cdb_column_type() { + sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_ctype(c int, a int, r int, t int, o int);' + sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_ctype(c text, a text, r text, t text, o text);' + + sql cdb_testmember_1 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "integer" + sql cdb_testmember_2 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "text" + + sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_1.table_ctype', 'c')" should "integer" + sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_2.table_ctype', 'c')" should "text" + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_ctype' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_ctype' +} + +function test_cdb_querytables_schema_and_table_names_with_dots() { + sql postgres 'CREATE SCHEMA "foo.bar";' + sql postgres 'CREATE TABLE "foo.bar"."c.a.r.t.o.d.b" (a int);' + sql postgres 'INSERT INTO "foo.bar"."c.a.r.t.o.d.b" values (1);' + sql postgres 'SELECT a FROM "foo.bar"."c.a.r.t.o.d.b";' should 1 + + sql postgres 'SELECT CDB_QueryTablesText($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}' + sql postgres 'SELECT CDB_QueryTables($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}' + + sql postgres 'DROP TABLE "foo.bar"."c.a.r.t.o.d.b";' + sql postgres 'DROP SCHEMA "foo.bar";' +} + +function test_cdb_querytables_table_name_with_dots() { + sql postgres 'CREATE TABLE "w.a.d.u.s" (a int);'; + + sql postgres 'SELECT CDB_QueryTablesText($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}' + sql postgres 'SELECT CDB_QueryTables($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}' + + sql postgres 'DROP TABLE "w.a.d.u.s";'; +} + +function test_cdb_querytables_happy_cases() { + sql postgres 'CREATE TABLE wadus (a int);'; + sql postgres 'CREATE TABLE "FOOBAR" (a int);'; + sql postgres 'CREATE SCHEMA foo;' + sql postgres 'CREATE TABLE foo.wadus (a int);'; + + ## See how it does NOT quote anything here + sql postgres 'SELECT CDB_QueryTablesText($q$select * from wadus$q$);' should '{public.wadus}' + sql postgres 'SELECT CDB_QueryTablesText($q$select * from foo.wadus$q$);' should '{foo.wadus}' + sql postgres 'SELECT CDB_QueryTables($q$select * from wadus$q$);' should '{public.wadus}' + sql postgres 'SELECT CDB_QueryTables($q$select * from foo.wadus$q$);' should '{foo.wadus}' + + ## But it quotes when it's needed even if table name has no dots but was created with quotes + sql postgres 'SELECT CDB_QueryTablesText($q$select * from "FOOBAR"$q$);' should '{"public.\"FOOBAR\""}' + + sql postgres 'DROP TABLE wadus;' + sql postgres 'DROP TABLE "FOOBAR";' + sql postgres 'DROP TABLE foo.wadus;' + sql postgres 'DROP SCHEMA foo;' +} + +function test_foreign_tables() { + + DATABASE=fdw_target setup_database + DATABASE=fdw_target sql postgres "DO +\$\$ +BEGIN + IF NOT EXISTS ( + SELECT * + FROM pg_catalog.pg_user + WHERE usename = 'publicuser') THEN + + CREATE ROLE publicuser LOGIN; + END IF; +END +\$\$;" + + DATABASE=fdw_target sql postgres 'CREATE SCHEMA test_fdw;' + DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.foo (a int);' + DATABASE=fdw_target sql postgres 'INSERT INTO test_fdw.foo (a) values (42);' + DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.foo2 (a int);' + DATABASE=fdw_target sql postgres 'INSERT INTO test_fdw.foo2 (a) values (42);' + DATABASE=fdw_target sql postgres "CREATE USER fdw_user WITH PASSWORD 'foobarino';" + DATABASE=fdw_target sql postgres 'GRANT USAGE ON SCHEMA test_fdw TO fdw_user;' + DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.foo TO fdw_user;' + DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.foo2 TO fdw_user;' + DATABASE=fdw_target sql postgres 'GRANT SELECT ON cdb_tablemetadata_text TO fdw_user;' + + DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo'::regclass);" + DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo2'::regclass);" + + # Add PGPORT to conf if it is set + PORT_SPEC="" + if [[ "$PGPORT" != "" ]] ; then + PORT_SPEC=", \"port\": \"$PGPORT\"" + fi + sql postgres "SELECT cartodb.CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\" $PORT_SPEC }, + \"users\": {\"public\": {\"user\": \"fdw_user\", \"password\": \"foobarino\"}}}}')" + + sql postgres "SELECT cartodb._CDB_Setup_FDW('test_fdw')" + + sql postgres "SELECT cartodb.CDB_Add_Remote_Table('test_fdw', 'foo')" + sql postgres "SELECT * from test_fdw.foo;" + + + sql postgres "SELECT n.nspname, + c.relname, + s.srvname FROM pg_catalog.pg_foreign_table ft + INNER JOIN pg_catalog.pg_class c ON c.oid = ft.ftrelid + INNER JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + INNER JOIN pg_catalog.pg_foreign_server s ON s.oid = ft.ftserver +ORDER BY 1, 2" should "test_fdw|cdb_tablemetadata|test_fdw +test_fdw|foo|test_fdw" + + sql postgres "SELECT cartodb.CDB_Get_Foreign_Updated_At('test_fdw.foo'::regclass) < NOW()" should 't' + + sql postgres "SELECT a from test_fdw.foo LIMIT 1;" should 42 + + # Check function CDB_QueryTables_Updated_At + sql postgres 'CREATE TABLE local (b int);' + sql postgres 'INSERT INTO local (b) VALUES (43);' + sql postgres "SELECT cdb_tablemetadatatouch('public.local'::regclass);" + local query='$query$ SELECT * FROM test_fdw.foo, local $query$::text' + sql postgres "SELECT dbname, schema_name, table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) ORDER BY dbname;" should 'fdw_target|test_fdw|foo +test_extension|public|local' + sql postgres "SELECT table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) order by updated_at;" should 'foo +local' + + # Check function CDB_Last_Updated_Time + sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) < now()" should 't' + sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) > (now() - interval '1 minute')" should 't' + + # Check we quote names on output as needed (as CDB_QueryTablesText does) + sql postgres 'CREATE TABLE "local-table-with-dashes" (c int)'; + sql postgres 'INSERT INTO "local-table-with-dashes" (c) VALUES (44)'; + sql postgres "SELECT cdb_tablemetadatatouch('public.local-table-with-dashes'::regclass);" + query='$query$ SELECT * FROM test_fdw.foo, local, public."local-table-with-dashes" $query$::text' + sql postgres "SELECT dbname, schema_name, table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) ORDER BY dbname, schema_name, table_name;" should 'fdw_target|test_fdw|foo +test_extension|public|local +test_extension|public|"local-table-with-dashes"' + + # Check CDB_Last_Updated_Time supports quoted identifiers + sql postgres "SELECT cartodb.CDB_Last_Updated_Time(ARRAY['test_extension.public.\"local-table-with-dashes\"']::text[]) < now()" should 't' + sql postgres "SELECT cartodb.CDB_Last_Updated_Time(ARRAY['test_extension.public.\"local-table-with-dashes\"']::text[]) > (now() - interval '1 minute')" should 't' + + # Check CDB_Get_Foreign_Updated_At is robust to unimported CDB_TableMetadata + sql postgres "DROP FOREIGN TABLE IF EXISTS test_fdw.cdb_tablemetadata;" + sql postgres "SELECT cartodb.CDB_Get_Foreign_Updated_At('test_fdw.foo') IS NULL" should 't' + + # Teardown + DATABASE=fdw_target sql postgres 'REVOKE USAGE ON SCHEMA test_fdw FROM fdw_user;' + DATABASE=fdw_target sql postgres 'REVOKE SELECT ON test_fdw.foo FROM fdw_user;' + DATABASE=fdw_target sql postgres 'REVOKE SELECT ON test_fdw.foo2 FROM fdw_user;' + DATABASE=fdw_target sql postgres 'REVOKE SELECT ON cdb_tablemetadata_text FROM fdw_user;' + DATABASE=fdw_target sql postgres 'DROP ROLE fdw_user;' + + sql postgres "select pg_terminate_backend(pid) from pg_stat_activity where datname='fdw_target';" + DATABASE=fdw_target tear_down_database +} + +function test_cdb_catalog_basic_node() { + DEF="'{\"type\":\"buffer\",\"source\":\"b2db66bc7ac02e135fd20bbfef0fdd81b2d15fad\",\"radio\":10000}'" + sql postgres "INSERT INTO cartodb.cdb_analysis_catalog (node_id, analysis_def) VALUES ('1bbc4c41ea7c9d3a7dc1509727f698b7', ${DEF}::json)" + sql postgres "SELECT status from cartodb.cdb_analysis_catalog where node_id = '1bbc4c41ea7c9d3a7dc1509727f698b7'" should 'pending' + sql postgres "DELETE FROM cartodb.cdb_analysis_catalog" +} + +#################################################### TESTS END HERE #################################################### + +run_tests $@ + +exit ${OK} diff --git a/lib/sql/test/organization/test.sh b/lib/sql/test/organization/test.sh new file mode 100644 index 0000000..9d3c5de --- /dev/null +++ b/lib/sql/test/organization/test.sh @@ -0,0 +1,631 @@ +#!/bin/sh + +# +# It is expected that you run this script +# as a PostgreSQL superuser, for example: +# +# PGUSER=postgres bash ./test.sh +# + +DATABASE=test_organizations +CMD=psql +SED=sed + +OK=0 +PARTIALOK=0 + +function set_failed() { + OK=1 + PARTIALOK=1 +} + + +function clear_partial_result() { + PARTIALOK=0 +} + +function sql() { + local ROLE + local QUERY + ERROR_OUTPUT_FILE='/tmp/test_error.log' + if [[ $# -ge 2 ]] + then + ROLE="$1" + QUERY="$2" + else + QUERY="$1" + fi + + if [ -n "${ROLE}" ]; then + log_debug "Executing query '${QUERY}' as ${ROLE}" + RESULT=`${CMD} -U "${ROLE}" ${DATABASE} -c "${QUERY}" -A -t 2>"${ERROR_OUTPUT_FILE}"` + else + log_debug "Executing query '${QUERY}'" + RESULT=`${CMD} ${DATABASE} -c "${QUERY}" -A -t 2>"${ERROR_OUTPUT_FILE}"` + fi + CODERESULT=$? + ERROR_OUTPUT=`cat "${ERROR_OUTPUT_FILE}"` + rm ${ERROR_OUTPUT_FILE} + + echo -n "> Code Result: " + echo -n ${CODERESULT} + echo -n "; Result: " + echo -n ${RESULT} + echo -n "; Error output: " + echo -n ${ERROR_OUTPUT} + + # Some warnings should actually be failures + if [[ ${CODERESULT} == "0" ]] + then + case "${ERROR_OUTPUT}" in + WARNING:*no*privileges*were*granted*for*) + echo -n "FAILED BECAUSE OF PRIVILEGES GRANTING WARNING" + CODERESULT=1 + ;; + WARNING:*no*privileges*could*be*revoked*for*) + echo -n "FAILED BECAUSE OF PRIVILEGES REVOKING WARNING" + CODERESULT=1 + ;; + *) ;; + esac + echo -n "; Code result after warnings: " + echo -n ${CODERESULT} + fi + echo + + if [[ ${CODERESULT} -ne 0 ]] + then + echo -n "FAILED TO EXECUTE QUERY: " + log_warning "${QUERY}" + if [[ "$3" != "fails" ]] + then + log_error "${QUERY}" + set_failed + fi + else + if [[ "$3" == "fails" ]] + then + log_error "QUERY: '${QUERY}' was expected to fail and it did not fail" + set_failed + fi + fi + + if [[ "$3" == "should" ]] + then + if [[ "${RESULT}" != "$4" ]] + then + log_error "QUERY '${QUERY}' expected result '${4}' but got '${RESULT}'" + set_failed + fi + fi +} + + +function log_info() +{ + echo + echo + echo + _log "1;34m" "$1" +} + +function log_error() { + _log "1;31m" "$1" +} + +function log_debug() { + _log "1;32m" "> $1" +} + +function log_warning() { + _log "0;33m" "$1" +} + +function _log() { + echo -e "\033[$1$2\033[0m" +} + +# '############################ HELPERS #############################' +function create_role_and_schema() { + local ROLE=$1 + sql "CREATE ROLE ${ROLE} LOGIN;" + sql "GRANT CONNECT ON DATABASE \"${DATABASE}\" TO ${ROLE};" + sql "CREATE SCHEMA ${ROLE} AUTHORIZATION ${ROLE};" + sql "SELECT cartodb.CDB_Organization_Create_Member('${ROLE}')" + sql "ALTER ROLE ${ROLE} SET search_path TO ${ROLE},cartodb,public;" +} + + +function drop_role_and_schema() { + local ROLE=$1 + sql "DROP SCHEMA \"${ROLE}\";" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM \"${ROLE}\";" + sql "DROP ROLE \"${ROLE}\";" +} + + +function create_table() { + if [[ $# -ne 2 ]] + then + log_error "create_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + sql ${ROLE} "CREATE TABLE ${ROLE}.${TABLENAME} ( a int );" +} + +function truncate_table() { + if [[ $# -ne 2 ]] + then + log_error "truncate_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + sql ${ROLE} "TRUNCATE TABLE ${ROLE}.${TABLENAME};" +} + + +function setup() { + ${CMD} -c "CREATE DATABASE ${DATABASE}" + ${CMD} -c "ALTER DATABASE ${DATABASE} SET search_path = public, cartodb;" + sql "CREATE EXTENSION cartodb CASCADE;" + ${CMD} -c "ALTER DATABASE ${DATABASE} SET search_path = public, cartodb;" + + + log_info "############################# SETUP #############################" + create_role_and_schema cdb_org_admin + sql "SELECT cartodb.CDB_Organization_AddAdmin('cdb_org_admin');" + create_role_and_schema cdb_testmember_1 + create_role_and_schema cdb_testmember_2 + sql postgres "DO +\$\$ +BEGIN + IF NOT EXISTS ( + SELECT * + FROM pg_catalog.pg_user + WHERE usename = 'publicuser') THEN + + CREATE ROLE publicuser LOGIN; + END IF; +END +\$\$;" + sql "GRANT CONNECT ON DATABASE \"${DATABASE}\" TO publicuser;" + + create_table cdb_testmember_1 foo + create_table cdb_testmember_2 bar + + sql "SELECT cartodb.CDB_Group_CreateGroup('group_a_tmp')" + sql "SELECT cartodb.CDB_Group_RenameGroup('group_a_tmp', 'group_a')" + + sql "SELECT cartodb.CDB_Group_AddUsers('group_a', ARRAY['cdb_testmember_1'])" + + sql "SELECT cartodb.CDB_Group_CreateGroup('group_b')" +} + + +function tear_down() { + log_info "########################### USER TEAR DOWN ###########################" + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2');" + sql cdb_testmember_2 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_2', 'bar', 'cdb_testmember_1');" + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.foo;' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.bar;' + + sql "select cartodb.CDB_Group_DropGroup('group_b')" + + sql "SELECT cartodb.CDB_Group_RemoveUsers('group_a', ARRAY['cdb_testmember_1'])" + + sql "select cartodb.CDB_Group_DropGroup('group_a')" + sql "SELECT cartodb.CDB_Organization_RemoveAdmin('cdb_org_admin');" + + sql "DROP SCHEMA cartodb CASCADE" + + log_info "########################### TEAR DOWN ###########################" + sql 'DROP SCHEMA cdb_testmember_1;' + sql 'DROP SCHEMA cdb_testmember_2;' + sql 'DROP SCHEMA cdb_org_admin;' + + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_1;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_2;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM publicuser;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_org_admin;" + + sql 'DROP ROLE cdb_testmember_1;' + sql 'DROP ROLE cdb_testmember_2;' + sql 'DROP ROLE cdb_org_admin;' + + ${CMD} -c "DROP DATABASE ${DATABASE}" +} + +function run_tests() { + local FAILED_TESTS=() + + local TESTS + if [[ $# -ge 1 ]] + then + TESTS="$@" + else + TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'` + fi + + setup + for t in ${TESTS} + do + echo "####################################################################" + echo "#" + echo "# Running: ${t}" + echo "#" + echo "####################################################################" + clear_partial_result + log_info "############################# TESTS #############################" + eval ${t} + if [[ ${PARTIALOK} -ne 0 ]] + then + FAILED_TESTS+=(${t}) + fi + done + tear_down + + if [[ ${OK} -ne 0 ]] + then + echo + log_error "The following tests are failing:" + printf -- '\t%s\n' "${FAILED_TESTS[@]}" + fi +} + + + +#################################################### TESTS GO HERE #################################################### + +function test_member_2_cannot_read_without_permission() { + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' fails +} + +function test_member_1_cannot_grant_read_permission_to_other_schema_than_its_one() { + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_2', 'foo', 'cdb_testmember_2')" fails +} + +function test_member_1_grants_read_permission_and_member_2_can_read() { + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_2.bar;' fails + + # Cleanup + truncate_table cdb_testmember_1 foo + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" +} + +function test_member_2_cannot_add_table_to_member_1_schema_after_table_permission_added() { + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 "CREATE TABLE cdb_testmember_1.bar ( a int );" fails +} + +function test_grant_read_permission_between_two_members() { + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_2 'INSERT INTO cdb_testmember_2.bar VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_2', 'bar', 'cdb_testmember_1')" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_2.bar;' should 5 + + # Cleanup + truncate_table cdb_testmember_1 foo + truncate_table cdb_testmember_2 bar + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_2', 'bar', 'cdb_testmember_1')" +} + +function test_member_2_cannot_write_to_member_1_table() { + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' fails +} + +function test_member_1_cannot_grant_read_write_permission_to_other_schema_than_its_one() { + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Write_Permission('cdb_testmember_2', 'foo', 'cdb_testmember_2')" fails +} + +function test_member_2_can_write_to_member_1_table_after_write_permission_is_added() { + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Write_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'DELETE FROM cdb_testmember_1.foo where a = 9;' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + + # Cleanup + truncate_table cdb_testmember_1 foo + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" +} + +function test_member_2_can_write_to_member_1_table_and_sequence_after_write_permission_is_added() { + sql cdb_testmember_1 "ALTER TABLE cdb_testmember_1.foo ADD cartodb_id SERIAL NOT NULL UNIQUE;" + + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Write_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'DELETE FROM cdb_testmember_1.foo where a = 9;' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + + sql cdb_testmember_1 "ALTER TABLE cdb_testmember_1.foo DROP cartodb_id;" + + # Cleanup + truncate_table cdb_testmember_1 foo + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" +} + +function test_member_2_can_write_to_member_1_table_with_non_sequence_cartodb_id_after_write_permission_is_added() { + sql cdb_testmember_1 "ALTER TABLE cdb_testmember_1.foo ADD cartodb_id INTEGER;" + + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Write_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 5 + sql cdb_testmember_2 'DELETE FROM cdb_testmember_1.foo where a = 9;' + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + + sql cdb_testmember_1 "ALTER TABLE cdb_testmember_1.foo DROP cartodb_id;" + + # Cleanup + truncate_table cdb_testmember_1 foo + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" +} + +function test_member_1_removes_access_and_member_2_can_no_longer_query_the_table() { + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9), (10);' + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 6 + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'SELECT * FROM cdb_testmember_1.foo;' fails + + # Cleanup + truncate_table cdb_testmember_1 foo +} + +function test_member_1_removes_access_and_member_2_can_no_longer_write_to_the_table() { + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Write_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'INSERT INTO cdb_testmember_1.foo VALUES (5), (6), (7), (8), (9);' fails + + # Cleanup + truncate_table cdb_testmember_1 foo +} + +function test_giving_permissions_to_two_tables_and_removing_from_first_table_should_not_remove_from_second() { + #### test setup + # create an extra table for cdb_testmember_1 + create_table cdb_testmember_1 foo_2 + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (1), (2), (3), (4);' + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo_2 VALUES (1), (2), (3), (4), (5);' + sql cdb_testmember_1 'SELECT * FROM cdb_testmember_1.foo_2;' + + # gives read permission to both tables + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo_2', 'cdb_testmember_2')" + + # cdb_testmember_2 has access to both tables + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo_2;' should 5 + + # cdb_testmember_1 removes access to foo table + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + + # cdb_testmember_2 should have access to foo_2 table but not to table foo + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' fails + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo_2;' should 5 + + + #### test tear down + truncate_table cdb_testmember_1 foo + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.foo_2;' +} + +function test_cdb_org_member_role_allows_reading_to_all_users_without_explicit_permission() { + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (1), (2), (3), (4);' + + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' fails + sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Add_Table_Organization_Read_Permission('cdb_testmember_1', 'foo');" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + + # Cleanup + sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Remove_Organization_Access_Permission('cdb_testmember_1', 'foo');" + truncate_table cdb_testmember_1 foo +} + +function test_user_can_read_when_it_has_permission_after_organization_permission_is_removed() { + create_role_and_schema cdb_testmember_3 + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (1), (2), (3), (4);' + + # shares with cdb_testmember_2 and can read but cdb_testmember_3 cannot + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Add_Table_Read_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_3 'SELECT count(*) FROM cdb_testmember_1.foo;' fails + + # granting to organization allows to read to both: cdb_testmember_2 and cdb_testmember_3 + sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Add_Table_Organization_Read_Permission('cdb_testmember_1', 'foo');" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_3 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + + # removing access from organization should keep permission on cdb_testmember_2 but drop it to cdb_testmember_3 + sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Remove_Organization_Access_Permission('cdb_testmember_1', 'foo');" + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_1.foo;' should 4 + sql cdb_testmember_3 'SELECT count(*) FROM cdb_testmember_1.foo;' fails + + # Cleanup + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2')" + truncate_table cdb_testmember_1 foo + drop_role_and_schema cdb_testmember_3 +} + +function test_cdb_querytables_returns_schema_and_table_name() { + sql cdb_testmember_1 "select * from CDB_QueryTables('select * from foo');" should "{cdb_testmember_1.foo}" +} + +function test_cdb_querytables_works_with_parentheses() { + sql cdb_testmember_1 "select * from CDB_QueryTables('(select * from foo)');" should "{cdb_testmember_1.foo}" +} + +function test_cdb_querytables_returns_schema_and_table_name_for_several_schemas() { + sql postgres "select * from CDB_QueryTables('select * from cdb_testmember_1.foo, cdb_testmember_2.bar');" should "{cdb_testmember_1.foo,cdb_testmember_2.bar}" +} + +function test_cdb_querytables_does_not_return_functions_as_part_of_the_resultset() { + sql postgres "select * from CDB_QueryTables('select * from cdb_testmember_1.foo, cdb_testmember_2.bar, plainto_tsquery(''foo'')');" should "{cdb_testmember_1.foo,cdb_testmember_2.bar}" +} + +function test_cdb_usertables_should_work_with_orgusers() { + + # This test validates the changes proposed in https://github.com/CartoDB/cartodb/pull/5021 + + # create tables + sql cdb_testmember_1 "CREATE TABLE test_perms_pub (a int)" + sql cdb_testmember_1 "INSERT INTO test_perms_pub (a) values (1);" + sql cdb_testmember_1 "GRANT SELECT ON TABLE test_perms_pub TO publicuser" + + sql cdb_testmember_1 "CREATE TABLE test_perms_priv (a int)" + + + # this is what we need to make public tables available in CDB_UserTables + sql postgres "grant publicuser to cdb_testmember_1;" + sql postgres "grant publicuser to cdb_testmember_2;" + + + # this is required to enable select from other schema + sql postgres "GRANT USAGE ON SCHEMA cdb_testmember_1 TO publicuser"; + + sql publicuser "SELECT count(*) FROM CDB_UserTables('all')" should 1 + sql publicuser "SELECT count(*) FROM CDB_UserTables('public')" should 1 + sql publicuser "SELECT count(*) FROM CDB_UserTables('private')" should 0 + sql publicuser "SELECT * FROM CDB_UserTables('all')" should "test_perms_pub" + sql publicuser "SELECT * FROM CDB_UserTables('public')" should "test_perms_pub" + sql publicuser "SELECT * FROM CDB_UserTables('private')" should "" + # the following tests are for https://github.com/CartoDB/cartodb-postgresql/issues/98 + # cdb_testmember_2 is already owner of `bar` table + sql cdb_testmember_2 "select string_agg(t,',') from (select cdb_usertables('all') t order by t) as s" should "bar,test_perms_pub" + sql cdb_testmember_2 "SELECT * FROM CDB_UserTables('public')" should "test_perms_pub" + sql cdb_testmember_2 "SELECT * FROM CDB_UserTables('private')" should "bar" + + # test cdb_testmember_2 can select from cdb_testmember_1's public table + sql cdb_testmember_2 "SELECT * FROM cdb_testmember_1.test_perms_pub" should 1 + + sql postgres 'REVOKE USAGE ON SCHEMA cdb_testmember_1 FROM publicuser;' + sql cdb_testmember_1 "DROP TABLE test_perms_pub" + sql cdb_testmember_1 "DROP TABLE test_perms_priv" +} + +function test_CDB_Group_Table_GrantRead_should_grant_select_and_RevokeAll_should_remove_it() { + create_table cdb_testmember_2 shared_with_group + + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' fails + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_GrantRead('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_RevokeAll('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_testmember_1 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' fails + sql cdb_testmember_2 'SELECT count(*) FROM cdb_testmember_2.shared_with_group;' + + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.shared_with_group;' +} + +function test_CDB_Group_Table_GrantReadWrite_should_grant_insert_and_RevokeAll_should_remove_it() { + create_table cdb_testmember_2 shared_with_group + + sql cdb_testmember_1 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' fails + sql cdb_testmember_2 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_GrantReadWrite('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_testmember_1 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' + sql cdb_testmember_2 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_RevokeAll('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_testmember_1 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' fails + sql cdb_testmember_2 'INSERT INTO cdb_testmember_2.shared_with_group VALUES (1), (2), (3), (4), (5)' + + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.shared_with_group;' +} + +function test_group_management_functions_cant_be_used_by_normal_members() { + sql cdb_testmember_1 "SELECT cartodb.CDB_Group_CreateGroup('group_x_1');" fails + sql cdb_testmember_1 "SELECT cartodb.CDB_Group_RenameGroup('group_a', 'group_x_2');" fails + sql cdb_testmember_1 "SELECT cartodb.CDB_Group_DropGroup('group_a');" fails + sql cdb_testmember_1 "SELECT cartodb.CDB_Group_AddUsers('group_a', ARRAY['cdb_testmember_2']);" fails + sql cdb_testmember_1 "SELECT cartodb.CDB_Group_RemoveUsers('group_a', ARRAY['cdb_testmember_1']);" fails +} + +function test_group_permission_functions_cant_be_used_by_normal_members() { + create_table cdb_testmember_2 shared_with_group + + sql cdb_testmember_1 "select cartoDB.CDB_Group_Table_GrantRead('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_testmember_1 "select cartoDB.CDB_Group_Table_GrantReadWrite('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + + # Checks that you can't grant even if your group has RW permissions + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_GrantReadWrite('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_testmember_1 "select cartoDB.CDB_Group_Table_GrantRead('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_testmember_1 "select cartoDB.CDB_Group_Table_GrantReadWrite('group_b', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_testmember_1 "select cartoDB.CDB_Group_Table_RevokeAll('group_b', 'cdb_testmember_2', 'shared_with_group');" fails + + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.shared_with_group;' +} + +function test_group_management_functions_can_be_used_by_org_admin() { + sql cdb_org_admin "SELECT cartodb.CDB_Group_CreateGroup('group_x_tmp');" + sql cdb_org_admin "SELECT cartodb.CDB_Group_RenameGroup('group_x_tmp', 'group_x');" + sql cdb_org_admin "SELECT cartodb.CDB_Group_AddUsers('group_x', ARRAY['cdb_testmember_1', 'cdb_testmember_2']);" + sql cdb_org_admin "SELECT cartodb.CDB_Group_RemoveUsers('group_x', ARRAY['cdb_testmember_1', 'cdb_testmember_2']);" + # TODO: workaround superadmin limitation + sql "SELECT cartodb.CDB_Group_DropGroup('group_x');" +} + +function test_org_admin_cant_grant_permissions_on_tables_he_does_not_own() { + create_table cdb_testmember_2 shared_with_group + + sql cdb_org_admin "select cartoDB.CDB_Group_Table_GrantRead('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_org_admin "select cartoDB.CDB_Group_Table_GrantReadWrite('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + + # Checks that you can't grant even if your group has RW permissions + sql cdb_testmember_2 "select cartoDB.CDB_Group_Table_GrantReadWrite('group_a', 'cdb_testmember_2', 'shared_with_group')" + sql cdb_org_admin "select cartoDB.CDB_Group_Table_GrantRead('group_a', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_org_admin "select cartoDB.CDB_Group_Table_GrantReadWrite('group_b', 'cdb_testmember_2', 'shared_with_group');" fails + sql cdb_org_admin "select cartoDB.CDB_Group_Table_RevokeAll('group_b', 'cdb_testmember_2', 'shared_with_group');" fails + + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.shared_with_group;' +} + +function test_valid_group_names() { + sql postgres "select cartodb._CDB_Group_GroupRole('group_1$_a');" + sql postgres "select cartodb._CDB_Group_GroupRole('GROUP_1$_A');" + sql postgres "select cartodb._CDB_Group_GroupRole('_group_1$_a');" +} + +function test_administrator_name_generation() { + sql postgres "select cartodb._CDB_Organization_Admin_Role_Name();" +} + +function test_conf() { + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf')" should '' + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf_2')" should '' + + sql postgres "SELECT cartodb.CDB_Conf_SetConf('test_conf', '{ \"a_key\": \"test_val\" }')" + + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf')" should '{ "a_key": "test_val" }' + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf_2')" should '' + + sql postgres "SELECT cartodb.CDB_Conf_RemoveConf('test_conf')" + + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf')" should '' + sql postgres "SELECT cartodb.CDB_Conf_GetConf('test_conf_2')" should '' +} + +#################################################### TESTS END HERE #################################################### + + + +run_tests $@ + +exit ${OK} diff --git a/lib/sql/test/overviews/fixtures.sql b/lib/sql/test/overviews/fixtures.sql new file mode 100644 index 0000000..44720c8 --- /dev/null +++ b/lib/sql/test/overviews/fixtures.sql @@ -0,0 +1,2249 @@ +-- bare table with no attribute columns +CREATE TABLE base_bare_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry); +INSERT INTO base_bare_t VALUES +(1, 'SRID=4326;POINT(9.718384 33.139879)'::geometry, ST_Transform('SRID=4326;POINT(9.718384 33.139879)'::geometry, 3857)), +(2, 'SRID=4326;POINT(9.71832 33.139846)'::geometry, ST_Transform('SRID=4326;POINT(9.71832 33.139846)'::geometry, 3857)), +(3, 'SRID=4326;POINT(9.718776 33.139394)'::geometry, ST_Transform('SRID=4326;POINT(9.718776 33.139394)'::geometry, 3857)), +(4, 'SRID=4326;POINT(9.718086 33.139576)'::geometry, ST_Transform('SRID=4326;POINT(9.718086 33.139576)'::geometry, 3857)), +(5, 'SRID=4326;POINT(9.718036 33.139538)'::geometry, ST_Transform('SRID=4326;POINT(9.718036 33.139538)'::geometry, 3857)), +(6, 'SRID=4326;POINT(9.718197 33.139667)'::geometry, ST_Transform('SRID=4326;POINT(9.718197 33.139667)'::geometry, 3857)), +(7, 'SRID=4326;POINT(9.718357 33.139511)'::geometry, ST_Transform('SRID=4326;POINT(9.718357 33.139511)'::geometry, 3857)), +(8, 'SRID=4326;POINT(9.718385 33.13984)'::geometry, ST_Transform('SRID=4326;POINT(9.718385 33.13984)'::geometry, 3857)), +(9, 'SRID=4326;POINT(9.718312 33.139405)'::geometry, ST_Transform('SRID=4326;POINT(9.718312 33.139405)'::geometry, 3857)), +(10, 'SRID=4326;POINT(9.718951 33.139878)'::geometry, ST_Transform('SRID=4326;POINT(9.718951 33.139878)'::geometry, 3857)), +(11, 'SRID=4326;POINT(9.718799 33.139942)'::geometry, ST_Transform('SRID=4326;POINT(9.718799 33.139942)'::geometry, 3857)), +(12, 'SRID=4326;POINT(9.718777 33.139681)'::geometry, ST_Transform('SRID=4326;POINT(9.718777 33.139681)'::geometry, 3857)), +(13, 'SRID=4326;POINT(9.717971 33.13981)'::geometry, ST_Transform('SRID=4326;POINT(9.717971 33.13981)'::geometry, 3857)), +(14, 'SRID=4326;POINT(9.718334 33.139541)'::geometry, ST_Transform('SRID=4326;POINT(9.718334 33.139541)'::geometry, 3857)), +(15, 'SRID=4326;POINT(-5.989195 39.206665)'::geometry, ST_Transform('SRID=4326;POINT(-5.989195 39.206665)'::geometry, 3857)), +(16, 'SRID=4326;POINT(-5.988446 39.207071)'::geometry, ST_Transform('SRID=4326;POINT(-5.988446 39.207071)'::geometry, 3857)), +(17, 'SRID=4326;POINT(-5.989083 39.207225)'::geometry, ST_Transform('SRID=4326;POINT(-5.989083 39.207225)'::geometry, 3857)), +(18, 'SRID=4326;POINT(8.510012 32.031818)'::geometry, ST_Transform('SRID=4326;POINT(8.510012 32.031818)'::geometry, 3857)), +(19, 'SRID=4326;POINT(8.509814 32.03189)'::geometry, ST_Transform('SRID=4326;POINT(8.509814 32.03189)'::geometry, 3857)), +(20, 'SRID=4326;POINT(8.510091 32.031737)'::geometry, ST_Transform('SRID=4326;POINT(8.510091 32.031737)'::geometry, 3857)), +(21, 'SRID=4326;POINT(-1.337826 37.660347)'::geometry, ST_Transform('SRID=4326;POINT(-1.337826 37.660347)'::geometry, 3857)), +(22, 'SRID=4326;POINT(-1.337618 37.660051)'::geometry, ST_Transform('SRID=4326;POINT(-1.337618 37.660051)'::geometry, 3857)), +(23, 'SRID=4326;POINT(-1.337644 37.659833)'::geometry, ST_Transform('SRID=4326;POINT(-1.337644 37.659833)'::geometry, 3857)), +(24, 'SRID=4326;POINT(-1.337701 37.659615)'::geometry, ST_Transform('SRID=4326;POINT(-1.337701 37.659615)'::geometry, 3857)), +(25, 'SRID=4326;POINT(-1.337237 37.659644)'::geometry, ST_Transform('SRID=4326;POINT(-1.337237 37.659644)'::geometry, 3857)), +(26, 'SRID=4326;POINT(-1.337542 37.660018)'::geometry, ST_Transform('SRID=4326;POINT(-1.337542 37.660018)'::geometry, 3857)), +(27, 'SRID=4326;POINT(-1.337848 37.659752)'::geometry, ST_Transform('SRID=4326;POINT(-1.337848 37.659752)'::geometry, 3857)), +(28, 'SRID=4326;POINT(-1.337659 37.659788)'::geometry, ST_Transform('SRID=4326;POINT(-1.337659 37.659788)'::geometry, 3857)), +(29, 'SRID=4326;POINT(-1.337194 37.660026)'::geometry, ST_Transform('SRID=4326;POINT(-1.337194 37.660026)'::geometry, 3857)), +(30, 'SRID=4326;POINT(-1.337714 37.659619)'::geometry, ST_Transform('SRID=4326;POINT(-1.337714 37.659619)'::geometry, 3857)), +(31, 'SRID=4326;POINT(-1.337846 37.659781)'::geometry, ST_Transform('SRID=4326;POINT(-1.337846 37.659781)'::geometry, 3857)), +(32, 'SRID=4326;POINT(-1.33751 37.66052)'::geometry, ST_Transform('SRID=4326;POINT(-1.33751 37.66052)'::geometry, 3857)), +(33, 'SRID=4326;POINT(-1.337669 37.660154)'::geometry, ST_Transform('SRID=4326;POINT(-1.337669 37.660154)'::geometry, 3857)), +(34, 'SRID=4326;POINT(-3.050809 34.810112)'::geometry, ST_Transform('SRID=4326;POINT(-3.050809 34.810112)'::geometry, 3857)), +(35, 'SRID=4326;POINT(-3.049988 34.811057)'::geometry, ST_Transform('SRID=4326;POINT(-3.049988 34.811057)'::geometry, 3857)), +(36, 'SRID=4326;POINT(-3.050564 34.810536)'::geometry, ST_Transform('SRID=4326;POINT(-3.050564 34.810536)'::geometry, 3857)), +(37, 'SRID=4326;POINT(-3.050442 34.810239)'::geometry, ST_Transform('SRID=4326;POINT(-3.050442 34.810239)'::geometry, 3857)), +(38, 'SRID=4326;POINT(-3.05032 34.810969)'::geometry, ST_Transform('SRID=4326;POINT(-3.05032 34.810969)'::geometry, 3857)), +(39, 'SRID=4326;POINT(-3.050097 34.810504)'::geometry, ST_Transform('SRID=4326;POINT(-3.050097 34.810504)'::geometry, 3857)), +(40, 'SRID=4326;POINT(-3.05055 34.810908)'::geometry, ST_Transform('SRID=4326;POINT(-3.05055 34.810908)'::geometry, 3857)), +(41, 'SRID=4326;POINT(-3.050086 34.810386)'::geometry, ST_Transform('SRID=4326;POINT(-3.050086 34.810386)'::geometry, 3857)), +(42, 'SRID=4326;POINT(-3.050485 34.810751)'::geometry, ST_Transform('SRID=4326;POINT(-3.050485 34.810751)'::geometry, 3857)), +(43, 'SRID=4326;POINT(-3.04984 34.810113)'::geometry, ST_Transform('SRID=4326;POINT(-3.04984 34.810113)'::geometry, 3857)), +(44, 'SRID=4326;POINT(-3.049975 34.810547)'::geometry, ST_Transform('SRID=4326;POINT(-3.049975 34.810547)'::geometry, 3857)), +(45, 'SRID=4326;POINT(-3.05065 34.810262)'::geometry, ST_Transform('SRID=4326;POINT(-3.05065 34.810262)'::geometry, 3857)), +(46, 'SRID=4326;POINT(-3.050618 34.8107)'::geometry, ST_Transform('SRID=4326;POINT(-3.050618 34.8107)'::geometry, 3857)), +(47, 'SRID=4326;POINT(-3.050325 34.810601)'::geometry, ST_Transform('SRID=4326;POINT(-3.050325 34.810601)'::geometry, 3857)), +(48, 'SRID=4326;POINT(-3.049874 34.810936)'::geometry, ST_Transform('SRID=4326;POINT(-3.049874 34.810936)'::geometry, 3857)), +(49, 'SRID=4326;POINT(-3.049991 34.810872)'::geometry, ST_Transform('SRID=4326;POINT(-3.049991 34.810872)'::geometry, 3857)), +(50, 'SRID=4326;POINT(-7.192205 34.110465)'::geometry, ST_Transform('SRID=4326;POINT(-7.192205 34.110465)'::geometry, 3857)), +(51, 'SRID=4326;POINT(-1.111773 31.260536)'::geometry, ST_Transform('SRID=4326;POINT(-1.111773 31.260536)'::geometry, 3857)), +(52, 'SRID=4326;POINT(-1.112389 31.26055)'::geometry, ST_Transform('SRID=4326;POINT(-1.112389 31.26055)'::geometry, 3857)), +(53, 'SRID=4326;POINT(-1.11196 31.260683)'::geometry, ST_Transform('SRID=4326;POINT(-1.11196 31.260683)'::geometry, 3857)), +(54, 'SRID=4326;POINT(-1.11169 31.260137)'::geometry, ST_Transform('SRID=4326;POINT(-1.11169 31.260137)'::geometry, 3857)), +(55, 'SRID=4326;POINT(-1.111784 31.259982)'::geometry, ST_Transform('SRID=4326;POINT(-1.111784 31.259982)'::geometry, 3857)), +(56, 'SRID=4326;POINT(-1.111957 31.26044)'::geometry, ST_Transform('SRID=4326;POINT(-1.111957 31.26044)'::geometry, 3857)), +(57, 'SRID=4326;POINT(-1.112346 31.260099)'::geometry, ST_Transform('SRID=4326;POINT(-1.112346 31.260099)'::geometry, 3857)), +(58, 'SRID=4326;POINT(-1.112361 31.260683)'::geometry, ST_Transform('SRID=4326;POINT(-1.112361 31.260683)'::geometry, 3857)), +(59, 'SRID=4326;POINT(-1.112424 31.260104)'::geometry, ST_Transform('SRID=4326;POINT(-1.112424 31.260104)'::geometry, 3857)), +(60, 'SRID=4326;POINT(-1.11189 31.260241)'::geometry, ST_Transform('SRID=4326;POINT(-1.11189 31.260241)'::geometry, 3857)), +(61, 'SRID=4326;POINT(-1.111632 31.260126)'::geometry, ST_Transform('SRID=4326;POINT(-1.111632 31.260126)'::geometry, 3857)), +(62, 'SRID=4326;POINT(-1.112057 31.260066)'::geometry, ST_Transform('SRID=4326;POINT(-1.112057 31.260066)'::geometry, 3857)), +(63, 'SRID=4326;POINT(-1.111878 31.260402)'::geometry, ST_Transform('SRID=4326;POINT(-1.111878 31.260402)'::geometry, 3857)), +(64, 'SRID=4326;POINT(-1.112086 31.260331)'::geometry, ST_Transform('SRID=4326;POINT(-1.112086 31.260331)'::geometry, 3857)), +(65, 'SRID=4326;POINT(-1.11192 31.25996)'::geometry, ST_Transform('SRID=4326;POINT(-1.11192 31.25996)'::geometry, 3857)), +(66, 'SRID=4326;POINT(-1.111971 31.260519)'::geometry, ST_Transform('SRID=4326;POINT(-1.111971 31.260519)'::geometry, 3857)), +(67, 'SRID=4326;POINT(1.981315 36.414172)'::geometry, ST_Transform('SRID=4326;POINT(1.981315 36.414172)'::geometry, 3857)), +(68, 'SRID=4326;POINT(1.981157 36.414659)'::geometry, ST_Transform('SRID=4326;POINT(1.981157 36.414659)'::geometry, 3857)), +(69, 'SRID=4326;POINT(1.981097 36.414188)'::geometry, ST_Transform('SRID=4326;POINT(1.981097 36.414188)'::geometry, 3857)), +(70, 'SRID=4326;POINT(1.98147 36.414969)'::geometry, ST_Transform('SRID=4326;POINT(1.98147 36.414969)'::geometry, 3857)), +(71, 'SRID=4326;POINT(1.981473 36.414819)'::geometry, ST_Transform('SRID=4326;POINT(1.981473 36.414819)'::geometry, 3857)), +(72, 'SRID=4326;POINT(1.981159 36.414521)'::geometry, ST_Transform('SRID=4326;POINT(1.981159 36.414521)'::geometry, 3857)), +(73, 'SRID=4326;POINT(1.981434 36.414368)'::geometry, ST_Transform('SRID=4326;POINT(1.981434 36.414368)'::geometry, 3857)), +(74, 'SRID=4326;POINT(1.981508 36.414849)'::geometry, ST_Transform('SRID=4326;POINT(1.981508 36.414849)'::geometry, 3857)), +(75, 'SRID=4326;POINT(1.980794 36.414325)'::geometry, ST_Transform('SRID=4326;POINT(1.980794 36.414325)'::geometry, 3857)), +(76, 'SRID=4326;POINT(1.981257 36.414346)'::geometry, ST_Transform('SRID=4326;POINT(1.981257 36.414346)'::geometry, 3857)), +(77, 'SRID=4326;POINT(-0.953948 39.768838)'::geometry, ST_Transform('SRID=4326;POINT(-0.953948 39.768838)'::geometry, 3857)), +(78, 'SRID=4326;POINT(-0.954525 39.768965)'::geometry, ST_Transform('SRID=4326;POINT(-0.954525 39.768965)'::geometry, 3857)), +(79, 'SRID=4326;POINT(-0.954753 39.76904)'::geometry, ST_Transform('SRID=4326;POINT(-0.954753 39.76904)'::geometry, 3857)), +(80, 'SRID=4326;POINT(-0.954287 39.769265)'::geometry, ST_Transform('SRID=4326;POINT(-0.954287 39.769265)'::geometry, 3857)), +(81, 'SRID=4326;POINT(-0.953996 39.76948)'::geometry, ST_Transform('SRID=4326;POINT(-0.953996 39.76948)'::geometry, 3857)), +(82, 'SRID=4326;POINT(-0.954469 39.769349)'::geometry, ST_Transform('SRID=4326;POINT(-0.954469 39.769349)'::geometry, 3857)), +(83, 'SRID=4326;POINT(-0.953957 39.769444)'::geometry, ST_Transform('SRID=4326;POINT(-0.953957 39.769444)'::geometry, 3857)), +(84, 'SRID=4326;POINT(-0.954757 39.7688)'::geometry, ST_Transform('SRID=4326;POINT(-0.954757 39.7688)'::geometry, 3857)), +(85, 'SRID=4326;POINT(-0.954196 39.769695)'::geometry, ST_Transform('SRID=4326;POINT(-0.954196 39.769695)'::geometry, 3857)), +(86, 'SRID=4326;POINT(-0.954047 39.768844)'::geometry, ST_Transform('SRID=4326;POINT(-0.954047 39.768844)'::geometry, 3857)), +(87, 'SRID=4326;POINT(-0.954191 39.769569)'::geometry, ST_Transform('SRID=4326;POINT(-0.954191 39.769569)'::geometry, 3857)), +(88, 'SRID=4326;POINT(-0.954122 39.7692)'::geometry, ST_Transform('SRID=4326;POINT(-0.954122 39.7692)'::geometry, 3857)), +(89, 'SRID=4326;POINT(-0.954273 39.76964)'::geometry, ST_Transform('SRID=4326;POINT(-0.954273 39.76964)'::geometry, 3857)), +(90, 'SRID=4326;POINT(-0.953816 39.769145)'::geometry, ST_Transform('SRID=4326;POINT(-0.953816 39.769145)'::geometry, 3857)), +(91, 'SRID=4326;POINT(-0.954025 39.7691)'::geometry, ST_Transform('SRID=4326;POINT(-0.954025 39.7691)'::geometry, 3857)), +(92, 'SRID=4326;POINT(-0.95416 39.769704)'::geometry, ST_Transform('SRID=4326;POINT(-0.95416 39.769704)'::geometry, 3857)), +(93, 'SRID=4326;POINT(-7.587221 32.009901)'::geometry, ST_Transform('SRID=4326;POINT(-7.587221 32.009901)'::geometry, 3857)), +(94, 'SRID=4326;POINT(-7.586856 32.010641)'::geometry, ST_Transform('SRID=4326;POINT(-7.586856 32.010641)'::geometry, 3857)), +(95, 'SRID=4326;POINT(-7.586722 32.010493)'::geometry, ST_Transform('SRID=4326;POINT(-7.586722 32.010493)'::geometry, 3857)), +(96, 'SRID=4326;POINT(-7.586391 32.010262)'::geometry, ST_Transform('SRID=4326;POINT(-7.586391 32.010262)'::geometry, 3857)), +(97, 'SRID=4326;POINT(-7.586974 32.010238)'::geometry, ST_Transform('SRID=4326;POINT(-7.586974 32.010238)'::geometry, 3857)), +(98, 'SRID=4326;POINT(-7.586775 32.010427)'::geometry, ST_Transform('SRID=4326;POINT(-7.586775 32.010427)'::geometry, 3857)), +(99, 'SRID=4326;POINT(-7.586872 32.009897)'::geometry, ST_Transform('SRID=4326;POINT(-7.586872 32.009897)'::geometry, 3857)), +(100, 'SRID=4326;POINT(-7.586628 32.010007)'::geometry, ST_Transform('SRID=4326;POINT(-7.586628 32.010007)'::geometry, 3857)), +(101, 'SRID=4326;POINT(-7.587165 32.010048)'::geometry, ST_Transform('SRID=4326;POINT(-7.587165 32.010048)'::geometry, 3857)), +(102, 'SRID=4326;POINT(1.184165 37.50755)'::geometry, ST_Transform('SRID=4326;POINT(1.184165 37.50755)'::geometry, 3857)), +(103, 'SRID=4326;POINT(1.183645 37.507603)'::geometry, ST_Transform('SRID=4326;POINT(1.183645 37.507603)'::geometry, 3857)), +(104, 'SRID=4326;POINT(1.184264 37.507825)'::geometry, ST_Transform('SRID=4326;POINT(1.184264 37.507825)'::geometry, 3857)), +(105, 'SRID=4326;POINT(1.184288 37.507609)'::geometry, ST_Transform('SRID=4326;POINT(1.184288 37.507609)'::geometry, 3857)), +(106, 'SRID=4326;POINT(1.183561 37.507407)'::geometry, ST_Transform('SRID=4326;POINT(1.183561 37.507407)'::geometry, 3857)), +(107, 'SRID=4326;POINT(1.184181 37.50741)'::geometry, ST_Transform('SRID=4326;POINT(1.184181 37.50741)'::geometry, 3857)), +(108, 'SRID=4326;POINT(1.183824 37.508023)'::geometry, ST_Transform('SRID=4326;POINT(1.183824 37.508023)'::geometry, 3857)), +(109, 'SRID=4326;POINT(1.183603 37.507709)'::geometry, ST_Transform('SRID=4326;POINT(1.183603 37.507709)'::geometry, 3857)), +(110, 'SRID=4326;POINT(1.18372 37.507527)'::geometry, ST_Transform('SRID=4326;POINT(1.18372 37.507527)'::geometry, 3857)), +(111, 'SRID=4326;POINT(1.183425 37.507321)'::geometry, ST_Transform('SRID=4326;POINT(1.183425 37.507321)'::geometry, 3857)), +(112, 'SRID=4326;POINT(1.184305 37.507615)'::geometry, ST_Transform('SRID=4326;POINT(1.184305 37.507615)'::geometry, 3857)), +(113, 'SRID=4326;POINT(1.183852 37.508007)'::geometry, ST_Transform('SRID=4326;POINT(1.183852 37.508007)'::geometry, 3857)), +(114, 'SRID=4326;POINT(3.831779 31.429738)'::geometry, ST_Transform('SRID=4326;POINT(3.831779 31.429738)'::geometry, 3857)), +(115, 'SRID=4326;POINT(3.831813 31.4298)'::geometry, ST_Transform('SRID=4326;POINT(3.831813 31.4298)'::geometry, 3857)), +(116, 'SRID=4326;POINT(3.831852 31.429751)'::geometry, ST_Transform('SRID=4326;POINT(3.831852 31.429751)'::geometry, 3857)), +(117, 'SRID=4326;POINT(3.832368 31.430079)'::geometry, ST_Transform('SRID=4326;POINT(3.832368 31.430079)'::geometry, 3857)), +(118, 'SRID=4326;POINT(3.83201 31.429663)'::geometry, ST_Transform('SRID=4326;POINT(3.83201 31.429663)'::geometry, 3857)), +(119, 'SRID=4326;POINT(3.832181 31.429739)'::geometry, ST_Transform('SRID=4326;POINT(3.832181 31.429739)'::geometry, 3857)), +(120, 'SRID=4326;POINT(3.831543 31.429602)'::geometry, ST_Transform('SRID=4326;POINT(3.831543 31.429602)'::geometry, 3857)), +(121, 'SRID=4326;POINT(3.831601 31.430119)'::geometry, ST_Transform('SRID=4326;POINT(3.831601 31.430119)'::geometry, 3857)), +(122, 'SRID=4326;POINT(3.831729 31.42977)'::geometry, ST_Transform('SRID=4326;POINT(3.831729 31.42977)'::geometry, 3857)), +(123, 'SRID=4326;POINT(3.831987 31.430192)'::geometry, ST_Transform('SRID=4326;POINT(3.831987 31.430192)'::geometry, 3857)), +(124, 'SRID=4326;POINT(8.47022 33.825659)'::geometry, ST_Transform('SRID=4326;POINT(8.47022 33.825659)'::geometry, 3857)), +(125, 'SRID=4326;POINT(8.470632 33.825421)'::geometry, ST_Transform('SRID=4326;POINT(8.470632 33.825421)'::geometry, 3857)), +(126, 'SRID=4326;POINT(8.470131 33.825262)'::geometry, ST_Transform('SRID=4326;POINT(8.470131 33.825262)'::geometry, 3857)), +(127, 'SRID=4326;POINT(8.470458 33.825972)'::geometry, ST_Transform('SRID=4326;POINT(8.470458 33.825972)'::geometry, 3857)), +(128, 'SRID=4326;POINT(8.470603 33.825651)'::geometry, ST_Transform('SRID=4326;POINT(8.470603 33.825651)'::geometry, 3857)), +(129, 'SRID=4326;POINT(8.470558 33.825475)'::geometry, ST_Transform('SRID=4326;POINT(8.470558 33.825475)'::geometry, 3857)), +(130, 'SRID=4326;POINT(8.470193 33.82544)'::geometry, ST_Transform('SRID=4326;POINT(8.470193 33.82544)'::geometry, 3857)), +(131, 'SRID=4326;POINT(8.47041 33.825325)'::geometry, ST_Transform('SRID=4326;POINT(8.47041 33.825325)'::geometry, 3857)), +(132, 'SRID=4326;POINT(8.470797 33.825402)'::geometry, ST_Transform('SRID=4326;POINT(8.470797 33.825402)'::geometry, 3857)), +(133, 'SRID=4326;POINT(8.470405 33.825234)'::geometry, ST_Transform('SRID=4326;POINT(8.470405 33.825234)'::geometry, 3857)), +(134, 'SRID=4326;POINT(8.47069 33.825547)'::geometry, ST_Transform('SRID=4326;POINT(8.47069 33.825547)'::geometry, 3857)), +(135, 'SRID=4326;POINT(8.470491 33.825588)'::geometry, ST_Transform('SRID=4326;POINT(8.470491 33.825588)'::geometry, 3857)), +(136, 'SRID=4326;POINT(8.470293 33.825798)'::geometry, ST_Transform('SRID=4326;POINT(8.470293 33.825798)'::geometry, 3857)), +(137, 'SRID=4326;POINT(8.47064 33.825412)'::geometry, ST_Transform('SRID=4326;POINT(8.47064 33.825412)'::geometry, 3857)), +(138, 'SRID=4326;POINT(8.470238 33.825427)'::geometry, ST_Transform('SRID=4326;POINT(8.470238 33.825427)'::geometry, 3857)), +(139, 'SRID=4326;POINT(8.20576 30.965218)'::geometry, ST_Transform('SRID=4326;POINT(8.20576 30.965218)'::geometry, 3857)), +(140, 'SRID=4326;POINT(8.205812 30.96474)'::geometry, ST_Transform('SRID=4326;POINT(8.205812 30.96474)'::geometry, 3857)), +(141, 'SRID=4326;POINT(8.205599 30.964695)'::geometry, ST_Transform('SRID=4326;POINT(8.205599 30.964695)'::geometry, 3857)), +(142, 'SRID=4326;POINT(-1.94997 37.466004)'::geometry, ST_Transform('SRID=4326;POINT(-1.94997 37.466004)'::geometry, 3857)), +(143, 'SRID=4326;POINT(-1.950577 37.466006)'::geometry, ST_Transform('SRID=4326;POINT(-1.950577 37.466006)'::geometry, 3857)), +(144, 'SRID=4326;POINT(-1.950744 37.465286)'::geometry, ST_Transform('SRID=4326;POINT(-1.950744 37.465286)'::geometry, 3857)), +(145, 'SRID=4326;POINT(-1.950241 37.466054)'::geometry, ST_Transform('SRID=4326;POINT(-1.950241 37.466054)'::geometry, 3857)), +(146, 'SRID=4326;POINT(-1.950335 37.465202)'::geometry, ST_Transform('SRID=4326;POINT(-1.950335 37.465202)'::geometry, 3857)), +(147, 'SRID=4326;POINT(-1.949968 37.465359)'::geometry, ST_Transform('SRID=4326;POINT(-1.949968 37.465359)'::geometry, 3857)), +(148, 'SRID=4326;POINT(-1.950149 37.465273)'::geometry, ST_Transform('SRID=4326;POINT(-1.950149 37.465273)'::geometry, 3857)), +(149, 'SRID=4326;POINT(-1.950008 37.46512)'::geometry, ST_Transform('SRID=4326;POINT(-1.950008 37.46512)'::geometry, 3857)), +(150, 'SRID=4326;POINT(-1.950516 37.465531)'::geometry, ST_Transform('SRID=4326;POINT(-1.950516 37.465531)'::geometry, 3857)), +(151, 'SRID=4326;POINT(-1.950595 37.465682)'::geometry, ST_Transform('SRID=4326;POINT(-1.950595 37.465682)'::geometry, 3857)), +(152, 'SRID=4326;POINT(-1.950222 37.465858)'::geometry, ST_Transform('SRID=4326;POINT(-1.950222 37.465858)'::geometry, 3857)), +(153, 'SRID=4326;POINT(-1.950306 37.465943)'::geometry, ST_Transform('SRID=4326;POINT(-1.950306 37.465943)'::geometry, 3857)), +(154, 'SRID=4326;POINT(-1.950272 37.466052)'::geometry, ST_Transform('SRID=4326;POINT(-1.950272 37.466052)'::geometry, 3857)), +(155, 'SRID=4326;POINT(-1.950724 37.465937)'::geometry, ST_Transform('SRID=4326;POINT(-1.950724 37.465937)'::geometry, 3857)), +(156, 'SRID=4326;POINT(-1.950334 37.465308)'::geometry, ST_Transform('SRID=4326;POINT(-1.950334 37.465308)'::geometry, 3857)), +(157, 'SRID=4326;POINT(-1.950797 37.465927)'::geometry, ST_Transform('SRID=4326;POINT(-1.950797 37.465927)'::geometry, 3857)), +(158, 'SRID=4326;POINT(9.779537 35.54475)'::geometry, ST_Transform('SRID=4326;POINT(9.779537 35.54475)'::geometry, 3857)), +(159, 'SRID=4326;POINT(9.779673 35.544579)'::geometry, ST_Transform('SRID=4326;POINT(9.779673 35.544579)'::geometry, 3857)), +(160, 'SRID=4326;POINT(9.779822 35.544831)'::geometry, ST_Transform('SRID=4326;POINT(9.779822 35.544831)'::geometry, 3857)), +(161, 'SRID=4326;POINT(-8.280843 31.373195)'::geometry, ST_Transform('SRID=4326;POINT(-8.280843 31.373195)'::geometry, 3857)), +(162, 'SRID=4326;POINT(-8.281007 31.374063)'::geometry, ST_Transform('SRID=4326;POINT(-8.281007 31.374063)'::geometry, 3857)), +(163, 'SRID=4326;POINT(-8.280772 31.373137)'::geometry, ST_Transform('SRID=4326;POINT(-8.280772 31.373137)'::geometry, 3857)), +(164, 'SRID=4326;POINT(-8.28126 31.373852)'::geometry, ST_Transform('SRID=4326;POINT(-8.28126 31.373852)'::geometry, 3857)), +(165, 'SRID=4326;POINT(-8.281032 31.374022)'::geometry, ST_Transform('SRID=4326;POINT(-8.281032 31.374022)'::geometry, 3857)), +(166, 'SRID=4326;POINT(-5.492422 32.876965)'::geometry, ST_Transform('SRID=4326;POINT(-5.492422 32.876965)'::geometry, 3857)), +(167, 'SRID=4326;POINT(-5.492822 32.877251)'::geometry, ST_Transform('SRID=4326;POINT(-5.492822 32.877251)'::geometry, 3857)), +(168, 'SRID=4326;POINT(-5.492531 32.877462)'::geometry, ST_Transform('SRID=4326;POINT(-5.492531 32.877462)'::geometry, 3857)), +(169, 'SRID=4326;POINT(-5.492944 32.877059)'::geometry, ST_Transform('SRID=4326;POINT(-5.492944 32.877059)'::geometry, 3857)), +(170, 'SRID=4326;POINT(-5.492309 32.877729)'::geometry, ST_Transform('SRID=4326;POINT(-5.492309 32.877729)'::geometry, 3857)), +(171, 'SRID=4326;POINT(-5.492892 32.877087)'::geometry, ST_Transform('SRID=4326;POINT(-5.492892 32.877087)'::geometry, 3857)), +(172, 'SRID=4326;POINT(3.901874 37.553725)'::geometry, ST_Transform('SRID=4326;POINT(3.901874 37.553725)'::geometry, 3857)), +(173, 'SRID=4326;POINT(3.902047 37.554527)'::geometry, ST_Transform('SRID=4326;POINT(3.902047 37.554527)'::geometry, 3857)), +(174, 'SRID=4326;POINT(3.901596 37.55417)'::geometry, ST_Transform('SRID=4326;POINT(3.901596 37.55417)'::geometry, 3857)), +(175, 'SRID=4326;POINT(3.902012 37.553726)'::geometry, ST_Transform('SRID=4326;POINT(3.902012 37.553726)'::geometry, 3857)), +(176, 'SRID=4326;POINT(3.901739 37.554492)'::geometry, ST_Transform('SRID=4326;POINT(3.901739 37.554492)'::geometry, 3857)), +(177, 'SRID=4326;POINT(3.901397 37.554598)'::geometry, ST_Transform('SRID=4326;POINT(3.901397 37.554598)'::geometry, 3857)), +(178, 'SRID=4326;POINT(3.901348 37.553662)'::geometry, ST_Transform('SRID=4326;POINT(3.901348 37.553662)'::geometry, 3857)), +(179, 'SRID=4326;POINT(3.90194 37.554032)'::geometry, ST_Transform('SRID=4326;POINT(3.90194 37.554032)'::geometry, 3857)), +(180, 'SRID=4326;POINT(-2.684028 31.988394)'::geometry, ST_Transform('SRID=4326;POINT(-2.684028 31.988394)'::geometry, 3857)), +(181, 'SRID=4326;POINT(-2.684145 31.988734)'::geometry, ST_Transform('SRID=4326;POINT(-2.684145 31.988734)'::geometry, 3857)), +(182, 'SRID=4326;POINT(-2.684262 31.988291)'::geometry, ST_Transform('SRID=4326;POINT(-2.684262 31.988291)'::geometry, 3857)), +(183, 'SRID=4326;POINT(-2.684535 31.988447)'::geometry, ST_Transform('SRID=4326;POINT(-2.684535 31.988447)'::geometry, 3857)), +(184, 'SRID=4326;POINT(-2.684214 31.9884)'::geometry, ST_Transform('SRID=4326;POINT(-2.684214 31.9884)'::geometry, 3857)), +(185, 'SRID=4326;POINT(-2.684298 31.989248)'::geometry, ST_Transform('SRID=4326;POINT(-2.684298 31.989248)'::geometry, 3857)), +(186, 'SRID=4326;POINT(-2.684349 31.988645)'::geometry, ST_Transform('SRID=4326;POINT(-2.684349 31.988645)'::geometry, 3857)), +(187, 'SRID=4326;POINT(-2.683797 31.988608)'::geometry, ST_Transform('SRID=4326;POINT(-2.683797 31.988608)'::geometry, 3857)), +(188, 'SRID=4326;POINT(-2.684117 31.988665)'::geometry, ST_Transform('SRID=4326;POINT(-2.684117 31.988665)'::geometry, 3857)), +(189, 'SRID=4326;POINT(-2.68444 31.988764)'::geometry, ST_Transform('SRID=4326;POINT(-2.68444 31.988764)'::geometry, 3857)), +(190, 'SRID=4326;POINT(-2.684519 31.98856)'::geometry, ST_Transform('SRID=4326;POINT(-2.684519 31.98856)'::geometry, 3857)), +(191, 'SRID=4326;POINT(-2.684361 31.988464)'::geometry, ST_Transform('SRID=4326;POINT(-2.684361 31.988464)'::geometry, 3857)), +(192, 'SRID=4326;POINT(-2.683966 31.988706)'::geometry, ST_Transform('SRID=4326;POINT(-2.683966 31.988706)'::geometry, 3857)), +(193, 'SRID=4326;POINT(-5.650994 38.876385)'::geometry, ST_Transform('SRID=4326;POINT(-5.650994 38.876385)'::geometry, 3857)), +(194, 'SRID=4326;POINT(-5.650197 38.876046)'::geometry, ST_Transform('SRID=4326;POINT(-5.650197 38.876046)'::geometry, 3857)), +(195, 'SRID=4326;POINT(-5.650764 38.875596)'::geometry, ST_Transform('SRID=4326;POINT(-5.650764 38.875596)'::geometry, 3857)), +(196, 'SRID=4326;POINT(-5.650742 38.875876)'::geometry, ST_Transform('SRID=4326;POINT(-5.650742 38.875876)'::geometry, 3857)), +(197, 'SRID=4326;POINT(-5.650184 38.876442)'::geometry, ST_Transform('SRID=4326;POINT(-5.650184 38.876442)'::geometry, 3857)), +(198, 'SRID=4326;POINT(-5.65088 38.876264)'::geometry, ST_Transform('SRID=4326;POINT(-5.65088 38.876264)'::geometry, 3857)), +(199, 'SRID=4326;POINT(-5.650245 38.876459)'::geometry, ST_Transform('SRID=4326;POINT(-5.650245 38.876459)'::geometry, 3857)), +(200, 'SRID=4326;POINT(0.94164 33.420389)'::geometry, ST_Transform('SRID=4326;POINT(0.94164 33.420389)'::geometry, 3857)), +(201, 'SRID=4326;POINT(0.942386 33.420323)'::geometry, ST_Transform('SRID=4326;POINT(0.942386 33.420323)'::geometry, 3857)), +(202, 'SRID=4326;POINT(0.942523 33.420441)'::geometry, ST_Transform('SRID=4326;POINT(0.942523 33.420441)'::geometry, 3857)), +(203, 'SRID=4326;POINT(0.941933 33.420348)'::geometry, ST_Transform('SRID=4326;POINT(0.941933 33.420348)'::geometry, 3857)), +(204, 'SRID=4326;POINT(0.942198 33.42006)'::geometry, ST_Transform('SRID=4326;POINT(0.942198 33.42006)'::geometry, 3857)), +(205, 'SRID=4326;POINT(0.942105 33.420254)'::geometry, ST_Transform('SRID=4326;POINT(0.942105 33.420254)'::geometry, 3857)), +(206, 'SRID=4326;POINT(0.94195 33.419859)'::geometry, ST_Transform('SRID=4326;POINT(0.94195 33.419859)'::geometry, 3857)), +(207, 'SRID=4326;POINT(0.9417 33.419948)'::geometry, ST_Transform('SRID=4326;POINT(0.9417 33.419948)'::geometry, 3857)), +(208, 'SRID=4326;POINT(0.942123 33.420747)'::geometry, ST_Transform('SRID=4326;POINT(0.942123 33.420747)'::geometry, 3857)), +(209, 'SRID=4326;POINT(0.942372 33.420072)'::geometry, ST_Transform('SRID=4326;POINT(0.942372 33.420072)'::geometry, 3857)), +(210, 'SRID=4326;POINT(0.941993 33.41995)'::geometry, ST_Transform('SRID=4326;POINT(0.941993 33.41995)'::geometry, 3857)), +(211, 'SRID=4326;POINT(6.372568 36.408838)'::geometry, ST_Transform('SRID=4326;POINT(6.372568 36.408838)'::geometry, 3857)), +(212, 'SRID=4326;POINT(6.372528 36.408063)'::geometry, ST_Transform('SRID=4326;POINT(6.372528 36.408063)'::geometry, 3857)), +(213, 'SRID=4326;POINT(6.373022 36.408816)'::geometry, ST_Transform('SRID=4326;POINT(6.373022 36.408816)'::geometry, 3857)), +(214, 'SRID=4326;POINT(6.373019 36.408548)'::geometry, ST_Transform('SRID=4326;POINT(6.373019 36.408548)'::geometry, 3857)), +(215, 'SRID=4326;POINT(6.372454 36.408772)'::geometry, ST_Transform('SRID=4326;POINT(6.372454 36.408772)'::geometry, 3857)), +(216, 'SRID=4326;POINT(6.372993 36.408855)'::geometry, ST_Transform('SRID=4326;POINT(6.372993 36.408855)'::geometry, 3857)), +(217, 'SRID=4326;POINT(6.372609 36.40839)'::geometry, ST_Transform('SRID=4326;POINT(6.372609 36.40839)'::geometry, 3857)), +(218, 'SRID=4326;POINT(6.373079 36.408347)'::geometry, ST_Transform('SRID=4326;POINT(6.373079 36.408347)'::geometry, 3857)), +(219, 'SRID=4326;POINT(6.37296 36.408476)'::geometry, ST_Transform('SRID=4326;POINT(6.37296 36.408476)'::geometry, 3857)), +(220, 'SRID=4326;POINT(6.245506 34.781366)'::geometry, ST_Transform('SRID=4326;POINT(6.245506 34.781366)'::geometry, 3857)), +(221, 'SRID=4326;POINT(6.246049 34.781405)'::geometry, ST_Transform('SRID=4326;POINT(6.246049 34.781405)'::geometry, 3857)), +(222, 'SRID=4326;POINT(6.245706 34.780982)'::geometry, ST_Transform('SRID=4326;POINT(6.245706 34.780982)'::geometry, 3857)), +(223, 'SRID=4326;POINT(6.245218 34.78099)'::geometry, ST_Transform('SRID=4326;POINT(6.245218 34.78099)'::geometry, 3857)), +(224, 'SRID=4326;POINT(6.245708 34.781197)'::geometry, ST_Transform('SRID=4326;POINT(6.245708 34.781197)'::geometry, 3857)), +(225, 'SRID=4326;POINT(6.245418 34.781542)'::geometry, ST_Transform('SRID=4326;POINT(6.245418 34.781542)'::geometry, 3857)), +(226, 'SRID=4326;POINT(6.245194 34.781294)'::geometry, ST_Transform('SRID=4326;POINT(6.245194 34.781294)'::geometry, 3857)), +(227, 'SRID=4326;POINT(6.245286 34.781662)'::geometry, ST_Transform('SRID=4326;POINT(6.245286 34.781662)'::geometry, 3857)), +(228, 'SRID=4326;POINT(6.246011 34.781247)'::geometry, ST_Transform('SRID=4326;POINT(6.246011 34.781247)'::geometry, 3857)), +(229, 'SRID=4326;POINT(-0.923093 32.167767)'::geometry, ST_Transform('SRID=4326;POINT(-0.923093 32.167767)'::geometry, 3857)), +(230, 'SRID=4326;POINT(-0.923549 32.167517)'::geometry, ST_Transform('SRID=4326;POINT(-0.923549 32.167517)'::geometry, 3857)), +(231, 'SRID=4326;POINT(-0.923094 32.166999)'::geometry, ST_Transform('SRID=4326;POINT(-0.923094 32.166999)'::geometry, 3857)), +(232, 'SRID=4326;POINT(-0.923765 32.166879)'::geometry, ST_Transform('SRID=4326;POINT(-0.923765 32.166879)'::geometry, 3857)), +(233, 'SRID=4326;POINT(-0.92404 32.167552)'::geometry, ST_Transform('SRID=4326;POINT(-0.92404 32.167552)'::geometry, 3857)), +(234, 'SRID=4326;POINT(-0.923406 32.166902)'::geometry, ST_Transform('SRID=4326;POINT(-0.923406 32.166902)'::geometry, 3857)), +(235, 'SRID=4326;POINT(-0.923247 32.167601)'::geometry, ST_Transform('SRID=4326;POINT(-0.923247 32.167601)'::geometry, 3857)), +(236, 'SRID=4326;POINT(-0.923771 32.167432)'::geometry, ST_Transform('SRID=4326;POINT(-0.923771 32.167432)'::geometry, 3857)), +(237, 'SRID=4326;POINT(-0.923963 32.167581)'::geometry, ST_Transform('SRID=4326;POINT(-0.923963 32.167581)'::geometry, 3857)), +(238, 'SRID=4326;POINT(-9.608738 39.303829)'::geometry, ST_Transform('SRID=4326;POINT(-9.608738 39.303829)'::geometry, 3857)), +(239, 'SRID=4326;POINT(-9.608444 39.303876)'::geometry, ST_Transform('SRID=4326;POINT(-9.608444 39.303876)'::geometry, 3857)), +(240, 'SRID=4326;POINT(8.268155 38.901343)'::geometry, ST_Transform('SRID=4326;POINT(8.268155 38.901343)'::geometry, 3857)), +(241, 'SRID=4326;POINT(8.267981 38.901286)'::geometry, ST_Transform('SRID=4326;POINT(8.267981 38.901286)'::geometry, 3857)), +(242, 'SRID=4326;POINT(8.268 38.901021)'::geometry, ST_Transform('SRID=4326;POINT(8.268 38.901021)'::geometry, 3857)), +(243, 'SRID=4326;POINT(8.26786 38.900806)'::geometry, ST_Transform('SRID=4326;POINT(8.26786 38.900806)'::geometry, 3857)), +(244, 'SRID=4326;POINT(8.268006 38.900948)'::geometry, ST_Transform('SRID=4326;POINT(8.268006 38.900948)'::geometry, 3857)), +(245, 'SRID=4326;POINT(8.26838 38.901022)'::geometry, ST_Transform('SRID=4326;POINT(8.26838 38.901022)'::geometry, 3857)), +(246, 'SRID=4326;POINT(6.530044 36.477513)'::geometry, ST_Transform('SRID=4326;POINT(6.530044 36.477513)'::geometry, 3857)), +(247, 'SRID=4326;POINT(6.529964 36.477625)'::geometry, ST_Transform('SRID=4326;POINT(6.529964 36.477625)'::geometry, 3857)), +(248, 'SRID=4326;POINT(6.529983 36.476846)'::geometry, ST_Transform('SRID=4326;POINT(6.529983 36.476846)'::geometry, 3857)), +(249, 'SRID=4326;POINT(-5.266262 38.716886)'::geometry, ST_Transform('SRID=4326;POINT(-5.266262 38.716886)'::geometry, 3857)), +(250, 'SRID=4326;POINT(-5.266413 38.716785)'::geometry, ST_Transform('SRID=4326;POINT(-5.266413 38.716785)'::geometry, 3857)), +(251, 'SRID=4326;POINT(-5.266222 38.717228)'::geometry, ST_Transform('SRID=4326;POINT(-5.266222 38.717228)'::geometry, 3857)), +(252, 'SRID=4326;POINT(-5.266795 38.717403)'::geometry, ST_Transform('SRID=4326;POINT(-5.266795 38.717403)'::geometry, 3857)), +(253, 'SRID=4326;POINT(-5.2668 38.716593)'::geometry, ST_Transform('SRID=4326;POINT(-5.2668 38.716593)'::geometry, 3857)), +(254, 'SRID=4326;POINT(-5.26693 38.716904)'::geometry, ST_Transform('SRID=4326;POINT(-5.26693 38.716904)'::geometry, 3857)), +(255, 'SRID=4326;POINT(-5.26618 38.717319)'::geometry, ST_Transform('SRID=4326;POINT(-5.26618 38.717319)'::geometry, 3857)), +(256, 'SRID=4326;POINT(-5.266235 38.716907)'::geometry, ST_Transform('SRID=4326;POINT(-5.266235 38.716907)'::geometry, 3857)), +(257, 'SRID=4326;POINT(-5.266846 38.716705)'::geometry, ST_Transform('SRID=4326;POINT(-5.266846 38.716705)'::geometry, 3857)), +(258, 'SRID=4326;POINT(-5.266687 38.717023)'::geometry, ST_Transform('SRID=4326;POINT(-5.266687 38.717023)'::geometry, 3857)), +(259, 'SRID=4326;POINT(-5.266512 38.717075)'::geometry, ST_Transform('SRID=4326;POINT(-5.266512 38.717075)'::geometry, 3857)), +(260, 'SRID=4326;POINT(-5.266189 38.716888)'::geometry, ST_Transform('SRID=4326;POINT(-5.266189 38.716888)'::geometry, 3857)), +(261, 'SRID=4326;POINT(-5.266565 38.717296)'::geometry, ST_Transform('SRID=4326;POINT(-5.266565 38.717296)'::geometry, 3857)), +(262, 'SRID=4326;POINT(9.504841 37.828039)'::geometry, ST_Transform('SRID=4326;POINT(9.504841 37.828039)'::geometry, 3857)), +(263, 'SRID=4326;POINT(9.504447 37.828131)'::geometry, ST_Transform('SRID=4326;POINT(9.504447 37.828131)'::geometry, 3857)), +(264, 'SRID=4326;POINT(9.505267 37.827879)'::geometry, ST_Transform('SRID=4326;POINT(9.505267 37.827879)'::geometry, 3857)), +(265, 'SRID=4326;POINT(9.505171 37.828127)'::geometry, ST_Transform('SRID=4326;POINT(9.505171 37.828127)'::geometry, 3857)), +(266, 'SRID=4326;POINT(9.505196 37.827809)'::geometry, ST_Transform('SRID=4326;POINT(9.505196 37.827809)'::geometry, 3857)), +(267, 'SRID=4326;POINT(9.505213 37.827885)'::geometry, ST_Transform('SRID=4326;POINT(9.505213 37.827885)'::geometry, 3857)), +(268, 'SRID=4326;POINT(9.504808 37.827401)'::geometry, ST_Transform('SRID=4326;POINT(9.504808 37.827401)'::geometry, 3857)), +(269, 'SRID=4326;POINT(-2.170801 36.903601)'::geometry, ST_Transform('SRID=4326;POINT(-2.170801 36.903601)'::geometry, 3857)), +(270, 'SRID=4326;POINT(-2.171542 36.904446)'::geometry, ST_Transform('SRID=4326;POINT(-2.171542 36.904446)'::geometry, 3857)), +(271, 'SRID=4326;POINT(-2.17161 36.904028)'::geometry, ST_Transform('SRID=4326;POINT(-2.17161 36.904028)'::geometry, 3857)), +(272, 'SRID=4326;POINT(-2.171332 36.903833)'::geometry, ST_Transform('SRID=4326;POINT(-2.171332 36.903833)'::geometry, 3857)), +(273, 'SRID=4326;POINT(-2.171042 36.904388)'::geometry, ST_Transform('SRID=4326;POINT(-2.171042 36.904388)'::geometry, 3857)), +(274, 'SRID=4326;POINT(-2.170963 36.903795)'::geometry, ST_Transform('SRID=4326;POINT(-2.170963 36.903795)'::geometry, 3857)), +(275, 'SRID=4326;POINT(-2.170688 36.903863)'::geometry, ST_Transform('SRID=4326;POINT(-2.170688 36.903863)'::geometry, 3857)), +(276, 'SRID=4326;POINT(-2.171087 36.903635)'::geometry, ST_Transform('SRID=4326;POINT(-2.171087 36.903635)'::geometry, 3857)), +(277, 'SRID=4326;POINT(-2.171346 36.903793)'::geometry, ST_Transform('SRID=4326;POINT(-2.171346 36.903793)'::geometry, 3857)), +(278, 'SRID=4326;POINT(-2.171005 36.903886)'::geometry, ST_Transform('SRID=4326;POINT(-2.171005 36.903886)'::geometry, 3857)), +(279, 'SRID=4326;POINT(-2.171343 36.9036)'::geometry, ST_Transform('SRID=4326;POINT(-2.171343 36.9036)'::geometry, 3857)), +(280, 'SRID=4326;POINT(-2.171242 36.904239)'::geometry, ST_Transform('SRID=4326;POINT(-2.171242 36.904239)'::geometry, 3857)), +(281, 'SRID=4326;POINT(-2.170868 36.903745)'::geometry, ST_Transform('SRID=4326;POINT(-2.170868 36.903745)'::geometry, 3857)), +(282, 'SRID=4326;POINT(-2.170799 36.90389)'::geometry, ST_Transform('SRID=4326;POINT(-2.170799 36.90389)'::geometry, 3857)), +(283, 'SRID=4326;POINT(-2.171564 36.903816)'::geometry, ST_Transform('SRID=4326;POINT(-2.171564 36.903816)'::geometry, 3857)), +(284, 'SRID=4326;POINT(8.368988 30.229265)'::geometry, ST_Transform('SRID=4326;POINT(8.368988 30.229265)'::geometry, 3857)), +(285, 'SRID=4326;POINT(8.369595 30.230013)'::geometry, ST_Transform('SRID=4326;POINT(8.369595 30.230013)'::geometry, 3857)), +(286, 'SRID=4326;POINT(8.3694 30.230109)'::geometry, ST_Transform('SRID=4326;POINT(8.3694 30.230109)'::geometry, 3857)), +(287, 'SRID=4326;POINT(8.369027 30.230082)'::geometry, ST_Transform('SRID=4326;POINT(8.369027 30.230082)'::geometry, 3857)), +(288, 'SRID=4326;POINT(8.368959 30.229372)'::geometry, ST_Transform('SRID=4326;POINT(8.368959 30.229372)'::geometry, 3857)), +(289, 'SRID=4326;POINT(8.369272 30.229717)'::geometry, ST_Transform('SRID=4326;POINT(8.369272 30.229717)'::geometry, 3857)), +(290, 'SRID=4326;POINT(8.369758 30.230161)'::geometry, ST_Transform('SRID=4326;POINT(8.369758 30.230161)'::geometry, 3857)), +(291, 'SRID=4326;POINT(8.36936 30.229783)'::geometry, ST_Transform('SRID=4326;POINT(8.36936 30.229783)'::geometry, 3857)), +(292, 'SRID=4326;POINT(-2.999782 31.589505)'::geometry, ST_Transform('SRID=4326;POINT(-2.999782 31.589505)'::geometry, 3857)), +(293, 'SRID=4326;POINT(-3.000221 31.589572)'::geometry, ST_Transform('SRID=4326;POINT(-3.000221 31.589572)'::geometry, 3857)), +(294, 'SRID=4326;POINT(-3.000412 31.589102)'::geometry, ST_Transform('SRID=4326;POINT(-3.000412 31.589102)'::geometry, 3857)), +(295, 'SRID=4326;POINT(-2.999662 31.589182)'::geometry, ST_Transform('SRID=4326;POINT(-2.999662 31.589182)'::geometry, 3857)), +(296, 'SRID=4326;POINT(-3.000224 31.589259)'::geometry, ST_Transform('SRID=4326;POINT(-3.000224 31.589259)'::geometry, 3857)), +(297, 'SRID=4326;POINT(-2.999983 31.589437)'::geometry, ST_Transform('SRID=4326;POINT(-2.999983 31.589437)'::geometry, 3857)), +(298, 'SRID=4326;POINT(-2.999877 31.589458)'::geometry, ST_Transform('SRID=4326;POINT(-2.999877 31.589458)'::geometry, 3857)), +(299, 'SRID=4326;POINT(-3.000263 31.589101)'::geometry, ST_Transform('SRID=4326;POINT(-3.000263 31.589101)'::geometry, 3857)), +(300, 'SRID=4326;POINT(-3.000401 31.589088)'::geometry, ST_Transform('SRID=4326;POINT(-3.000401 31.589088)'::geometry, 3857)), +(301, 'SRID=4326;POINT(-4.385852 39.752276)'::geometry, ST_Transform('SRID=4326;POINT(-4.385852 39.752276)'::geometry, 3857)), +(302, 'SRID=4326;POINT(-4.385884 39.752477)'::geometry, ST_Transform('SRID=4326;POINT(-4.385884 39.752477)'::geometry, 3857)), +(303, 'SRID=4326;POINT(-4.385735 39.752246)'::geometry, ST_Transform('SRID=4326;POINT(-4.385735 39.752246)'::geometry, 3857)), +(304, 'SRID=4326;POINT(-4.385942 39.752032)'::geometry, ST_Transform('SRID=4326;POINT(-4.385942 39.752032)'::geometry, 3857)), +(305, 'SRID=4326;POINT(-4.386277 39.751596)'::geometry, ST_Transform('SRID=4326;POINT(-4.386277 39.751596)'::geometry, 3857)), +(306, 'SRID=4326;POINT(-4.386394 39.751679)'::geometry, ST_Transform('SRID=4326;POINT(-4.386394 39.751679)'::geometry, 3857)), +(307, 'SRID=4326;POINT(-4.385727 39.752405)'::geometry, ST_Transform('SRID=4326;POINT(-4.385727 39.752405)'::geometry, 3857)), +(308, 'SRID=4326;POINT(-4.38659 39.752503)'::geometry, ST_Transform('SRID=4326;POINT(-4.38659 39.752503)'::geometry, 3857)), +(309, 'SRID=4326;POINT(-4.386676 39.751577)'::geometry, ST_Transform('SRID=4326;POINT(-4.386676 39.751577)'::geometry, 3857)), +(310, 'SRID=4326;POINT(-4.386058 39.752441)'::geometry, ST_Transform('SRID=4326;POINT(-4.386058 39.752441)'::geometry, 3857)), +(311, 'SRID=4326;POINT(8.783959 38.480157)'::geometry, ST_Transform('SRID=4326;POINT(8.783959 38.480157)'::geometry, 3857)), +(312, 'SRID=4326;POINT(8.784044 38.480085)'::geometry, ST_Transform('SRID=4326;POINT(8.784044 38.480085)'::geometry, 3857)), +(313, 'SRID=4326;POINT(8.78403 38.480162)'::geometry, ST_Transform('SRID=4326;POINT(8.78403 38.480162)'::geometry, 3857)), +(314, 'SRID=4326;POINT(8.784699 38.480106)'::geometry, ST_Transform('SRID=4326;POINT(8.784699 38.480106)'::geometry, 3857)), +(315, 'SRID=4326;POINT(8.784249 38.479839)'::geometry, ST_Transform('SRID=4326;POINT(8.784249 38.479839)'::geometry, 3857)), +(316, 'SRID=4326;POINT(8.783899 38.479817)'::geometry, ST_Transform('SRID=4326;POINT(8.783899 38.479817)'::geometry, 3857)), +(317, 'SRID=4326;POINT(8.78446 38.480156)'::geometry, ST_Transform('SRID=4326;POINT(8.78446 38.480156)'::geometry, 3857)), +(318, 'SRID=4326;POINT(8.784665 38.479739)'::geometry, ST_Transform('SRID=4326;POINT(8.784665 38.479739)'::geometry, 3857)), +(319, 'SRID=4326;POINT(8.784078 38.479956)'::geometry, ST_Transform('SRID=4326;POINT(8.784078 38.479956)'::geometry, 3857)), +(320, 'SRID=4326;POINT(8.783993 38.47977)'::geometry, ST_Transform('SRID=4326;POINT(8.783993 38.47977)'::geometry, 3857)), +(321, 'SRID=4326;POINT(8.784086 38.479532)'::geometry, ST_Transform('SRID=4326;POINT(8.784086 38.479532)'::geometry, 3857)), +(322, 'SRID=4326;POINT(8.784273 38.47969)'::geometry, ST_Transform('SRID=4326;POINT(8.784273 38.47969)'::geometry, 3857)), +(323, 'SRID=4326;POINT(8.784413 38.480132)'::geometry, ST_Transform('SRID=4326;POINT(8.784413 38.480132)'::geometry, 3857)), +(324, 'SRID=4326;POINT(8.784039 38.479655)'::geometry, ST_Transform('SRID=4326;POINT(8.784039 38.479655)'::geometry, 3857)), +(325, 'SRID=4326;POINT(8.783959 38.479375)'::geometry, ST_Transform('SRID=4326;POINT(8.783959 38.479375)'::geometry, 3857)), +(326, 'SRID=4326;POINT(-8.060178 31.973027)'::geometry, ST_Transform('SRID=4326;POINT(-8.060178 31.973027)'::geometry, 3857)), +(327, 'SRID=4326;POINT(-8.059659 31.973225)'::geometry, ST_Transform('SRID=4326;POINT(-8.059659 31.973225)'::geometry, 3857)), +(328, 'SRID=4326;POINT(-8.059924 31.973108)'::geometry, ST_Transform('SRID=4326;POINT(-8.059924 31.973108)'::geometry, 3857)), +(329, 'SRID=4326;POINT(-8.060125 31.973226)'::geometry, ST_Transform('SRID=4326;POINT(-8.060125 31.973226)'::geometry, 3857)), +(330, 'SRID=4326;POINT(-8.059829 31.973612)'::geometry, ST_Transform('SRID=4326;POINT(-8.059829 31.973612)'::geometry, 3857)), +(331, 'SRID=4326;POINT(-8.060249 31.97362)'::geometry, ST_Transform('SRID=4326;POINT(-8.060249 31.97362)'::geometry, 3857)), +(332, 'SRID=4326;POINT(-8.059803 31.972989)'::geometry, ST_Transform('SRID=4326;POINT(-8.059803 31.972989)'::geometry, 3857)), +(333, 'SRID=4326;POINT(-8.059599 31.973695)'::geometry, ST_Transform('SRID=4326;POINT(-8.059599 31.973695)'::geometry, 3857)), +(334, 'SRID=4326;POINT(-8.059936 31.973495)'::geometry, ST_Transform('SRID=4326;POINT(-8.059936 31.973495)'::geometry, 3857)), +(335, 'SRID=4326;POINT(-8.05947 31.97354)'::geometry, ST_Transform('SRID=4326;POINT(-8.05947 31.97354)'::geometry, 3857)), +(336, 'SRID=4326;POINT(-8.059534 31.973116)'::geometry, ST_Transform('SRID=4326;POINT(-8.059534 31.973116)'::geometry, 3857)), +(337, 'SRID=4326;POINT(-8.059575 31.973105)'::geometry, ST_Transform('SRID=4326;POINT(-8.059575 31.973105)'::geometry, 3857)), +(338, 'SRID=4326;POINT(-4.63212 35.998127)'::geometry, ST_Transform('SRID=4326;POINT(-4.63212 35.998127)'::geometry, 3857)), +(339, 'SRID=4326;POINT(-4.632715 35.998019)'::geometry, ST_Transform('SRID=4326;POINT(-4.632715 35.998019)'::geometry, 3857)), +(340, 'SRID=4326;POINT(-4.632119 35.997393)'::geometry, ST_Transform('SRID=4326;POINT(-4.632119 35.997393)'::geometry, 3857)), +(341, 'SRID=4326;POINT(-4.632803 35.99753)'::geometry, ST_Transform('SRID=4326;POINT(-4.632803 35.99753)'::geometry, 3857)), +(342, 'SRID=4326;POINT(-9.077417 37.751901)'::geometry, ST_Transform('SRID=4326;POINT(-9.077417 37.751901)'::geometry, 3857)), +(343, 'SRID=4326;POINT(-9.077265 37.752111)'::geometry, ST_Transform('SRID=4326;POINT(-9.077265 37.752111)'::geometry, 3857)), +(344, 'SRID=4326;POINT(-9.077343 37.75176)'::geometry, ST_Transform('SRID=4326;POINT(-9.077343 37.75176)'::geometry, 3857)), +(345, 'SRID=4326;POINT(-9.077467 37.751908)'::geometry, ST_Transform('SRID=4326;POINT(-9.077467 37.751908)'::geometry, 3857)), +(346, 'SRID=4326;POINT(-9.077027 37.751421)'::geometry, ST_Transform('SRID=4326;POINT(-9.077027 37.751421)'::geometry, 3857)), +(347, 'SRID=4326;POINT(-9.077902 37.751891)'::geometry, ST_Transform('SRID=4326;POINT(-9.077902 37.751891)'::geometry, 3857)), +(348, 'SRID=4326;POINT(-9.077804 37.751888)'::geometry, ST_Transform('SRID=4326;POINT(-9.077804 37.751888)'::geometry, 3857)), +(349, 'SRID=4326;POINT(-9.077673 37.751405)'::geometry, ST_Transform('SRID=4326;POINT(-9.077673 37.751405)'::geometry, 3857)), +(350, 'SRID=4326;POINT(-9.076988 37.751842)'::geometry, ST_Transform('SRID=4326;POINT(-9.076988 37.751842)'::geometry, 3857)), +(351, 'SRID=4326;POINT(-9.077688 37.75141)'::geometry, ST_Transform('SRID=4326;POINT(-9.077688 37.75141)'::geometry, 3857)), +(352, 'SRID=4326;POINT(-9.077493 37.751423)'::geometry, ST_Transform('SRID=4326;POINT(-9.077493 37.751423)'::geometry, 3857)), +(353, 'SRID=4326;POINT(-9.07777 37.75196)'::geometry, ST_Transform('SRID=4326;POINT(-9.07777 37.75196)'::geometry, 3857)), +(354, 'SRID=4326;POINT(-9.077415 37.751844)'::geometry, ST_Transform('SRID=4326;POINT(-9.077415 37.751844)'::geometry, 3857)), +(355, 'SRID=4326;POINT(-9.077104 37.751428)'::geometry, ST_Transform('SRID=4326;POINT(-9.077104 37.751428)'::geometry, 3857)), +(356, 'SRID=4326;POINT(-9.077731 37.751225)'::geometry, ST_Transform('SRID=4326;POINT(-9.077731 37.751225)'::geometry, 3857)), +(357, 'SRID=4326;POINT(5.736671 39.05025)'::geometry, ST_Transform('SRID=4326;POINT(5.736671 39.05025)'::geometry, 3857)), +(358, 'SRID=4326;POINT(2.486706 38.642451)'::geometry, ST_Transform('SRID=4326;POINT(2.486706 38.642451)'::geometry, 3857)), +(359, 'SRID=4326;POINT(2.487244 38.642613)'::geometry, ST_Transform('SRID=4326;POINT(2.487244 38.642613)'::geometry, 3857)), +(360, 'SRID=4326;POINT(2.487265 38.64297)'::geometry, ST_Transform('SRID=4326;POINT(2.487265 38.64297)'::geometry, 3857)), +(361, 'SRID=4326;POINT(2.487094 38.642426)'::geometry, ST_Transform('SRID=4326;POINT(2.487094 38.642426)'::geometry, 3857)), +(362, 'SRID=4326;POINT(2.486678 38.642585)'::geometry, ST_Transform('SRID=4326;POINT(2.486678 38.642585)'::geometry, 3857)), +(363, 'SRID=4326;POINT(2.487308 38.642908)'::geometry, ST_Transform('SRID=4326;POINT(2.487308 38.642908)'::geometry, 3857)), +(364, 'SRID=4326;POINT(2.486737 38.642071)'::geometry, ST_Transform('SRID=4326;POINT(2.486737 38.642071)'::geometry, 3857)), +(365, 'SRID=4326;POINT(2.486899 38.642834)'::geometry, ST_Transform('SRID=4326;POINT(2.486899 38.642834)'::geometry, 3857)), +(366, 'SRID=4326;POINT(2.487133 38.642518)'::geometry, ST_Transform('SRID=4326;POINT(2.487133 38.642518)'::geometry, 3857)), +(367, 'SRID=4326;POINT(0.190222 39.022953)'::geometry, ST_Transform('SRID=4326;POINT(0.190222 39.022953)'::geometry, 3857)), +(368, 'SRID=4326;POINT(0.190043 39.023114)'::geometry, ST_Transform('SRID=4326;POINT(0.190043 39.023114)'::geometry, 3857)), +(369, 'SRID=4326;POINT(0.190124 39.023072)'::geometry, ST_Transform('SRID=4326;POINT(0.190124 39.023072)'::geometry, 3857)), +(370, 'SRID=4326;POINT(0.190422 39.023139)'::geometry, ST_Transform('SRID=4326;POINT(0.190422 39.023139)'::geometry, 3857)), +(371, 'SRID=4326;POINT(0.190447 39.023119)'::geometry, ST_Transform('SRID=4326;POINT(0.190447 39.023119)'::geometry, 3857)), +(372, 'SRID=4326;POINT(0.190864 39.022787)'::geometry, ST_Transform('SRID=4326;POINT(0.190864 39.022787)'::geometry, 3857)), +(373, 'SRID=4326;POINT(0.190587 39.023213)'::geometry, ST_Transform('SRID=4326;POINT(0.190587 39.023213)'::geometry, 3857)), +(374, 'SRID=4326;POINT(0.190173 39.023267)'::geometry, ST_Transform('SRID=4326;POINT(0.190173 39.023267)'::geometry, 3857)), +(375, 'SRID=4326;POINT(0.190158 39.023269)'::geometry, ST_Transform('SRID=4326;POINT(0.190158 39.023269)'::geometry, 3857)), +(376, 'SRID=4326;POINT(0.190034 39.023105)'::geometry, ST_Transform('SRID=4326;POINT(0.190034 39.023105)'::geometry, 3857)), +(377, 'SRID=4326;POINT(0.190614 39.023247)'::geometry, ST_Transform('SRID=4326;POINT(0.190614 39.023247)'::geometry, 3857)), +(378, 'SRID=4326;POINT(0.19013 39.022976)'::geometry, ST_Transform('SRID=4326;POINT(0.19013 39.022976)'::geometry, 3857)), +(379, 'SRID=4326;POINT(0.190578 39.023254)'::geometry, ST_Transform('SRID=4326;POINT(0.190578 39.023254)'::geometry, 3857)), +(380, 'SRID=4326;POINT(-4.726492 38.505264)'::geometry, ST_Transform('SRID=4326;POINT(-4.726492 38.505264)'::geometry, 3857)), +(381, 'SRID=4326;POINT(-4.726996 38.505473)'::geometry, ST_Transform('SRID=4326;POINT(-4.726996 38.505473)'::geometry, 3857)), +(382, 'SRID=4326;POINT(6.295031 33.792646)'::geometry, ST_Transform('SRID=4326;POINT(6.295031 33.792646)'::geometry, 3857)), +(383, 'SRID=4326;POINT(6.29525 33.792686)'::geometry, ST_Transform('SRID=4326;POINT(6.29525 33.792686)'::geometry, 3857)), +(384, 'SRID=4326;POINT(6.294926 33.793128)'::geometry, ST_Transform('SRID=4326;POINT(6.294926 33.793128)'::geometry, 3857)), +(385, 'SRID=4326;POINT(6.295688 33.792557)'::geometry, ST_Transform('SRID=4326;POINT(6.295688 33.792557)'::geometry, 3857)), +(386, 'SRID=4326;POINT(6.295214 33.792642)'::geometry, ST_Transform('SRID=4326;POINT(6.295214 33.792642)'::geometry, 3857)), +(387, 'SRID=4326;POINT(6.295116 33.792807)'::geometry, ST_Transform('SRID=4326;POINT(6.295116 33.792807)'::geometry, 3857)), +(388, 'SRID=4326;POINT(6.295144 33.792432)'::geometry, ST_Transform('SRID=4326;POINT(6.295144 33.792432)'::geometry, 3857)), +(389, 'SRID=4326;POINT(6.295344 33.793005)'::geometry, ST_Transform('SRID=4326;POINT(6.295344 33.793005)'::geometry, 3857)), +(390, 'SRID=4326;POINT(6.294974 33.792792)'::geometry, ST_Transform('SRID=4326;POINT(6.294974 33.792792)'::geometry, 3857)), +(391, 'SRID=4326;POINT(6.29545 33.792402)'::geometry, ST_Transform('SRID=4326;POINT(6.29545 33.792402)'::geometry, 3857)), +(392, 'SRID=4326;POINT(6.295601 33.792992)'::geometry, ST_Transform('SRID=4326;POINT(6.295601 33.792992)'::geometry, 3857)), +(393, 'SRID=4326;POINT(6.295289 33.79258)'::geometry, ST_Transform('SRID=4326;POINT(6.295289 33.79258)'::geometry, 3857)), +(394, 'SRID=4326;POINT(6.295285 33.79334)'::geometry, ST_Transform('SRID=4326;POINT(6.295285 33.79334)'::geometry, 3857)), +(395, 'SRID=4326;POINT(6.295307 33.792945)'::geometry, ST_Transform('SRID=4326;POINT(6.295307 33.792945)'::geometry, 3857)), +(396, 'SRID=4326;POINT(-3.961321 37.574227)'::geometry, ST_Transform('SRID=4326;POINT(-3.961321 37.574227)'::geometry, 3857)), +(397, 'SRID=4326;POINT(-3.961179 37.574737)'::geometry, ST_Transform('SRID=4326;POINT(-3.961179 37.574737)'::geometry, 3857)), +(398, 'SRID=4326;POINT(-3.961895 37.574623)'::geometry, ST_Transform('SRID=4326;POINT(-3.961895 37.574623)'::geometry, 3857)), +(399, 'SRID=4326;POINT(-3.961152 37.574831)'::geometry, ST_Transform('SRID=4326;POINT(-3.961152 37.574831)'::geometry, 3857)), +(400, 'SRID=4326;POINT(-3.961619 37.574905)'::geometry, ST_Transform('SRID=4326;POINT(-3.961619 37.574905)'::geometry, 3857)), +(401, 'SRID=4326;POINT(-3.961297 37.574127)'::geometry, ST_Transform('SRID=4326;POINT(-3.961297 37.574127)'::geometry, 3857)), +(402, 'SRID=4326;POINT(-3.961714 37.574449)'::geometry, ST_Transform('SRID=4326;POINT(-3.961714 37.574449)'::geometry, 3857)), +(403, 'SRID=4326;POINT(-3.961663 37.574729)'::geometry, ST_Transform('SRID=4326;POINT(-3.961663 37.574729)'::geometry, 3857)), +(404, 'SRID=4326;POINT(-3.962034 37.574013)'::geometry, ST_Transform('SRID=4326;POINT(-3.962034 37.574013)'::geometry, 3857)), +(405, 'SRID=4326;POINT(-3.961185 37.574931)'::geometry, ST_Transform('SRID=4326;POINT(-3.961185 37.574931)'::geometry, 3857)), +(406, 'SRID=4326;POINT(-3.96149 37.574124)'::geometry, ST_Transform('SRID=4326;POINT(-3.96149 37.574124)'::geometry, 3857)), +(407, 'SRID=4326;POINT(-3.961513 37.574389)'::geometry, ST_Transform('SRID=4326;POINT(-3.961513 37.574389)'::geometry, 3857)), +(408, 'SRID=4326;POINT(-3.962069 37.57462)'::geometry, ST_Transform('SRID=4326;POINT(-3.962069 37.57462)'::geometry, 3857)), +(409, 'SRID=4326;POINT(-3.961603 37.574585)'::geometry, ST_Transform('SRID=4326;POINT(-3.961603 37.574585)'::geometry, 3857)), +(410, 'SRID=4326;POINT(-9.221169 39.607003)'::geometry, ST_Transform('SRID=4326;POINT(-9.221169 39.607003)'::geometry, 3857)), +(411, 'SRID=4326;POINT(-9.221883 39.607595)'::geometry, ST_Transform('SRID=4326;POINT(-9.221883 39.607595)'::geometry, 3857)), +(412, 'SRID=4326;POINT(-9.222102 39.607298)'::geometry, ST_Transform('SRID=4326;POINT(-9.222102 39.607298)'::geometry, 3857)), +(413, 'SRID=4326;POINT(-9.222118 39.606969)'::geometry, ST_Transform('SRID=4326;POINT(-9.222118 39.606969)'::geometry, 3857)), +(414, 'SRID=4326;POINT(-9.221516 39.607447)'::geometry, ST_Transform('SRID=4326;POINT(-9.221516 39.607447)'::geometry, 3857)), +(415, 'SRID=4326;POINT(-9.222017 39.607394)'::geometry, ST_Transform('SRID=4326;POINT(-9.222017 39.607394)'::geometry, 3857)), +(416, 'SRID=4326;POINT(-9.22136 39.607455)'::geometry, ST_Transform('SRID=4326;POINT(-9.22136 39.607455)'::geometry, 3857)), +(417, 'SRID=4326;POINT(-9.222014 39.606962)'::geometry, ST_Transform('SRID=4326;POINT(-9.222014 39.606962)'::geometry, 3857)), +(418, 'SRID=4326;POINT(-9.221755 39.607393)'::geometry, ST_Transform('SRID=4326;POINT(-9.221755 39.607393)'::geometry, 3857)), +(419, 'SRID=4326;POINT(-9.221748 39.607181)'::geometry, ST_Transform('SRID=4326;POINT(-9.221748 39.607181)'::geometry, 3857)), +(420, 'SRID=4326;POINT(-9.221728 39.607402)'::geometry, ST_Transform('SRID=4326;POINT(-9.221728 39.607402)'::geometry, 3857)), +(421, 'SRID=4326;POINT(-9.221372 39.60722)'::geometry, ST_Transform('SRID=4326;POINT(-9.221372 39.60722)'::geometry, 3857)), +(422, 'SRID=4326;POINT(-9.221399 39.607532)'::geometry, ST_Transform('SRID=4326;POINT(-9.221399 39.607532)'::geometry, 3857)), +(423, 'SRID=4326;POINT(-9.221766 39.60764)'::geometry, ST_Transform('SRID=4326;POINT(-9.221766 39.60764)'::geometry, 3857)), +(424, 'SRID=4326;POINT(-9.221211 39.607327)'::geometry, ST_Transform('SRID=4326;POINT(-9.221211 39.607327)'::geometry, 3857)), +(425, 'SRID=4326;POINT(-9.221834 39.607635)'::geometry, ST_Transform('SRID=4326;POINT(-9.221834 39.607635)'::geometry, 3857)), +(426, 'SRID=4326;POINT(6.85655 34.912087)'::geometry, ST_Transform('SRID=4326;POINT(6.85655 34.912087)'::geometry, 3857)), +(427, 'SRID=4326;POINT(6.856473 34.912241)'::geometry, ST_Transform('SRID=4326;POINT(6.856473 34.912241)'::geometry, 3857)), +(428, 'SRID=4326;POINT(6.856142 34.912217)'::geometry, ST_Transform('SRID=4326;POINT(6.856142 34.912217)'::geometry, 3857)), +(429, 'SRID=4326;POINT(6.856378 34.912182)'::geometry, ST_Transform('SRID=4326;POINT(6.856378 34.912182)'::geometry, 3857)), +(430, 'SRID=4326;POINT(6.856079 34.912444)'::geometry, ST_Transform('SRID=4326;POINT(6.856079 34.912444)'::geometry, 3857)), +(431, 'SRID=4326;POINT(6.856087 34.911668)'::geometry, ST_Transform('SRID=4326;POINT(6.856087 34.911668)'::geometry, 3857)), +(432, 'SRID=4326;POINT(6.856699 34.911491)'::geometry, ST_Transform('SRID=4326;POINT(6.856699 34.911491)'::geometry, 3857)), +(433, 'SRID=4326;POINT(6.856371 34.911687)'::geometry, ST_Transform('SRID=4326;POINT(6.856371 34.911687)'::geometry, 3857)), +(434, 'SRID=4326;POINT(6.856564 34.91177)'::geometry, ST_Transform('SRID=4326;POINT(6.856564 34.91177)'::geometry, 3857)), +(435, 'SRID=4326;POINT(6.856768 34.911903)'::geometry, ST_Transform('SRID=4326;POINT(6.856768 34.911903)'::geometry, 3857)), +(436, 'SRID=4326;POINT(6.856324 34.912415)'::geometry, ST_Transform('SRID=4326;POINT(6.856324 34.912415)'::geometry, 3857)), +(437, 'SRID=4326;POINT(6.856826 34.911767)'::geometry, ST_Transform('SRID=4326;POINT(6.856826 34.911767)'::geometry, 3857)), +(438, 'SRID=4326;POINT(6.856792 34.912182)'::geometry, ST_Transform('SRID=4326;POINT(6.856792 34.912182)'::geometry, 3857)), +(439, 'SRID=4326;POINT(6.856929 34.912379)'::geometry, ST_Transform('SRID=4326;POINT(6.856929 34.912379)'::geometry, 3857)), +(440, 'SRID=4326;POINT(6.85643 34.912242)'::geometry, ST_Transform('SRID=4326;POINT(6.85643 34.912242)'::geometry, 3857)), +(441, 'SRID=4326;POINT(3.596947 38.1486)'::geometry, ST_Transform('SRID=4326;POINT(3.596947 38.1486)'::geometry, 3857)), +(442, 'SRID=4326;POINT(3.596769 38.148948)'::geometry, ST_Transform('SRID=4326;POINT(3.596769 38.148948)'::geometry, 3857)), +(443, 'SRID=4326;POINT(3.596829 38.148394)'::geometry, ST_Transform('SRID=4326;POINT(3.596829 38.148394)'::geometry, 3857)), +(444, 'SRID=4326;POINT(3.597295 38.14811)'::geometry, ST_Transform('SRID=4326;POINT(3.597295 38.14811)'::geometry, 3857)), +(445, 'SRID=4326;POINT(3.597307 38.148007)'::geometry, ST_Transform('SRID=4326;POINT(3.597307 38.148007)'::geometry, 3857)), +(446, 'SRID=4326;POINT(3.597512 38.148592)'::geometry, ST_Transform('SRID=4326;POINT(3.597512 38.148592)'::geometry, 3857)), +(447, 'SRID=4326;POINT(3.596798 38.148721)'::geometry, ST_Transform('SRID=4326;POINT(3.596798 38.148721)'::geometry, 3857)), +(448, 'SRID=4326;POINT(3.597043 38.14809)'::geometry, ST_Transform('SRID=4326;POINT(3.597043 38.14809)'::geometry, 3857)), +(449, 'SRID=4326;POINT(3.597261 38.148706)'::geometry, ST_Transform('SRID=4326;POINT(3.597261 38.148706)'::geometry, 3857)), +(450, 'SRID=4326;POINT(3.597318 38.14896)'::geometry, ST_Transform('SRID=4326;POINT(3.597318 38.14896)'::geometry, 3857)), +(451, 'SRID=4326;POINT(7.017467 32.682268)'::geometry, ST_Transform('SRID=4326;POINT(7.017467 32.682268)'::geometry, 3857)), +(452, 'SRID=4326;POINT(7.017442 32.682523)'::geometry, ST_Transform('SRID=4326;POINT(7.017442 32.682523)'::geometry, 3857)), +(453, 'SRID=4326;POINT(7.017381 32.682706)'::geometry, ST_Transform('SRID=4326;POINT(7.017381 32.682706)'::geometry, 3857)), +(454, 'SRID=4326;POINT(7.017033 32.6818)'::geometry, ST_Transform('SRID=4326;POINT(7.017033 32.6818)'::geometry, 3857)), +(455, 'SRID=4326;POINT(7.017106 32.681931)'::geometry, ST_Transform('SRID=4326;POINT(7.017106 32.681931)'::geometry, 3857)), +(456, 'SRID=4326;POINT(7.017705 32.682579)'::geometry, ST_Transform('SRID=4326;POINT(7.017705 32.682579)'::geometry, 3857)), +(457, 'SRID=4326;POINT(7.017261 32.682337)'::geometry, ST_Transform('SRID=4326;POINT(7.017261 32.682337)'::geometry, 3857)), +(458, 'SRID=4326;POINT(7.017581 32.682233)'::geometry, ST_Transform('SRID=4326;POINT(7.017581 32.682233)'::geometry, 3857)), +(459, 'SRID=4326;POINT(7.017235 32.682232)'::geometry, ST_Transform('SRID=4326;POINT(7.017235 32.682232)'::geometry, 3857)), +(460, 'SRID=4326;POINT(7.017307 32.682267)'::geometry, ST_Transform('SRID=4326;POINT(7.017307 32.682267)'::geometry, 3857)), +(461, 'SRID=4326;POINT(7.017528 32.682155)'::geometry, ST_Transform('SRID=4326;POINT(7.017528 32.682155)'::geometry, 3857)), +(462, 'SRID=4326;POINT(7.017666 32.682105)'::geometry, ST_Transform('SRID=4326;POINT(7.017666 32.682105)'::geometry, 3857)), +(463, 'SRID=4326;POINT(7.017189 32.682041)'::geometry, ST_Transform('SRID=4326;POINT(7.017189 32.682041)'::geometry, 3857)), +(464, 'SRID=4326;POINT(-8.05544 34.279282)'::geometry, ST_Transform('SRID=4326;POINT(-8.05544 34.279282)'::geometry, 3857)), +(465, 'SRID=4326;POINT(-8.055997 34.279187)'::geometry, ST_Transform('SRID=4326;POINT(-8.055997 34.279187)'::geometry, 3857)), +(466, 'SRID=4326;POINT(-8.055628 34.278509)'::geometry, ST_Transform('SRID=4326;POINT(-8.055628 34.278509)'::geometry, 3857)), +(467, 'SRID=4326;POINT(-8.056024 34.278599)'::geometry, ST_Transform('SRID=4326;POINT(-8.056024 34.278599)'::geometry, 3857)), +(468, 'SRID=4326;POINT(-8.056048 34.278384)'::geometry, ST_Transform('SRID=4326;POINT(-8.056048 34.278384)'::geometry, 3857)), +(469, 'SRID=4326;POINT(-8.05553 34.278415)'::geometry, ST_Transform('SRID=4326;POINT(-8.05553 34.278415)'::geometry, 3857)), +(470, 'SRID=4326;POINT(-8.055728 34.279115)'::geometry, ST_Transform('SRID=4326;POINT(-8.055728 34.279115)'::geometry, 3857)), +(471, 'SRID=4326;POINT(-8.056245 34.278838)'::geometry, ST_Transform('SRID=4326;POINT(-8.056245 34.278838)'::geometry, 3857)), +(472, 'SRID=4326;POINT(-8.055941 34.279043)'::geometry, ST_Transform('SRID=4326;POINT(-8.055941 34.279043)'::geometry, 3857)), +(473, 'SRID=4326;POINT(-7.228337 37.816001)'::geometry, ST_Transform('SRID=4326;POINT(-7.228337 37.816001)'::geometry, 3857)), +(474, 'SRID=4326;POINT(-7.227998 37.816439)'::geometry, ST_Transform('SRID=4326;POINT(-7.227998 37.816439)'::geometry, 3857)), +(475, 'SRID=4326;POINT(-7.228233 37.816839)'::geometry, ST_Transform('SRID=4326;POINT(-7.228233 37.816839)'::geometry, 3857)), +(476, 'SRID=4326;POINT(-7.228156 37.816186)'::geometry, ST_Transform('SRID=4326;POINT(-7.228156 37.816186)'::geometry, 3857)), +(477, 'SRID=4326;POINT(-7.227702 37.816616)'::geometry, ST_Transform('SRID=4326;POINT(-7.227702 37.816616)'::geometry, 3857)), +(478, 'SRID=4326;POINT(-1.129358 38.380395)'::geometry, ST_Transform('SRID=4326;POINT(-1.129358 38.380395)'::geometry, 3857)), +(479, 'SRID=4326;POINT(-1.129632 38.379986)'::geometry, ST_Transform('SRID=4326;POINT(-1.129632 38.379986)'::geometry, 3857)), +(480, 'SRID=4326;POINT(-1.129738 38.379575)'::geometry, ST_Transform('SRID=4326;POINT(-1.129738 38.379575)'::geometry, 3857)), +(481, 'SRID=4326;POINT(-1.129916 38.38044)'::geometry, ST_Transform('SRID=4326;POINT(-1.129916 38.38044)'::geometry, 3857)), +(482, 'SRID=4326;POINT(-1.129103 38.379631)'::geometry, ST_Transform('SRID=4326;POINT(-1.129103 38.379631)'::geometry, 3857)), +(483, 'SRID=4326;POINT(-1.129994 38.379868)'::geometry, ST_Transform('SRID=4326;POINT(-1.129994 38.379868)'::geometry, 3857)), +(484, 'SRID=4326;POINT(5.367991 30.545321)'::geometry, ST_Transform('SRID=4326;POINT(5.367991 30.545321)'::geometry, 3857)), +(485, 'SRID=4326;POINT(5.367515 30.544982)'::geometry, ST_Transform('SRID=4326;POINT(5.367515 30.544982)'::geometry, 3857)), +(486, 'SRID=4326;POINT(5.367259 30.545084)'::geometry, ST_Transform('SRID=4326;POINT(5.367259 30.545084)'::geometry, 3857)), +(487, 'SRID=4326;POINT(5.368137 30.54498)'::geometry, ST_Transform('SRID=4326;POINT(5.368137 30.54498)'::geometry, 3857)), +(488, 'SRID=4326;POINT(5.367194 30.545244)'::geometry, ST_Transform('SRID=4326;POINT(5.367194 30.545244)'::geometry, 3857)), +(489, 'SRID=4326;POINT(5.367261 30.54535)'::geometry, ST_Transform('SRID=4326;POINT(5.367261 30.54535)'::geometry, 3857)), +(490, 'SRID=4326;POINT(5.367572 30.54492)'::geometry, ST_Transform('SRID=4326;POINT(5.367572 30.54492)'::geometry, 3857)), +(491, 'SRID=4326;POINT(5.367869 30.544706)'::geometry, ST_Transform('SRID=4326;POINT(5.367869 30.544706)'::geometry, 3857)), +(492, 'SRID=4326;POINT(5.368171 30.544438)'::geometry, ST_Transform('SRID=4326;POINT(5.368171 30.544438)'::geometry, 3857)), +(493, 'SRID=4326;POINT(5.367826 30.544732)'::geometry, ST_Transform('SRID=4326;POINT(5.367826 30.544732)'::geometry, 3857)), +(494, 'SRID=4326;POINT(5.367472 30.544565)'::geometry, ST_Transform('SRID=4326;POINT(5.367472 30.544565)'::geometry, 3857)), +(495, 'SRID=4326;POINT(5.367818 30.544714)'::geometry, ST_Transform('SRID=4326;POINT(5.367818 30.544714)'::geometry, 3857)), +(496, 'SRID=4326;POINT(5.367437 30.544804)'::geometry, ST_Transform('SRID=4326;POINT(5.367437 30.544804)'::geometry, 3857)), +(497, 'SRID=4326;POINT(3.578513 39.192891)'::geometry, ST_Transform('SRID=4326;POINT(3.578513 39.192891)'::geometry, 3857)), +(498, 'SRID=4326;POINT(3.578994 39.192304)'::geometry, ST_Transform('SRID=4326;POINT(3.578994 39.192304)'::geometry, 3857)), +(499, 'SRID=4326;POINT(3.578709 39.192954)'::geometry, ST_Transform('SRID=4326;POINT(3.578709 39.192954)'::geometry, 3857)), +(500, 'SRID=4326;POINT(3.5789 39.192329)'::geometry, ST_Transform('SRID=4326;POINT(3.5789 39.192329)'::geometry, 3857)), +(501, 'SRID=4326;POINT(3.57896 39.192534)'::geometry, ST_Transform('SRID=4326;POINT(3.57896 39.192534)'::geometry, 3857)), +(502, 'SRID=4326;POINT(3.578331 39.1927)'::geometry, ST_Transform('SRID=4326;POINT(3.578331 39.1927)'::geometry, 3857)), +(503, 'SRID=4326;POINT(6.467563 35.761929)'::geometry, ST_Transform('SRID=4326;POINT(6.467563 35.761929)'::geometry, 3857)), +(504, 'SRID=4326;POINT(6.467797 35.76232)'::geometry, ST_Transform('SRID=4326;POINT(6.467797 35.76232)'::geometry, 3857)), +(505, 'SRID=4326;POINT(6.468167 35.762407)'::geometry, ST_Transform('SRID=4326;POINT(6.468167 35.762407)'::geometry, 3857)), +(506, 'SRID=4326;POINT(6.467727 35.76243)'::geometry, ST_Transform('SRID=4326;POINT(6.467727 35.76243)'::geometry, 3857)), +(507, 'SRID=4326;POINT(6.467698 35.761842)'::geometry, ST_Transform('SRID=4326;POINT(6.467698 35.761842)'::geometry, 3857)), +(508, 'SRID=4326;POINT(6.468043 35.761548)'::geometry, ST_Transform('SRID=4326;POINT(6.468043 35.761548)'::geometry, 3857)), +(509, 'SRID=4326;POINT(6.467748 35.761895)'::geometry, ST_Transform('SRID=4326;POINT(6.467748 35.761895)'::geometry, 3857)), +(510, 'SRID=4326;POINT(-9.376008 37.66543)'::geometry, ST_Transform('SRID=4326;POINT(-9.376008 37.66543)'::geometry, 3857)), +(511, 'SRID=4326;POINT(-9.376352 37.665134)'::geometry, ST_Transform('SRID=4326;POINT(-9.376352 37.665134)'::geometry, 3857)), +(512, 'SRID=4326;POINT(-9.375792 37.665016)'::geometry, ST_Transform('SRID=4326;POINT(-9.375792 37.665016)'::geometry, 3857)), +(513, 'SRID=4326;POINT(-9.376451 37.664977)'::geometry, ST_Transform('SRID=4326;POINT(-9.376451 37.664977)'::geometry, 3857)), +(514, 'SRID=4326;POINT(-9.37563 37.664995)'::geometry, ST_Transform('SRID=4326;POINT(-9.37563 37.664995)'::geometry, 3857)), +(515, 'SRID=4326;POINT(-9.37582 37.665323)'::geometry, ST_Transform('SRID=4326;POINT(-9.37582 37.665323)'::geometry, 3857)), +(516, 'SRID=4326;POINT(-9.37587 37.665407)'::geometry, ST_Transform('SRID=4326;POINT(-9.37587 37.665407)'::geometry, 3857)), +(517, 'SRID=4326;POINT(-9.376338 37.665701)'::geometry, ST_Transform('SRID=4326;POINT(-9.376338 37.665701)'::geometry, 3857)), +(518, 'SRID=4326;POINT(-9.376514 37.665477)'::geometry, ST_Transform('SRID=4326;POINT(-9.376514 37.665477)'::geometry, 3857)), +(519, 'SRID=4326;POINT(-9.375748 37.66524)'::geometry, ST_Transform('SRID=4326;POINT(-9.375748 37.66524)'::geometry, 3857)), +(520, 'SRID=4326;POINT(1.260345 31.995092)'::geometry, ST_Transform('SRID=4326;POINT(1.260345 31.995092)'::geometry, 3857)), +(521, 'SRID=4326;POINT(1.259769 31.994365)'::geometry, ST_Transform('SRID=4326;POINT(1.259769 31.994365)'::geometry, 3857)), +(522, 'SRID=4326;POINT(1.259952 31.994605)'::geometry, ST_Transform('SRID=4326;POINT(1.259952 31.994605)'::geometry, 3857)), +(523, 'SRID=4326;POINT(1.26004 31.994175)'::geometry, ST_Transform('SRID=4326;POINT(1.26004 31.994175)'::geometry, 3857)), +(524, 'SRID=4326;POINT(1.260128 31.995111)'::geometry, ST_Transform('SRID=4326;POINT(1.260128 31.995111)'::geometry, 3857)), +(525, 'SRID=4326;POINT(1.259655 31.994736)'::geometry, ST_Transform('SRID=4326;POINT(1.259655 31.994736)'::geometry, 3857)), +(526, 'SRID=4326;POINT(1.259791 31.994912)'::geometry, ST_Transform('SRID=4326;POINT(1.259791 31.994912)'::geometry, 3857)), +(527, 'SRID=4326;POINT(1.260467 31.994231)'::geometry, ST_Transform('SRID=4326;POINT(1.260467 31.994231)'::geometry, 3857)), +(528, 'SRID=4326;POINT(1.25997 31.994557)'::geometry, ST_Transform('SRID=4326;POINT(1.25997 31.994557)'::geometry, 3857)), +(529, 'SRID=4326;POINT(1.260369 31.994511)'::geometry, ST_Transform('SRID=4326;POINT(1.260369 31.994511)'::geometry, 3857)), +(530, 'SRID=4326;POINT(1.259745 31.994475)'::geometry, ST_Transform('SRID=4326;POINT(1.259745 31.994475)'::geometry, 3857)), +(531, 'SRID=4326;POINT(1.259567 31.995074)'::geometry, ST_Transform('SRID=4326;POINT(1.259567 31.995074)'::geometry, 3857)), +(532, 'SRID=4326;POINT(1.260254 31.994468)'::geometry, ST_Transform('SRID=4326;POINT(1.260254 31.994468)'::geometry, 3857)), +(533, 'SRID=4326;POINT(1.259734 31.994586)'::geometry, ST_Transform('SRID=4326;POINT(1.259734 31.994586)'::geometry, 3857)), +(534, 'SRID=4326;POINT(1.260463 31.994721)'::geometry, ST_Transform('SRID=4326;POINT(1.260463 31.994721)'::geometry, 3857)), +(535, 'SRID=4326;POINT(2.729133 38.492349)'::geometry, ST_Transform('SRID=4326;POINT(2.729133 38.492349)'::geometry, 3857)), +(536, 'SRID=4326;POINT(-6.622615 33.402887)'::geometry, ST_Transform('SRID=4326;POINT(-6.622615 33.402887)'::geometry, 3857)), +(537, 'SRID=4326;POINT(-6.62201 33.40347)'::geometry, ST_Transform('SRID=4326;POINT(-6.62201 33.40347)'::geometry, 3857)), +(538, 'SRID=4326;POINT(-6.622602 33.403156)'::geometry, ST_Transform('SRID=4326;POINT(-6.622602 33.403156)'::geometry, 3857)), +(539, 'SRID=4326;POINT(-6.62229 33.403373)'::geometry, ST_Transform('SRID=4326;POINT(-6.62229 33.403373)'::geometry, 3857)), +(540, 'SRID=4326;POINT(-6.622021 33.403713)'::geometry, ST_Transform('SRID=4326;POINT(-6.622021 33.403713)'::geometry, 3857)), +(541, 'SRID=4326;POINT(-6.621709 33.403616)'::geometry, ST_Transform('SRID=4326;POINT(-6.621709 33.403616)'::geometry, 3857)), +(542, 'SRID=4326;POINT(-6.622664 33.403289)'::geometry, ST_Transform('SRID=4326;POINT(-6.622664 33.403289)'::geometry, 3857)), +(543, 'SRID=4326;POINT(-6.621894 33.403001)'::geometry, ST_Transform('SRID=4326;POINT(-6.621894 33.403001)'::geometry, 3857)), +(544, 'SRID=4326;POINT(-6.621753 33.403296)'::geometry, ST_Transform('SRID=4326;POINT(-6.621753 33.403296)'::geometry, 3857)), +(545, 'SRID=4326;POINT(-6.622631 33.403423)'::geometry, ST_Transform('SRID=4326;POINT(-6.622631 33.403423)'::geometry, 3857)), +(546, 'SRID=4326;POINT(-6.622649 33.402773)'::geometry, ST_Transform('SRID=4326;POINT(-6.622649 33.402773)'::geometry, 3857)), +(547, 'SRID=4326;POINT(-4.40069 32.83652)'::geometry, ST_Transform('SRID=4326;POINT(-4.40069 32.83652)'::geometry, 3857)), +(548, 'SRID=4326;POINT(-4.400915 32.835874)'::geometry, ST_Transform('SRID=4326;POINT(-4.400915 32.835874)'::geometry, 3857)), +(549, 'SRID=4326;POINT(-4.400611 32.836162)'::geometry, ST_Transform('SRID=4326;POINT(-4.400611 32.836162)'::geometry, 3857)), +(550, 'SRID=4326;POINT(-4.401156 32.836423)'::geometry, ST_Transform('SRID=4326;POINT(-4.401156 32.836423)'::geometry, 3857)), +(551, 'SRID=4326;POINT(-4.400751 32.836387)'::geometry, ST_Transform('SRID=4326;POINT(-4.400751 32.836387)'::geometry, 3857)), +(552, 'SRID=4326;POINT(-4.401099 32.836165)'::geometry, ST_Transform('SRID=4326;POINT(-4.401099 32.836165)'::geometry, 3857)), +(553, 'SRID=4326;POINT(-4.401483 32.836585)'::geometry, ST_Transform('SRID=4326;POINT(-4.401483 32.836585)'::geometry, 3857)), +(554, 'SRID=4326;POINT(-4.400596 32.836855)'::geometry, ST_Transform('SRID=4326;POINT(-4.400596 32.836855)'::geometry, 3857)), +(555, 'SRID=4326;POINT(-4.400921 32.836087)'::geometry, ST_Transform('SRID=4326;POINT(-4.400921 32.836087)'::geometry, 3857)), +(556, 'SRID=4326;POINT(-4.401047 32.836189)'::geometry, ST_Transform('SRID=4326;POINT(-4.401047 32.836189)'::geometry, 3857)), +(557, 'SRID=4326;POINT(-4.400684 32.836472)'::geometry, ST_Transform('SRID=4326;POINT(-4.400684 32.836472)'::geometry, 3857)), +(558, 'SRID=4326;POINT(4.492599 35.25261)'::geometry, ST_Transform('SRID=4326;POINT(4.492599 35.25261)'::geometry, 3857)), +(559, 'SRID=4326;POINT(4.492929 35.252912)'::geometry, ST_Transform('SRID=4326;POINT(4.492929 35.252912)'::geometry, 3857)), +(560, 'SRID=4326;POINT(4.49299 35.25299)'::geometry, ST_Transform('SRID=4326;POINT(4.49299 35.25299)'::geometry, 3857)), +(561, 'SRID=4326;POINT(-9.9593 31.93916)'::geometry, ST_Transform('SRID=4326;POINT(-9.9593 31.93916)'::geometry, 3857)), +(562, 'SRID=4326;POINT(-9.959219 31.939457)'::geometry, ST_Transform('SRID=4326;POINT(-9.959219 31.939457)'::geometry, 3857)), +(563, 'SRID=4326;POINT(-9.959225 31.938742)'::geometry, ST_Transform('SRID=4326;POINT(-9.959225 31.938742)'::geometry, 3857)), +(564, 'SRID=4326;POINT(-9.959793 31.939377)'::geometry, ST_Transform('SRID=4326;POINT(-9.959793 31.939377)'::geometry, 3857)), +(565, 'SRID=4326;POINT(-9.959077 31.9388)'::geometry, ST_Transform('SRID=4326;POINT(-9.959077 31.9388)'::geometry, 3857)), +(566, 'SRID=4326;POINT(-9.959222 31.93878)'::geometry, ST_Transform('SRID=4326;POINT(-9.959222 31.93878)'::geometry, 3857)), +(567, 'SRID=4326;POINT(-9.959156 31.939046)'::geometry, ST_Transform('SRID=4326;POINT(-9.959156 31.939046)'::geometry, 3857)), +(568, 'SRID=4326;POINT(-9.95889 31.938758)'::geometry, ST_Transform('SRID=4326;POINT(-9.95889 31.938758)'::geometry, 3857)), +(569, 'SRID=4326;POINT(-9.959658 31.939125)'::geometry, ST_Transform('SRID=4326;POINT(-9.959658 31.939125)'::geometry, 3857)), +(570, 'SRID=4326;POINT(-9.959243 31.939014)'::geometry, ST_Transform('SRID=4326;POINT(-9.959243 31.939014)'::geometry, 3857)), +(571, 'SRID=4326;POINT(-9.959627 31.939155)'::geometry, ST_Transform('SRID=4326;POINT(-9.959627 31.939155)'::geometry, 3857)), +(572, 'SRID=4326;POINT(-9.959284 31.938954)'::geometry, ST_Transform('SRID=4326;POINT(-9.959284 31.938954)'::geometry, 3857)), +(573, 'SRID=4326;POINT(-4.056215 35.879559)'::geometry, ST_Transform('SRID=4326;POINT(-4.056215 35.879559)'::geometry, 3857)), +(574, 'SRID=4326;POINT(9.407199 35.632402)'::geometry, ST_Transform('SRID=4326;POINT(9.407199 35.632402)'::geometry, 3857)), +(575, 'SRID=4326;POINT(9.407456 35.632353)'::geometry, ST_Transform('SRID=4326;POINT(9.407456 35.632353)'::geometry, 3857)), +(576, 'SRID=4326;POINT(9.407844 35.632295)'::geometry, ST_Transform('SRID=4326;POINT(9.407844 35.632295)'::geometry, 3857)), +(577, 'SRID=4326;POINT(9.40776 35.631777)'::geometry, ST_Transform('SRID=4326;POINT(9.40776 35.631777)'::geometry, 3857)), +(578, 'SRID=4326;POINT(2.231809 36.542849)'::geometry, ST_Transform('SRID=4326;POINT(2.231809 36.542849)'::geometry, 3857)), +(579, 'SRID=4326;POINT(2.232178 36.543185)'::geometry, ST_Transform('SRID=4326;POINT(2.232178 36.543185)'::geometry, 3857)), +(580, 'SRID=4326;POINT(2.232212 36.542512)'::geometry, ST_Transform('SRID=4326;POINT(2.232212 36.542512)'::geometry, 3857)), +(581, 'SRID=4326;POINT(2.232029 36.543168)'::geometry, ST_Transform('SRID=4326;POINT(2.232029 36.543168)'::geometry, 3857)), +(582, 'SRID=4326;POINT(2.231443 36.542672)'::geometry, ST_Transform('SRID=4326;POINT(2.231443 36.542672)'::geometry, 3857)), +(583, 'SRID=4326;POINT(2.231272 36.543057)'::geometry, ST_Transform('SRID=4326;POINT(2.231272 36.543057)'::geometry, 3857)), +(584, 'SRID=4326;POINT(2.231296 36.542955)'::geometry, ST_Transform('SRID=4326;POINT(2.231296 36.542955)'::geometry, 3857)), +(585, 'SRID=4326;POINT(2.231748 36.543061)'::geometry, ST_Transform('SRID=4326;POINT(2.231748 36.543061)'::geometry, 3857)), +(586, 'SRID=4326;POINT(2.232033 36.542659)'::geometry, ST_Transform('SRID=4326;POINT(2.232033 36.542659)'::geometry, 3857)), +(587, 'SRID=4326;POINT(2.23203 36.542826)'::geometry, ST_Transform('SRID=4326;POINT(2.23203 36.542826)'::geometry, 3857)), +(588, 'SRID=4326;POINT(2.232181 36.542546)'::geometry, ST_Transform('SRID=4326;POINT(2.232181 36.542546)'::geometry, 3857)), +(589, 'SRID=4326;POINT(2.232023 36.543425)'::geometry, ST_Transform('SRID=4326;POINT(2.232023 36.543425)'::geometry, 3857)), +(590, 'SRID=4326;POINT(0.948501 32.875271)'::geometry, ST_Transform('SRID=4326;POINT(0.948501 32.875271)'::geometry, 3857)), +(591, 'SRID=4326;POINT(0.9481 32.874688)'::geometry, ST_Transform('SRID=4326;POINT(0.9481 32.874688)'::geometry, 3857)), +(592, 'SRID=4326;POINT(0.948466 32.875415)'::geometry, ST_Transform('SRID=4326;POINT(0.948466 32.875415)'::geometry, 3857)), +(593, 'SRID=4326;POINT(0.947954 32.874821)'::geometry, ST_Transform('SRID=4326;POINT(0.947954 32.874821)'::geometry, 3857)), +(594, 'SRID=4326;POINT(0.947609 32.875461)'::geometry, ST_Transform('SRID=4326;POINT(0.947609 32.875461)'::geometry, 3857)), +(595, 'SRID=4326;POINT(0.948057 32.875049)'::geometry, ST_Transform('SRID=4326;POINT(0.948057 32.875049)'::geometry, 3857)), +(596, 'SRID=4326;POINT(0.94801 32.874707)'::geometry, ST_Transform('SRID=4326;POINT(0.94801 32.874707)'::geometry, 3857)), +(597, 'SRID=4326;POINT(0.947579 32.875047)'::geometry, ST_Transform('SRID=4326;POINT(0.947579 32.875047)'::geometry, 3857)), +(598, 'SRID=4326;POINT(0.948398 32.875394)'::geometry, ST_Transform('SRID=4326;POINT(0.948398 32.875394)'::geometry, 3857)), +(599, 'SRID=4326;POINT(0.948466 32.875444)'::geometry, ST_Transform('SRID=4326;POINT(0.948466 32.875444)'::geometry, 3857)), +(600, 'SRID=4326;POINT(0.94785 32.875375)'::geometry, ST_Transform('SRID=4326;POINT(0.94785 32.875375)'::geometry, 3857)), +(601, 'SRID=4326;POINT(0.948108 32.875197)'::geometry, ST_Transform('SRID=4326;POINT(0.948108 32.875197)'::geometry, 3857)), +(602, 'SRID=4326;POINT(0.948288 32.875307)'::geometry, ST_Transform('SRID=4326;POINT(0.948288 32.875307)'::geometry, 3857)), +(603, 'SRID=4326;POINT(0.948283 32.874956)'::geometry, ST_Transform('SRID=4326;POINT(0.948283 32.874956)'::geometry, 3857)), +(604, 'SRID=4326;POINT(0.948033 32.874929)'::geometry, ST_Transform('SRID=4326;POINT(0.948033 32.874929)'::geometry, 3857)), +(605, 'SRID=4326;POINT(0.948309 32.874623)'::geometry, ST_Transform('SRID=4326;POINT(0.948309 32.874623)'::geometry, 3857)), +(606, 'SRID=4326;POINT(-1.377445 36.13206)'::geometry, ST_Transform('SRID=4326;POINT(-1.377445 36.13206)'::geometry, 3857)), +(607, 'SRID=4326;POINT(-1.377573 36.132389)'::geometry, ST_Transform('SRID=4326;POINT(-1.377573 36.132389)'::geometry, 3857)), +(608, 'SRID=4326;POINT(-1.377342 36.132377)'::geometry, ST_Transform('SRID=4326;POINT(-1.377342 36.132377)'::geometry, 3857)), +(609, 'SRID=4326;POINT(-1.378103 36.131979)'::geometry, ST_Transform('SRID=4326;POINT(-1.378103 36.131979)'::geometry, 3857)), +(610, 'SRID=4326;POINT(-1.37759 36.132034)'::geometry, ST_Transform('SRID=4326;POINT(-1.37759 36.132034)'::geometry, 3857)), +(611, 'SRID=4326;POINT(-1.377544 36.13201)'::geometry, ST_Transform('SRID=4326;POINT(-1.377544 36.13201)'::geometry, 3857)), +(612, 'SRID=4326;POINT(-1.377877 36.132664)'::geometry, ST_Transform('SRID=4326;POINT(-1.377877 36.132664)'::geometry, 3857)), +(613, 'SRID=4326;POINT(-1.377243 36.1327)'::geometry, ST_Transform('SRID=4326;POINT(-1.377243 36.1327)'::geometry, 3857)), +(614, 'SRID=4326;POINT(-1.377821 36.132226)'::geometry, ST_Transform('SRID=4326;POINT(-1.377821 36.132226)'::geometry, 3857)), +(615, 'SRID=4326;POINT(-1.377819 36.131905)'::geometry, ST_Transform('SRID=4326;POINT(-1.377819 36.131905)'::geometry, 3857)), +(616, 'SRID=4326;POINT(-1.377647 36.132385)'::geometry, ST_Transform('SRID=4326;POINT(-1.377647 36.132385)'::geometry, 3857)), +(617, 'SRID=4326;POINT(-1.378114 36.132113)'::geometry, ST_Transform('SRID=4326;POINT(-1.378114 36.132113)'::geometry, 3857)), +(618, 'SRID=4326;POINT(1.281128 38.138626)'::geometry, ST_Transform('SRID=4326;POINT(1.281128 38.138626)'::geometry, 3857)), +(619, 'SRID=4326;POINT(1.281305 38.138959)'::geometry, ST_Transform('SRID=4326;POINT(1.281305 38.138959)'::geometry, 3857)), +(620, 'SRID=4326;POINT(1.281758 38.138407)'::geometry, ST_Transform('SRID=4326;POINT(1.281758 38.138407)'::geometry, 3857)), +(621, 'SRID=4326;POINT(1.281123 38.138734)'::geometry, ST_Transform('SRID=4326;POINT(1.281123 38.138734)'::geometry, 3857)), +(622, 'SRID=4326;POINT(1.281161 38.138177)'::geometry, ST_Transform('SRID=4326;POINT(1.281161 38.138177)'::geometry, 3857)), +(623, 'SRID=4326;POINT(1.281354 38.138617)'::geometry, ST_Transform('SRID=4326;POINT(1.281354 38.138617)'::geometry, 3857)), +(624, 'SRID=4326;POINT(1.281123 38.138171)'::geometry, ST_Transform('SRID=4326;POINT(1.281123 38.138171)'::geometry, 3857)), +(625, 'SRID=4326;POINT(1.001776 36.920915)'::geometry, ST_Transform('SRID=4326;POINT(1.001776 36.920915)'::geometry, 3857)), +(626, 'SRID=4326;POINT(1.001429 36.921273)'::geometry, ST_Transform('SRID=4326;POINT(1.001429 36.921273)'::geometry, 3857)), +(627, 'SRID=4326;POINT(1.001985 36.921254)'::geometry, ST_Transform('SRID=4326;POINT(1.001985 36.921254)'::geometry, 3857)), +(628, 'SRID=4326;POINT(1.001384 36.92111)'::geometry, ST_Transform('SRID=4326;POINT(1.001384 36.92111)'::geometry, 3857)), +(629, 'SRID=4326;POINT(1.001699 36.920728)'::geometry, ST_Transform('SRID=4326;POINT(1.001699 36.920728)'::geometry, 3857)), +(630, 'SRID=4326;POINT(1.002016 36.920362)'::geometry, ST_Transform('SRID=4326;POINT(1.002016 36.920362)'::geometry, 3857)), +(631, 'SRID=4326;POINT(1.001573 36.921188)'::geometry, ST_Transform('SRID=4326;POINT(1.001573 36.921188)'::geometry, 3857)), +(632, 'SRID=4326;POINT(1.00177 36.920421)'::geometry, ST_Transform('SRID=4326;POINT(1.00177 36.920421)'::geometry, 3857)), +(633, 'SRID=4326;POINT(1.001975 36.920794)'::geometry, ST_Transform('SRID=4326;POINT(1.001975 36.920794)'::geometry, 3857)), +(634, 'SRID=4326;POINT(1.001852 36.920518)'::geometry, ST_Transform('SRID=4326;POINT(1.001852 36.920518)'::geometry, 3857)), +(635, 'SRID=4326;POINT(1.001596 36.920567)'::geometry, ST_Transform('SRID=4326;POINT(1.001596 36.920567)'::geometry, 3857)), +(636, 'SRID=4326;POINT(1.002041 36.921094)'::geometry, ST_Transform('SRID=4326;POINT(1.002041 36.921094)'::geometry, 3857)), +(637, 'SRID=4326;POINT(1.00193 36.92129)'::geometry, ST_Transform('SRID=4326;POINT(1.00193 36.92129)'::geometry, 3857)), +(638, 'SRID=4326;POINT(1.001253 36.920578)'::geometry, ST_Transform('SRID=4326;POINT(1.001253 36.920578)'::geometry, 3857)), +(639, 'SRID=4326;POINT(1.001296 36.920603)'::geometry, ST_Transform('SRID=4326;POINT(1.001296 36.920603)'::geometry, 3857)), +(640, 'SRID=4326;POINT(1.001743 36.921216)'::geometry, ST_Transform('SRID=4326;POINT(1.001743 36.921216)'::geometry, 3857)), +(641, 'SRID=4326;POINT(-9.439246 39.930375)'::geometry, ST_Transform('SRID=4326;POINT(-9.439246 39.930375)'::geometry, 3857)), +(642, 'SRID=4326;POINT(-9.439831 39.93007)'::geometry, ST_Transform('SRID=4326;POINT(-9.439831 39.93007)'::geometry, 3857)), +(643, 'SRID=4326;POINT(-9.439794 39.930747)'::geometry, ST_Transform('SRID=4326;POINT(-9.439794 39.930747)'::geometry, 3857)), +(644, 'SRID=4326;POINT(7.051979 39.998654)'::geometry, ST_Transform('SRID=4326;POINT(7.051979 39.998654)'::geometry, 3857)), +(645, 'SRID=4326;POINT(7.052303 39.998459)'::geometry, ST_Transform('SRID=4326;POINT(7.052303 39.998459)'::geometry, 3857)), +(646, 'SRID=4326;POINT(7.051495 39.998286)'::geometry, ST_Transform('SRID=4326;POINT(7.051495 39.998286)'::geometry, 3857)), +(647, 'SRID=4326;POINT(7.052358 39.998959)'::geometry, ST_Transform('SRID=4326;POINT(7.052358 39.998959)'::geometry, 3857)), +(648, 'SRID=4326;POINT(7.051902 39.998646)'::geometry, ST_Transform('SRID=4326;POINT(7.051902 39.998646)'::geometry, 3857)), +(649, 'SRID=4326;POINT(7.051961 39.998936)'::geometry, ST_Transform('SRID=4326;POINT(7.051961 39.998936)'::geometry, 3857)), +(650, 'SRID=4326;POINT(7.052188 39.998715)'::geometry, ST_Transform('SRID=4326;POINT(7.052188 39.998715)'::geometry, 3857)), +(651, 'SRID=4326;POINT(7.051928 39.999019)'::geometry, ST_Transform('SRID=4326;POINT(7.051928 39.999019)'::geometry, 3857)), +(652, 'SRID=4326;POINT(7.051679 39.999193)'::geometry, ST_Transform('SRID=4326;POINT(7.051679 39.999193)'::geometry, 3857)), +(653, 'SRID=4326;POINT(7.052355 39.998444)'::geometry, ST_Transform('SRID=4326;POINT(7.052355 39.998444)'::geometry, 3857)), +(654, 'SRID=4326;POINT(7.052312 39.998467)'::geometry, ST_Transform('SRID=4326;POINT(7.052312 39.998467)'::geometry, 3857)), +(655, 'SRID=4326;POINT(3.946722 30.978786)'::geometry, ST_Transform('SRID=4326;POINT(3.946722 30.978786)'::geometry, 3857)), +(656, 'SRID=4326;POINT(3.946383 30.979446)'::geometry, ST_Transform('SRID=4326;POINT(3.946383 30.979446)'::geometry, 3857)), +(657, 'SRID=4326;POINT(3.946577 30.978671)'::geometry, ST_Transform('SRID=4326;POINT(3.946577 30.978671)'::geometry, 3857)), +(658, 'SRID=4326;POINT(3.946805 30.979383)'::geometry, ST_Transform('SRID=4326;POINT(3.946805 30.979383)'::geometry, 3857)), +(659, 'SRID=4326;POINT(4.739725 32.536293)'::geometry, ST_Transform('SRID=4326;POINT(4.739725 32.536293)'::geometry, 3857)), +(660, 'SRID=4326;POINT(4.739867 32.5367)'::geometry, ST_Transform('SRID=4326;POINT(4.739867 32.5367)'::geometry, 3857)), +(661, 'SRID=4326;POINT(4.739999 32.536189)'::geometry, ST_Transform('SRID=4326;POINT(4.739999 32.536189)'::geometry, 3857)), +(662, 'SRID=4326;POINT(4.739876 32.536571)'::geometry, ST_Transform('SRID=4326;POINT(4.739876 32.536571)'::geometry, 3857)), +(663, 'SRID=4326;POINT(4.739204 32.536119)'::geometry, ST_Transform('SRID=4326;POINT(4.739204 32.536119)'::geometry, 3857)), +(664, 'SRID=4326;POINT(4.739705 32.53637)'::geometry, ST_Transform('SRID=4326;POINT(4.739705 32.53637)'::geometry, 3857)), +(665, 'SRID=4326;POINT(4.739147 32.536027)'::geometry, ST_Transform('SRID=4326;POINT(4.739147 32.536027)'::geometry, 3857)), +(666, 'SRID=4326;POINT(4.739809 32.535831)'::geometry, ST_Transform('SRID=4326;POINT(4.739809 32.535831)'::geometry, 3857)), +(667, 'SRID=4326;POINT(4.739446 32.535993)'::geometry, ST_Transform('SRID=4326;POINT(4.739446 32.535993)'::geometry, 3857)), +(668, 'SRID=4326;POINT(4.739356 32.536354)'::geometry, ST_Transform('SRID=4326;POINT(4.739356 32.536354)'::geometry, 3857)), +(669, 'SRID=4326;POINT(4.73949 32.536547)'::geometry, ST_Transform('SRID=4326;POINT(4.73949 32.536547)'::geometry, 3857)), +(670, 'SRID=4326;POINT(4.739345 32.536142)'::geometry, ST_Transform('SRID=4326;POINT(4.739345 32.536142)'::geometry, 3857)), +(671, 'SRID=4326;POINT(4.73992 32.536513)'::geometry, ST_Transform('SRID=4326;POINT(4.73992 32.536513)'::geometry, 3857)), +(672, 'SRID=4326;POINT(4.739484 32.536518)'::geometry, ST_Transform('SRID=4326;POINT(4.739484 32.536518)'::geometry, 3857)), +(673, 'SRID=4326;POINT(4.739594 32.535765)'::geometry, ST_Transform('SRID=4326;POINT(4.739594 32.535765)'::geometry, 3857)), +(674, 'SRID=4326;POINT(-1.897518 32.955127)'::geometry, ST_Transform('SRID=4326;POINT(-1.897518 32.955127)'::geometry, 3857)), +(675, 'SRID=4326;POINT(-1.897857 32.955143)'::geometry, ST_Transform('SRID=4326;POINT(-1.897857 32.955143)'::geometry, 3857)), +(676, 'SRID=4326;POINT(-1.897766 32.954686)'::geometry, ST_Transform('SRID=4326;POINT(-1.897766 32.954686)'::geometry, 3857)), +(677, 'SRID=4326;POINT(6.858485 32.878875)'::geometry, ST_Transform('SRID=4326;POINT(6.858485 32.878875)'::geometry, 3857)), +(678, 'SRID=4326;POINT(6.858625 32.879165)'::geometry, ST_Transform('SRID=4326;POINT(6.858625 32.879165)'::geometry, 3857)), +(679, 'SRID=4326;POINT(6.859173 32.879623)'::geometry, ST_Transform('SRID=4326;POINT(6.859173 32.879623)'::geometry, 3857)), +(680, 'SRID=4326;POINT(6.858652 32.879073)'::geometry, ST_Transform('SRID=4326;POINT(6.858652 32.879073)'::geometry, 3857)), +(681, 'SRID=4326;POINT(6.858875 32.879512)'::geometry, ST_Transform('SRID=4326;POINT(6.858875 32.879512)'::geometry, 3857)), +(682, 'SRID=4326;POINT(2.489402 36.24209)'::geometry, ST_Transform('SRID=4326;POINT(2.489402 36.24209)'::geometry, 3857)), +(683, 'SRID=4326;POINT(2.490019 36.242308)'::geometry, ST_Transform('SRID=4326;POINT(2.490019 36.242308)'::geometry, 3857)), +(684, 'SRID=4326;POINT(2.490157 36.242104)'::geometry, ST_Transform('SRID=4326;POINT(2.490157 36.242104)'::geometry, 3857)), +(685, 'SRID=4326;POINT(2.48969 36.242247)'::geometry, ST_Transform('SRID=4326;POINT(2.48969 36.242247)'::geometry, 3857)), +(686, 'SRID=4326;POINT(2.489518 36.242617)'::geometry, ST_Transform('SRID=4326;POINT(2.489518 36.242617)'::geometry, 3857)), +(687, 'SRID=4326;POINT(2.490287 36.242602)'::geometry, ST_Transform('SRID=4326;POINT(2.490287 36.242602)'::geometry, 3857)), +(688, 'SRID=4326;POINT(2.490008 36.242113)'::geometry, ST_Transform('SRID=4326;POINT(2.490008 36.242113)'::geometry, 3857)), +(689, 'SRID=4326;POINT(2.489767 36.242141)'::geometry, ST_Transform('SRID=4326;POINT(2.489767 36.242141)'::geometry, 3857)), +(690, 'SRID=4326;POINT(2.490068 36.24219)'::geometry, ST_Transform('SRID=4326;POINT(2.490068 36.24219)'::geometry, 3857)), +(691, 'SRID=4326;POINT(2.489361 36.242592)'::geometry, ST_Transform('SRID=4326;POINT(2.489361 36.242592)'::geometry, 3857)), +(692, 'SRID=4326;POINT(4.675157 34.745728)'::geometry, ST_Transform('SRID=4326;POINT(4.675157 34.745728)'::geometry, 3857)), +(693, 'SRID=4326;POINT(4.675288 34.745268)'::geometry, ST_Transform('SRID=4326;POINT(4.675288 34.745268)'::geometry, 3857)), +(694, 'SRID=4326;POINT(4.67474 34.745439)'::geometry, ST_Transform('SRID=4326;POINT(4.67474 34.745439)'::geometry, 3857)), +(695, 'SRID=4326;POINT(-1.619779 36.505134)'::geometry, ST_Transform('SRID=4326;POINT(-1.619779 36.505134)'::geometry, 3857)), +(696, 'SRID=4326;POINT(-1.619178 36.504973)'::geometry, ST_Transform('SRID=4326;POINT(-1.619178 36.504973)'::geometry, 3857)), +(697, 'SRID=4326;POINT(1.443654 35.03996)'::geometry, ST_Transform('SRID=4326;POINT(1.443654 35.03996)'::geometry, 3857)), +(698, 'SRID=4326;POINT(1.443555 35.040102)'::geometry, ST_Transform('SRID=4326;POINT(1.443555 35.040102)'::geometry, 3857)), +(699, 'SRID=4326;POINT(1.444439 35.040191)'::geometry, ST_Transform('SRID=4326;POINT(1.444439 35.040191)'::geometry, 3857)), +(700, 'SRID=4326;POINT(1.443705 35.040334)'::geometry, ST_Transform('SRID=4326;POINT(1.443705 35.040334)'::geometry, 3857)), +(701, 'SRID=4326;POINT(1.444309 35.040845)'::geometry, ST_Transform('SRID=4326;POINT(1.444309 35.040845)'::geometry, 3857)), +(702, 'SRID=4326;POINT(1.444155 35.040343)'::geometry, ST_Transform('SRID=4326;POINT(1.444155 35.040343)'::geometry, 3857)), +(703, 'SRID=4326;POINT(1.443996 35.040538)'::geometry, ST_Transform('SRID=4326;POINT(1.443996 35.040538)'::geometry, 3857)), +(704, 'SRID=4326;POINT(1.443617 35.040449)'::geometry, ST_Transform('SRID=4326;POINT(1.443617 35.040449)'::geometry, 3857)), +(705, 'SRID=4326;POINT(1.443732 35.040449)'::geometry, ST_Transform('SRID=4326;POINT(1.443732 35.040449)'::geometry, 3857)), +(706, 'SRID=4326;POINT(1.510391 37.025753)'::geometry, ST_Transform('SRID=4326;POINT(1.510391 37.025753)'::geometry, 3857)), +(707, 'SRID=4326;POINT(1.510774 37.025573)'::geometry, ST_Transform('SRID=4326;POINT(1.510774 37.025573)'::geometry, 3857)), +(708, 'SRID=4326;POINT(-1.068005 30.909683)'::geometry, ST_Transform('SRID=4326;POINT(-1.068005 30.909683)'::geometry, 3857)), +(709, 'SRID=4326;POINT(-1.067915 30.910178)'::geometry, ST_Transform('SRID=4326;POINT(-1.067915 30.910178)'::geometry, 3857)), +(710, 'SRID=4326;POINT(-1.067998 30.909856)'::geometry, ST_Transform('SRID=4326;POINT(-1.067998 30.909856)'::geometry, 3857)), +(711, 'SRID=4326;POINT(-1.067593 30.910177)'::geometry, ST_Transform('SRID=4326;POINT(-1.067593 30.910177)'::geometry, 3857)), +(712, 'SRID=4326;POINT(-1.068124 30.909608)'::geometry, ST_Transform('SRID=4326;POINT(-1.068124 30.909608)'::geometry, 3857)), +(713, 'SRID=4326;POINT(-1.067982 30.909937)'::geometry, ST_Transform('SRID=4326;POINT(-1.067982 30.909937)'::geometry, 3857)), +(714, 'SRID=4326;POINT(-1.068222 30.909692)'::geometry, ST_Transform('SRID=4326;POINT(-1.068222 30.909692)'::geometry, 3857)), +(715, 'SRID=4326;POINT(-1.067383 30.909904)'::geometry, ST_Transform('SRID=4326;POINT(-1.067383 30.909904)'::geometry, 3857)), +(716, 'SRID=4326;POINT(-1.067335 30.91012)'::geometry, ST_Transform('SRID=4326;POINT(-1.067335 30.91012)'::geometry, 3857)), +(717, 'SRID=4326;POINT(-1.06821 30.909356)'::geometry, ST_Transform('SRID=4326;POINT(-1.06821 30.909356)'::geometry, 3857)), +(718, 'SRID=4326;POINT(-1.067598 30.909364)'::geometry, ST_Transform('SRID=4326;POINT(-1.067598 30.909364)'::geometry, 3857)), +(719, 'SRID=4326;POINT(-1.067629 30.909687)'::geometry, ST_Transform('SRID=4326;POINT(-1.067629 30.909687)'::geometry, 3857)), +(720, 'SRID=4326;POINT(-1.068031 30.90956)'::geometry, ST_Transform('SRID=4326;POINT(-1.068031 30.90956)'::geometry, 3857)), +(721, 'SRID=4326;POINT(-1.067461 30.909412)'::geometry, ST_Transform('SRID=4326;POINT(-1.067461 30.909412)'::geometry, 3857)), +(722, 'SRID=4326;POINT(-4.441301 35.734339)'::geometry, ST_Transform('SRID=4326;POINT(-4.441301 35.734339)'::geometry, 3857)), +(723, 'SRID=4326;POINT(-4.441614 35.734596)'::geometry, ST_Transform('SRID=4326;POINT(-4.441614 35.734596)'::geometry, 3857)), +(724, 'SRID=4326;POINT(-4.441374 35.734511)'::geometry, ST_Transform('SRID=4326;POINT(-4.441374 35.734511)'::geometry, 3857)), +(725, 'SRID=4326;POINT(-4.442144 35.733728)'::geometry, ST_Transform('SRID=4326;POINT(-4.442144 35.733728)'::geometry, 3857)), +(726, 'SRID=4326;POINT(-4.442129 35.733779)'::geometry, ST_Transform('SRID=4326;POINT(-4.442129 35.733779)'::geometry, 3857)), +(727, 'SRID=4326;POINT(-4.442129 35.7343)'::geometry, ST_Transform('SRID=4326;POINT(-4.442129 35.7343)'::geometry, 3857)), +(728, 'SRID=4326;POINT(-4.441357 35.734573)'::geometry, ST_Transform('SRID=4326;POINT(-4.441357 35.734573)'::geometry, 3857)), +(729, 'SRID=4326;POINT(-4.441611 35.734042)'::geometry, ST_Transform('SRID=4326;POINT(-4.441611 35.734042)'::geometry, 3857)), +(730, 'SRID=4326;POINT(-4.442273 35.734478)'::geometry, ST_Transform('SRID=4326;POINT(-4.442273 35.734478)'::geometry, 3857)), +(731, 'SRID=4326;POINT(3.777839 39.080855)'::geometry, ST_Transform('SRID=4326;POINT(3.777839 39.080855)'::geometry, 3857)), +(732, 'SRID=4326;POINT(3.778302 39.081637)'::geometry, ST_Transform('SRID=4326;POINT(3.778302 39.081637)'::geometry, 3857)), +(733, 'SRID=4326;POINT(3.778134 39.081327)'::geometry, ST_Transform('SRID=4326;POINT(3.778134 39.081327)'::geometry, 3857)), +(734, 'SRID=4326;POINT(3.77753 39.080837)'::geometry, ST_Transform('SRID=4326;POINT(3.77753 39.080837)'::geometry, 3857)), +(735, 'SRID=4326;POINT(3.777524 39.08106)'::geometry, ST_Transform('SRID=4326;POINT(3.777524 39.08106)'::geometry, 3857)), +(736, 'SRID=4326;POINT(3.778196 39.081177)'::geometry, ST_Transform('SRID=4326;POINT(3.778196 39.081177)'::geometry, 3857)), +(737, 'SRID=4326;POINT(3.777824 39.081648)'::geometry, ST_Transform('SRID=4326;POINT(3.777824 39.081648)'::geometry, 3857)), +(738, 'SRID=4326;POINT(3.778294 39.081016)'::geometry, ST_Transform('SRID=4326;POINT(3.778294 39.081016)'::geometry, 3857)), +(739, 'SRID=4326;POINT(3.778384 39.080821)'::geometry, ST_Transform('SRID=4326;POINT(3.778384 39.080821)'::geometry, 3857)), +(740, 'SRID=4326;POINT(3.77832 39.081738)'::geometry, ST_Transform('SRID=4326;POINT(3.77832 39.081738)'::geometry, 3857)), +(741, 'SRID=4326;POINT(3.77775 39.081581)'::geometry, ST_Transform('SRID=4326;POINT(3.77775 39.081581)'::geometry, 3857)), +(742, 'SRID=4326;POINT(3.777606 39.080794)'::geometry, ST_Transform('SRID=4326;POINT(3.777606 39.080794)'::geometry, 3857)), +(743, 'SRID=4326;POINT(3.777891 39.081417)'::geometry, ST_Transform('SRID=4326;POINT(3.777891 39.081417)'::geometry, 3857)), +(744, 'SRID=4326;POINT(5.649526 31.865244)'::geometry, ST_Transform('SRID=4326;POINT(5.649526 31.865244)'::geometry, 3857)), +(745, 'SRID=4326;POINT(5.649871 31.865085)'::geometry, ST_Transform('SRID=4326;POINT(5.649871 31.865085)'::geometry, 3857)), +(746, 'SRID=4326;POINT(5.649532 31.86498)'::geometry, ST_Transform('SRID=4326;POINT(5.649532 31.86498)'::geometry, 3857)), +(747, 'SRID=4326;POINT(5.650394 31.864659)'::geometry, ST_Transform('SRID=4326;POINT(5.650394 31.864659)'::geometry, 3857)), +(748, 'SRID=4326;POINT(5.650448 31.865148)'::geometry, ST_Transform('SRID=4326;POINT(5.650448 31.865148)'::geometry, 3857)), +(749, 'SRID=4326;POINT(5.649964 31.865283)'::geometry, ST_Transform('SRID=4326;POINT(5.649964 31.865283)'::geometry, 3857)), +(750, 'SRID=4326;POINT(5.650139 31.865148)'::geometry, ST_Transform('SRID=4326;POINT(5.650139 31.865148)'::geometry, 3857)), +(751, 'SRID=4326;POINT(5.650438 31.865057)'::geometry, ST_Transform('SRID=4326;POINT(5.650438 31.865057)'::geometry, 3857)), +(752, 'SRID=4326;POINT(5.649977 31.86457)'::geometry, ST_Transform('SRID=4326;POINT(5.649977 31.86457)'::geometry, 3857)), +(753, 'SRID=4326;POINT(5.649628 31.864566)'::geometry, ST_Transform('SRID=4326;POINT(5.649628 31.864566)'::geometry, 3857)), +(754, 'SRID=4326;POINT(-9.754618 33.438008)'::geometry, ST_Transform('SRID=4326;POINT(-9.754618 33.438008)'::geometry, 3857)), +(755, 'SRID=4326;POINT(-9.75386 33.437609)'::geometry, ST_Transform('SRID=4326;POINT(-9.75386 33.437609)'::geometry, 3857)), +(756, 'SRID=4326;POINT(-9.754443 33.437308)'::geometry, ST_Transform('SRID=4326;POINT(-9.754443 33.437308)'::geometry, 3857)), +(757, 'SRID=4326;POINT(-9.75421 33.437932)'::geometry, ST_Transform('SRID=4326;POINT(-9.75421 33.437932)'::geometry, 3857)), +(758, 'SRID=4326;POINT(-9.753773 33.437663)'::geometry, ST_Transform('SRID=4326;POINT(-9.753773 33.437663)'::geometry, 3857)), +(759, 'SRID=4326;POINT(-9.754267 33.437916)'::geometry, ST_Transform('SRID=4326;POINT(-9.754267 33.437916)'::geometry, 3857)), +(760, 'SRID=4326;POINT(-9.754199 33.437889)'::geometry, ST_Transform('SRID=4326;POINT(-9.754199 33.437889)'::geometry, 3857)), +(761, 'SRID=4326;POINT(-9.75385 33.437159)'::geometry, ST_Transform('SRID=4326;POINT(-9.75385 33.437159)'::geometry, 3857)), +(762, 'SRID=4326;POINT(-3.543263 37.732976)'::geometry, ST_Transform('SRID=4326;POINT(-3.543263 37.732976)'::geometry, 3857)), +(763, 'SRID=4326;POINT(-3.542739 37.73271)'::geometry, ST_Transform('SRID=4326;POINT(-3.542739 37.73271)'::geometry, 3857)), +(764, 'SRID=4326;POINT(-3.54322 37.733139)'::geometry, ST_Transform('SRID=4326;POINT(-3.54322 37.733139)'::geometry, 3857)), +(765, 'SRID=4326;POINT(-3.54322 37.732576)'::geometry, ST_Transform('SRID=4326;POINT(-3.54322 37.732576)'::geometry, 3857)), +(766, 'SRID=4326;POINT(-3.543006 37.732667)'::geometry, ST_Transform('SRID=4326;POINT(-3.543006 37.732667)'::geometry, 3857)), +(767, 'SRID=4326;POINT(-8.711766 37.59638)'::geometry, ST_Transform('SRID=4326;POINT(-8.711766 37.59638)'::geometry, 3857)), +(768, 'SRID=4326;POINT(-8.711754 37.596229)'::geometry, ST_Transform('SRID=4326;POINT(-8.711754 37.596229)'::geometry, 3857)), +(769, 'SRID=4326;POINT(-8.711602 37.596288)'::geometry, ST_Transform('SRID=4326;POINT(-8.711602 37.596288)'::geometry, 3857)), +(770, 'SRID=4326;POINT(-8.712524 37.59617)'::geometry, ST_Transform('SRID=4326;POINT(-8.712524 37.59617)'::geometry, 3857)), +(771, 'SRID=4326;POINT(-8.712334 37.596219)'::geometry, ST_Transform('SRID=4326;POINT(-8.712334 37.596219)'::geometry, 3857)), +(772, 'SRID=4326;POINT(-8.71181 37.596124)'::geometry, ST_Transform('SRID=4326;POINT(-8.71181 37.596124)'::geometry, 3857)), +(773, 'SRID=4326;POINT(-8.712069 37.596608)'::geometry, ST_Transform('SRID=4326;POINT(-8.712069 37.596608)'::geometry, 3857)), +(774, 'SRID=4326;POINT(-8.711985 37.596911)'::geometry, ST_Transform('SRID=4326;POINT(-8.711985 37.596911)'::geometry, 3857)), +(775, 'SRID=4326;POINT(-3.044214 35.702146)'::geometry, ST_Transform('SRID=4326;POINT(-3.044214 35.702146)'::geometry, 3857)), +(776, 'SRID=4326;POINT(-3.044209 35.702853)'::geometry, ST_Transform('SRID=4326;POINT(-3.044209 35.702853)'::geometry, 3857)), +(777, 'SRID=4326;POINT(-3.044276 35.703038)'::geometry, ST_Transform('SRID=4326;POINT(-3.044276 35.703038)'::geometry, 3857)), +(778, 'SRID=4326;POINT(-3.043811 35.702228)'::geometry, ST_Transform('SRID=4326;POINT(-3.043811 35.702228)'::geometry, 3857)), +(779, 'SRID=4326;POINT(-3.043957 35.702876)'::geometry, ST_Transform('SRID=4326;POINT(-3.043957 35.702876)'::geometry, 3857)), +(780, 'SRID=4326;POINT(-3.044306 35.70211)'::geometry, ST_Transform('SRID=4326;POINT(-3.044306 35.70211)'::geometry, 3857)), +(781, 'SRID=4326;POINT(-3.044272 35.702647)'::geometry, ST_Transform('SRID=4326;POINT(-3.044272 35.702647)'::geometry, 3857)), +(782, 'SRID=4326;POINT(-3.044 35.702192)'::geometry, ST_Transform('SRID=4326;POINT(-3.044 35.702192)'::geometry, 3857)), +(783, 'SRID=4326;POINT(-3.044468 35.702635)'::geometry, ST_Transform('SRID=4326;POINT(-3.044468 35.702635)'::geometry, 3857)), +(784, 'SRID=4326;POINT(-3.044076 35.702746)'::geometry, ST_Transform('SRID=4326;POINT(-3.044076 35.702746)'::geometry, 3857)), +(785, 'SRID=4326;POINT(-3.043738 35.702675)'::geometry, ST_Transform('SRID=4326;POINT(-3.043738 35.702675)'::geometry, 3857)), +(786, 'SRID=4326;POINT(-3.043795 35.702232)'::geometry, ST_Transform('SRID=4326;POINT(-3.043795 35.702232)'::geometry, 3857)), +(787, 'SRID=4326;POINT(-3.044209 35.702984)'::geometry, ST_Transform('SRID=4326;POINT(-3.044209 35.702984)'::geometry, 3857)), +(788, 'SRID=4326;POINT(-7.790389 34.460937)'::geometry, ST_Transform('SRID=4326;POINT(-7.790389 34.460937)'::geometry, 3857)), +(789, 'SRID=4326;POINT(-7.789629 34.460861)'::geometry, ST_Transform('SRID=4326;POINT(-7.789629 34.460861)'::geometry, 3857)), +(790, 'SRID=4326;POINT(-7.78971 34.460351)'::geometry, ST_Transform('SRID=4326;POINT(-7.78971 34.460351)'::geometry, 3857)), +(791, 'SRID=4326;POINT(-3.638793 31.769061)'::geometry, ST_Transform('SRID=4326;POINT(-3.638793 31.769061)'::geometry, 3857)), +(792, 'SRID=4326;POINT(-3.638466 31.768737)'::geometry, ST_Transform('SRID=4326;POINT(-3.638466 31.768737)'::geometry, 3857)), +(793, 'SRID=4326;POINT(-3.63824 31.768573)'::geometry, ST_Transform('SRID=4326;POINT(-3.63824 31.768573)'::geometry, 3857)), +(794, 'SRID=4326;POINT(-3.638398 31.768979)'::geometry, ST_Transform('SRID=4326;POINT(-3.638398 31.768979)'::geometry, 3857)), +(795, 'SRID=4326;POINT(-3.63876 31.768587)'::geometry, ST_Transform('SRID=4326;POINT(-3.63876 31.768587)'::geometry, 3857)), +(796, 'SRID=4326;POINT(-3.638016 31.769415)'::geometry, ST_Transform('SRID=4326;POINT(-3.638016 31.769415)'::geometry, 3857)), +(797, 'SRID=4326;POINT(-3.638079 31.768865)'::geometry, ST_Transform('SRID=4326;POINT(-3.638079 31.768865)'::geometry, 3857)), +(798, 'SRID=4326;POINT(-3.638309 31.768567)'::geometry, ST_Transform('SRID=4326;POINT(-3.638309 31.768567)'::geometry, 3857)), +(799, 'SRID=4326;POINT(-3.638519 31.76941)'::geometry, ST_Transform('SRID=4326;POINT(-3.638519 31.76941)'::geometry, 3857)), +(800, 'SRID=4326;POINT(-3.638692 31.768971)'::geometry, ST_Transform('SRID=4326;POINT(-3.638692 31.768971)'::geometry, 3857)), +(801, 'SRID=4326;POINT(-3.6379 31.768873)'::geometry, ST_Transform('SRID=4326;POINT(-3.6379 31.768873)'::geometry, 3857)), +(802, 'SRID=4326;POINT(-3.638416 31.768977)'::geometry, ST_Transform('SRID=4326;POINT(-3.638416 31.768977)'::geometry, 3857)), +(803, 'SRID=4326;POINT(3.482375 34.823772)'::geometry, ST_Transform('SRID=4326;POINT(3.482375 34.823772)'::geometry, 3857)), +(804, 'SRID=4326;POINT(3.482611 34.823862)'::geometry, ST_Transform('SRID=4326;POINT(3.482611 34.823862)'::geometry, 3857)), +(805, 'SRID=4326;POINT(3.482458 34.823835)'::geometry, ST_Transform('SRID=4326;POINT(3.482458 34.823835)'::geometry, 3857)), +(806, 'SRID=4326;POINT(3.482499 34.823217)'::geometry, ST_Transform('SRID=4326;POINT(3.482499 34.823217)'::geometry, 3857)), +(807, 'SRID=4326;POINT(3.481979 34.824033)'::geometry, ST_Transform('SRID=4326;POINT(3.481979 34.824033)'::geometry, 3857)), +(808, 'SRID=4326;POINT(-2.509218 34.847743)'::geometry, ST_Transform('SRID=4326;POINT(-2.509218 34.847743)'::geometry, 3857)), +(809, 'SRID=4326;POINT(-2.508889 34.847727)'::geometry, ST_Transform('SRID=4326;POINT(-2.508889 34.847727)'::geometry, 3857)), +(810, 'SRID=4326;POINT(-2.50892 34.846884)'::geometry, ST_Transform('SRID=4326;POINT(-2.50892 34.846884)'::geometry, 3857)), +(811, 'SRID=4326;POINT(-2.508925 34.847728)'::geometry, ST_Transform('SRID=4326;POINT(-2.508925 34.847728)'::geometry, 3857)), +(812, 'SRID=4326;POINT(-2.509686 34.847259)'::geometry, ST_Transform('SRID=4326;POINT(-2.509686 34.847259)'::geometry, 3857)), +(813, 'SRID=4326;POINT(-2.509642 34.847683)'::geometry, ST_Transform('SRID=4326;POINT(-2.509642 34.847683)'::geometry, 3857)), +(814, 'SRID=4326;POINT(-2.509494 34.847088)'::geometry, ST_Transform('SRID=4326;POINT(-2.509494 34.847088)'::geometry, 3857)), +(815, 'SRID=4326;POINT(-2.508858 34.847826)'::geometry, ST_Transform('SRID=4326;POINT(-2.508858 34.847826)'::geometry, 3857)), +(816, 'SRID=4326;POINT(-2.508911 34.84779)'::geometry, ST_Transform('SRID=4326;POINT(-2.508911 34.84779)'::geometry, 3857)), +(817, 'SRID=4326;POINT(-2.509036 34.847235)'::geometry, ST_Transform('SRID=4326;POINT(-2.509036 34.847235)'::geometry, 3857)), +(818, 'SRID=4326;POINT(-2.508977 34.847441)'::geometry, ST_Transform('SRID=4326;POINT(-2.508977 34.847441)'::geometry, 3857)), +(819, 'SRID=4326;POINT(-2.509094 34.847048)'::geometry, ST_Transform('SRID=4326;POINT(-2.509094 34.847048)'::geometry, 3857)), +(820, 'SRID=4326;POINT(-2.509022 34.847189)'::geometry, ST_Transform('SRID=4326;POINT(-2.509022 34.847189)'::geometry, 3857)), +(821, 'SRID=4326;POINT(-2.509208 34.847051)'::geometry, ST_Transform('SRID=4326;POINT(-2.509208 34.847051)'::geometry, 3857)), +(822, 'SRID=4326;POINT(-2.509642 34.847293)'::geometry, ST_Transform('SRID=4326;POINT(-2.509642 34.847293)'::geometry, 3857)), +(823, 'SRID=4326;POINT(0.326508 39.66647)'::geometry, ST_Transform('SRID=4326;POINT(0.326508 39.66647)'::geometry, 3857)), +(824, 'SRID=4326;POINT(0.325896 39.666548)'::geometry, ST_Transform('SRID=4326;POINT(0.325896 39.666548)'::geometry, 3857)), +(825, 'SRID=4326;POINT(0.326264 39.66692)'::geometry, ST_Transform('SRID=4326;POINT(0.326264 39.66692)'::geometry, 3857)), +(826, 'SRID=4326;POINT(0.326113 39.666649)'::geometry, ST_Transform('SRID=4326;POINT(0.326113 39.666649)'::geometry, 3857)), +(827, 'SRID=4326;POINT(0.326511 39.666485)'::geometry, ST_Transform('SRID=4326;POINT(0.326511 39.666485)'::geometry, 3857)), +(828, 'SRID=4326;POINT(0.326479 39.667199)'::geometry, ST_Transform('SRID=4326;POINT(0.326479 39.667199)'::geometry, 3857)), +(829, 'SRID=4326;POINT(0.325908 39.667345)'::geometry, ST_Transform('SRID=4326;POINT(0.325908 39.667345)'::geometry, 3857)), +(830, 'SRID=4326;POINT(0.326475 39.666531)'::geometry, ST_Transform('SRID=4326;POINT(0.326475 39.666531)'::geometry, 3857)), +(831, 'SRID=4326;POINT(0.325636 39.666852)'::geometry, ST_Transform('SRID=4326;POINT(0.325636 39.666852)'::geometry, 3857)), +(832, 'SRID=4326;POINT(0.326265 39.666438)'::geometry, ST_Transform('SRID=4326;POINT(0.326265 39.666438)'::geometry, 3857)), +(833, 'SRID=4326;POINT(9.174032 33.398054)'::geometry, ST_Transform('SRID=4326;POINT(9.174032 33.398054)'::geometry, 3857)), +(834, 'SRID=4326;POINT(9.174151 33.397592)'::geometry, ST_Transform('SRID=4326;POINT(9.174151 33.397592)'::geometry, 3857)), +(835, 'SRID=4326;POINT(9.173741 33.397925)'::geometry, ST_Transform('SRID=4326;POINT(9.173741 33.397925)'::geometry, 3857)), +(836, 'SRID=4326;POINT(9.173967 33.397743)'::geometry, ST_Transform('SRID=4326;POINT(9.173967 33.397743)'::geometry, 3857)), +(837, 'SRID=4326;POINT(9.173591 33.397683)'::geometry, ST_Transform('SRID=4326;POINT(9.173591 33.397683)'::geometry, 3857)), +(838, 'SRID=4326;POINT(9.17437 33.398353)'::geometry, ST_Transform('SRID=4326;POINT(9.17437 33.398353)'::geometry, 3857)), +(839, 'SRID=4326;POINT(1.83634 38.816707)'::geometry, ST_Transform('SRID=4326;POINT(1.83634 38.816707)'::geometry, 3857)), +(840, 'SRID=4326;POINT(1.836636 38.815905)'::geometry, ST_Transform('SRID=4326;POINT(1.836636 38.815905)'::geometry, 3857)), +(841, 'SRID=4326;POINT(1.836376 38.81682)'::geometry, ST_Transform('SRID=4326;POINT(1.836376 38.81682)'::geometry, 3857)), +(842, 'SRID=4326;POINT(1.836335 38.816239)'::geometry, ST_Transform('SRID=4326;POINT(1.836335 38.816239)'::geometry, 3857)), +(843, 'SRID=4326;POINT(1.83687 38.816413)'::geometry, ST_Transform('SRID=4326;POINT(1.83687 38.816413)'::geometry, 3857)), +(844, 'SRID=4326;POINT(1.837073 38.81631)'::geometry, ST_Transform('SRID=4326;POINT(1.837073 38.81631)'::geometry, 3857)), +(845, 'SRID=4326;POINT(1.836343 38.816733)'::geometry, ST_Transform('SRID=4326;POINT(1.836343 38.816733)'::geometry, 3857)), +(846, 'SRID=4326;POINT(1.836489 38.816262)'::geometry, ST_Transform('SRID=4326;POINT(1.836489 38.816262)'::geometry, 3857)), +(847, 'SRID=4326;POINT(1.83676 38.816723)'::geometry, ST_Transform('SRID=4326;POINT(1.83676 38.816723)'::geometry, 3857)), +(848, 'SRID=4326;POINT(-6.101184 30.891359)'::geometry, ST_Transform('SRID=4326;POINT(-6.101184 30.891359)'::geometry, 3857)), +(849, 'SRID=4326;POINT(-6.101891 30.891475)'::geometry, ST_Transform('SRID=4326;POINT(-6.101891 30.891475)'::geometry, 3857)), +(850, 'SRID=4326;POINT(-6.101454 30.890926)'::geometry, ST_Transform('SRID=4326;POINT(-6.101454 30.890926)'::geometry, 3857)), +(851, 'SRID=4326;POINT(-6.101107 30.891705)'::geometry, ST_Transform('SRID=4326;POINT(-6.101107 30.891705)'::geometry, 3857)), +(852, 'SRID=4326;POINT(-6.102024 30.891119)'::geometry, ST_Transform('SRID=4326;POINT(-6.102024 30.891119)'::geometry, 3857)), +(853, 'SRID=4326;POINT(-6.101783 30.891325)'::geometry, ST_Transform('SRID=4326;POINT(-6.101783 30.891325)'::geometry, 3857)), +(854, 'SRID=4326;POINT(-6.101777 30.891247)'::geometry, ST_Transform('SRID=4326;POINT(-6.101777 30.891247)'::geometry, 3857)), +(855, 'SRID=4326;POINT(-6.101719 30.891249)'::geometry, ST_Transform('SRID=4326;POINT(-6.101719 30.891249)'::geometry, 3857)), +(856, 'SRID=4326;POINT(-6.101544 30.891609)'::geometry, ST_Transform('SRID=4326;POINT(-6.101544 30.891609)'::geometry, 3857)), +(857, 'SRID=4326;POINT(-6.101199 30.891006)'::geometry, ST_Transform('SRID=4326;POINT(-6.101199 30.891006)'::geometry, 3857)), +(858, 'SRID=4326;POINT(-6.101879 30.891786)'::geometry, ST_Transform('SRID=4326;POINT(-6.101879 30.891786)'::geometry, 3857)), +(859, 'SRID=4326;POINT(0.467665 33.036704)'::geometry, ST_Transform('SRID=4326;POINT(0.467665 33.036704)'::geometry, 3857)), +(860, 'SRID=4326;POINT(0.46855 33.036736)'::geometry, ST_Transform('SRID=4326;POINT(0.46855 33.036736)'::geometry, 3857)), +(861, 'SRID=4326;POINT(0.467955 33.036171)'::geometry, ST_Transform('SRID=4326;POINT(0.467955 33.036171)'::geometry, 3857)), +(862, 'SRID=4326;POINT(0.46803 33.036307)'::geometry, ST_Transform('SRID=4326;POINT(0.46803 33.036307)'::geometry, 3857)), +(863, 'SRID=4326;POINT(0.467935 33.036645)'::geometry, ST_Transform('SRID=4326;POINT(0.467935 33.036645)'::geometry, 3857)), +(864, 'SRID=4326;POINT(0.468476 33.036343)'::geometry, ST_Transform('SRID=4326;POINT(0.468476 33.036343)'::geometry, 3857)), +(865, 'SRID=4326;POINT(-4.397995 38.108926)'::geometry, ST_Transform('SRID=4326;POINT(-4.397995 38.108926)'::geometry, 3857)), +(866, 'SRID=4326;POINT(-4.397981 38.10856)'::geometry, ST_Transform('SRID=4326;POINT(-4.397981 38.10856)'::geometry, 3857)), +(867, 'SRID=4326;POINT(-4.398207 38.107988)'::geometry, ST_Transform('SRID=4326;POINT(-4.398207 38.107988)'::geometry, 3857)), +(868, 'SRID=4326;POINT(9.353839 32.862791)'::geometry, ST_Transform('SRID=4326;POINT(9.353839 32.862791)'::geometry, 3857)), +(869, 'SRID=4326;POINT(4.939926 35.255665)'::geometry, ST_Transform('SRID=4326;POINT(4.939926 35.255665)'::geometry, 3857)), +(870, 'SRID=4326;POINT(4.940045 35.255507)'::geometry, ST_Transform('SRID=4326;POINT(4.940045 35.255507)'::geometry, 3857)), +(871, 'SRID=4326;POINT(4.94067 35.255616)'::geometry, ST_Transform('SRID=4326;POINT(4.94067 35.255616)'::geometry, 3857)), +(872, 'SRID=4326;POINT(4.940524 35.255542)'::geometry, ST_Transform('SRID=4326;POINT(4.940524 35.255542)'::geometry, 3857)), +(873, 'SRID=4326;POINT(4.940745 35.254987)'::geometry, ST_Transform('SRID=4326;POINT(4.940745 35.254987)'::geometry, 3857)), +(874, 'SRID=4326;POINT(4.939899 35.255589)'::geometry, ST_Transform('SRID=4326;POINT(4.939899 35.255589)'::geometry, 3857)), +(875, 'SRID=4326;POINT(4.940335 35.25572)'::geometry, ST_Transform('SRID=4326;POINT(4.940335 35.25572)'::geometry, 3857)), +(876, 'SRID=4326;POINT(4.93996 35.255052)'::geometry, ST_Transform('SRID=4326;POINT(4.93996 35.255052)'::geometry, 3857)), +(877, 'SRID=4326;POINT(4.940408 35.255539)'::geometry, ST_Transform('SRID=4326;POINT(4.940408 35.255539)'::geometry, 3857)), +(878, 'SRID=4326;POINT(4.940393 35.25571)'::geometry, ST_Transform('SRID=4326;POINT(4.940393 35.25571)'::geometry, 3857)), +(879, 'SRID=4326;POINT(4.940594 35.255653)'::geometry, ST_Transform('SRID=4326;POINT(4.940594 35.255653)'::geometry, 3857)), +(880, 'SRID=4326;POINT(4.940249 35.255422)'::geometry, ST_Transform('SRID=4326;POINT(4.940249 35.255422)'::geometry, 3857)), +(881, 'SRID=4326;POINT(4.940547 35.255623)'::geometry, ST_Transform('SRID=4326;POINT(4.940547 35.255623)'::geometry, 3857)), +(882, 'SRID=4326;POINT(4.940604 35.255766)'::geometry, ST_Transform('SRID=4326;POINT(4.940604 35.255766)'::geometry, 3857)), +(883, 'SRID=4326;POINT(-4.361161 35.792722)'::geometry, ST_Transform('SRID=4326;POINT(-4.361161 35.792722)'::geometry, 3857)), +(884, 'SRID=4326;POINT(-4.361616 35.792782)'::geometry, ST_Transform('SRID=4326;POINT(-4.361616 35.792782)'::geometry, 3857)), +(885, 'SRID=4326;POINT(-4.361326 35.793018)'::geometry, ST_Transform('SRID=4326;POINT(-4.361326 35.793018)'::geometry, 3857)), +(886, 'SRID=4326;POINT(-4.361662 35.793089)'::geometry, ST_Transform('SRID=4326;POINT(-4.361662 35.793089)'::geometry, 3857)), +(887, 'SRID=4326;POINT(-4.360844 35.793344)'::geometry, ST_Transform('SRID=4326;POINT(-4.360844 35.793344)'::geometry, 3857)), +(888, 'SRID=4326;POINT(-4.360797 35.792963)'::geometry, ST_Transform('SRID=4326;POINT(-4.360797 35.792963)'::geometry, 3857)), +(889, 'SRID=4326;POINT(-4.361643 35.792646)'::geometry, ST_Transform('SRID=4326;POINT(-4.361643 35.792646)'::geometry, 3857)), +(890, 'SRID=4326;POINT(-4.361294 35.792786)'::geometry, ST_Transform('SRID=4326;POINT(-4.361294 35.792786)'::geometry, 3857)), +(891, 'SRID=4326;POINT(-4.361255 35.792726)'::geometry, ST_Transform('SRID=4326;POINT(-4.361255 35.792726)'::geometry, 3857)), +(892, 'SRID=4326;POINT(-4.361299 35.793037)'::geometry, ST_Transform('SRID=4326;POINT(-4.361299 35.793037)'::geometry, 3857)), +(893, 'SRID=4326;POINT(-4.360759 35.793348)'::geometry, ST_Transform('SRID=4326;POINT(-4.360759 35.793348)'::geometry, 3857)), +(894, 'SRID=4326;POINT(-4.361492 35.792563)'::geometry, ST_Transform('SRID=4326;POINT(-4.361492 35.792563)'::geometry, 3857)), +(895, 'SRID=4326;POINT(-4.361138 35.792639)'::geometry, ST_Transform('SRID=4326;POINT(-4.361138 35.792639)'::geometry, 3857)), +(896, 'SRID=4326;POINT(-4.361626 35.793258)'::geometry, ST_Transform('SRID=4326;POINT(-4.361626 35.793258)'::geometry, 3857)), +(897, 'SRID=4326;POINT(-4.361442 35.792772)'::geometry, ST_Transform('SRID=4326;POINT(-4.361442 35.792772)'::geometry, 3857)), +(898, 'SRID=4326;POINT(9.523596 36.520863)'::geometry, ST_Transform('SRID=4326;POINT(9.523596 36.520863)'::geometry, 3857)), +(899, 'SRID=4326;POINT(9.524498 36.520605)'::geometry, ST_Transform('SRID=4326;POINT(9.524498 36.520605)'::geometry, 3857)), +(900, 'SRID=4326;POINT(9.524193 36.520504)'::geometry, ST_Transform('SRID=4326;POINT(9.524193 36.520504)'::geometry, 3857)), +(901, 'SRID=4326;POINT(9.523808 36.520676)'::geometry, ST_Transform('SRID=4326;POINT(9.523808 36.520676)'::geometry, 3857)), +(902, 'SRID=4326;POINT(9.523765 36.520077)'::geometry, ST_Transform('SRID=4326;POINT(9.523765 36.520077)'::geometry, 3857)), +(903, 'SRID=4326;POINT(9.524111 36.52008)'::geometry, ST_Transform('SRID=4326;POINT(9.524111 36.52008)'::geometry, 3857)), +(904, 'SRID=4326;POINT(9.523609 36.520475)'::geometry, ST_Transform('SRID=4326;POINT(9.523609 36.520475)'::geometry, 3857)), +(905, 'SRID=4326;POINT(9.523761 36.520034)'::geometry, ST_Transform('SRID=4326;POINT(9.523761 36.520034)'::geometry, 3857)), +(906, 'SRID=4326;POINT(2.691972 39.13515)'::geometry, ST_Transform('SRID=4326;POINT(2.691972 39.13515)'::geometry, 3857)), +(907, 'SRID=4326;POINT(2.692015 39.135473)'::geometry, ST_Transform('SRID=4326;POINT(2.692015 39.135473)'::geometry, 3857)), +(908, 'SRID=4326;POINT(2.691972 39.135047)'::geometry, ST_Transform('SRID=4326;POINT(2.691972 39.135047)'::geometry, 3857)), +(909, 'SRID=4326;POINT(2.692026 39.135081)'::geometry, ST_Transform('SRID=4326;POINT(2.692026 39.135081)'::geometry, 3857)), +(910, 'SRID=4326;POINT(0.008581 37.840553)'::geometry, ST_Transform('SRID=4326;POINT(0.008581 37.840553)'::geometry, 3857)), +(911, 'SRID=4326;POINT(0.008625 37.840396)'::geometry, ST_Transform('SRID=4326;POINT(0.008625 37.840396)'::geometry, 3857)), +(912, 'SRID=4326;POINT(0.00866 37.840515)'::geometry, ST_Transform('SRID=4326;POINT(0.00866 37.840515)'::geometry, 3857)), +(913, 'SRID=4326;POINT(0.008149 37.840567)'::geometry, ST_Transform('SRID=4326;POINT(0.008149 37.840567)'::geometry, 3857)), +(914, 'SRID=4326;POINT(0.008371 37.840179)'::geometry, ST_Transform('SRID=4326;POINT(0.008371 37.840179)'::geometry, 3857)), +(915, 'SRID=4326;POINT(0.008235 37.840314)'::geometry, ST_Transform('SRID=4326;POINT(0.008235 37.840314)'::geometry, 3857)), +(916, 'SRID=4326;POINT(0.008591 37.840371)'::geometry, ST_Transform('SRID=4326;POINT(0.008591 37.840371)'::geometry, 3857)), +(917, 'SRID=4326;POINT(0.007883 37.840346)'::geometry, ST_Transform('SRID=4326;POINT(0.007883 37.840346)'::geometry, 3857)), +(918, 'SRID=4326;POINT(0.007834 37.841039)'::geometry, ST_Transform('SRID=4326;POINT(0.007834 37.841039)'::geometry, 3857)), +(919, 'SRID=4326;POINT(-3.502093 32.72715)'::geometry, ST_Transform('SRID=4326;POINT(-3.502093 32.72715)'::geometry, 3857)), +(920, 'SRID=4326;POINT(-3.502619 32.726865)'::geometry, ST_Transform('SRID=4326;POINT(-3.502619 32.726865)'::geometry, 3857)), +(921, 'SRID=4326;POINT(-3.501994 32.726925)'::geometry, ST_Transform('SRID=4326;POINT(-3.501994 32.726925)'::geometry, 3857)), +(922, 'SRID=4326;POINT(-3.502067 32.726896)'::geometry, ST_Transform('SRID=4326;POINT(-3.502067 32.726896)'::geometry, 3857)), +(923, 'SRID=4326;POINT(-3.501996 32.727402)'::geometry, ST_Transform('SRID=4326;POINT(-3.501996 32.727402)'::geometry, 3857)), +(924, 'SRID=4326;POINT(-3.502351 32.727182)'::geometry, ST_Transform('SRID=4326;POINT(-3.502351 32.727182)'::geometry, 3857)), +(925, 'SRID=4326;POINT(-3.502569 32.727488)'::geometry, ST_Transform('SRID=4326;POINT(-3.502569 32.727488)'::geometry, 3857)), +(926, 'SRID=4326;POINT(-3.502554 32.727055)'::geometry, ST_Transform('SRID=4326;POINT(-3.502554 32.727055)'::geometry, 3857)), +(927, 'SRID=4326;POINT(-3.501757 32.726911)'::geometry, ST_Transform('SRID=4326;POINT(-3.501757 32.726911)'::geometry, 3857)), +(928, 'SRID=4326;POINT(-3.501867 32.7268)'::geometry, ST_Transform('SRID=4326;POINT(-3.501867 32.7268)'::geometry, 3857)), +(929, 'SRID=4326;POINT(-4.517406 37.456378)'::geometry, ST_Transform('SRID=4326;POINT(-4.517406 37.456378)'::geometry, 3857)), +(930, 'SRID=4326;POINT(-4.516774 37.456898)'::geometry, ST_Transform('SRID=4326;POINT(-4.516774 37.456898)'::geometry, 3857)), +(931, 'SRID=4326;POINT(-4.517543 37.456407)'::geometry, ST_Transform('SRID=4326;POINT(-4.517543 37.456407)'::geometry, 3857)), +(932, 'SRID=4326;POINT(-4.517597 37.456574)'::geometry, ST_Transform('SRID=4326;POINT(-4.517597 37.456574)'::geometry, 3857)), +(933, 'SRID=4326;POINT(-4.516927 37.456282)'::geometry, ST_Transform('SRID=4326;POINT(-4.516927 37.456282)'::geometry, 3857)), +(934, 'SRID=4326;POINT(-4.517612 37.456792)'::geometry, ST_Transform('SRID=4326;POINT(-4.517612 37.456792)'::geometry, 3857)), +(935, 'SRID=4326;POINT(-4.516852 37.456605)'::geometry, ST_Transform('SRID=4326;POINT(-4.516852 37.456605)'::geometry, 3857)), +(936, 'SRID=4326;POINT(-4.51704 37.456707)'::geometry, ST_Transform('SRID=4326;POINT(-4.51704 37.456707)'::geometry, 3857)), +(937, 'SRID=4326;POINT(-4.517468 37.456538)'::geometry, ST_Transform('SRID=4326;POINT(-4.517468 37.456538)'::geometry, 3857)), +(938, 'SRID=4326;POINT(-4.51699 37.456715)'::geometry, ST_Transform('SRID=4326;POINT(-4.51699 37.456715)'::geometry, 3857)), +(939, 'SRID=4326;POINT(-4.51686 37.45712)'::geometry, ST_Transform('SRID=4326;POINT(-4.51686 37.45712)'::geometry, 3857)), +(940, 'SRID=4326;POINT(-4.516981 37.456901)'::geometry, ST_Transform('SRID=4326;POINT(-4.516981 37.456901)'::geometry, 3857)), +(941, 'SRID=4326;POINT(-4.517565 37.45646)'::geometry, ST_Transform('SRID=4326;POINT(-4.517565 37.45646)'::geometry, 3857)), +(942, 'SRID=4326;POINT(-4.516979 37.456419)'::geometry, ST_Transform('SRID=4326;POINT(-4.516979 37.456419)'::geometry, 3857)), +(943, 'SRID=4326;POINT(-5.25281 39.208222)'::geometry, ST_Transform('SRID=4326;POINT(-5.25281 39.208222)'::geometry, 3857)), +(944, 'SRID=4326;POINT(-5.252193 39.208342)'::geometry, ST_Transform('SRID=4326;POINT(-5.252193 39.208342)'::geometry, 3857)), +(945, 'SRID=4326;POINT(-5.252944 39.208113)'::geometry, ST_Transform('SRID=4326;POINT(-5.252944 39.208113)'::geometry, 3857)), +(946, 'SRID=4326;POINT(-3.392779 38.996535)'::geometry, ST_Transform('SRID=4326;POINT(-3.392779 38.996535)'::geometry, 3857)), +(947, 'SRID=4326;POINT(-3.392354 38.996052)'::geometry, ST_Transform('SRID=4326;POINT(-3.392354 38.996052)'::geometry, 3857)), +(948, 'SRID=4326;POINT(-3.392873 38.996805)'::geometry, ST_Transform('SRID=4326;POINT(-3.392873 38.996805)'::geometry, 3857)), +(949, 'SRID=4326;POINT(7.450684 31.45342)'::geometry, ST_Transform('SRID=4326;POINT(7.450684 31.45342)'::geometry, 3857)), +(950, 'SRID=4326;POINT(7.451103 31.453188)'::geometry, ST_Transform('SRID=4326;POINT(7.451103 31.453188)'::geometry, 3857)), +(951, 'SRID=4326;POINT(7.451097 31.453074)'::geometry, ST_Transform('SRID=4326;POINT(7.451097 31.453074)'::geometry, 3857)), +(952, 'SRID=4326;POINT(7.451434 31.453789)'::geometry, ST_Transform('SRID=4326;POINT(7.451434 31.453789)'::geometry, 3857)), +(953, 'SRID=4326;POINT(7.451138 31.453362)'::geometry, ST_Transform('SRID=4326;POINT(7.451138 31.453362)'::geometry, 3857)), +(954, 'SRID=4326;POINT(7.450761 31.453573)'::geometry, ST_Transform('SRID=4326;POINT(7.450761 31.453573)'::geometry, 3857)), +(955, 'SRID=4326;POINT(7.451598 31.453288)'::geometry, ST_Transform('SRID=4326;POINT(7.451598 31.453288)'::geometry, 3857)), +(956, 'SRID=4326;POINT(7.450992 31.453536)'::geometry, ST_Transform('SRID=4326;POINT(7.450992 31.453536)'::geometry, 3857)), +(957, 'SRID=4326;POINT(7.450987 31.453982)'::geometry, ST_Transform('SRID=4326;POINT(7.450987 31.453982)'::geometry, 3857)), +(958, 'SRID=4326;POINT(7.45092 31.453151)'::geometry, ST_Transform('SRID=4326;POINT(7.45092 31.453151)'::geometry, 3857)), +(959, 'SRID=4326;POINT(-5.166299 39.804795)'::geometry, ST_Transform('SRID=4326;POINT(-5.166299 39.804795)'::geometry, 3857)), +(960, 'SRID=4326;POINT(-5.166162 39.804953)'::geometry, ST_Transform('SRID=4326;POINT(-5.166162 39.804953)'::geometry, 3857)), +(961, 'SRID=4326;POINT(-5.166126 39.804703)'::geometry, ST_Transform('SRID=4326;POINT(-5.166126 39.804703)'::geometry, 3857)), +(962, 'SRID=4326;POINT(-5.166944 39.80527)'::geometry, ST_Transform('SRID=4326;POINT(-5.166944 39.80527)'::geometry, 3857)), +(963, 'SRID=4326;POINT(-5.166758 39.805624)'::geometry, ST_Transform('SRID=4326;POINT(-5.166758 39.805624)'::geometry, 3857)), +(964, 'SRID=4326;POINT(-5.166371 39.805331)'::geometry, ST_Transform('SRID=4326;POINT(-5.166371 39.805331)'::geometry, 3857)), +(965, 'SRID=4326;POINT(-5.166318 39.805433)'::geometry, ST_Transform('SRID=4326;POINT(-5.166318 39.805433)'::geometry, 3857)), +(966, 'SRID=4326;POINT(-5.166562 39.804734)'::geometry, ST_Transform('SRID=4326;POINT(-5.166562 39.804734)'::geometry, 3857)), +(967, 'SRID=4326;POINT(-5.167058 39.805388)'::geometry, ST_Transform('SRID=4326;POINT(-5.167058 39.805388)'::geometry, 3857)), +(968, 'SRID=4326;POINT(-5.166405 39.805063)'::geometry, ST_Transform('SRID=4326;POINT(-5.166405 39.805063)'::geometry, 3857)), +(969, 'SRID=4326;POINT(-5.167102 39.805551)'::geometry, ST_Transform('SRID=4326;POINT(-5.167102 39.805551)'::geometry, 3857)), +(970, 'SRID=4326;POINT(5.52788 37.61853)'::geometry, ST_Transform('SRID=4326;POINT(5.52788 37.61853)'::geometry, 3857)), +(971, 'SRID=4326;POINT(5.527105 37.618486)'::geometry, ST_Transform('SRID=4326;POINT(5.527105 37.618486)'::geometry, 3857)), +(972, 'SRID=4326;POINT(5.527643 37.618122)'::geometry, ST_Transform('SRID=4326;POINT(5.527643 37.618122)'::geometry, 3857)), +(973, 'SRID=4326;POINT(6.030142 31.306772)'::geometry, ST_Transform('SRID=4326;POINT(6.030142 31.306772)'::geometry, 3857)), +(974, 'SRID=4326;POINT(6.030499 31.306908)'::geometry, ST_Transform('SRID=4326;POINT(6.030499 31.306908)'::geometry, 3857)), +(975, 'SRID=4326;POINT(6.030614 31.307568)'::geometry, ST_Transform('SRID=4326;POINT(6.030614 31.307568)'::geometry, 3857)), +(976, 'SRID=4326;POINT(6.030637 31.306666)'::geometry, ST_Transform('SRID=4326;POINT(6.030637 31.306666)'::geometry, 3857)), +(977, 'SRID=4326;POINT(6.030282 31.307541)'::geometry, ST_Transform('SRID=4326;POINT(6.030282 31.307541)'::geometry, 3857)), +(978, 'SRID=4326;POINT(6.030282 31.306832)'::geometry, ST_Transform('SRID=4326;POINT(6.030282 31.306832)'::geometry, 3857)), +(979, 'SRID=4326;POINT(6.03011 31.306838)'::geometry, ST_Transform('SRID=4326;POINT(6.03011 31.306838)'::geometry, 3857)), +(980, 'SRID=4326;POINT(1.829057 34.422718)'::geometry, ST_Transform('SRID=4326;POINT(1.829057 34.422718)'::geometry, 3857)), +(981, 'SRID=4326;POINT(8.782734 33.24252)'::geometry, ST_Transform('SRID=4326;POINT(8.782734 33.24252)'::geometry, 3857)), +(982, 'SRID=4326;POINT(8.782245 33.24248)'::geometry, ST_Transform('SRID=4326;POINT(8.782245 33.24248)'::geometry, 3857)), +(983, 'SRID=4326;POINT(8.78309 33.242807)'::geometry, ST_Transform('SRID=4326;POINT(8.78309 33.242807)'::geometry, 3857)), +(984, 'SRID=4326;POINT(8.783052 33.24202)'::geometry, ST_Transform('SRID=4326;POINT(8.783052 33.24202)'::geometry, 3857)), +(985, 'SRID=4326;POINT(8.782844 33.24273)'::geometry, ST_Transform('SRID=4326;POINT(8.782844 33.24273)'::geometry, 3857)), +(986, 'SRID=4326;POINT(8.782231 33.242443)'::geometry, ST_Transform('SRID=4326;POINT(8.782231 33.242443)'::geometry, 3857)), +(987, 'SRID=4326;POINT(8.782856 33.24207)'::geometry, ST_Transform('SRID=4326;POINT(8.782856 33.24207)'::geometry, 3857)), +(988, 'SRID=4326;POINT(8.783088 33.242078)'::geometry, ST_Transform('SRID=4326;POINT(8.783088 33.242078)'::geometry, 3857)), +(989, 'SRID=4326;POINT(8.782783 33.24224)'::geometry, ST_Transform('SRID=4326;POINT(8.782783 33.24224)'::geometry, 3857)), +(990, 'SRID=4326;POINT(8.783071 33.242071)'::geometry, ST_Transform('SRID=4326;POINT(8.783071 33.242071)'::geometry, 3857)), +(991, 'SRID=4326;POINT(8.783033 33.242419)'::geometry, ST_Transform('SRID=4326;POINT(8.783033 33.242419)'::geometry, 3857)), +(992, 'SRID=4326;POINT(8.782311 33.242637)'::geometry, ST_Transform('SRID=4326;POINT(8.782311 33.242637)'::geometry, 3857)), +(993, 'SRID=4326;POINT(4.39674 36.892468)'::geometry, ST_Transform('SRID=4326;POINT(4.39674 36.892468)'::geometry, 3857)), +(994, 'SRID=4326;POINT(4.396783 36.891769)'::geometry, ST_Transform('SRID=4326;POINT(4.396783 36.891769)'::geometry, 3857)), +(995, 'SRID=4326;POINT(4.396202 36.891833)'::geometry, ST_Transform('SRID=4326;POINT(4.396202 36.891833)'::geometry, 3857)), +(996, 'SRID=4326;POINT(4.396442 36.892369)'::geometry, ST_Transform('SRID=4326;POINT(4.396442 36.892369)'::geometry, 3857)), +(997, 'SRID=4326;POINT(4.396019 36.892199)'::geometry, ST_Transform('SRID=4326;POINT(4.396019 36.892199)'::geometry, 3857)), +(998, 'SRID=4326;POINT(4.396474 36.892466)'::geometry, ST_Transform('SRID=4326;POINT(4.396474 36.892466)'::geometry, 3857)), +(999, 'SRID=4326;POINT(4.396306 36.891886)'::geometry, ST_Transform('SRID=4326;POINT(4.396306 36.891886)'::geometry, 3857)), +(1000, 'SRID=4326;POINT(4.396362 36.89161)'::geometry, ST_Transform('SRID=4326;POINT(4.396362 36.89161)'::geometry, 3857)), +(1001, 'SRID=4326;POINT(-3.025791 39.730985)'::geometry, ST_Transform('SRID=4326;POINT(-3.025791 39.730985)'::geometry, 3857)), +(1002, 'SRID=4326;POINT(-3.025076 39.731156)'::geometry, ST_Transform('SRID=4326;POINT(-3.025076 39.731156)'::geometry, 3857)), +(1003, 'SRID=4326;POINT(-3.025444 39.731737)'::geometry, ST_Transform('SRID=4326;POINT(-3.025444 39.731737)'::geometry, 3857)), +(1004, 'SRID=4326;POINT(-3.025222 39.731439)'::geometry, ST_Transform('SRID=4326;POINT(-3.025222 39.731439)'::geometry, 3857)), +(1005, 'SRID=4326;POINT(-3.025759 39.731847)'::geometry, ST_Transform('SRID=4326;POINT(-3.025759 39.731847)'::geometry, 3857)), +(1006, 'SRID=4326;POINT(-3.025799 39.731368)'::geometry, ST_Transform('SRID=4326;POINT(-3.025799 39.731368)'::geometry, 3857)), +(1007, 'SRID=4326;POINT(3.297084 30.775964)'::geometry, ST_Transform('SRID=4326;POINT(3.297084 30.775964)'::geometry, 3857)), +(1008, 'SRID=4326;POINT(3.297041 30.775622)'::geometry, ST_Transform('SRID=4326;POINT(3.297041 30.775622)'::geometry, 3857)), +(1009, 'SRID=4326;POINT(3.297415 30.775269)'::geometry, ST_Transform('SRID=4326;POINT(3.297415 30.775269)'::geometry, 3857)), +(1010, 'SRID=4326;POINT(3.296819 30.775614)'::geometry, ST_Transform('SRID=4326;POINT(3.296819 30.775614)'::geometry, 3857)), +(1011, 'SRID=4326;POINT(1.946867 38.568477)'::geometry, ST_Transform('SRID=4326;POINT(1.946867 38.568477)'::geometry, 3857)), +(1012, 'SRID=4326;POINT(1.94724 38.568368)'::geometry, ST_Transform('SRID=4326;POINT(1.94724 38.568368)'::geometry, 3857)), +(1013, 'SRID=4326;POINT(1.946641 38.568434)'::geometry, ST_Transform('SRID=4326;POINT(1.946641 38.568434)'::geometry, 3857)), +(1014, 'SRID=4326;POINT(1.946387 38.568415)'::geometry, ST_Transform('SRID=4326;POINT(1.946387 38.568415)'::geometry, 3857)), +(1015, 'SRID=4326;POINT(1.947139 38.568329)'::geometry, ST_Transform('SRID=4326;POINT(1.947139 38.568329)'::geometry, 3857)), +(1016, 'SRID=4326;POINT(1.947311 38.568084)'::geometry, ST_Transform('SRID=4326;POINT(1.947311 38.568084)'::geometry, 3857)), +(1017, 'SRID=4326;POINT(1.946555 38.5683)'::geometry, ST_Transform('SRID=4326;POINT(1.946555 38.5683)'::geometry, 3857)), +(1018, 'SRID=4326;POINT(1.946498 38.568167)'::geometry, ST_Transform('SRID=4326;POINT(1.946498 38.568167)'::geometry, 3857)), +(1019, 'SRID=4326;POINT(3.078254 39.32079)'::geometry, ST_Transform('SRID=4326;POINT(3.078254 39.32079)'::geometry, 3857)), +(1020, 'SRID=4326;POINT(3.07886 39.321409)'::geometry, ST_Transform('SRID=4326;POINT(3.07886 39.321409)'::geometry, 3857)), +(1021, 'SRID=4326;POINT(3.078319 39.32066)'::geometry, ST_Transform('SRID=4326;POINT(3.078319 39.32066)'::geometry, 3857)), +(1022, 'SRID=4326;POINT(3.078967 39.321233)'::geometry, ST_Transform('SRID=4326;POINT(3.078967 39.321233)'::geometry, 3857)), +(1023, 'SRID=4326;POINT(3.079088 39.321035)'::geometry, ST_Transform('SRID=4326;POINT(3.079088 39.321035)'::geometry, 3857)), +(1024, 'SRID=4326;POINT(3.078989 39.32099)'::geometry, ST_Transform('SRID=4326;POINT(3.078989 39.32099)'::geometry, 3857)), +(1025, 'SRID=4326;POINT(-4.467508 33.62169)'::geometry, ST_Transform('SRID=4326;POINT(-4.467508 33.62169)'::geometry, 3857)), +(1026, 'SRID=4326;POINT(-4.467668 33.621298)'::geometry, ST_Transform('SRID=4326;POINT(-4.467668 33.621298)'::geometry, 3857)), +(1027, 'SRID=4326;POINT(-4.467722 33.621318)'::geometry, ST_Transform('SRID=4326;POINT(-4.467722 33.621318)'::geometry, 3857)), +(1028, 'SRID=4326;POINT(-4.467164 33.621939)'::geometry, ST_Transform('SRID=4326;POINT(-4.467164 33.621939)'::geometry, 3857)), +(1029, 'SRID=4326;POINT(-4.467144 33.621807)'::geometry, ST_Transform('SRID=4326;POINT(-4.467144 33.621807)'::geometry, 3857)), +(1030, 'SRID=4326;POINT(-4.467366 33.621429)'::geometry, ST_Transform('SRID=4326;POINT(-4.467366 33.621429)'::geometry, 3857)), +(1031, 'SRID=4326;POINT(-4.467878 33.622214)'::geometry, ST_Transform('SRID=4326;POINT(-4.467878 33.622214)'::geometry, 3857)), +(1032, 'SRID=4326;POINT(-4.467818 33.621395)'::geometry, ST_Transform('SRID=4326;POINT(-4.467818 33.621395)'::geometry, 3857)), +(1033, 'SRID=4326;POINT(-4.467505 33.621982)'::geometry, ST_Transform('SRID=4326;POINT(-4.467505 33.621982)'::geometry, 3857)), +(1034, 'SRID=4326;POINT(-4.467095 33.622136)'::geometry, ST_Transform('SRID=4326;POINT(-4.467095 33.622136)'::geometry, 3857)), +(1035, 'SRID=4326;POINT(-4.467018 33.62219)'::geometry, ST_Transform('SRID=4326;POINT(-4.467018 33.62219)'::geometry, 3857)), +(1036, 'SRID=4326;POINT(-9.386335 38.537964)'::geometry, ST_Transform('SRID=4326;POINT(-9.386335 38.537964)'::geometry, 3857)), +(1037, 'SRID=4326;POINT(-9.387058 38.537527)'::geometry, ST_Transform('SRID=4326;POINT(-9.387058 38.537527)'::geometry, 3857)), +(1038, 'SRID=4326;POINT(-9.386532 38.538384)'::geometry, ST_Transform('SRID=4326;POINT(-9.386532 38.538384)'::geometry, 3857)), +(1039, 'SRID=4326;POINT(-9.386851 38.538101)'::geometry, ST_Transform('SRID=4326;POINT(-9.386851 38.538101)'::geometry, 3857)), +(1040, 'SRID=4326;POINT(-9.38632 38.538314)'::geometry, ST_Transform('SRID=4326;POINT(-9.38632 38.538314)'::geometry, 3857)), +(1041, 'SRID=4326;POINT(1.724469 36.566868)'::geometry, ST_Transform('SRID=4326;POINT(1.724469 36.566868)'::geometry, 3857)), +(1042, 'SRID=4326;POINT(1.724216 36.567273)'::geometry, ST_Transform('SRID=4326;POINT(1.724216 36.567273)'::geometry, 3857)), +(1043, 'SRID=4326;POINT(1.725133 36.56699)'::geometry, ST_Transform('SRID=4326;POINT(1.725133 36.56699)'::geometry, 3857)), +(1044, 'SRID=4326;POINT(1.72427 36.566541)'::geometry, ST_Transform('SRID=4326;POINT(1.72427 36.566541)'::geometry, 3857)), +(1045, 'SRID=4326;POINT(1.724579 36.566727)'::geometry, ST_Transform('SRID=4326;POINT(1.724579 36.566727)'::geometry, 3857)), +(1046, 'SRID=4326;POINT(1.724377 36.566944)'::geometry, ST_Transform('SRID=4326;POINT(1.724377 36.566944)'::geometry, 3857)), +(1047, 'SRID=4326;POINT(1.724544 36.566997)'::geometry, ST_Transform('SRID=4326;POINT(1.724544 36.566997)'::geometry, 3857)), +(1048, 'SRID=4326;POINT(1.725159 36.567219)'::geometry, ST_Transform('SRID=4326;POINT(1.725159 36.567219)'::geometry, 3857)), +(1049, 'SRID=4326;POINT(1.724639 36.567126)'::geometry, ST_Transform('SRID=4326;POINT(1.724639 36.567126)'::geometry, 3857)), +(1050, 'SRID=4326;POINT(1.724887 36.566844)'::geometry, ST_Transform('SRID=4326;POINT(1.724887 36.566844)'::geometry, 3857)), +(1051, 'SRID=4326;POINT(1.7245 36.566783)'::geometry, ST_Transform('SRID=4326;POINT(1.7245 36.566783)'::geometry, 3857)), +(1052, 'SRID=4326;POINT(1.725173 36.566542)'::geometry, ST_Transform('SRID=4326;POINT(1.725173 36.566542)'::geometry, 3857)), +(1053, 'SRID=4326;POINT(-1.215975 32.547197)'::geometry, ST_Transform('SRID=4326;POINT(-1.215975 32.547197)'::geometry, 3857)), +(1054, 'SRID=4326;POINT(-1.215926 32.547507)'::geometry, ST_Transform('SRID=4326;POINT(-1.215926 32.547507)'::geometry, 3857)), +(1055, 'SRID=4326;POINT(-1.216752 32.546703)'::geometry, ST_Transform('SRID=4326;POINT(-1.216752 32.546703)'::geometry, 3857)), +(1056, 'SRID=4326;POINT(-1.216613 32.54718)'::geometry, ST_Transform('SRID=4326;POINT(-1.216613 32.54718)'::geometry, 3857)), +(1057, 'SRID=4326;POINT(-7.993157 37.187857)'::geometry, ST_Transform('SRID=4326;POINT(-7.993157 37.187857)'::geometry, 3857)), +(1058, 'SRID=4326;POINT(-7.992873 37.187745)'::geometry, ST_Transform('SRID=4326;POINT(-7.992873 37.187745)'::geometry, 3857)), +(1059, 'SRID=4326;POINT(-7.993091 37.18814)'::geometry, ST_Transform('SRID=4326;POINT(-7.993091 37.18814)'::geometry, 3857)), +(1060, 'SRID=4326;POINT(-7.992773 37.187507)'::geometry, ST_Transform('SRID=4326;POINT(-7.992773 37.187507)'::geometry, 3857)), +(1061, 'SRID=4326;POINT(-7.99343 37.18819)'::geometry, ST_Transform('SRID=4326;POINT(-7.99343 37.18819)'::geometry, 3857)), +(1062, 'SRID=4326;POINT(-7.992727 37.187234)'::geometry, ST_Transform('SRID=4326;POINT(-7.992727 37.187234)'::geometry, 3857)), +(1063, 'SRID=4326;POINT(-7.992672 37.188057)'::geometry, ST_Transform('SRID=4326;POINT(-7.992672 37.188057)'::geometry, 3857)), +(1064, 'SRID=4326;POINT(-7.99318 37.18763)'::geometry, ST_Transform('SRID=4326;POINT(-7.99318 37.18763)'::geometry, 3857)), +(1065, 'SRID=4326;POINT(8.900398 32.262535)'::geometry, ST_Transform('SRID=4326;POINT(8.900398 32.262535)'::geometry, 3857)), +(1066, 'SRID=4326;POINT(8.900427 32.262327)'::geometry, ST_Transform('SRID=4326;POINT(8.900427 32.262327)'::geometry, 3857)), +(1067, 'SRID=4326;POINT(8.899843 32.262289)'::geometry, ST_Transform('SRID=4326;POINT(8.899843 32.262289)'::geometry, 3857)), +(1068, 'SRID=4326;POINT(8.900334 32.261977)'::geometry, ST_Transform('SRID=4326;POINT(8.900334 32.261977)'::geometry, 3857)), +(1069, 'SRID=4326;POINT(8.900136 32.262758)'::geometry, ST_Transform('SRID=4326;POINT(8.900136 32.262758)'::geometry, 3857)), +(1070, 'SRID=4326;POINT(8.90022 32.262509)'::geometry, ST_Transform('SRID=4326;POINT(8.90022 32.262509)'::geometry, 3857)), +(1071, 'SRID=4326;POINT(8.899751 32.262215)'::geometry, ST_Transform('SRID=4326;POINT(8.899751 32.262215)'::geometry, 3857)), +(1072, 'SRID=4326;POINT(8.900191 32.262102)'::geometry, ST_Transform('SRID=4326;POINT(8.900191 32.262102)'::geometry, 3857)), +(1073, 'SRID=4326;POINT(8.899721 32.262195)'::geometry, ST_Transform('SRID=4326;POINT(8.899721 32.262195)'::geometry, 3857)), +(1074, 'SRID=4326;POINT(8.899932 32.262497)'::geometry, ST_Transform('SRID=4326;POINT(8.899932 32.262497)'::geometry, 3857)), +(1075, 'SRID=4326;POINT(8.899968 32.262464)'::geometry, ST_Transform('SRID=4326;POINT(8.899968 32.262464)'::geometry, 3857)), +(1076, 'SRID=4326;POINT(8.899792 32.262717)'::geometry, ST_Transform('SRID=4326;POINT(8.899792 32.262717)'::geometry, 3857)), +(1077, 'SRID=4326;POINT(8.899919 32.262467)'::geometry, ST_Transform('SRID=4326;POINT(8.899919 32.262467)'::geometry, 3857)), +(1078, 'SRID=4326;POINT(8.9004 32.262731)'::geometry, ST_Transform('SRID=4326;POINT(8.9004 32.262731)'::geometry, 3857)), +(1079, 'SRID=4326;POINT(8.900461 32.262179)'::geometry, ST_Transform('SRID=4326;POINT(8.900461 32.262179)'::geometry, 3857)), +(1080, 'SRID=4326;POINT(8.900539 32.262052)'::geometry, ST_Transform('SRID=4326;POINT(8.900539 32.262052)'::geometry, 3857)), +(1081, 'SRID=4326;POINT(4.408361 39.427357)'::geometry, ST_Transform('SRID=4326;POINT(4.408361 39.427357)'::geometry, 3857)), +(1082, 'SRID=4326;POINT(4.409058 39.42786)'::geometry, ST_Transform('SRID=4326;POINT(4.409058 39.42786)'::geometry, 3857)), +(1083, 'SRID=4326;POINT(4.4091 39.427155)'::geometry, ST_Transform('SRID=4326;POINT(4.4091 39.427155)'::geometry, 3857)), +(1084, 'SRID=4326;POINT(4.408596 39.427209)'::geometry, ST_Transform('SRID=4326;POINT(4.408596 39.427209)'::geometry, 3857)), +(1085, 'SRID=4326;POINT(4.40852 39.427486)'::geometry, ST_Transform('SRID=4326;POINT(4.40852 39.427486)'::geometry, 3857)), +(1086, 'SRID=4326;POINT(4.408387 39.427188)'::geometry, ST_Transform('SRID=4326;POINT(4.408387 39.427188)'::geometry, 3857)), +(1087, 'SRID=4326;POINT(4.408612 39.427674)'::geometry, ST_Transform('SRID=4326;POINT(4.408612 39.427674)'::geometry, 3857)), +(1088, 'SRID=4326;POINT(4.408695 39.427922)'::geometry, ST_Transform('SRID=4326;POINT(4.408695 39.427922)'::geometry, 3857)), +(1089, 'SRID=4326;POINT(4.408693 39.427178)'::geometry, ST_Transform('SRID=4326;POINT(4.408693 39.427178)'::geometry, 3857)), +(1090, 'SRID=4326;POINT(4.408216 39.427706)'::geometry, ST_Transform('SRID=4326;POINT(4.408216 39.427706)'::geometry, 3857)), +(1091, 'SRID=4326;POINT(4.408435 39.427732)'::geometry, ST_Transform('SRID=4326;POINT(4.408435 39.427732)'::geometry, 3857)), +(1092, 'SRID=4326;POINT(4.408737 39.42783)'::geometry, ST_Transform('SRID=4326;POINT(4.408737 39.42783)'::geometry, 3857)), +(1093, 'SRID=4326;POINT(4.408624 39.427073)'::geometry, ST_Transform('SRID=4326;POINT(4.408624 39.427073)'::geometry, 3857)), +(1094, 'SRID=4326;POINT(4.408561 39.427638)'::geometry, ST_Transform('SRID=4326;POINT(4.408561 39.427638)'::geometry, 3857)), +(1095, 'SRID=4326;POINT(4.408244 39.427218)'::geometry, ST_Transform('SRID=4326;POINT(4.408244 39.427218)'::geometry, 3857)), +(1096, 'SRID=4326;POINT(4.408828 39.427396)'::geometry, ST_Transform('SRID=4326;POINT(4.408828 39.427396)'::geometry, 3857)), +(1097, 'SRID=4326;POINT(3.576089 38.267499)'::geometry, ST_Transform('SRID=4326;POINT(3.576089 38.267499)'::geometry, 3857)), +(1098, 'SRID=4326;POINT(3.575583 38.267731)'::geometry, ST_Transform('SRID=4326;POINT(3.575583 38.267731)'::geometry, 3857)), +(1099, 'SRID=4326;POINT(3.576442 38.267889)'::geometry, ST_Transform('SRID=4326;POINT(3.576442 38.267889)'::geometry, 3857)), +(1100, 'SRID=4326;POINT(3.576552 38.267045)'::geometry, ST_Transform('SRID=4326;POINT(3.576552 38.267045)'::geometry, 3857)), +(1101, 'SRID=4326;POINT(3.576473 38.267962)'::geometry, ST_Transform('SRID=4326;POINT(3.576473 38.267962)'::geometry, 3857)), +(1102, 'SRID=4326;POINT(3.576205 38.267778)'::geometry, ST_Transform('SRID=4326;POINT(3.576205 38.267778)'::geometry, 3857)), +(1103, 'SRID=4326;POINT(3.575928 38.267777)'::geometry, ST_Transform('SRID=4326;POINT(3.575928 38.267777)'::geometry, 3857)), +(1104, 'SRID=4326;POINT(3.575696 38.267961)'::geometry, ST_Transform('SRID=4326;POINT(3.575696 38.267961)'::geometry, 3857)), +(1105, 'SRID=4326;POINT(3.57577 38.267063)'::geometry, ST_Transform('SRID=4326;POINT(3.57577 38.267063)'::geometry, 3857)), +(1106, 'SRID=4326;POINT(5.456027 39.062911)'::geometry, ST_Transform('SRID=4326;POINT(5.456027 39.062911)'::geometry, 3857)), +(1107, 'SRID=4326;POINT(5.456313 39.063416)'::geometry, ST_Transform('SRID=4326;POINT(5.456313 39.063416)'::geometry, 3857)), +(1108, 'SRID=4326;POINT(5.455901 39.063434)'::geometry, ST_Transform('SRID=4326;POINT(5.455901 39.063434)'::geometry, 3857)), +(1109, 'SRID=4326;POINT(5.455573 39.06381)'::geometry, ST_Transform('SRID=4326;POINT(5.455573 39.06381)'::geometry, 3857)), +(1110, 'SRID=4326;POINT(5.45574 39.063318)'::geometry, ST_Transform('SRID=4326;POINT(5.45574 39.063318)'::geometry, 3857)), +(1111, 'SRID=4326;POINT(-1.544808 33.33398)'::geometry, ST_Transform('SRID=4326;POINT(-1.544808 33.33398)'::geometry, 3857)), +(1112, 'SRID=4326;POINT(-1.544993 33.333714)'::geometry, ST_Transform('SRID=4326;POINT(-1.544993 33.333714)'::geometry, 3857)), +(1113, 'SRID=4326;POINT(-1.544859 33.333711)'::geometry, ST_Transform('SRID=4326;POINT(-1.544859 33.333711)'::geometry, 3857)), +(1114, 'SRID=4326;POINT(-1.544863 33.334479)'::geometry, ST_Transform('SRID=4326;POINT(-1.544863 33.334479)'::geometry, 3857)); +-- table with attributes +CREATE TABLE base_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry, number double precision, int_number integer, name text, start date); +INSERT INTO base_t VALUES +(1, 'SRID=4326;POINT(9.718384 33.139879)'::geometry, ST_Transform('SRID=4326;POINT(9.718384 33.139879)'::geometry, 3857)), +(2, 'SRID=4326;POINT(9.71832 33.139846)'::geometry, ST_Transform('SRID=4326;POINT(9.71832 33.139846)'::geometry, 3857)), +(3, 'SRID=4326;POINT(9.718776 33.139394)'::geometry, ST_Transform('SRID=4326;POINT(9.718776 33.139394)'::geometry, 3857)), +(4, 'SRID=4326;POINT(9.718086 33.139576)'::geometry, ST_Transform('SRID=4326;POINT(9.718086 33.139576)'::geometry, 3857)), +(5, 'SRID=4326;POINT(9.718036 33.139538)'::geometry, ST_Transform('SRID=4326;POINT(9.718036 33.139538)'::geometry, 3857)), +(6, 'SRID=4326;POINT(9.718197 33.139667)'::geometry, ST_Transform('SRID=4326;POINT(9.718197 33.139667)'::geometry, 3857)), +(7, 'SRID=4326;POINT(9.718357 33.139511)'::geometry, ST_Transform('SRID=4326;POINT(9.718357 33.139511)'::geometry, 3857)), +(8, 'SRID=4326;POINT(9.718385 33.13984)'::geometry, ST_Transform('SRID=4326;POINT(9.718385 33.13984)'::geometry, 3857)), +(9, 'SRID=4326;POINT(9.718312 33.139405)'::geometry, ST_Transform('SRID=4326;POINT(9.718312 33.139405)'::geometry, 3857)), +(10, 'SRID=4326;POINT(9.718951 33.139878)'::geometry, ST_Transform('SRID=4326;POINT(9.718951 33.139878)'::geometry, 3857)), +(11, 'SRID=4326;POINT(9.718799 33.139942)'::geometry, ST_Transform('SRID=4326;POINT(9.718799 33.139942)'::geometry, 3857)), +(12, 'SRID=4326;POINT(9.718777 33.139681)'::geometry, ST_Transform('SRID=4326;POINT(9.718777 33.139681)'::geometry, 3857)), +(13, 'SRID=4326;POINT(9.717971 33.13981)'::geometry, ST_Transform('SRID=4326;POINT(9.717971 33.13981)'::geometry, 3857)), +(14, 'SRID=4326;POINT(9.718334 33.139541)'::geometry, ST_Transform('SRID=4326;POINT(9.718334 33.139541)'::geometry, 3857)), +(15, 'SRID=4326;POINT(-5.989195 39.206665)'::geometry, ST_Transform('SRID=4326;POINT(-5.989195 39.206665)'::geometry, 3857)), +(16, 'SRID=4326;POINT(-5.988446 39.207071)'::geometry, ST_Transform('SRID=4326;POINT(-5.988446 39.207071)'::geometry, 3857)), +(17, 'SRID=4326;POINT(-5.989083 39.207225)'::geometry, ST_Transform('SRID=4326;POINT(-5.989083 39.207225)'::geometry, 3857)), +(18, 'SRID=4326;POINT(8.510012 32.031818)'::geometry, ST_Transform('SRID=4326;POINT(8.510012 32.031818)'::geometry, 3857)), +(19, 'SRID=4326;POINT(8.509814 32.03189)'::geometry, ST_Transform('SRID=4326;POINT(8.509814 32.03189)'::geometry, 3857)), +(20, 'SRID=4326;POINT(8.510091 32.031737)'::geometry, ST_Transform('SRID=4326;POINT(8.510091 32.031737)'::geometry, 3857)), +(21, 'SRID=4326;POINT(-1.337826 37.660347)'::geometry, ST_Transform('SRID=4326;POINT(-1.337826 37.660347)'::geometry, 3857)), +(22, 'SRID=4326;POINT(-1.337618 37.660051)'::geometry, ST_Transform('SRID=4326;POINT(-1.337618 37.660051)'::geometry, 3857)), +(23, 'SRID=4326;POINT(-1.337644 37.659833)'::geometry, ST_Transform('SRID=4326;POINT(-1.337644 37.659833)'::geometry, 3857)), +(24, 'SRID=4326;POINT(-1.337701 37.659615)'::geometry, ST_Transform('SRID=4326;POINT(-1.337701 37.659615)'::geometry, 3857)), +(25, 'SRID=4326;POINT(-1.337237 37.659644)'::geometry, ST_Transform('SRID=4326;POINT(-1.337237 37.659644)'::geometry, 3857)), +(26, 'SRID=4326;POINT(-1.337542 37.660018)'::geometry, ST_Transform('SRID=4326;POINT(-1.337542 37.660018)'::geometry, 3857)), +(27, 'SRID=4326;POINT(-1.337848 37.659752)'::geometry, ST_Transform('SRID=4326;POINT(-1.337848 37.659752)'::geometry, 3857)), +(28, 'SRID=4326;POINT(-1.337659 37.659788)'::geometry, ST_Transform('SRID=4326;POINT(-1.337659 37.659788)'::geometry, 3857)), +(29, 'SRID=4326;POINT(-1.337194 37.660026)'::geometry, ST_Transform('SRID=4326;POINT(-1.337194 37.660026)'::geometry, 3857)), +(30, 'SRID=4326;POINT(-1.337714 37.659619)'::geometry, ST_Transform('SRID=4326;POINT(-1.337714 37.659619)'::geometry, 3857)), +(31, 'SRID=4326;POINT(-1.337846 37.659781)'::geometry, ST_Transform('SRID=4326;POINT(-1.337846 37.659781)'::geometry, 3857)), +(32, 'SRID=4326;POINT(-1.33751 37.66052)'::geometry, ST_Transform('SRID=4326;POINT(-1.33751 37.66052)'::geometry, 3857)), +(33, 'SRID=4326;POINT(-1.337669 37.660154)'::geometry, ST_Transform('SRID=4326;POINT(-1.337669 37.660154)'::geometry, 3857)), +(34, 'SRID=4326;POINT(-3.050809 34.810112)'::geometry, ST_Transform('SRID=4326;POINT(-3.050809 34.810112)'::geometry, 3857)), +(35, 'SRID=4326;POINT(-3.049988 34.811057)'::geometry, ST_Transform('SRID=4326;POINT(-3.049988 34.811057)'::geometry, 3857)), +(36, 'SRID=4326;POINT(-3.050564 34.810536)'::geometry, ST_Transform('SRID=4326;POINT(-3.050564 34.810536)'::geometry, 3857)), +(37, 'SRID=4326;POINT(-3.050442 34.810239)'::geometry, ST_Transform('SRID=4326;POINT(-3.050442 34.810239)'::geometry, 3857)), +(38, 'SRID=4326;POINT(-3.05032 34.810969)'::geometry, ST_Transform('SRID=4326;POINT(-3.05032 34.810969)'::geometry, 3857)), +(39, 'SRID=4326;POINT(-3.050097 34.810504)'::geometry, ST_Transform('SRID=4326;POINT(-3.050097 34.810504)'::geometry, 3857)), +(40, 'SRID=4326;POINT(-3.05055 34.810908)'::geometry, ST_Transform('SRID=4326;POINT(-3.05055 34.810908)'::geometry, 3857)), +(41, 'SRID=4326;POINT(-3.050086 34.810386)'::geometry, ST_Transform('SRID=4326;POINT(-3.050086 34.810386)'::geometry, 3857)), +(42, 'SRID=4326;POINT(-3.050485 34.810751)'::geometry, ST_Transform('SRID=4326;POINT(-3.050485 34.810751)'::geometry, 3857)), +(43, 'SRID=4326;POINT(-3.04984 34.810113)'::geometry, ST_Transform('SRID=4326;POINT(-3.04984 34.810113)'::geometry, 3857)), +(44, 'SRID=4326;POINT(-3.049975 34.810547)'::geometry, ST_Transform('SRID=4326;POINT(-3.049975 34.810547)'::geometry, 3857)), +(45, 'SRID=4326;POINT(-3.05065 34.810262)'::geometry, ST_Transform('SRID=4326;POINT(-3.05065 34.810262)'::geometry, 3857)), +(46, 'SRID=4326;POINT(-3.050618 34.8107)'::geometry, ST_Transform('SRID=4326;POINT(-3.050618 34.8107)'::geometry, 3857)), +(47, 'SRID=4326;POINT(-3.050325 34.810601)'::geometry, ST_Transform('SRID=4326;POINT(-3.050325 34.810601)'::geometry, 3857)), +(48, 'SRID=4326;POINT(-3.049874 34.810936)'::geometry, ST_Transform('SRID=4326;POINT(-3.049874 34.810936)'::geometry, 3857)), +(49, 'SRID=4326;POINT(-3.049991 34.810872)'::geometry, ST_Transform('SRID=4326;POINT(-3.049991 34.810872)'::geometry, 3857)), +(50, 'SRID=4326;POINT(-7.192205 34.110465)'::geometry, ST_Transform('SRID=4326;POINT(-7.192205 34.110465)'::geometry, 3857)), +(51, 'SRID=4326;POINT(-1.111773 31.260536)'::geometry, ST_Transform('SRID=4326;POINT(-1.111773 31.260536)'::geometry, 3857)), +(52, 'SRID=4326;POINT(-1.112389 31.26055)'::geometry, ST_Transform('SRID=4326;POINT(-1.112389 31.26055)'::geometry, 3857)), +(53, 'SRID=4326;POINT(-1.11196 31.260683)'::geometry, ST_Transform('SRID=4326;POINT(-1.11196 31.260683)'::geometry, 3857)), +(54, 'SRID=4326;POINT(-1.11169 31.260137)'::geometry, ST_Transform('SRID=4326;POINT(-1.11169 31.260137)'::geometry, 3857)), +(55, 'SRID=4326;POINT(-1.111784 31.259982)'::geometry, ST_Transform('SRID=4326;POINT(-1.111784 31.259982)'::geometry, 3857)), +(56, 'SRID=4326;POINT(-1.111957 31.26044)'::geometry, ST_Transform('SRID=4326;POINT(-1.111957 31.26044)'::geometry, 3857)), +(57, 'SRID=4326;POINT(-1.112346 31.260099)'::geometry, ST_Transform('SRID=4326;POINT(-1.112346 31.260099)'::geometry, 3857)), +(58, 'SRID=4326;POINT(-1.112361 31.260683)'::geometry, ST_Transform('SRID=4326;POINT(-1.112361 31.260683)'::geometry, 3857)), +(59, 'SRID=4326;POINT(-1.112424 31.260104)'::geometry, ST_Transform('SRID=4326;POINT(-1.112424 31.260104)'::geometry, 3857)), +(60, 'SRID=4326;POINT(-1.11189 31.260241)'::geometry, ST_Transform('SRID=4326;POINT(-1.11189 31.260241)'::geometry, 3857)), +(61, 'SRID=4326;POINT(-1.111632 31.260126)'::geometry, ST_Transform('SRID=4326;POINT(-1.111632 31.260126)'::geometry, 3857)), +(62, 'SRID=4326;POINT(-1.112057 31.260066)'::geometry, ST_Transform('SRID=4326;POINT(-1.112057 31.260066)'::geometry, 3857)), +(63, 'SRID=4326;POINT(-1.111878 31.260402)'::geometry, ST_Transform('SRID=4326;POINT(-1.111878 31.260402)'::geometry, 3857)), +(64, 'SRID=4326;POINT(-1.112086 31.260331)'::geometry, ST_Transform('SRID=4326;POINT(-1.112086 31.260331)'::geometry, 3857)), +(65, 'SRID=4326;POINT(-1.11192 31.25996)'::geometry, ST_Transform('SRID=4326;POINT(-1.11192 31.25996)'::geometry, 3857)), +(66, 'SRID=4326;POINT(-1.111971 31.260519)'::geometry, ST_Transform('SRID=4326;POINT(-1.111971 31.260519)'::geometry, 3857)), +(67, 'SRID=4326;POINT(1.981315 36.414172)'::geometry, ST_Transform('SRID=4326;POINT(1.981315 36.414172)'::geometry, 3857)), +(68, 'SRID=4326;POINT(1.981157 36.414659)'::geometry, ST_Transform('SRID=4326;POINT(1.981157 36.414659)'::geometry, 3857)), +(69, 'SRID=4326;POINT(1.981097 36.414188)'::geometry, ST_Transform('SRID=4326;POINT(1.981097 36.414188)'::geometry, 3857)), +(70, 'SRID=4326;POINT(1.98147 36.414969)'::geometry, ST_Transform('SRID=4326;POINT(1.98147 36.414969)'::geometry, 3857)), +(71, 'SRID=4326;POINT(1.981473 36.414819)'::geometry, ST_Transform('SRID=4326;POINT(1.981473 36.414819)'::geometry, 3857)), +(72, 'SRID=4326;POINT(1.981159 36.414521)'::geometry, ST_Transform('SRID=4326;POINT(1.981159 36.414521)'::geometry, 3857)), +(73, 'SRID=4326;POINT(1.981434 36.414368)'::geometry, ST_Transform('SRID=4326;POINT(1.981434 36.414368)'::geometry, 3857)), +(74, 'SRID=4326;POINT(1.981508 36.414849)'::geometry, ST_Transform('SRID=4326;POINT(1.981508 36.414849)'::geometry, 3857)), +(75, 'SRID=4326;POINT(1.980794 36.414325)'::geometry, ST_Transform('SRID=4326;POINT(1.980794 36.414325)'::geometry, 3857)), +(76, 'SRID=4326;POINT(1.981257 36.414346)'::geometry, ST_Transform('SRID=4326;POINT(1.981257 36.414346)'::geometry, 3857)), +(77, 'SRID=4326;POINT(-0.953948 39.768838)'::geometry, ST_Transform('SRID=4326;POINT(-0.953948 39.768838)'::geometry, 3857)), +(78, 'SRID=4326;POINT(-0.954525 39.768965)'::geometry, ST_Transform('SRID=4326;POINT(-0.954525 39.768965)'::geometry, 3857)), +(79, 'SRID=4326;POINT(-0.954753 39.76904)'::geometry, ST_Transform('SRID=4326;POINT(-0.954753 39.76904)'::geometry, 3857)), +(80, 'SRID=4326;POINT(-0.954287 39.769265)'::geometry, ST_Transform('SRID=4326;POINT(-0.954287 39.769265)'::geometry, 3857)), +(81, 'SRID=4326;POINT(-0.953996 39.76948)'::geometry, ST_Transform('SRID=4326;POINT(-0.953996 39.76948)'::geometry, 3857)), +(82, 'SRID=4326;POINT(-0.954469 39.769349)'::geometry, ST_Transform('SRID=4326;POINT(-0.954469 39.769349)'::geometry, 3857)), +(83, 'SRID=4326;POINT(-0.953957 39.769444)'::geometry, ST_Transform('SRID=4326;POINT(-0.953957 39.769444)'::geometry, 3857)), +(84, 'SRID=4326;POINT(-0.954757 39.7688)'::geometry, ST_Transform('SRID=4326;POINT(-0.954757 39.7688)'::geometry, 3857)), +(85, 'SRID=4326;POINT(-0.954196 39.769695)'::geometry, ST_Transform('SRID=4326;POINT(-0.954196 39.769695)'::geometry, 3857)), +(86, 'SRID=4326;POINT(-0.954047 39.768844)'::geometry, ST_Transform('SRID=4326;POINT(-0.954047 39.768844)'::geometry, 3857)), +(87, 'SRID=4326;POINT(-0.954191 39.769569)'::geometry, ST_Transform('SRID=4326;POINT(-0.954191 39.769569)'::geometry, 3857)), +(88, 'SRID=4326;POINT(-0.954122 39.7692)'::geometry, ST_Transform('SRID=4326;POINT(-0.954122 39.7692)'::geometry, 3857)), +(89, 'SRID=4326;POINT(-0.954273 39.76964)'::geometry, ST_Transform('SRID=4326;POINT(-0.954273 39.76964)'::geometry, 3857)), +(90, 'SRID=4326;POINT(-0.953816 39.769145)'::geometry, ST_Transform('SRID=4326;POINT(-0.953816 39.769145)'::geometry, 3857)), +(91, 'SRID=4326;POINT(-0.954025 39.7691)'::geometry, ST_Transform('SRID=4326;POINT(-0.954025 39.7691)'::geometry, 3857)), +(92, 'SRID=4326;POINT(-0.95416 39.769704)'::geometry, ST_Transform('SRID=4326;POINT(-0.95416 39.769704)'::geometry, 3857)), +(93, 'SRID=4326;POINT(-7.587221 32.009901)'::geometry, ST_Transform('SRID=4326;POINT(-7.587221 32.009901)'::geometry, 3857)), +(94, 'SRID=4326;POINT(-7.586856 32.010641)'::geometry, ST_Transform('SRID=4326;POINT(-7.586856 32.010641)'::geometry, 3857)), +(95, 'SRID=4326;POINT(-7.586722 32.010493)'::geometry, ST_Transform('SRID=4326;POINT(-7.586722 32.010493)'::geometry, 3857)), +(96, 'SRID=4326;POINT(-7.586391 32.010262)'::geometry, ST_Transform('SRID=4326;POINT(-7.586391 32.010262)'::geometry, 3857)), +(97, 'SRID=4326;POINT(-7.586974 32.010238)'::geometry, ST_Transform('SRID=4326;POINT(-7.586974 32.010238)'::geometry, 3857)), +(98, 'SRID=4326;POINT(-7.586775 32.010427)'::geometry, ST_Transform('SRID=4326;POINT(-7.586775 32.010427)'::geometry, 3857)), +(99, 'SRID=4326;POINT(-7.586872 32.009897)'::geometry, ST_Transform('SRID=4326;POINT(-7.586872 32.009897)'::geometry, 3857)), +(100, 'SRID=4326;POINT(-7.586628 32.010007)'::geometry, ST_Transform('SRID=4326;POINT(-7.586628 32.010007)'::geometry, 3857)), +(101, 'SRID=4326;POINT(-7.587165 32.010048)'::geometry, ST_Transform('SRID=4326;POINT(-7.587165 32.010048)'::geometry, 3857)), +(102, 'SRID=4326;POINT(1.184165 37.50755)'::geometry, ST_Transform('SRID=4326;POINT(1.184165 37.50755)'::geometry, 3857)), +(103, 'SRID=4326;POINT(1.183645 37.507603)'::geometry, ST_Transform('SRID=4326;POINT(1.183645 37.507603)'::geometry, 3857)), +(104, 'SRID=4326;POINT(1.184264 37.507825)'::geometry, ST_Transform('SRID=4326;POINT(1.184264 37.507825)'::geometry, 3857)), +(105, 'SRID=4326;POINT(1.184288 37.507609)'::geometry, ST_Transform('SRID=4326;POINT(1.184288 37.507609)'::geometry, 3857)), +(106, 'SRID=4326;POINT(1.183561 37.507407)'::geometry, ST_Transform('SRID=4326;POINT(1.183561 37.507407)'::geometry, 3857)), +(107, 'SRID=4326;POINT(1.184181 37.50741)'::geometry, ST_Transform('SRID=4326;POINT(1.184181 37.50741)'::geometry, 3857)), +(108, 'SRID=4326;POINT(1.183824 37.508023)'::geometry, ST_Transform('SRID=4326;POINT(1.183824 37.508023)'::geometry, 3857)), +(109, 'SRID=4326;POINT(1.183603 37.507709)'::geometry, ST_Transform('SRID=4326;POINT(1.183603 37.507709)'::geometry, 3857)), +(110, 'SRID=4326;POINT(1.18372 37.507527)'::geometry, ST_Transform('SRID=4326;POINT(1.18372 37.507527)'::geometry, 3857)), +(111, 'SRID=4326;POINT(1.183425 37.507321)'::geometry, ST_Transform('SRID=4326;POINT(1.183425 37.507321)'::geometry, 3857)), +(112, 'SRID=4326;POINT(1.184305 37.507615)'::geometry, ST_Transform('SRID=4326;POINT(1.184305 37.507615)'::geometry, 3857)), +(113, 'SRID=4326;POINT(1.183852 37.508007)'::geometry, ST_Transform('SRID=4326;POINT(1.183852 37.508007)'::geometry, 3857)), +(114, 'SRID=4326;POINT(3.831779 31.429738)'::geometry, ST_Transform('SRID=4326;POINT(3.831779 31.429738)'::geometry, 3857)), +(115, 'SRID=4326;POINT(3.831813 31.4298)'::geometry, ST_Transform('SRID=4326;POINT(3.831813 31.4298)'::geometry, 3857)), +(116, 'SRID=4326;POINT(3.831852 31.429751)'::geometry, ST_Transform('SRID=4326;POINT(3.831852 31.429751)'::geometry, 3857)), +(117, 'SRID=4326;POINT(3.832368 31.430079)'::geometry, ST_Transform('SRID=4326;POINT(3.832368 31.430079)'::geometry, 3857)), +(118, 'SRID=4326;POINT(3.83201 31.429663)'::geometry, ST_Transform('SRID=4326;POINT(3.83201 31.429663)'::geometry, 3857)), +(119, 'SRID=4326;POINT(3.832181 31.429739)'::geometry, ST_Transform('SRID=4326;POINT(3.832181 31.429739)'::geometry, 3857)), +(120, 'SRID=4326;POINT(3.831543 31.429602)'::geometry, ST_Transform('SRID=4326;POINT(3.831543 31.429602)'::geometry, 3857)), +(121, 'SRID=4326;POINT(3.831601 31.430119)'::geometry, ST_Transform('SRID=4326;POINT(3.831601 31.430119)'::geometry, 3857)), +(122, 'SRID=4326;POINT(3.831729 31.42977)'::geometry, ST_Transform('SRID=4326;POINT(3.831729 31.42977)'::geometry, 3857)), +(123, 'SRID=4326;POINT(3.831987 31.430192)'::geometry, ST_Transform('SRID=4326;POINT(3.831987 31.430192)'::geometry, 3857)), +(124, 'SRID=4326;POINT(8.47022 33.825659)'::geometry, ST_Transform('SRID=4326;POINT(8.47022 33.825659)'::geometry, 3857)), +(125, 'SRID=4326;POINT(8.470632 33.825421)'::geometry, ST_Transform('SRID=4326;POINT(8.470632 33.825421)'::geometry, 3857)), +(126, 'SRID=4326;POINT(8.470131 33.825262)'::geometry, ST_Transform('SRID=4326;POINT(8.470131 33.825262)'::geometry, 3857)), +(127, 'SRID=4326;POINT(8.470458 33.825972)'::geometry, ST_Transform('SRID=4326;POINT(8.470458 33.825972)'::geometry, 3857)), +(128, 'SRID=4326;POINT(8.470603 33.825651)'::geometry, ST_Transform('SRID=4326;POINT(8.470603 33.825651)'::geometry, 3857)), +(129, 'SRID=4326;POINT(8.470558 33.825475)'::geometry, ST_Transform('SRID=4326;POINT(8.470558 33.825475)'::geometry, 3857)), +(130, 'SRID=4326;POINT(8.470193 33.82544)'::geometry, ST_Transform('SRID=4326;POINT(8.470193 33.82544)'::geometry, 3857)), +(131, 'SRID=4326;POINT(8.47041 33.825325)'::geometry, ST_Transform('SRID=4326;POINT(8.47041 33.825325)'::geometry, 3857)), +(132, 'SRID=4326;POINT(8.470797 33.825402)'::geometry, ST_Transform('SRID=4326;POINT(8.470797 33.825402)'::geometry, 3857)), +(133, 'SRID=4326;POINT(8.470405 33.825234)'::geometry, ST_Transform('SRID=4326;POINT(8.470405 33.825234)'::geometry, 3857)), +(134, 'SRID=4326;POINT(8.47069 33.825547)'::geometry, ST_Transform('SRID=4326;POINT(8.47069 33.825547)'::geometry, 3857)), +(135, 'SRID=4326;POINT(8.470491 33.825588)'::geometry, ST_Transform('SRID=4326;POINT(8.470491 33.825588)'::geometry, 3857)), +(136, 'SRID=4326;POINT(8.470293 33.825798)'::geometry, ST_Transform('SRID=4326;POINT(8.470293 33.825798)'::geometry, 3857)), +(137, 'SRID=4326;POINT(8.47064 33.825412)'::geometry, ST_Transform('SRID=4326;POINT(8.47064 33.825412)'::geometry, 3857)), +(138, 'SRID=4326;POINT(8.470238 33.825427)'::geometry, ST_Transform('SRID=4326;POINT(8.470238 33.825427)'::geometry, 3857)), +(139, 'SRID=4326;POINT(8.20576 30.965218)'::geometry, ST_Transform('SRID=4326;POINT(8.20576 30.965218)'::geometry, 3857)), +(140, 'SRID=4326;POINT(8.205812 30.96474)'::geometry, ST_Transform('SRID=4326;POINT(8.205812 30.96474)'::geometry, 3857)), +(141, 'SRID=4326;POINT(8.205599 30.964695)'::geometry, ST_Transform('SRID=4326;POINT(8.205599 30.964695)'::geometry, 3857)), +(142, 'SRID=4326;POINT(-1.94997 37.466004)'::geometry, ST_Transform('SRID=4326;POINT(-1.94997 37.466004)'::geometry, 3857)), +(143, 'SRID=4326;POINT(-1.950577 37.466006)'::geometry, ST_Transform('SRID=4326;POINT(-1.950577 37.466006)'::geometry, 3857)), +(144, 'SRID=4326;POINT(-1.950744 37.465286)'::geometry, ST_Transform('SRID=4326;POINT(-1.950744 37.465286)'::geometry, 3857)), +(145, 'SRID=4326;POINT(-1.950241 37.466054)'::geometry, ST_Transform('SRID=4326;POINT(-1.950241 37.466054)'::geometry, 3857)), +(146, 'SRID=4326;POINT(-1.950335 37.465202)'::geometry, ST_Transform('SRID=4326;POINT(-1.950335 37.465202)'::geometry, 3857)), +(147, 'SRID=4326;POINT(-1.949968 37.465359)'::geometry, ST_Transform('SRID=4326;POINT(-1.949968 37.465359)'::geometry, 3857)), +(148, 'SRID=4326;POINT(-1.950149 37.465273)'::geometry, ST_Transform('SRID=4326;POINT(-1.950149 37.465273)'::geometry, 3857)), +(149, 'SRID=4326;POINT(-1.950008 37.46512)'::geometry, ST_Transform('SRID=4326;POINT(-1.950008 37.46512)'::geometry, 3857)), +(150, 'SRID=4326;POINT(-1.950516 37.465531)'::geometry, ST_Transform('SRID=4326;POINT(-1.950516 37.465531)'::geometry, 3857)), +(151, 'SRID=4326;POINT(-1.950595 37.465682)'::geometry, ST_Transform('SRID=4326;POINT(-1.950595 37.465682)'::geometry, 3857)), +(152, 'SRID=4326;POINT(-1.950222 37.465858)'::geometry, ST_Transform('SRID=4326;POINT(-1.950222 37.465858)'::geometry, 3857)), +(153, 'SRID=4326;POINT(-1.950306 37.465943)'::geometry, ST_Transform('SRID=4326;POINT(-1.950306 37.465943)'::geometry, 3857)), +(154, 'SRID=4326;POINT(-1.950272 37.466052)'::geometry, ST_Transform('SRID=4326;POINT(-1.950272 37.466052)'::geometry, 3857)), +(155, 'SRID=4326;POINT(-1.950724 37.465937)'::geometry, ST_Transform('SRID=4326;POINT(-1.950724 37.465937)'::geometry, 3857)), +(156, 'SRID=4326;POINT(-1.950334 37.465308)'::geometry, ST_Transform('SRID=4326;POINT(-1.950334 37.465308)'::geometry, 3857)), +(157, 'SRID=4326;POINT(-1.950797 37.465927)'::geometry, ST_Transform('SRID=4326;POINT(-1.950797 37.465927)'::geometry, 3857)), +(158, 'SRID=4326;POINT(9.779537 35.54475)'::geometry, ST_Transform('SRID=4326;POINT(9.779537 35.54475)'::geometry, 3857)), +(159, 'SRID=4326;POINT(9.779673 35.544579)'::geometry, ST_Transform('SRID=4326;POINT(9.779673 35.544579)'::geometry, 3857)), +(160, 'SRID=4326;POINT(9.779822 35.544831)'::geometry, ST_Transform('SRID=4326;POINT(9.779822 35.544831)'::geometry, 3857)), +(161, 'SRID=4326;POINT(-8.280843 31.373195)'::geometry, ST_Transform('SRID=4326;POINT(-8.280843 31.373195)'::geometry, 3857)), +(162, 'SRID=4326;POINT(-8.281007 31.374063)'::geometry, ST_Transform('SRID=4326;POINT(-8.281007 31.374063)'::geometry, 3857)), +(163, 'SRID=4326;POINT(-8.280772 31.373137)'::geometry, ST_Transform('SRID=4326;POINT(-8.280772 31.373137)'::geometry, 3857)), +(164, 'SRID=4326;POINT(-8.28126 31.373852)'::geometry, ST_Transform('SRID=4326;POINT(-8.28126 31.373852)'::geometry, 3857)), +(165, 'SRID=4326;POINT(-8.281032 31.374022)'::geometry, ST_Transform('SRID=4326;POINT(-8.281032 31.374022)'::geometry, 3857)), +(166, 'SRID=4326;POINT(-5.492422 32.876965)'::geometry, ST_Transform('SRID=4326;POINT(-5.492422 32.876965)'::geometry, 3857)), +(167, 'SRID=4326;POINT(-5.492822 32.877251)'::geometry, ST_Transform('SRID=4326;POINT(-5.492822 32.877251)'::geometry, 3857)), +(168, 'SRID=4326;POINT(-5.492531 32.877462)'::geometry, ST_Transform('SRID=4326;POINT(-5.492531 32.877462)'::geometry, 3857)), +(169, 'SRID=4326;POINT(-5.492944 32.877059)'::geometry, ST_Transform('SRID=4326;POINT(-5.492944 32.877059)'::geometry, 3857)), +(170, 'SRID=4326;POINT(-5.492309 32.877729)'::geometry, ST_Transform('SRID=4326;POINT(-5.492309 32.877729)'::geometry, 3857)), +(171, 'SRID=4326;POINT(-5.492892 32.877087)'::geometry, ST_Transform('SRID=4326;POINT(-5.492892 32.877087)'::geometry, 3857)), +(172, 'SRID=4326;POINT(3.901874 37.553725)'::geometry, ST_Transform('SRID=4326;POINT(3.901874 37.553725)'::geometry, 3857)), +(173, 'SRID=4326;POINT(3.902047 37.554527)'::geometry, ST_Transform('SRID=4326;POINT(3.902047 37.554527)'::geometry, 3857)), +(174, 'SRID=4326;POINT(3.901596 37.55417)'::geometry, ST_Transform('SRID=4326;POINT(3.901596 37.55417)'::geometry, 3857)), +(175, 'SRID=4326;POINT(3.902012 37.553726)'::geometry, ST_Transform('SRID=4326;POINT(3.902012 37.553726)'::geometry, 3857)), +(176, 'SRID=4326;POINT(3.901739 37.554492)'::geometry, ST_Transform('SRID=4326;POINT(3.901739 37.554492)'::geometry, 3857)), +(177, 'SRID=4326;POINT(3.901397 37.554598)'::geometry, ST_Transform('SRID=4326;POINT(3.901397 37.554598)'::geometry, 3857)), +(178, 'SRID=4326;POINT(3.901348 37.553662)'::geometry, ST_Transform('SRID=4326;POINT(3.901348 37.553662)'::geometry, 3857)), +(179, 'SRID=4326;POINT(3.90194 37.554032)'::geometry, ST_Transform('SRID=4326;POINT(3.90194 37.554032)'::geometry, 3857)), +(180, 'SRID=4326;POINT(-2.684028 31.988394)'::geometry, ST_Transform('SRID=4326;POINT(-2.684028 31.988394)'::geometry, 3857)), +(181, 'SRID=4326;POINT(-2.684145 31.988734)'::geometry, ST_Transform('SRID=4326;POINT(-2.684145 31.988734)'::geometry, 3857)), +(182, 'SRID=4326;POINT(-2.684262 31.988291)'::geometry, ST_Transform('SRID=4326;POINT(-2.684262 31.988291)'::geometry, 3857)), +(183, 'SRID=4326;POINT(-2.684535 31.988447)'::geometry, ST_Transform('SRID=4326;POINT(-2.684535 31.988447)'::geometry, 3857)), +(184, 'SRID=4326;POINT(-2.684214 31.9884)'::geometry, ST_Transform('SRID=4326;POINT(-2.684214 31.9884)'::geometry, 3857)), +(185, 'SRID=4326;POINT(-2.684298 31.989248)'::geometry, ST_Transform('SRID=4326;POINT(-2.684298 31.989248)'::geometry, 3857)), +(186, 'SRID=4326;POINT(-2.684349 31.988645)'::geometry, ST_Transform('SRID=4326;POINT(-2.684349 31.988645)'::geometry, 3857)), +(187, 'SRID=4326;POINT(-2.683797 31.988608)'::geometry, ST_Transform('SRID=4326;POINT(-2.683797 31.988608)'::geometry, 3857)), +(188, 'SRID=4326;POINT(-2.684117 31.988665)'::geometry, ST_Transform('SRID=4326;POINT(-2.684117 31.988665)'::geometry, 3857)), +(189, 'SRID=4326;POINT(-2.68444 31.988764)'::geometry, ST_Transform('SRID=4326;POINT(-2.68444 31.988764)'::geometry, 3857)), +(190, 'SRID=4326;POINT(-2.684519 31.98856)'::geometry, ST_Transform('SRID=4326;POINT(-2.684519 31.98856)'::geometry, 3857)), +(191, 'SRID=4326;POINT(-2.684361 31.988464)'::geometry, ST_Transform('SRID=4326;POINT(-2.684361 31.988464)'::geometry, 3857)), +(192, 'SRID=4326;POINT(-2.683966 31.988706)'::geometry, ST_Transform('SRID=4326;POINT(-2.683966 31.988706)'::geometry, 3857)), +(193, 'SRID=4326;POINT(-5.650994 38.876385)'::geometry, ST_Transform('SRID=4326;POINT(-5.650994 38.876385)'::geometry, 3857)), +(194, 'SRID=4326;POINT(-5.650197 38.876046)'::geometry, ST_Transform('SRID=4326;POINT(-5.650197 38.876046)'::geometry, 3857)), +(195, 'SRID=4326;POINT(-5.650764 38.875596)'::geometry, ST_Transform('SRID=4326;POINT(-5.650764 38.875596)'::geometry, 3857)), +(196, 'SRID=4326;POINT(-5.650742 38.875876)'::geometry, ST_Transform('SRID=4326;POINT(-5.650742 38.875876)'::geometry, 3857)), +(197, 'SRID=4326;POINT(-5.650184 38.876442)'::geometry, ST_Transform('SRID=4326;POINT(-5.650184 38.876442)'::geometry, 3857)), +(198, 'SRID=4326;POINT(-5.65088 38.876264)'::geometry, ST_Transform('SRID=4326;POINT(-5.65088 38.876264)'::geometry, 3857)), +(199, 'SRID=4326;POINT(-5.650245 38.876459)'::geometry, ST_Transform('SRID=4326;POINT(-5.650245 38.876459)'::geometry, 3857)), +(200, 'SRID=4326;POINT(0.94164 33.420389)'::geometry, ST_Transform('SRID=4326;POINT(0.94164 33.420389)'::geometry, 3857)), +(201, 'SRID=4326;POINT(0.942386 33.420323)'::geometry, ST_Transform('SRID=4326;POINT(0.942386 33.420323)'::geometry, 3857)), +(202, 'SRID=4326;POINT(0.942523 33.420441)'::geometry, ST_Transform('SRID=4326;POINT(0.942523 33.420441)'::geometry, 3857)), +(203, 'SRID=4326;POINT(0.941933 33.420348)'::geometry, ST_Transform('SRID=4326;POINT(0.941933 33.420348)'::geometry, 3857)), +(204, 'SRID=4326;POINT(0.942198 33.42006)'::geometry, ST_Transform('SRID=4326;POINT(0.942198 33.42006)'::geometry, 3857)), +(205, 'SRID=4326;POINT(0.942105 33.420254)'::geometry, ST_Transform('SRID=4326;POINT(0.942105 33.420254)'::geometry, 3857)), +(206, 'SRID=4326;POINT(0.94195 33.419859)'::geometry, ST_Transform('SRID=4326;POINT(0.94195 33.419859)'::geometry, 3857)), +(207, 'SRID=4326;POINT(0.9417 33.419948)'::geometry, ST_Transform('SRID=4326;POINT(0.9417 33.419948)'::geometry, 3857)), +(208, 'SRID=4326;POINT(0.942123 33.420747)'::geometry, ST_Transform('SRID=4326;POINT(0.942123 33.420747)'::geometry, 3857)), +(209, 'SRID=4326;POINT(0.942372 33.420072)'::geometry, ST_Transform('SRID=4326;POINT(0.942372 33.420072)'::geometry, 3857)), +(210, 'SRID=4326;POINT(0.941993 33.41995)'::geometry, ST_Transform('SRID=4326;POINT(0.941993 33.41995)'::geometry, 3857)), +(211, 'SRID=4326;POINT(6.372568 36.408838)'::geometry, ST_Transform('SRID=4326;POINT(6.372568 36.408838)'::geometry, 3857)), +(212, 'SRID=4326;POINT(6.372528 36.408063)'::geometry, ST_Transform('SRID=4326;POINT(6.372528 36.408063)'::geometry, 3857)), +(213, 'SRID=4326;POINT(6.373022 36.408816)'::geometry, ST_Transform('SRID=4326;POINT(6.373022 36.408816)'::geometry, 3857)), +(214, 'SRID=4326;POINT(6.373019 36.408548)'::geometry, ST_Transform('SRID=4326;POINT(6.373019 36.408548)'::geometry, 3857)), +(215, 'SRID=4326;POINT(6.372454 36.408772)'::geometry, ST_Transform('SRID=4326;POINT(6.372454 36.408772)'::geometry, 3857)), +(216, 'SRID=4326;POINT(6.372993 36.408855)'::geometry, ST_Transform('SRID=4326;POINT(6.372993 36.408855)'::geometry, 3857)), +(217, 'SRID=4326;POINT(6.372609 36.40839)'::geometry, ST_Transform('SRID=4326;POINT(6.372609 36.40839)'::geometry, 3857)), +(218, 'SRID=4326;POINT(6.373079 36.408347)'::geometry, ST_Transform('SRID=4326;POINT(6.373079 36.408347)'::geometry, 3857)), +(219, 'SRID=4326;POINT(6.37296 36.408476)'::geometry, ST_Transform('SRID=4326;POINT(6.37296 36.408476)'::geometry, 3857)), +(220, 'SRID=4326;POINT(6.245506 34.781366)'::geometry, ST_Transform('SRID=4326;POINT(6.245506 34.781366)'::geometry, 3857)), +(221, 'SRID=4326;POINT(6.246049 34.781405)'::geometry, ST_Transform('SRID=4326;POINT(6.246049 34.781405)'::geometry, 3857)), +(222, 'SRID=4326;POINT(6.245706 34.780982)'::geometry, ST_Transform('SRID=4326;POINT(6.245706 34.780982)'::geometry, 3857)), +(223, 'SRID=4326;POINT(6.245218 34.78099)'::geometry, ST_Transform('SRID=4326;POINT(6.245218 34.78099)'::geometry, 3857)), +(224, 'SRID=4326;POINT(6.245708 34.781197)'::geometry, ST_Transform('SRID=4326;POINT(6.245708 34.781197)'::geometry, 3857)), +(225, 'SRID=4326;POINT(6.245418 34.781542)'::geometry, ST_Transform('SRID=4326;POINT(6.245418 34.781542)'::geometry, 3857)), +(226, 'SRID=4326;POINT(6.245194 34.781294)'::geometry, ST_Transform('SRID=4326;POINT(6.245194 34.781294)'::geometry, 3857)), +(227, 'SRID=4326;POINT(6.245286 34.781662)'::geometry, ST_Transform('SRID=4326;POINT(6.245286 34.781662)'::geometry, 3857)), +(228, 'SRID=4326;POINT(6.246011 34.781247)'::geometry, ST_Transform('SRID=4326;POINT(6.246011 34.781247)'::geometry, 3857)), +(229, 'SRID=4326;POINT(-0.923093 32.167767)'::geometry, ST_Transform('SRID=4326;POINT(-0.923093 32.167767)'::geometry, 3857)), +(230, 'SRID=4326;POINT(-0.923549 32.167517)'::geometry, ST_Transform('SRID=4326;POINT(-0.923549 32.167517)'::geometry, 3857)), +(231, 'SRID=4326;POINT(-0.923094 32.166999)'::geometry, ST_Transform('SRID=4326;POINT(-0.923094 32.166999)'::geometry, 3857)), +(232, 'SRID=4326;POINT(-0.923765 32.166879)'::geometry, ST_Transform('SRID=4326;POINT(-0.923765 32.166879)'::geometry, 3857)), +(233, 'SRID=4326;POINT(-0.92404 32.167552)'::geometry, ST_Transform('SRID=4326;POINT(-0.92404 32.167552)'::geometry, 3857)), +(234, 'SRID=4326;POINT(-0.923406 32.166902)'::geometry, ST_Transform('SRID=4326;POINT(-0.923406 32.166902)'::geometry, 3857)), +(235, 'SRID=4326;POINT(-0.923247 32.167601)'::geometry, ST_Transform('SRID=4326;POINT(-0.923247 32.167601)'::geometry, 3857)), +(236, 'SRID=4326;POINT(-0.923771 32.167432)'::geometry, ST_Transform('SRID=4326;POINT(-0.923771 32.167432)'::geometry, 3857)), +(237, 'SRID=4326;POINT(-0.923963 32.167581)'::geometry, ST_Transform('SRID=4326;POINT(-0.923963 32.167581)'::geometry, 3857)), +(238, 'SRID=4326;POINT(-9.608738 39.303829)'::geometry, ST_Transform('SRID=4326;POINT(-9.608738 39.303829)'::geometry, 3857)), +(239, 'SRID=4326;POINT(-9.608444 39.303876)'::geometry, ST_Transform('SRID=4326;POINT(-9.608444 39.303876)'::geometry, 3857)), +(240, 'SRID=4326;POINT(8.268155 38.901343)'::geometry, ST_Transform('SRID=4326;POINT(8.268155 38.901343)'::geometry, 3857)), +(241, 'SRID=4326;POINT(8.267981 38.901286)'::geometry, ST_Transform('SRID=4326;POINT(8.267981 38.901286)'::geometry, 3857)), +(242, 'SRID=4326;POINT(8.268 38.901021)'::geometry, ST_Transform('SRID=4326;POINT(8.268 38.901021)'::geometry, 3857)), +(243, 'SRID=4326;POINT(8.26786 38.900806)'::geometry, ST_Transform('SRID=4326;POINT(8.26786 38.900806)'::geometry, 3857)), +(244, 'SRID=4326;POINT(8.268006 38.900948)'::geometry, ST_Transform('SRID=4326;POINT(8.268006 38.900948)'::geometry, 3857)), +(245, 'SRID=4326;POINT(8.26838 38.901022)'::geometry, ST_Transform('SRID=4326;POINT(8.26838 38.901022)'::geometry, 3857)), +(246, 'SRID=4326;POINT(6.530044 36.477513)'::geometry, ST_Transform('SRID=4326;POINT(6.530044 36.477513)'::geometry, 3857)), +(247, 'SRID=4326;POINT(6.529964 36.477625)'::geometry, ST_Transform('SRID=4326;POINT(6.529964 36.477625)'::geometry, 3857)), +(248, 'SRID=4326;POINT(6.529983 36.476846)'::geometry, ST_Transform('SRID=4326;POINT(6.529983 36.476846)'::geometry, 3857)), +(249, 'SRID=4326;POINT(-5.266262 38.716886)'::geometry, ST_Transform('SRID=4326;POINT(-5.266262 38.716886)'::geometry, 3857)), +(250, 'SRID=4326;POINT(-5.266413 38.716785)'::geometry, ST_Transform('SRID=4326;POINT(-5.266413 38.716785)'::geometry, 3857)), +(251, 'SRID=4326;POINT(-5.266222 38.717228)'::geometry, ST_Transform('SRID=4326;POINT(-5.266222 38.717228)'::geometry, 3857)), +(252, 'SRID=4326;POINT(-5.266795 38.717403)'::geometry, ST_Transform('SRID=4326;POINT(-5.266795 38.717403)'::geometry, 3857)), +(253, 'SRID=4326;POINT(-5.2668 38.716593)'::geometry, ST_Transform('SRID=4326;POINT(-5.2668 38.716593)'::geometry, 3857)), +(254, 'SRID=4326;POINT(-5.26693 38.716904)'::geometry, ST_Transform('SRID=4326;POINT(-5.26693 38.716904)'::geometry, 3857)), +(255, 'SRID=4326;POINT(-5.26618 38.717319)'::geometry, ST_Transform('SRID=4326;POINT(-5.26618 38.717319)'::geometry, 3857)), +(256, 'SRID=4326;POINT(-5.266235 38.716907)'::geometry, ST_Transform('SRID=4326;POINT(-5.266235 38.716907)'::geometry, 3857)), +(257, 'SRID=4326;POINT(-5.266846 38.716705)'::geometry, ST_Transform('SRID=4326;POINT(-5.266846 38.716705)'::geometry, 3857)), +(258, 'SRID=4326;POINT(-5.266687 38.717023)'::geometry, ST_Transform('SRID=4326;POINT(-5.266687 38.717023)'::geometry, 3857)), +(259, 'SRID=4326;POINT(-5.266512 38.717075)'::geometry, ST_Transform('SRID=4326;POINT(-5.266512 38.717075)'::geometry, 3857)), +(260, 'SRID=4326;POINT(-5.266189 38.716888)'::geometry, ST_Transform('SRID=4326;POINT(-5.266189 38.716888)'::geometry, 3857)), +(261, 'SRID=4326;POINT(-5.266565 38.717296)'::geometry, ST_Transform('SRID=4326;POINT(-5.266565 38.717296)'::geometry, 3857)), +(262, 'SRID=4326;POINT(9.504841 37.828039)'::geometry, ST_Transform('SRID=4326;POINT(9.504841 37.828039)'::geometry, 3857)), +(263, 'SRID=4326;POINT(9.504447 37.828131)'::geometry, ST_Transform('SRID=4326;POINT(9.504447 37.828131)'::geometry, 3857)), +(264, 'SRID=4326;POINT(9.505267 37.827879)'::geometry, ST_Transform('SRID=4326;POINT(9.505267 37.827879)'::geometry, 3857)), +(265, 'SRID=4326;POINT(9.505171 37.828127)'::geometry, ST_Transform('SRID=4326;POINT(9.505171 37.828127)'::geometry, 3857)), +(266, 'SRID=4326;POINT(9.505196 37.827809)'::geometry, ST_Transform('SRID=4326;POINT(9.505196 37.827809)'::geometry, 3857)), +(267, 'SRID=4326;POINT(9.505213 37.827885)'::geometry, ST_Transform('SRID=4326;POINT(9.505213 37.827885)'::geometry, 3857)), +(268, 'SRID=4326;POINT(9.504808 37.827401)'::geometry, ST_Transform('SRID=4326;POINT(9.504808 37.827401)'::geometry, 3857)), +(269, 'SRID=4326;POINT(-2.170801 36.903601)'::geometry, ST_Transform('SRID=4326;POINT(-2.170801 36.903601)'::geometry, 3857)), +(270, 'SRID=4326;POINT(-2.171542 36.904446)'::geometry, ST_Transform('SRID=4326;POINT(-2.171542 36.904446)'::geometry, 3857)), +(271, 'SRID=4326;POINT(-2.17161 36.904028)'::geometry, ST_Transform('SRID=4326;POINT(-2.17161 36.904028)'::geometry, 3857)), +(272, 'SRID=4326;POINT(-2.171332 36.903833)'::geometry, ST_Transform('SRID=4326;POINT(-2.171332 36.903833)'::geometry, 3857)), +(273, 'SRID=4326;POINT(-2.171042 36.904388)'::geometry, ST_Transform('SRID=4326;POINT(-2.171042 36.904388)'::geometry, 3857)), +(274, 'SRID=4326;POINT(-2.170963 36.903795)'::geometry, ST_Transform('SRID=4326;POINT(-2.170963 36.903795)'::geometry, 3857)), +(275, 'SRID=4326;POINT(-2.170688 36.903863)'::geometry, ST_Transform('SRID=4326;POINT(-2.170688 36.903863)'::geometry, 3857)), +(276, 'SRID=4326;POINT(-2.171087 36.903635)'::geometry, ST_Transform('SRID=4326;POINT(-2.171087 36.903635)'::geometry, 3857)), +(277, 'SRID=4326;POINT(-2.171346 36.903793)'::geometry, ST_Transform('SRID=4326;POINT(-2.171346 36.903793)'::geometry, 3857)), +(278, 'SRID=4326;POINT(-2.171005 36.903886)'::geometry, ST_Transform('SRID=4326;POINT(-2.171005 36.903886)'::geometry, 3857)), +(279, 'SRID=4326;POINT(-2.171343 36.9036)'::geometry, ST_Transform('SRID=4326;POINT(-2.171343 36.9036)'::geometry, 3857)), +(280, 'SRID=4326;POINT(-2.171242 36.904239)'::geometry, ST_Transform('SRID=4326;POINT(-2.171242 36.904239)'::geometry, 3857)), +(281, 'SRID=4326;POINT(-2.170868 36.903745)'::geometry, ST_Transform('SRID=4326;POINT(-2.170868 36.903745)'::geometry, 3857)), +(282, 'SRID=4326;POINT(-2.170799 36.90389)'::geometry, ST_Transform('SRID=4326;POINT(-2.170799 36.90389)'::geometry, 3857)), +(283, 'SRID=4326;POINT(-2.171564 36.903816)'::geometry, ST_Transform('SRID=4326;POINT(-2.171564 36.903816)'::geometry, 3857)), +(284, 'SRID=4326;POINT(8.368988 30.229265)'::geometry, ST_Transform('SRID=4326;POINT(8.368988 30.229265)'::geometry, 3857)), +(285, 'SRID=4326;POINT(8.369595 30.230013)'::geometry, ST_Transform('SRID=4326;POINT(8.369595 30.230013)'::geometry, 3857)), +(286, 'SRID=4326;POINT(8.3694 30.230109)'::geometry, ST_Transform('SRID=4326;POINT(8.3694 30.230109)'::geometry, 3857)), +(287, 'SRID=4326;POINT(8.369027 30.230082)'::geometry, ST_Transform('SRID=4326;POINT(8.369027 30.230082)'::geometry, 3857)), +(288, 'SRID=4326;POINT(8.368959 30.229372)'::geometry, ST_Transform('SRID=4326;POINT(8.368959 30.229372)'::geometry, 3857)), +(289, 'SRID=4326;POINT(8.369272 30.229717)'::geometry, ST_Transform('SRID=4326;POINT(8.369272 30.229717)'::geometry, 3857)), +(290, 'SRID=4326;POINT(8.369758 30.230161)'::geometry, ST_Transform('SRID=4326;POINT(8.369758 30.230161)'::geometry, 3857)), +(291, 'SRID=4326;POINT(8.36936 30.229783)'::geometry, ST_Transform('SRID=4326;POINT(8.36936 30.229783)'::geometry, 3857)), +(292, 'SRID=4326;POINT(-2.999782 31.589505)'::geometry, ST_Transform('SRID=4326;POINT(-2.999782 31.589505)'::geometry, 3857)), +(293, 'SRID=4326;POINT(-3.000221 31.589572)'::geometry, ST_Transform('SRID=4326;POINT(-3.000221 31.589572)'::geometry, 3857)), +(294, 'SRID=4326;POINT(-3.000412 31.589102)'::geometry, ST_Transform('SRID=4326;POINT(-3.000412 31.589102)'::geometry, 3857)), +(295, 'SRID=4326;POINT(-2.999662 31.589182)'::geometry, ST_Transform('SRID=4326;POINT(-2.999662 31.589182)'::geometry, 3857)), +(296, 'SRID=4326;POINT(-3.000224 31.589259)'::geometry, ST_Transform('SRID=4326;POINT(-3.000224 31.589259)'::geometry, 3857)), +(297, 'SRID=4326;POINT(-2.999983 31.589437)'::geometry, ST_Transform('SRID=4326;POINT(-2.999983 31.589437)'::geometry, 3857)), +(298, 'SRID=4326;POINT(-2.999877 31.589458)'::geometry, ST_Transform('SRID=4326;POINT(-2.999877 31.589458)'::geometry, 3857)), +(299, 'SRID=4326;POINT(-3.000263 31.589101)'::geometry, ST_Transform('SRID=4326;POINT(-3.000263 31.589101)'::geometry, 3857)), +(300, 'SRID=4326;POINT(-3.000401 31.589088)'::geometry, ST_Transform('SRID=4326;POINT(-3.000401 31.589088)'::geometry, 3857)), +(301, 'SRID=4326;POINT(-4.385852 39.752276)'::geometry, ST_Transform('SRID=4326;POINT(-4.385852 39.752276)'::geometry, 3857)), +(302, 'SRID=4326;POINT(-4.385884 39.752477)'::geometry, ST_Transform('SRID=4326;POINT(-4.385884 39.752477)'::geometry, 3857)), +(303, 'SRID=4326;POINT(-4.385735 39.752246)'::geometry, ST_Transform('SRID=4326;POINT(-4.385735 39.752246)'::geometry, 3857)), +(304, 'SRID=4326;POINT(-4.385942 39.752032)'::geometry, ST_Transform('SRID=4326;POINT(-4.385942 39.752032)'::geometry, 3857)), +(305, 'SRID=4326;POINT(-4.386277 39.751596)'::geometry, ST_Transform('SRID=4326;POINT(-4.386277 39.751596)'::geometry, 3857)), +(306, 'SRID=4326;POINT(-4.386394 39.751679)'::geometry, ST_Transform('SRID=4326;POINT(-4.386394 39.751679)'::geometry, 3857)), +(307, 'SRID=4326;POINT(-4.385727 39.752405)'::geometry, ST_Transform('SRID=4326;POINT(-4.385727 39.752405)'::geometry, 3857)), +(308, 'SRID=4326;POINT(-4.38659 39.752503)'::geometry, ST_Transform('SRID=4326;POINT(-4.38659 39.752503)'::geometry, 3857)), +(309, 'SRID=4326;POINT(-4.386676 39.751577)'::geometry, ST_Transform('SRID=4326;POINT(-4.386676 39.751577)'::geometry, 3857)), +(310, 'SRID=4326;POINT(-4.386058 39.752441)'::geometry, ST_Transform('SRID=4326;POINT(-4.386058 39.752441)'::geometry, 3857)), +(311, 'SRID=4326;POINT(8.783959 38.480157)'::geometry, ST_Transform('SRID=4326;POINT(8.783959 38.480157)'::geometry, 3857)), +(312, 'SRID=4326;POINT(8.784044 38.480085)'::geometry, ST_Transform('SRID=4326;POINT(8.784044 38.480085)'::geometry, 3857)), +(313, 'SRID=4326;POINT(8.78403 38.480162)'::geometry, ST_Transform('SRID=4326;POINT(8.78403 38.480162)'::geometry, 3857)), +(314, 'SRID=4326;POINT(8.784699 38.480106)'::geometry, ST_Transform('SRID=4326;POINT(8.784699 38.480106)'::geometry, 3857)), +(315, 'SRID=4326;POINT(8.784249 38.479839)'::geometry, ST_Transform('SRID=4326;POINT(8.784249 38.479839)'::geometry, 3857)), +(316, 'SRID=4326;POINT(8.783899 38.479817)'::geometry, ST_Transform('SRID=4326;POINT(8.783899 38.479817)'::geometry, 3857)), +(317, 'SRID=4326;POINT(8.78446 38.480156)'::geometry, ST_Transform('SRID=4326;POINT(8.78446 38.480156)'::geometry, 3857)), +(318, 'SRID=4326;POINT(8.784665 38.479739)'::geometry, ST_Transform('SRID=4326;POINT(8.784665 38.479739)'::geometry, 3857)), +(319, 'SRID=4326;POINT(8.784078 38.479956)'::geometry, ST_Transform('SRID=4326;POINT(8.784078 38.479956)'::geometry, 3857)), +(320, 'SRID=4326;POINT(8.783993 38.47977)'::geometry, ST_Transform('SRID=4326;POINT(8.783993 38.47977)'::geometry, 3857)), +(321, 'SRID=4326;POINT(8.784086 38.479532)'::geometry, ST_Transform('SRID=4326;POINT(8.784086 38.479532)'::geometry, 3857)), +(322, 'SRID=4326;POINT(8.784273 38.47969)'::geometry, ST_Transform('SRID=4326;POINT(8.784273 38.47969)'::geometry, 3857)), +(323, 'SRID=4326;POINT(8.784413 38.480132)'::geometry, ST_Transform('SRID=4326;POINT(8.784413 38.480132)'::geometry, 3857)), +(324, 'SRID=4326;POINT(8.784039 38.479655)'::geometry, ST_Transform('SRID=4326;POINT(8.784039 38.479655)'::geometry, 3857)), +(325, 'SRID=4326;POINT(8.783959 38.479375)'::geometry, ST_Transform('SRID=4326;POINT(8.783959 38.479375)'::geometry, 3857)), +(326, 'SRID=4326;POINT(-8.060178 31.973027)'::geometry, ST_Transform('SRID=4326;POINT(-8.060178 31.973027)'::geometry, 3857)), +(327, 'SRID=4326;POINT(-8.059659 31.973225)'::geometry, ST_Transform('SRID=4326;POINT(-8.059659 31.973225)'::geometry, 3857)), +(328, 'SRID=4326;POINT(-8.059924 31.973108)'::geometry, ST_Transform('SRID=4326;POINT(-8.059924 31.973108)'::geometry, 3857)), +(329, 'SRID=4326;POINT(-8.060125 31.973226)'::geometry, ST_Transform('SRID=4326;POINT(-8.060125 31.973226)'::geometry, 3857)), +(330, 'SRID=4326;POINT(-8.059829 31.973612)'::geometry, ST_Transform('SRID=4326;POINT(-8.059829 31.973612)'::geometry, 3857)), +(331, 'SRID=4326;POINT(-8.060249 31.97362)'::geometry, ST_Transform('SRID=4326;POINT(-8.060249 31.97362)'::geometry, 3857)), +(332, 'SRID=4326;POINT(-8.059803 31.972989)'::geometry, ST_Transform('SRID=4326;POINT(-8.059803 31.972989)'::geometry, 3857)), +(333, 'SRID=4326;POINT(-8.059599 31.973695)'::geometry, ST_Transform('SRID=4326;POINT(-8.059599 31.973695)'::geometry, 3857)), +(334, 'SRID=4326;POINT(-8.059936 31.973495)'::geometry, ST_Transform('SRID=4326;POINT(-8.059936 31.973495)'::geometry, 3857)), +(335, 'SRID=4326;POINT(-8.05947 31.97354)'::geometry, ST_Transform('SRID=4326;POINT(-8.05947 31.97354)'::geometry, 3857)), +(336, 'SRID=4326;POINT(-8.059534 31.973116)'::geometry, ST_Transform('SRID=4326;POINT(-8.059534 31.973116)'::geometry, 3857)), +(337, 'SRID=4326;POINT(-8.059575 31.973105)'::geometry, ST_Transform('SRID=4326;POINT(-8.059575 31.973105)'::geometry, 3857)), +(338, 'SRID=4326;POINT(-4.63212 35.998127)'::geometry, ST_Transform('SRID=4326;POINT(-4.63212 35.998127)'::geometry, 3857)), +(339, 'SRID=4326;POINT(-4.632715 35.998019)'::geometry, ST_Transform('SRID=4326;POINT(-4.632715 35.998019)'::geometry, 3857)), +(340, 'SRID=4326;POINT(-4.632119 35.997393)'::geometry, ST_Transform('SRID=4326;POINT(-4.632119 35.997393)'::geometry, 3857)), +(341, 'SRID=4326;POINT(-4.632803 35.99753)'::geometry, ST_Transform('SRID=4326;POINT(-4.632803 35.99753)'::geometry, 3857)), +(342, 'SRID=4326;POINT(-9.077417 37.751901)'::geometry, ST_Transform('SRID=4326;POINT(-9.077417 37.751901)'::geometry, 3857)), +(343, 'SRID=4326;POINT(-9.077265 37.752111)'::geometry, ST_Transform('SRID=4326;POINT(-9.077265 37.752111)'::geometry, 3857)), +(344, 'SRID=4326;POINT(-9.077343 37.75176)'::geometry, ST_Transform('SRID=4326;POINT(-9.077343 37.75176)'::geometry, 3857)), +(345, 'SRID=4326;POINT(-9.077467 37.751908)'::geometry, ST_Transform('SRID=4326;POINT(-9.077467 37.751908)'::geometry, 3857)), +(346, 'SRID=4326;POINT(-9.077027 37.751421)'::geometry, ST_Transform('SRID=4326;POINT(-9.077027 37.751421)'::geometry, 3857)), +(347, 'SRID=4326;POINT(-9.077902 37.751891)'::geometry, ST_Transform('SRID=4326;POINT(-9.077902 37.751891)'::geometry, 3857)), +(348, 'SRID=4326;POINT(-9.077804 37.751888)'::geometry, ST_Transform('SRID=4326;POINT(-9.077804 37.751888)'::geometry, 3857)), +(349, 'SRID=4326;POINT(-9.077673 37.751405)'::geometry, ST_Transform('SRID=4326;POINT(-9.077673 37.751405)'::geometry, 3857)), +(350, 'SRID=4326;POINT(-9.076988 37.751842)'::geometry, ST_Transform('SRID=4326;POINT(-9.076988 37.751842)'::geometry, 3857)), +(351, 'SRID=4326;POINT(-9.077688 37.75141)'::geometry, ST_Transform('SRID=4326;POINT(-9.077688 37.75141)'::geometry, 3857)), +(352, 'SRID=4326;POINT(-9.077493 37.751423)'::geometry, ST_Transform('SRID=4326;POINT(-9.077493 37.751423)'::geometry, 3857)), +(353, 'SRID=4326;POINT(-9.07777 37.75196)'::geometry, ST_Transform('SRID=4326;POINT(-9.07777 37.75196)'::geometry, 3857)), +(354, 'SRID=4326;POINT(-9.077415 37.751844)'::geometry, ST_Transform('SRID=4326;POINT(-9.077415 37.751844)'::geometry, 3857)), +(355, 'SRID=4326;POINT(-9.077104 37.751428)'::geometry, ST_Transform('SRID=4326;POINT(-9.077104 37.751428)'::geometry, 3857)), +(356, 'SRID=4326;POINT(-9.077731 37.751225)'::geometry, ST_Transform('SRID=4326;POINT(-9.077731 37.751225)'::geometry, 3857)), +(357, 'SRID=4326;POINT(5.736671 39.05025)'::geometry, ST_Transform('SRID=4326;POINT(5.736671 39.05025)'::geometry, 3857)), +(358, 'SRID=4326;POINT(2.486706 38.642451)'::geometry, ST_Transform('SRID=4326;POINT(2.486706 38.642451)'::geometry, 3857)), +(359, 'SRID=4326;POINT(2.487244 38.642613)'::geometry, ST_Transform('SRID=4326;POINT(2.487244 38.642613)'::geometry, 3857)), +(360, 'SRID=4326;POINT(2.487265 38.64297)'::geometry, ST_Transform('SRID=4326;POINT(2.487265 38.64297)'::geometry, 3857)), +(361, 'SRID=4326;POINT(2.487094 38.642426)'::geometry, ST_Transform('SRID=4326;POINT(2.487094 38.642426)'::geometry, 3857)), +(362, 'SRID=4326;POINT(2.486678 38.642585)'::geometry, ST_Transform('SRID=4326;POINT(2.486678 38.642585)'::geometry, 3857)), +(363, 'SRID=4326;POINT(2.487308 38.642908)'::geometry, ST_Transform('SRID=4326;POINT(2.487308 38.642908)'::geometry, 3857)), +(364, 'SRID=4326;POINT(2.486737 38.642071)'::geometry, ST_Transform('SRID=4326;POINT(2.486737 38.642071)'::geometry, 3857)), +(365, 'SRID=4326;POINT(2.486899 38.642834)'::geometry, ST_Transform('SRID=4326;POINT(2.486899 38.642834)'::geometry, 3857)), +(366, 'SRID=4326;POINT(2.487133 38.642518)'::geometry, ST_Transform('SRID=4326;POINT(2.487133 38.642518)'::geometry, 3857)), +(367, 'SRID=4326;POINT(0.190222 39.022953)'::geometry, ST_Transform('SRID=4326;POINT(0.190222 39.022953)'::geometry, 3857)), +(368, 'SRID=4326;POINT(0.190043 39.023114)'::geometry, ST_Transform('SRID=4326;POINT(0.190043 39.023114)'::geometry, 3857)), +(369, 'SRID=4326;POINT(0.190124 39.023072)'::geometry, ST_Transform('SRID=4326;POINT(0.190124 39.023072)'::geometry, 3857)), +(370, 'SRID=4326;POINT(0.190422 39.023139)'::geometry, ST_Transform('SRID=4326;POINT(0.190422 39.023139)'::geometry, 3857)), +(371, 'SRID=4326;POINT(0.190447 39.023119)'::geometry, ST_Transform('SRID=4326;POINT(0.190447 39.023119)'::geometry, 3857)), +(372, 'SRID=4326;POINT(0.190864 39.022787)'::geometry, ST_Transform('SRID=4326;POINT(0.190864 39.022787)'::geometry, 3857)), +(373, 'SRID=4326;POINT(0.190587 39.023213)'::geometry, ST_Transform('SRID=4326;POINT(0.190587 39.023213)'::geometry, 3857)), +(374, 'SRID=4326;POINT(0.190173 39.023267)'::geometry, ST_Transform('SRID=4326;POINT(0.190173 39.023267)'::geometry, 3857)), +(375, 'SRID=4326;POINT(0.190158 39.023269)'::geometry, ST_Transform('SRID=4326;POINT(0.190158 39.023269)'::geometry, 3857)), +(376, 'SRID=4326;POINT(0.190034 39.023105)'::geometry, ST_Transform('SRID=4326;POINT(0.190034 39.023105)'::geometry, 3857)), +(377, 'SRID=4326;POINT(0.190614 39.023247)'::geometry, ST_Transform('SRID=4326;POINT(0.190614 39.023247)'::geometry, 3857)), +(378, 'SRID=4326;POINT(0.19013 39.022976)'::geometry, ST_Transform('SRID=4326;POINT(0.19013 39.022976)'::geometry, 3857)), +(379, 'SRID=4326;POINT(0.190578 39.023254)'::geometry, ST_Transform('SRID=4326;POINT(0.190578 39.023254)'::geometry, 3857)), +(380, 'SRID=4326;POINT(-4.726492 38.505264)'::geometry, ST_Transform('SRID=4326;POINT(-4.726492 38.505264)'::geometry, 3857)), +(381, 'SRID=4326;POINT(-4.726996 38.505473)'::geometry, ST_Transform('SRID=4326;POINT(-4.726996 38.505473)'::geometry, 3857)), +(382, 'SRID=4326;POINT(6.295031 33.792646)'::geometry, ST_Transform('SRID=4326;POINT(6.295031 33.792646)'::geometry, 3857)), +(383, 'SRID=4326;POINT(6.29525 33.792686)'::geometry, ST_Transform('SRID=4326;POINT(6.29525 33.792686)'::geometry, 3857)), +(384, 'SRID=4326;POINT(6.294926 33.793128)'::geometry, ST_Transform('SRID=4326;POINT(6.294926 33.793128)'::geometry, 3857)), +(385, 'SRID=4326;POINT(6.295688 33.792557)'::geometry, ST_Transform('SRID=4326;POINT(6.295688 33.792557)'::geometry, 3857)), +(386, 'SRID=4326;POINT(6.295214 33.792642)'::geometry, ST_Transform('SRID=4326;POINT(6.295214 33.792642)'::geometry, 3857)), +(387, 'SRID=4326;POINT(6.295116 33.792807)'::geometry, ST_Transform('SRID=4326;POINT(6.295116 33.792807)'::geometry, 3857)), +(388, 'SRID=4326;POINT(6.295144 33.792432)'::geometry, ST_Transform('SRID=4326;POINT(6.295144 33.792432)'::geometry, 3857)), +(389, 'SRID=4326;POINT(6.295344 33.793005)'::geometry, ST_Transform('SRID=4326;POINT(6.295344 33.793005)'::geometry, 3857)), +(390, 'SRID=4326;POINT(6.294974 33.792792)'::geometry, ST_Transform('SRID=4326;POINT(6.294974 33.792792)'::geometry, 3857)), +(391, 'SRID=4326;POINT(6.29545 33.792402)'::geometry, ST_Transform('SRID=4326;POINT(6.29545 33.792402)'::geometry, 3857)), +(392, 'SRID=4326;POINT(6.295601 33.792992)'::geometry, ST_Transform('SRID=4326;POINT(6.295601 33.792992)'::geometry, 3857)), +(393, 'SRID=4326;POINT(6.295289 33.79258)'::geometry, ST_Transform('SRID=4326;POINT(6.295289 33.79258)'::geometry, 3857)), +(394, 'SRID=4326;POINT(6.295285 33.79334)'::geometry, ST_Transform('SRID=4326;POINT(6.295285 33.79334)'::geometry, 3857)), +(395, 'SRID=4326;POINT(6.295307 33.792945)'::geometry, ST_Transform('SRID=4326;POINT(6.295307 33.792945)'::geometry, 3857)), +(396, 'SRID=4326;POINT(-3.961321 37.574227)'::geometry, ST_Transform('SRID=4326;POINT(-3.961321 37.574227)'::geometry, 3857)), +(397, 'SRID=4326;POINT(-3.961179 37.574737)'::geometry, ST_Transform('SRID=4326;POINT(-3.961179 37.574737)'::geometry, 3857)), +(398, 'SRID=4326;POINT(-3.961895 37.574623)'::geometry, ST_Transform('SRID=4326;POINT(-3.961895 37.574623)'::geometry, 3857)), +(399, 'SRID=4326;POINT(-3.961152 37.574831)'::geometry, ST_Transform('SRID=4326;POINT(-3.961152 37.574831)'::geometry, 3857)), +(400, 'SRID=4326;POINT(-3.961619 37.574905)'::geometry, ST_Transform('SRID=4326;POINT(-3.961619 37.574905)'::geometry, 3857)), +(401, 'SRID=4326;POINT(-3.961297 37.574127)'::geometry, ST_Transform('SRID=4326;POINT(-3.961297 37.574127)'::geometry, 3857)), +(402, 'SRID=4326;POINT(-3.961714 37.574449)'::geometry, ST_Transform('SRID=4326;POINT(-3.961714 37.574449)'::geometry, 3857)), +(403, 'SRID=4326;POINT(-3.961663 37.574729)'::geometry, ST_Transform('SRID=4326;POINT(-3.961663 37.574729)'::geometry, 3857)), +(404, 'SRID=4326;POINT(-3.962034 37.574013)'::geometry, ST_Transform('SRID=4326;POINT(-3.962034 37.574013)'::geometry, 3857)), +(405, 'SRID=4326;POINT(-3.961185 37.574931)'::geometry, ST_Transform('SRID=4326;POINT(-3.961185 37.574931)'::geometry, 3857)), +(406, 'SRID=4326;POINT(-3.96149 37.574124)'::geometry, ST_Transform('SRID=4326;POINT(-3.96149 37.574124)'::geometry, 3857)), +(407, 'SRID=4326;POINT(-3.961513 37.574389)'::geometry, ST_Transform('SRID=4326;POINT(-3.961513 37.574389)'::geometry, 3857)), +(408, 'SRID=4326;POINT(-3.962069 37.57462)'::geometry, ST_Transform('SRID=4326;POINT(-3.962069 37.57462)'::geometry, 3857)), +(409, 'SRID=4326;POINT(-3.961603 37.574585)'::geometry, ST_Transform('SRID=4326;POINT(-3.961603 37.574585)'::geometry, 3857)), +(410, 'SRID=4326;POINT(-9.221169 39.607003)'::geometry, ST_Transform('SRID=4326;POINT(-9.221169 39.607003)'::geometry, 3857)), +(411, 'SRID=4326;POINT(-9.221883 39.607595)'::geometry, ST_Transform('SRID=4326;POINT(-9.221883 39.607595)'::geometry, 3857)), +(412, 'SRID=4326;POINT(-9.222102 39.607298)'::geometry, ST_Transform('SRID=4326;POINT(-9.222102 39.607298)'::geometry, 3857)), +(413, 'SRID=4326;POINT(-9.222118 39.606969)'::geometry, ST_Transform('SRID=4326;POINT(-9.222118 39.606969)'::geometry, 3857)), +(414, 'SRID=4326;POINT(-9.221516 39.607447)'::geometry, ST_Transform('SRID=4326;POINT(-9.221516 39.607447)'::geometry, 3857)), +(415, 'SRID=4326;POINT(-9.222017 39.607394)'::geometry, ST_Transform('SRID=4326;POINT(-9.222017 39.607394)'::geometry, 3857)), +(416, 'SRID=4326;POINT(-9.22136 39.607455)'::geometry, ST_Transform('SRID=4326;POINT(-9.22136 39.607455)'::geometry, 3857)), +(417, 'SRID=4326;POINT(-9.222014 39.606962)'::geometry, ST_Transform('SRID=4326;POINT(-9.222014 39.606962)'::geometry, 3857)), +(418, 'SRID=4326;POINT(-9.221755 39.607393)'::geometry, ST_Transform('SRID=4326;POINT(-9.221755 39.607393)'::geometry, 3857)), +(419, 'SRID=4326;POINT(-9.221748 39.607181)'::geometry, ST_Transform('SRID=4326;POINT(-9.221748 39.607181)'::geometry, 3857)), +(420, 'SRID=4326;POINT(-9.221728 39.607402)'::geometry, ST_Transform('SRID=4326;POINT(-9.221728 39.607402)'::geometry, 3857)), +(421, 'SRID=4326;POINT(-9.221372 39.60722)'::geometry, ST_Transform('SRID=4326;POINT(-9.221372 39.60722)'::geometry, 3857)), +(422, 'SRID=4326;POINT(-9.221399 39.607532)'::geometry, ST_Transform('SRID=4326;POINT(-9.221399 39.607532)'::geometry, 3857)), +(423, 'SRID=4326;POINT(-9.221766 39.60764)'::geometry, ST_Transform('SRID=4326;POINT(-9.221766 39.60764)'::geometry, 3857)), +(424, 'SRID=4326;POINT(-9.221211 39.607327)'::geometry, ST_Transform('SRID=4326;POINT(-9.221211 39.607327)'::geometry, 3857)), +(425, 'SRID=4326;POINT(-9.221834 39.607635)'::geometry, ST_Transform('SRID=4326;POINT(-9.221834 39.607635)'::geometry, 3857)), +(426, 'SRID=4326;POINT(6.85655 34.912087)'::geometry, ST_Transform('SRID=4326;POINT(6.85655 34.912087)'::geometry, 3857)), +(427, 'SRID=4326;POINT(6.856473 34.912241)'::geometry, ST_Transform('SRID=4326;POINT(6.856473 34.912241)'::geometry, 3857)), +(428, 'SRID=4326;POINT(6.856142 34.912217)'::geometry, ST_Transform('SRID=4326;POINT(6.856142 34.912217)'::geometry, 3857)), +(429, 'SRID=4326;POINT(6.856378 34.912182)'::geometry, ST_Transform('SRID=4326;POINT(6.856378 34.912182)'::geometry, 3857)), +(430, 'SRID=4326;POINT(6.856079 34.912444)'::geometry, ST_Transform('SRID=4326;POINT(6.856079 34.912444)'::geometry, 3857)), +(431, 'SRID=4326;POINT(6.856087 34.911668)'::geometry, ST_Transform('SRID=4326;POINT(6.856087 34.911668)'::geometry, 3857)), +(432, 'SRID=4326;POINT(6.856699 34.911491)'::geometry, ST_Transform('SRID=4326;POINT(6.856699 34.911491)'::geometry, 3857)), +(433, 'SRID=4326;POINT(6.856371 34.911687)'::geometry, ST_Transform('SRID=4326;POINT(6.856371 34.911687)'::geometry, 3857)), +(434, 'SRID=4326;POINT(6.856564 34.91177)'::geometry, ST_Transform('SRID=4326;POINT(6.856564 34.91177)'::geometry, 3857)), +(435, 'SRID=4326;POINT(6.856768 34.911903)'::geometry, ST_Transform('SRID=4326;POINT(6.856768 34.911903)'::geometry, 3857)), +(436, 'SRID=4326;POINT(6.856324 34.912415)'::geometry, ST_Transform('SRID=4326;POINT(6.856324 34.912415)'::geometry, 3857)), +(437, 'SRID=4326;POINT(6.856826 34.911767)'::geometry, ST_Transform('SRID=4326;POINT(6.856826 34.911767)'::geometry, 3857)), +(438, 'SRID=4326;POINT(6.856792 34.912182)'::geometry, ST_Transform('SRID=4326;POINT(6.856792 34.912182)'::geometry, 3857)), +(439, 'SRID=4326;POINT(6.856929 34.912379)'::geometry, ST_Transform('SRID=4326;POINT(6.856929 34.912379)'::geometry, 3857)), +(440, 'SRID=4326;POINT(6.85643 34.912242)'::geometry, ST_Transform('SRID=4326;POINT(6.85643 34.912242)'::geometry, 3857)), +(441, 'SRID=4326;POINT(3.596947 38.1486)'::geometry, ST_Transform('SRID=4326;POINT(3.596947 38.1486)'::geometry, 3857)), +(442, 'SRID=4326;POINT(3.596769 38.148948)'::geometry, ST_Transform('SRID=4326;POINT(3.596769 38.148948)'::geometry, 3857)), +(443, 'SRID=4326;POINT(3.596829 38.148394)'::geometry, ST_Transform('SRID=4326;POINT(3.596829 38.148394)'::geometry, 3857)), +(444, 'SRID=4326;POINT(3.597295 38.14811)'::geometry, ST_Transform('SRID=4326;POINT(3.597295 38.14811)'::geometry, 3857)), +(445, 'SRID=4326;POINT(3.597307 38.148007)'::geometry, ST_Transform('SRID=4326;POINT(3.597307 38.148007)'::geometry, 3857)), +(446, 'SRID=4326;POINT(3.597512 38.148592)'::geometry, ST_Transform('SRID=4326;POINT(3.597512 38.148592)'::geometry, 3857)), +(447, 'SRID=4326;POINT(3.596798 38.148721)'::geometry, ST_Transform('SRID=4326;POINT(3.596798 38.148721)'::geometry, 3857)), +(448, 'SRID=4326;POINT(3.597043 38.14809)'::geometry, ST_Transform('SRID=4326;POINT(3.597043 38.14809)'::geometry, 3857)), +(449, 'SRID=4326;POINT(3.597261 38.148706)'::geometry, ST_Transform('SRID=4326;POINT(3.597261 38.148706)'::geometry, 3857)), +(450, 'SRID=4326;POINT(3.597318 38.14896)'::geometry, ST_Transform('SRID=4326;POINT(3.597318 38.14896)'::geometry, 3857)), +(451, 'SRID=4326;POINT(7.017467 32.682268)'::geometry, ST_Transform('SRID=4326;POINT(7.017467 32.682268)'::geometry, 3857)), +(452, 'SRID=4326;POINT(7.017442 32.682523)'::geometry, ST_Transform('SRID=4326;POINT(7.017442 32.682523)'::geometry, 3857)), +(453, 'SRID=4326;POINT(7.017381 32.682706)'::geometry, ST_Transform('SRID=4326;POINT(7.017381 32.682706)'::geometry, 3857)), +(454, 'SRID=4326;POINT(7.017033 32.6818)'::geometry, ST_Transform('SRID=4326;POINT(7.017033 32.6818)'::geometry, 3857)), +(455, 'SRID=4326;POINT(7.017106 32.681931)'::geometry, ST_Transform('SRID=4326;POINT(7.017106 32.681931)'::geometry, 3857)), +(456, 'SRID=4326;POINT(7.017705 32.682579)'::geometry, ST_Transform('SRID=4326;POINT(7.017705 32.682579)'::geometry, 3857)), +(457, 'SRID=4326;POINT(7.017261 32.682337)'::geometry, ST_Transform('SRID=4326;POINT(7.017261 32.682337)'::geometry, 3857)), +(458, 'SRID=4326;POINT(7.017581 32.682233)'::geometry, ST_Transform('SRID=4326;POINT(7.017581 32.682233)'::geometry, 3857)), +(459, 'SRID=4326;POINT(7.017235 32.682232)'::geometry, ST_Transform('SRID=4326;POINT(7.017235 32.682232)'::geometry, 3857)), +(460, 'SRID=4326;POINT(7.017307 32.682267)'::geometry, ST_Transform('SRID=4326;POINT(7.017307 32.682267)'::geometry, 3857)), +(461, 'SRID=4326;POINT(7.017528 32.682155)'::geometry, ST_Transform('SRID=4326;POINT(7.017528 32.682155)'::geometry, 3857)), +(462, 'SRID=4326;POINT(7.017666 32.682105)'::geometry, ST_Transform('SRID=4326;POINT(7.017666 32.682105)'::geometry, 3857)), +(463, 'SRID=4326;POINT(7.017189 32.682041)'::geometry, ST_Transform('SRID=4326;POINT(7.017189 32.682041)'::geometry, 3857)), +(464, 'SRID=4326;POINT(-8.05544 34.279282)'::geometry, ST_Transform('SRID=4326;POINT(-8.05544 34.279282)'::geometry, 3857)), +(465, 'SRID=4326;POINT(-8.055997 34.279187)'::geometry, ST_Transform('SRID=4326;POINT(-8.055997 34.279187)'::geometry, 3857)), +(466, 'SRID=4326;POINT(-8.055628 34.278509)'::geometry, ST_Transform('SRID=4326;POINT(-8.055628 34.278509)'::geometry, 3857)), +(467, 'SRID=4326;POINT(-8.056024 34.278599)'::geometry, ST_Transform('SRID=4326;POINT(-8.056024 34.278599)'::geometry, 3857)), +(468, 'SRID=4326;POINT(-8.056048 34.278384)'::geometry, ST_Transform('SRID=4326;POINT(-8.056048 34.278384)'::geometry, 3857)), +(469, 'SRID=4326;POINT(-8.05553 34.278415)'::geometry, ST_Transform('SRID=4326;POINT(-8.05553 34.278415)'::geometry, 3857)), +(470, 'SRID=4326;POINT(-8.055728 34.279115)'::geometry, ST_Transform('SRID=4326;POINT(-8.055728 34.279115)'::geometry, 3857)), +(471, 'SRID=4326;POINT(-8.056245 34.278838)'::geometry, ST_Transform('SRID=4326;POINT(-8.056245 34.278838)'::geometry, 3857)), +(472, 'SRID=4326;POINT(-8.055941 34.279043)'::geometry, ST_Transform('SRID=4326;POINT(-8.055941 34.279043)'::geometry, 3857)), +(473, 'SRID=4326;POINT(-7.228337 37.816001)'::geometry, ST_Transform('SRID=4326;POINT(-7.228337 37.816001)'::geometry, 3857)), +(474, 'SRID=4326;POINT(-7.227998 37.816439)'::geometry, ST_Transform('SRID=4326;POINT(-7.227998 37.816439)'::geometry, 3857)), +(475, 'SRID=4326;POINT(-7.228233 37.816839)'::geometry, ST_Transform('SRID=4326;POINT(-7.228233 37.816839)'::geometry, 3857)), +(476, 'SRID=4326;POINT(-7.228156 37.816186)'::geometry, ST_Transform('SRID=4326;POINT(-7.228156 37.816186)'::geometry, 3857)), +(477, 'SRID=4326;POINT(-7.227702 37.816616)'::geometry, ST_Transform('SRID=4326;POINT(-7.227702 37.816616)'::geometry, 3857)), +(478, 'SRID=4326;POINT(-1.129358 38.380395)'::geometry, ST_Transform('SRID=4326;POINT(-1.129358 38.380395)'::geometry, 3857)), +(479, 'SRID=4326;POINT(-1.129632 38.379986)'::geometry, ST_Transform('SRID=4326;POINT(-1.129632 38.379986)'::geometry, 3857)), +(480, 'SRID=4326;POINT(-1.129738 38.379575)'::geometry, ST_Transform('SRID=4326;POINT(-1.129738 38.379575)'::geometry, 3857)), +(481, 'SRID=4326;POINT(-1.129916 38.38044)'::geometry, ST_Transform('SRID=4326;POINT(-1.129916 38.38044)'::geometry, 3857)), +(482, 'SRID=4326;POINT(-1.129103 38.379631)'::geometry, ST_Transform('SRID=4326;POINT(-1.129103 38.379631)'::geometry, 3857)), +(483, 'SRID=4326;POINT(-1.129994 38.379868)'::geometry, ST_Transform('SRID=4326;POINT(-1.129994 38.379868)'::geometry, 3857)), +(484, 'SRID=4326;POINT(5.367991 30.545321)'::geometry, ST_Transform('SRID=4326;POINT(5.367991 30.545321)'::geometry, 3857)), +(485, 'SRID=4326;POINT(5.367515 30.544982)'::geometry, ST_Transform('SRID=4326;POINT(5.367515 30.544982)'::geometry, 3857)), +(486, 'SRID=4326;POINT(5.367259 30.545084)'::geometry, ST_Transform('SRID=4326;POINT(5.367259 30.545084)'::geometry, 3857)), +(487, 'SRID=4326;POINT(5.368137 30.54498)'::geometry, ST_Transform('SRID=4326;POINT(5.368137 30.54498)'::geometry, 3857)), +(488, 'SRID=4326;POINT(5.367194 30.545244)'::geometry, ST_Transform('SRID=4326;POINT(5.367194 30.545244)'::geometry, 3857)), +(489, 'SRID=4326;POINT(5.367261 30.54535)'::geometry, ST_Transform('SRID=4326;POINT(5.367261 30.54535)'::geometry, 3857)), +(490, 'SRID=4326;POINT(5.367572 30.54492)'::geometry, ST_Transform('SRID=4326;POINT(5.367572 30.54492)'::geometry, 3857)), +(491, 'SRID=4326;POINT(5.367869 30.544706)'::geometry, ST_Transform('SRID=4326;POINT(5.367869 30.544706)'::geometry, 3857)), +(492, 'SRID=4326;POINT(5.368171 30.544438)'::geometry, ST_Transform('SRID=4326;POINT(5.368171 30.544438)'::geometry, 3857)), +(493, 'SRID=4326;POINT(5.367826 30.544732)'::geometry, ST_Transform('SRID=4326;POINT(5.367826 30.544732)'::geometry, 3857)), +(494, 'SRID=4326;POINT(5.367472 30.544565)'::geometry, ST_Transform('SRID=4326;POINT(5.367472 30.544565)'::geometry, 3857)), +(495, 'SRID=4326;POINT(5.367818 30.544714)'::geometry, ST_Transform('SRID=4326;POINT(5.367818 30.544714)'::geometry, 3857)), +(496, 'SRID=4326;POINT(5.367437 30.544804)'::geometry, ST_Transform('SRID=4326;POINT(5.367437 30.544804)'::geometry, 3857)), +(497, 'SRID=4326;POINT(3.578513 39.192891)'::geometry, ST_Transform('SRID=4326;POINT(3.578513 39.192891)'::geometry, 3857)), +(498, 'SRID=4326;POINT(3.578994 39.192304)'::geometry, ST_Transform('SRID=4326;POINT(3.578994 39.192304)'::geometry, 3857)), +(499, 'SRID=4326;POINT(3.578709 39.192954)'::geometry, ST_Transform('SRID=4326;POINT(3.578709 39.192954)'::geometry, 3857)), +(500, 'SRID=4326;POINT(3.5789 39.192329)'::geometry, ST_Transform('SRID=4326;POINT(3.5789 39.192329)'::geometry, 3857)), +(501, 'SRID=4326;POINT(3.57896 39.192534)'::geometry, ST_Transform('SRID=4326;POINT(3.57896 39.192534)'::geometry, 3857)), +(502, 'SRID=4326;POINT(3.578331 39.1927)'::geometry, ST_Transform('SRID=4326;POINT(3.578331 39.1927)'::geometry, 3857)), +(503, 'SRID=4326;POINT(6.467563 35.761929)'::geometry, ST_Transform('SRID=4326;POINT(6.467563 35.761929)'::geometry, 3857)), +(504, 'SRID=4326;POINT(6.467797 35.76232)'::geometry, ST_Transform('SRID=4326;POINT(6.467797 35.76232)'::geometry, 3857)), +(505, 'SRID=4326;POINT(6.468167 35.762407)'::geometry, ST_Transform('SRID=4326;POINT(6.468167 35.762407)'::geometry, 3857)), +(506, 'SRID=4326;POINT(6.467727 35.76243)'::geometry, ST_Transform('SRID=4326;POINT(6.467727 35.76243)'::geometry, 3857)), +(507, 'SRID=4326;POINT(6.467698 35.761842)'::geometry, ST_Transform('SRID=4326;POINT(6.467698 35.761842)'::geometry, 3857)), +(508, 'SRID=4326;POINT(6.468043 35.761548)'::geometry, ST_Transform('SRID=4326;POINT(6.468043 35.761548)'::geometry, 3857)), +(509, 'SRID=4326;POINT(6.467748 35.761895)'::geometry, ST_Transform('SRID=4326;POINT(6.467748 35.761895)'::geometry, 3857)), +(510, 'SRID=4326;POINT(-9.376008 37.66543)'::geometry, ST_Transform('SRID=4326;POINT(-9.376008 37.66543)'::geometry, 3857)), +(511, 'SRID=4326;POINT(-9.376352 37.665134)'::geometry, ST_Transform('SRID=4326;POINT(-9.376352 37.665134)'::geometry, 3857)), +(512, 'SRID=4326;POINT(-9.375792 37.665016)'::geometry, ST_Transform('SRID=4326;POINT(-9.375792 37.665016)'::geometry, 3857)), +(513, 'SRID=4326;POINT(-9.376451 37.664977)'::geometry, ST_Transform('SRID=4326;POINT(-9.376451 37.664977)'::geometry, 3857)), +(514, 'SRID=4326;POINT(-9.37563 37.664995)'::geometry, ST_Transform('SRID=4326;POINT(-9.37563 37.664995)'::geometry, 3857)), +(515, 'SRID=4326;POINT(-9.37582 37.665323)'::geometry, ST_Transform('SRID=4326;POINT(-9.37582 37.665323)'::geometry, 3857)), +(516, 'SRID=4326;POINT(-9.37587 37.665407)'::geometry, ST_Transform('SRID=4326;POINT(-9.37587 37.665407)'::geometry, 3857)), +(517, 'SRID=4326;POINT(-9.376338 37.665701)'::geometry, ST_Transform('SRID=4326;POINT(-9.376338 37.665701)'::geometry, 3857)), +(518, 'SRID=4326;POINT(-9.376514 37.665477)'::geometry, ST_Transform('SRID=4326;POINT(-9.376514 37.665477)'::geometry, 3857)), +(519, 'SRID=4326;POINT(-9.375748 37.66524)'::geometry, ST_Transform('SRID=4326;POINT(-9.375748 37.66524)'::geometry, 3857)), +(520, 'SRID=4326;POINT(1.260345 31.995092)'::geometry, ST_Transform('SRID=4326;POINT(1.260345 31.995092)'::geometry, 3857)), +(521, 'SRID=4326;POINT(1.259769 31.994365)'::geometry, ST_Transform('SRID=4326;POINT(1.259769 31.994365)'::geometry, 3857)), +(522, 'SRID=4326;POINT(1.259952 31.994605)'::geometry, ST_Transform('SRID=4326;POINT(1.259952 31.994605)'::geometry, 3857)), +(523, 'SRID=4326;POINT(1.26004 31.994175)'::geometry, ST_Transform('SRID=4326;POINT(1.26004 31.994175)'::geometry, 3857)), +(524, 'SRID=4326;POINT(1.260128 31.995111)'::geometry, ST_Transform('SRID=4326;POINT(1.260128 31.995111)'::geometry, 3857)), +(525, 'SRID=4326;POINT(1.259655 31.994736)'::geometry, ST_Transform('SRID=4326;POINT(1.259655 31.994736)'::geometry, 3857)), +(526, 'SRID=4326;POINT(1.259791 31.994912)'::geometry, ST_Transform('SRID=4326;POINT(1.259791 31.994912)'::geometry, 3857)), +(527, 'SRID=4326;POINT(1.260467 31.994231)'::geometry, ST_Transform('SRID=4326;POINT(1.260467 31.994231)'::geometry, 3857)), +(528, 'SRID=4326;POINT(1.25997 31.994557)'::geometry, ST_Transform('SRID=4326;POINT(1.25997 31.994557)'::geometry, 3857)), +(529, 'SRID=4326;POINT(1.260369 31.994511)'::geometry, ST_Transform('SRID=4326;POINT(1.260369 31.994511)'::geometry, 3857)), +(530, 'SRID=4326;POINT(1.259745 31.994475)'::geometry, ST_Transform('SRID=4326;POINT(1.259745 31.994475)'::geometry, 3857)), +(531, 'SRID=4326;POINT(1.259567 31.995074)'::geometry, ST_Transform('SRID=4326;POINT(1.259567 31.995074)'::geometry, 3857)), +(532, 'SRID=4326;POINT(1.260254 31.994468)'::geometry, ST_Transform('SRID=4326;POINT(1.260254 31.994468)'::geometry, 3857)), +(533, 'SRID=4326;POINT(1.259734 31.994586)'::geometry, ST_Transform('SRID=4326;POINT(1.259734 31.994586)'::geometry, 3857)), +(534, 'SRID=4326;POINT(1.260463 31.994721)'::geometry, ST_Transform('SRID=4326;POINT(1.260463 31.994721)'::geometry, 3857)), +(535, 'SRID=4326;POINT(2.729133 38.492349)'::geometry, ST_Transform('SRID=4326;POINT(2.729133 38.492349)'::geometry, 3857)), +(536, 'SRID=4326;POINT(-6.622615 33.402887)'::geometry, ST_Transform('SRID=4326;POINT(-6.622615 33.402887)'::geometry, 3857)), +(537, 'SRID=4326;POINT(-6.62201 33.40347)'::geometry, ST_Transform('SRID=4326;POINT(-6.62201 33.40347)'::geometry, 3857)), +(538, 'SRID=4326;POINT(-6.622602 33.403156)'::geometry, ST_Transform('SRID=4326;POINT(-6.622602 33.403156)'::geometry, 3857)), +(539, 'SRID=4326;POINT(-6.62229 33.403373)'::geometry, ST_Transform('SRID=4326;POINT(-6.62229 33.403373)'::geometry, 3857)), +(540, 'SRID=4326;POINT(-6.622021 33.403713)'::geometry, ST_Transform('SRID=4326;POINT(-6.622021 33.403713)'::geometry, 3857)), +(541, 'SRID=4326;POINT(-6.621709 33.403616)'::geometry, ST_Transform('SRID=4326;POINT(-6.621709 33.403616)'::geometry, 3857)), +(542, 'SRID=4326;POINT(-6.622664 33.403289)'::geometry, ST_Transform('SRID=4326;POINT(-6.622664 33.403289)'::geometry, 3857)), +(543, 'SRID=4326;POINT(-6.621894 33.403001)'::geometry, ST_Transform('SRID=4326;POINT(-6.621894 33.403001)'::geometry, 3857)), +(544, 'SRID=4326;POINT(-6.621753 33.403296)'::geometry, ST_Transform('SRID=4326;POINT(-6.621753 33.403296)'::geometry, 3857)), +(545, 'SRID=4326;POINT(-6.622631 33.403423)'::geometry, ST_Transform('SRID=4326;POINT(-6.622631 33.403423)'::geometry, 3857)), +(546, 'SRID=4326;POINT(-6.622649 33.402773)'::geometry, ST_Transform('SRID=4326;POINT(-6.622649 33.402773)'::geometry, 3857)), +(547, 'SRID=4326;POINT(-4.40069 32.83652)'::geometry, ST_Transform('SRID=4326;POINT(-4.40069 32.83652)'::geometry, 3857)), +(548, 'SRID=4326;POINT(-4.400915 32.835874)'::geometry, ST_Transform('SRID=4326;POINT(-4.400915 32.835874)'::geometry, 3857)), +(549, 'SRID=4326;POINT(-4.400611 32.836162)'::geometry, ST_Transform('SRID=4326;POINT(-4.400611 32.836162)'::geometry, 3857)), +(550, 'SRID=4326;POINT(-4.401156 32.836423)'::geometry, ST_Transform('SRID=4326;POINT(-4.401156 32.836423)'::geometry, 3857)), +(551, 'SRID=4326;POINT(-4.400751 32.836387)'::geometry, ST_Transform('SRID=4326;POINT(-4.400751 32.836387)'::geometry, 3857)), +(552, 'SRID=4326;POINT(-4.401099 32.836165)'::geometry, ST_Transform('SRID=4326;POINT(-4.401099 32.836165)'::geometry, 3857)), +(553, 'SRID=4326;POINT(-4.401483 32.836585)'::geometry, ST_Transform('SRID=4326;POINT(-4.401483 32.836585)'::geometry, 3857)), +(554, 'SRID=4326;POINT(-4.400596 32.836855)'::geometry, ST_Transform('SRID=4326;POINT(-4.400596 32.836855)'::geometry, 3857)), +(555, 'SRID=4326;POINT(-4.400921 32.836087)'::geometry, ST_Transform('SRID=4326;POINT(-4.400921 32.836087)'::geometry, 3857)), +(556, 'SRID=4326;POINT(-4.401047 32.836189)'::geometry, ST_Transform('SRID=4326;POINT(-4.401047 32.836189)'::geometry, 3857)), +(557, 'SRID=4326;POINT(-4.400684 32.836472)'::geometry, ST_Transform('SRID=4326;POINT(-4.400684 32.836472)'::geometry, 3857)), +(558, 'SRID=4326;POINT(4.492599 35.25261)'::geometry, ST_Transform('SRID=4326;POINT(4.492599 35.25261)'::geometry, 3857)), +(559, 'SRID=4326;POINT(4.492929 35.252912)'::geometry, ST_Transform('SRID=4326;POINT(4.492929 35.252912)'::geometry, 3857)), +(560, 'SRID=4326;POINT(4.49299 35.25299)'::geometry, ST_Transform('SRID=4326;POINT(4.49299 35.25299)'::geometry, 3857)), +(561, 'SRID=4326;POINT(-9.9593 31.93916)'::geometry, ST_Transform('SRID=4326;POINT(-9.9593 31.93916)'::geometry, 3857)), +(562, 'SRID=4326;POINT(-9.959219 31.939457)'::geometry, ST_Transform('SRID=4326;POINT(-9.959219 31.939457)'::geometry, 3857)), +(563, 'SRID=4326;POINT(-9.959225 31.938742)'::geometry, ST_Transform('SRID=4326;POINT(-9.959225 31.938742)'::geometry, 3857)), +(564, 'SRID=4326;POINT(-9.959793 31.939377)'::geometry, ST_Transform('SRID=4326;POINT(-9.959793 31.939377)'::geometry, 3857)), +(565, 'SRID=4326;POINT(-9.959077 31.9388)'::geometry, ST_Transform('SRID=4326;POINT(-9.959077 31.9388)'::geometry, 3857)), +(566, 'SRID=4326;POINT(-9.959222 31.93878)'::geometry, ST_Transform('SRID=4326;POINT(-9.959222 31.93878)'::geometry, 3857)), +(567, 'SRID=4326;POINT(-9.959156 31.939046)'::geometry, ST_Transform('SRID=4326;POINT(-9.959156 31.939046)'::geometry, 3857)), +(568, 'SRID=4326;POINT(-9.95889 31.938758)'::geometry, ST_Transform('SRID=4326;POINT(-9.95889 31.938758)'::geometry, 3857)), +(569, 'SRID=4326;POINT(-9.959658 31.939125)'::geometry, ST_Transform('SRID=4326;POINT(-9.959658 31.939125)'::geometry, 3857)), +(570, 'SRID=4326;POINT(-9.959243 31.939014)'::geometry, ST_Transform('SRID=4326;POINT(-9.959243 31.939014)'::geometry, 3857)), +(571, 'SRID=4326;POINT(-9.959627 31.939155)'::geometry, ST_Transform('SRID=4326;POINT(-9.959627 31.939155)'::geometry, 3857)), +(572, 'SRID=4326;POINT(-9.959284 31.938954)'::geometry, ST_Transform('SRID=4326;POINT(-9.959284 31.938954)'::geometry, 3857)), +(573, 'SRID=4326;POINT(-4.056215 35.879559)'::geometry, ST_Transform('SRID=4326;POINT(-4.056215 35.879559)'::geometry, 3857)), +(574, 'SRID=4326;POINT(9.407199 35.632402)'::geometry, ST_Transform('SRID=4326;POINT(9.407199 35.632402)'::geometry, 3857)), +(575, 'SRID=4326;POINT(9.407456 35.632353)'::geometry, ST_Transform('SRID=4326;POINT(9.407456 35.632353)'::geometry, 3857)), +(576, 'SRID=4326;POINT(9.407844 35.632295)'::geometry, ST_Transform('SRID=4326;POINT(9.407844 35.632295)'::geometry, 3857)), +(577, 'SRID=4326;POINT(9.40776 35.631777)'::geometry, ST_Transform('SRID=4326;POINT(9.40776 35.631777)'::geometry, 3857)), +(578, 'SRID=4326;POINT(2.231809 36.542849)'::geometry, ST_Transform('SRID=4326;POINT(2.231809 36.542849)'::geometry, 3857)), +(579, 'SRID=4326;POINT(2.232178 36.543185)'::geometry, ST_Transform('SRID=4326;POINT(2.232178 36.543185)'::geometry, 3857)), +(580, 'SRID=4326;POINT(2.232212 36.542512)'::geometry, ST_Transform('SRID=4326;POINT(2.232212 36.542512)'::geometry, 3857)), +(581, 'SRID=4326;POINT(2.232029 36.543168)'::geometry, ST_Transform('SRID=4326;POINT(2.232029 36.543168)'::geometry, 3857)), +(582, 'SRID=4326;POINT(2.231443 36.542672)'::geometry, ST_Transform('SRID=4326;POINT(2.231443 36.542672)'::geometry, 3857)), +(583, 'SRID=4326;POINT(2.231272 36.543057)'::geometry, ST_Transform('SRID=4326;POINT(2.231272 36.543057)'::geometry, 3857)), +(584, 'SRID=4326;POINT(2.231296 36.542955)'::geometry, ST_Transform('SRID=4326;POINT(2.231296 36.542955)'::geometry, 3857)), +(585, 'SRID=4326;POINT(2.231748 36.543061)'::geometry, ST_Transform('SRID=4326;POINT(2.231748 36.543061)'::geometry, 3857)), +(586, 'SRID=4326;POINT(2.232033 36.542659)'::geometry, ST_Transform('SRID=4326;POINT(2.232033 36.542659)'::geometry, 3857)), +(587, 'SRID=4326;POINT(2.23203 36.542826)'::geometry, ST_Transform('SRID=4326;POINT(2.23203 36.542826)'::geometry, 3857)), +(588, 'SRID=4326;POINT(2.232181 36.542546)'::geometry, ST_Transform('SRID=4326;POINT(2.232181 36.542546)'::geometry, 3857)), +(589, 'SRID=4326;POINT(2.232023 36.543425)'::geometry, ST_Transform('SRID=4326;POINT(2.232023 36.543425)'::geometry, 3857)), +(590, 'SRID=4326;POINT(0.948501 32.875271)'::geometry, ST_Transform('SRID=4326;POINT(0.948501 32.875271)'::geometry, 3857)), +(591, 'SRID=4326;POINT(0.9481 32.874688)'::geometry, ST_Transform('SRID=4326;POINT(0.9481 32.874688)'::geometry, 3857)), +(592, 'SRID=4326;POINT(0.948466 32.875415)'::geometry, ST_Transform('SRID=4326;POINT(0.948466 32.875415)'::geometry, 3857)), +(593, 'SRID=4326;POINT(0.947954 32.874821)'::geometry, ST_Transform('SRID=4326;POINT(0.947954 32.874821)'::geometry, 3857)), +(594, 'SRID=4326;POINT(0.947609 32.875461)'::geometry, ST_Transform('SRID=4326;POINT(0.947609 32.875461)'::geometry, 3857)), +(595, 'SRID=4326;POINT(0.948057 32.875049)'::geometry, ST_Transform('SRID=4326;POINT(0.948057 32.875049)'::geometry, 3857)), +(596, 'SRID=4326;POINT(0.94801 32.874707)'::geometry, ST_Transform('SRID=4326;POINT(0.94801 32.874707)'::geometry, 3857)), +(597, 'SRID=4326;POINT(0.947579 32.875047)'::geometry, ST_Transform('SRID=4326;POINT(0.947579 32.875047)'::geometry, 3857)), +(598, 'SRID=4326;POINT(0.948398 32.875394)'::geometry, ST_Transform('SRID=4326;POINT(0.948398 32.875394)'::geometry, 3857)), +(599, 'SRID=4326;POINT(0.948466 32.875444)'::geometry, ST_Transform('SRID=4326;POINT(0.948466 32.875444)'::geometry, 3857)), +(600, 'SRID=4326;POINT(0.94785 32.875375)'::geometry, ST_Transform('SRID=4326;POINT(0.94785 32.875375)'::geometry, 3857)), +(601, 'SRID=4326;POINT(0.948108 32.875197)'::geometry, ST_Transform('SRID=4326;POINT(0.948108 32.875197)'::geometry, 3857)), +(602, 'SRID=4326;POINT(0.948288 32.875307)'::geometry, ST_Transform('SRID=4326;POINT(0.948288 32.875307)'::geometry, 3857)), +(603, 'SRID=4326;POINT(0.948283 32.874956)'::geometry, ST_Transform('SRID=4326;POINT(0.948283 32.874956)'::geometry, 3857)), +(604, 'SRID=4326;POINT(0.948033 32.874929)'::geometry, ST_Transform('SRID=4326;POINT(0.948033 32.874929)'::geometry, 3857)), +(605, 'SRID=4326;POINT(0.948309 32.874623)'::geometry, ST_Transform('SRID=4326;POINT(0.948309 32.874623)'::geometry, 3857)), +(606, 'SRID=4326;POINT(-1.377445 36.13206)'::geometry, ST_Transform('SRID=4326;POINT(-1.377445 36.13206)'::geometry, 3857)), +(607, 'SRID=4326;POINT(-1.377573 36.132389)'::geometry, ST_Transform('SRID=4326;POINT(-1.377573 36.132389)'::geometry, 3857)), +(608, 'SRID=4326;POINT(-1.377342 36.132377)'::geometry, ST_Transform('SRID=4326;POINT(-1.377342 36.132377)'::geometry, 3857)), +(609, 'SRID=4326;POINT(-1.378103 36.131979)'::geometry, ST_Transform('SRID=4326;POINT(-1.378103 36.131979)'::geometry, 3857)), +(610, 'SRID=4326;POINT(-1.37759 36.132034)'::geometry, ST_Transform('SRID=4326;POINT(-1.37759 36.132034)'::geometry, 3857)), +(611, 'SRID=4326;POINT(-1.377544 36.13201)'::geometry, ST_Transform('SRID=4326;POINT(-1.377544 36.13201)'::geometry, 3857)), +(612, 'SRID=4326;POINT(-1.377877 36.132664)'::geometry, ST_Transform('SRID=4326;POINT(-1.377877 36.132664)'::geometry, 3857)), +(613, 'SRID=4326;POINT(-1.377243 36.1327)'::geometry, ST_Transform('SRID=4326;POINT(-1.377243 36.1327)'::geometry, 3857)), +(614, 'SRID=4326;POINT(-1.377821 36.132226)'::geometry, ST_Transform('SRID=4326;POINT(-1.377821 36.132226)'::geometry, 3857)), +(615, 'SRID=4326;POINT(-1.377819 36.131905)'::geometry, ST_Transform('SRID=4326;POINT(-1.377819 36.131905)'::geometry, 3857)), +(616, 'SRID=4326;POINT(-1.377647 36.132385)'::geometry, ST_Transform('SRID=4326;POINT(-1.377647 36.132385)'::geometry, 3857)), +(617, 'SRID=4326;POINT(-1.378114 36.132113)'::geometry, ST_Transform('SRID=4326;POINT(-1.378114 36.132113)'::geometry, 3857)), +(618, 'SRID=4326;POINT(1.281128 38.138626)'::geometry, ST_Transform('SRID=4326;POINT(1.281128 38.138626)'::geometry, 3857)), +(619, 'SRID=4326;POINT(1.281305 38.138959)'::geometry, ST_Transform('SRID=4326;POINT(1.281305 38.138959)'::geometry, 3857)), +(620, 'SRID=4326;POINT(1.281758 38.138407)'::geometry, ST_Transform('SRID=4326;POINT(1.281758 38.138407)'::geometry, 3857)), +(621, 'SRID=4326;POINT(1.281123 38.138734)'::geometry, ST_Transform('SRID=4326;POINT(1.281123 38.138734)'::geometry, 3857)), +(622, 'SRID=4326;POINT(1.281161 38.138177)'::geometry, ST_Transform('SRID=4326;POINT(1.281161 38.138177)'::geometry, 3857)), +(623, 'SRID=4326;POINT(1.281354 38.138617)'::geometry, ST_Transform('SRID=4326;POINT(1.281354 38.138617)'::geometry, 3857)), +(624, 'SRID=4326;POINT(1.281123 38.138171)'::geometry, ST_Transform('SRID=4326;POINT(1.281123 38.138171)'::geometry, 3857)), +(625, 'SRID=4326;POINT(1.001776 36.920915)'::geometry, ST_Transform('SRID=4326;POINT(1.001776 36.920915)'::geometry, 3857)), +(626, 'SRID=4326;POINT(1.001429 36.921273)'::geometry, ST_Transform('SRID=4326;POINT(1.001429 36.921273)'::geometry, 3857)), +(627, 'SRID=4326;POINT(1.001985 36.921254)'::geometry, ST_Transform('SRID=4326;POINT(1.001985 36.921254)'::geometry, 3857)), +(628, 'SRID=4326;POINT(1.001384 36.92111)'::geometry, ST_Transform('SRID=4326;POINT(1.001384 36.92111)'::geometry, 3857)), +(629, 'SRID=4326;POINT(1.001699 36.920728)'::geometry, ST_Transform('SRID=4326;POINT(1.001699 36.920728)'::geometry, 3857)), +(630, 'SRID=4326;POINT(1.002016 36.920362)'::geometry, ST_Transform('SRID=4326;POINT(1.002016 36.920362)'::geometry, 3857)), +(631, 'SRID=4326;POINT(1.001573 36.921188)'::geometry, ST_Transform('SRID=4326;POINT(1.001573 36.921188)'::geometry, 3857)), +(632, 'SRID=4326;POINT(1.00177 36.920421)'::geometry, ST_Transform('SRID=4326;POINT(1.00177 36.920421)'::geometry, 3857)), +(633, 'SRID=4326;POINT(1.001975 36.920794)'::geometry, ST_Transform('SRID=4326;POINT(1.001975 36.920794)'::geometry, 3857)), +(634, 'SRID=4326;POINT(1.001852 36.920518)'::geometry, ST_Transform('SRID=4326;POINT(1.001852 36.920518)'::geometry, 3857)), +(635, 'SRID=4326;POINT(1.001596 36.920567)'::geometry, ST_Transform('SRID=4326;POINT(1.001596 36.920567)'::geometry, 3857)), +(636, 'SRID=4326;POINT(1.002041 36.921094)'::geometry, ST_Transform('SRID=4326;POINT(1.002041 36.921094)'::geometry, 3857)), +(637, 'SRID=4326;POINT(1.00193 36.92129)'::geometry, ST_Transform('SRID=4326;POINT(1.00193 36.92129)'::geometry, 3857)), +(638, 'SRID=4326;POINT(1.001253 36.920578)'::geometry, ST_Transform('SRID=4326;POINT(1.001253 36.920578)'::geometry, 3857)), +(639, 'SRID=4326;POINT(1.001296 36.920603)'::geometry, ST_Transform('SRID=4326;POINT(1.001296 36.920603)'::geometry, 3857)), +(640, 'SRID=4326;POINT(1.001743 36.921216)'::geometry, ST_Transform('SRID=4326;POINT(1.001743 36.921216)'::geometry, 3857)), +(641, 'SRID=4326;POINT(-9.439246 39.930375)'::geometry, ST_Transform('SRID=4326;POINT(-9.439246 39.930375)'::geometry, 3857)), +(642, 'SRID=4326;POINT(-9.439831 39.93007)'::geometry, ST_Transform('SRID=4326;POINT(-9.439831 39.93007)'::geometry, 3857)), +(643, 'SRID=4326;POINT(-9.439794 39.930747)'::geometry, ST_Transform('SRID=4326;POINT(-9.439794 39.930747)'::geometry, 3857)), +(644, 'SRID=4326;POINT(7.051979 39.998654)'::geometry, ST_Transform('SRID=4326;POINT(7.051979 39.998654)'::geometry, 3857)), +(645, 'SRID=4326;POINT(7.052303 39.998459)'::geometry, ST_Transform('SRID=4326;POINT(7.052303 39.998459)'::geometry, 3857)), +(646, 'SRID=4326;POINT(7.051495 39.998286)'::geometry, ST_Transform('SRID=4326;POINT(7.051495 39.998286)'::geometry, 3857)), +(647, 'SRID=4326;POINT(7.052358 39.998959)'::geometry, ST_Transform('SRID=4326;POINT(7.052358 39.998959)'::geometry, 3857)), +(648, 'SRID=4326;POINT(7.051902 39.998646)'::geometry, ST_Transform('SRID=4326;POINT(7.051902 39.998646)'::geometry, 3857)), +(649, 'SRID=4326;POINT(7.051961 39.998936)'::geometry, ST_Transform('SRID=4326;POINT(7.051961 39.998936)'::geometry, 3857)), +(650, 'SRID=4326;POINT(7.052188 39.998715)'::geometry, ST_Transform('SRID=4326;POINT(7.052188 39.998715)'::geometry, 3857)), +(651, 'SRID=4326;POINT(7.051928 39.999019)'::geometry, ST_Transform('SRID=4326;POINT(7.051928 39.999019)'::geometry, 3857)), +(652, 'SRID=4326;POINT(7.051679 39.999193)'::geometry, ST_Transform('SRID=4326;POINT(7.051679 39.999193)'::geometry, 3857)), +(653, 'SRID=4326;POINT(7.052355 39.998444)'::geometry, ST_Transform('SRID=4326;POINT(7.052355 39.998444)'::geometry, 3857)), +(654, 'SRID=4326;POINT(7.052312 39.998467)'::geometry, ST_Transform('SRID=4326;POINT(7.052312 39.998467)'::geometry, 3857)), +(655, 'SRID=4326;POINT(3.946722 30.978786)'::geometry, ST_Transform('SRID=4326;POINT(3.946722 30.978786)'::geometry, 3857)), +(656, 'SRID=4326;POINT(3.946383 30.979446)'::geometry, ST_Transform('SRID=4326;POINT(3.946383 30.979446)'::geometry, 3857)), +(657, 'SRID=4326;POINT(3.946577 30.978671)'::geometry, ST_Transform('SRID=4326;POINT(3.946577 30.978671)'::geometry, 3857)), +(658, 'SRID=4326;POINT(3.946805 30.979383)'::geometry, ST_Transform('SRID=4326;POINT(3.946805 30.979383)'::geometry, 3857)), +(659, 'SRID=4326;POINT(4.739725 32.536293)'::geometry, ST_Transform('SRID=4326;POINT(4.739725 32.536293)'::geometry, 3857)), +(660, 'SRID=4326;POINT(4.739867 32.5367)'::geometry, ST_Transform('SRID=4326;POINT(4.739867 32.5367)'::geometry, 3857)), +(661, 'SRID=4326;POINT(4.739999 32.536189)'::geometry, ST_Transform('SRID=4326;POINT(4.739999 32.536189)'::geometry, 3857)), +(662, 'SRID=4326;POINT(4.739876 32.536571)'::geometry, ST_Transform('SRID=4326;POINT(4.739876 32.536571)'::geometry, 3857)), +(663, 'SRID=4326;POINT(4.739204 32.536119)'::geometry, ST_Transform('SRID=4326;POINT(4.739204 32.536119)'::geometry, 3857)), +(664, 'SRID=4326;POINT(4.739705 32.53637)'::geometry, ST_Transform('SRID=4326;POINT(4.739705 32.53637)'::geometry, 3857)), +(665, 'SRID=4326;POINT(4.739147 32.536027)'::geometry, ST_Transform('SRID=4326;POINT(4.739147 32.536027)'::geometry, 3857)), +(666, 'SRID=4326;POINT(4.739809 32.535831)'::geometry, ST_Transform('SRID=4326;POINT(4.739809 32.535831)'::geometry, 3857)), +(667, 'SRID=4326;POINT(4.739446 32.535993)'::geometry, ST_Transform('SRID=4326;POINT(4.739446 32.535993)'::geometry, 3857)), +(668, 'SRID=4326;POINT(4.739356 32.536354)'::geometry, ST_Transform('SRID=4326;POINT(4.739356 32.536354)'::geometry, 3857)), +(669, 'SRID=4326;POINT(4.73949 32.536547)'::geometry, ST_Transform('SRID=4326;POINT(4.73949 32.536547)'::geometry, 3857)), +(670, 'SRID=4326;POINT(4.739345 32.536142)'::geometry, ST_Transform('SRID=4326;POINT(4.739345 32.536142)'::geometry, 3857)), +(671, 'SRID=4326;POINT(4.73992 32.536513)'::geometry, ST_Transform('SRID=4326;POINT(4.73992 32.536513)'::geometry, 3857)), +(672, 'SRID=4326;POINT(4.739484 32.536518)'::geometry, ST_Transform('SRID=4326;POINT(4.739484 32.536518)'::geometry, 3857)), +(673, 'SRID=4326;POINT(4.739594 32.535765)'::geometry, ST_Transform('SRID=4326;POINT(4.739594 32.535765)'::geometry, 3857)), +(674, 'SRID=4326;POINT(-1.897518 32.955127)'::geometry, ST_Transform('SRID=4326;POINT(-1.897518 32.955127)'::geometry, 3857)), +(675, 'SRID=4326;POINT(-1.897857 32.955143)'::geometry, ST_Transform('SRID=4326;POINT(-1.897857 32.955143)'::geometry, 3857)), +(676, 'SRID=4326;POINT(-1.897766 32.954686)'::geometry, ST_Transform('SRID=4326;POINT(-1.897766 32.954686)'::geometry, 3857)), +(677, 'SRID=4326;POINT(6.858485 32.878875)'::geometry, ST_Transform('SRID=4326;POINT(6.858485 32.878875)'::geometry, 3857)), +(678, 'SRID=4326;POINT(6.858625 32.879165)'::geometry, ST_Transform('SRID=4326;POINT(6.858625 32.879165)'::geometry, 3857)), +(679, 'SRID=4326;POINT(6.859173 32.879623)'::geometry, ST_Transform('SRID=4326;POINT(6.859173 32.879623)'::geometry, 3857)), +(680, 'SRID=4326;POINT(6.858652 32.879073)'::geometry, ST_Transform('SRID=4326;POINT(6.858652 32.879073)'::geometry, 3857)), +(681, 'SRID=4326;POINT(6.858875 32.879512)'::geometry, ST_Transform('SRID=4326;POINT(6.858875 32.879512)'::geometry, 3857)), +(682, 'SRID=4326;POINT(2.489402 36.24209)'::geometry, ST_Transform('SRID=4326;POINT(2.489402 36.24209)'::geometry, 3857)), +(683, 'SRID=4326;POINT(2.490019 36.242308)'::geometry, ST_Transform('SRID=4326;POINT(2.490019 36.242308)'::geometry, 3857)), +(684, 'SRID=4326;POINT(2.490157 36.242104)'::geometry, ST_Transform('SRID=4326;POINT(2.490157 36.242104)'::geometry, 3857)), +(685, 'SRID=4326;POINT(2.48969 36.242247)'::geometry, ST_Transform('SRID=4326;POINT(2.48969 36.242247)'::geometry, 3857)), +(686, 'SRID=4326;POINT(2.489518 36.242617)'::geometry, ST_Transform('SRID=4326;POINT(2.489518 36.242617)'::geometry, 3857)), +(687, 'SRID=4326;POINT(2.490287 36.242602)'::geometry, ST_Transform('SRID=4326;POINT(2.490287 36.242602)'::geometry, 3857)), +(688, 'SRID=4326;POINT(2.490008 36.242113)'::geometry, ST_Transform('SRID=4326;POINT(2.490008 36.242113)'::geometry, 3857)), +(689, 'SRID=4326;POINT(2.489767 36.242141)'::geometry, ST_Transform('SRID=4326;POINT(2.489767 36.242141)'::geometry, 3857)), +(690, 'SRID=4326;POINT(2.490068 36.24219)'::geometry, ST_Transform('SRID=4326;POINT(2.490068 36.24219)'::geometry, 3857)), +(691, 'SRID=4326;POINT(2.489361 36.242592)'::geometry, ST_Transform('SRID=4326;POINT(2.489361 36.242592)'::geometry, 3857)), +(692, 'SRID=4326;POINT(4.675157 34.745728)'::geometry, ST_Transform('SRID=4326;POINT(4.675157 34.745728)'::geometry, 3857)), +(693, 'SRID=4326;POINT(4.675288 34.745268)'::geometry, ST_Transform('SRID=4326;POINT(4.675288 34.745268)'::geometry, 3857)), +(694, 'SRID=4326;POINT(4.67474 34.745439)'::geometry, ST_Transform('SRID=4326;POINT(4.67474 34.745439)'::geometry, 3857)), +(695, 'SRID=4326;POINT(-1.619779 36.505134)'::geometry, ST_Transform('SRID=4326;POINT(-1.619779 36.505134)'::geometry, 3857)), +(696, 'SRID=4326;POINT(-1.619178 36.504973)'::geometry, ST_Transform('SRID=4326;POINT(-1.619178 36.504973)'::geometry, 3857)), +(697, 'SRID=4326;POINT(1.443654 35.03996)'::geometry, ST_Transform('SRID=4326;POINT(1.443654 35.03996)'::geometry, 3857)), +(698, 'SRID=4326;POINT(1.443555 35.040102)'::geometry, ST_Transform('SRID=4326;POINT(1.443555 35.040102)'::geometry, 3857)), +(699, 'SRID=4326;POINT(1.444439 35.040191)'::geometry, ST_Transform('SRID=4326;POINT(1.444439 35.040191)'::geometry, 3857)), +(700, 'SRID=4326;POINT(1.443705 35.040334)'::geometry, ST_Transform('SRID=4326;POINT(1.443705 35.040334)'::geometry, 3857)), +(701, 'SRID=4326;POINT(1.444309 35.040845)'::geometry, ST_Transform('SRID=4326;POINT(1.444309 35.040845)'::geometry, 3857)), +(702, 'SRID=4326;POINT(1.444155 35.040343)'::geometry, ST_Transform('SRID=4326;POINT(1.444155 35.040343)'::geometry, 3857)), +(703, 'SRID=4326;POINT(1.443996 35.040538)'::geometry, ST_Transform('SRID=4326;POINT(1.443996 35.040538)'::geometry, 3857)), +(704, 'SRID=4326;POINT(1.443617 35.040449)'::geometry, ST_Transform('SRID=4326;POINT(1.443617 35.040449)'::geometry, 3857)), +(705, 'SRID=4326;POINT(1.443732 35.040449)'::geometry, ST_Transform('SRID=4326;POINT(1.443732 35.040449)'::geometry, 3857)), +(706, 'SRID=4326;POINT(1.510391 37.025753)'::geometry, ST_Transform('SRID=4326;POINT(1.510391 37.025753)'::geometry, 3857)), +(707, 'SRID=4326;POINT(1.510774 37.025573)'::geometry, ST_Transform('SRID=4326;POINT(1.510774 37.025573)'::geometry, 3857)), +(708, 'SRID=4326;POINT(-1.068005 30.909683)'::geometry, ST_Transform('SRID=4326;POINT(-1.068005 30.909683)'::geometry, 3857)), +(709, 'SRID=4326;POINT(-1.067915 30.910178)'::geometry, ST_Transform('SRID=4326;POINT(-1.067915 30.910178)'::geometry, 3857)), +(710, 'SRID=4326;POINT(-1.067998 30.909856)'::geometry, ST_Transform('SRID=4326;POINT(-1.067998 30.909856)'::geometry, 3857)), +(711, 'SRID=4326;POINT(-1.067593 30.910177)'::geometry, ST_Transform('SRID=4326;POINT(-1.067593 30.910177)'::geometry, 3857)), +(712, 'SRID=4326;POINT(-1.068124 30.909608)'::geometry, ST_Transform('SRID=4326;POINT(-1.068124 30.909608)'::geometry, 3857)), +(713, 'SRID=4326;POINT(-1.067982 30.909937)'::geometry, ST_Transform('SRID=4326;POINT(-1.067982 30.909937)'::geometry, 3857)), +(714, 'SRID=4326;POINT(-1.068222 30.909692)'::geometry, ST_Transform('SRID=4326;POINT(-1.068222 30.909692)'::geometry, 3857)), +(715, 'SRID=4326;POINT(-1.067383 30.909904)'::geometry, ST_Transform('SRID=4326;POINT(-1.067383 30.909904)'::geometry, 3857)), +(716, 'SRID=4326;POINT(-1.067335 30.91012)'::geometry, ST_Transform('SRID=4326;POINT(-1.067335 30.91012)'::geometry, 3857)), +(717, 'SRID=4326;POINT(-1.06821 30.909356)'::geometry, ST_Transform('SRID=4326;POINT(-1.06821 30.909356)'::geometry, 3857)), +(718, 'SRID=4326;POINT(-1.067598 30.909364)'::geometry, ST_Transform('SRID=4326;POINT(-1.067598 30.909364)'::geometry, 3857)), +(719, 'SRID=4326;POINT(-1.067629 30.909687)'::geometry, ST_Transform('SRID=4326;POINT(-1.067629 30.909687)'::geometry, 3857)), +(720, 'SRID=4326;POINT(-1.068031 30.90956)'::geometry, ST_Transform('SRID=4326;POINT(-1.068031 30.90956)'::geometry, 3857)), +(721, 'SRID=4326;POINT(-1.067461 30.909412)'::geometry, ST_Transform('SRID=4326;POINT(-1.067461 30.909412)'::geometry, 3857)), +(722, 'SRID=4326;POINT(-4.441301 35.734339)'::geometry, ST_Transform('SRID=4326;POINT(-4.441301 35.734339)'::geometry, 3857)), +(723, 'SRID=4326;POINT(-4.441614 35.734596)'::geometry, ST_Transform('SRID=4326;POINT(-4.441614 35.734596)'::geometry, 3857)), +(724, 'SRID=4326;POINT(-4.441374 35.734511)'::geometry, ST_Transform('SRID=4326;POINT(-4.441374 35.734511)'::geometry, 3857)), +(725, 'SRID=4326;POINT(-4.442144 35.733728)'::geometry, ST_Transform('SRID=4326;POINT(-4.442144 35.733728)'::geometry, 3857)), +(726, 'SRID=4326;POINT(-4.442129 35.733779)'::geometry, ST_Transform('SRID=4326;POINT(-4.442129 35.733779)'::geometry, 3857)), +(727, 'SRID=4326;POINT(-4.442129 35.7343)'::geometry, ST_Transform('SRID=4326;POINT(-4.442129 35.7343)'::geometry, 3857)), +(728, 'SRID=4326;POINT(-4.441357 35.734573)'::geometry, ST_Transform('SRID=4326;POINT(-4.441357 35.734573)'::geometry, 3857)), +(729, 'SRID=4326;POINT(-4.441611 35.734042)'::geometry, ST_Transform('SRID=4326;POINT(-4.441611 35.734042)'::geometry, 3857)), +(730, 'SRID=4326;POINT(-4.442273 35.734478)'::geometry, ST_Transform('SRID=4326;POINT(-4.442273 35.734478)'::geometry, 3857)), +(731, 'SRID=4326;POINT(3.777839 39.080855)'::geometry, ST_Transform('SRID=4326;POINT(3.777839 39.080855)'::geometry, 3857)), +(732, 'SRID=4326;POINT(3.778302 39.081637)'::geometry, ST_Transform('SRID=4326;POINT(3.778302 39.081637)'::geometry, 3857)), +(733, 'SRID=4326;POINT(3.778134 39.081327)'::geometry, ST_Transform('SRID=4326;POINT(3.778134 39.081327)'::geometry, 3857)), +(734, 'SRID=4326;POINT(3.77753 39.080837)'::geometry, ST_Transform('SRID=4326;POINT(3.77753 39.080837)'::geometry, 3857)), +(735, 'SRID=4326;POINT(3.777524 39.08106)'::geometry, ST_Transform('SRID=4326;POINT(3.777524 39.08106)'::geometry, 3857)), +(736, 'SRID=4326;POINT(3.778196 39.081177)'::geometry, ST_Transform('SRID=4326;POINT(3.778196 39.081177)'::geometry, 3857)), +(737, 'SRID=4326;POINT(3.777824 39.081648)'::geometry, ST_Transform('SRID=4326;POINT(3.777824 39.081648)'::geometry, 3857)), +(738, 'SRID=4326;POINT(3.778294 39.081016)'::geometry, ST_Transform('SRID=4326;POINT(3.778294 39.081016)'::geometry, 3857)), +(739, 'SRID=4326;POINT(3.778384 39.080821)'::geometry, ST_Transform('SRID=4326;POINT(3.778384 39.080821)'::geometry, 3857)), +(740, 'SRID=4326;POINT(3.77832 39.081738)'::geometry, ST_Transform('SRID=4326;POINT(3.77832 39.081738)'::geometry, 3857)), +(741, 'SRID=4326;POINT(3.77775 39.081581)'::geometry, ST_Transform('SRID=4326;POINT(3.77775 39.081581)'::geometry, 3857)), +(742, 'SRID=4326;POINT(3.777606 39.080794)'::geometry, ST_Transform('SRID=4326;POINT(3.777606 39.080794)'::geometry, 3857)), +(743, 'SRID=4326;POINT(3.777891 39.081417)'::geometry, ST_Transform('SRID=4326;POINT(3.777891 39.081417)'::geometry, 3857)), +(744, 'SRID=4326;POINT(5.649526 31.865244)'::geometry, ST_Transform('SRID=4326;POINT(5.649526 31.865244)'::geometry, 3857)), +(745, 'SRID=4326;POINT(5.649871 31.865085)'::geometry, ST_Transform('SRID=4326;POINT(5.649871 31.865085)'::geometry, 3857)), +(746, 'SRID=4326;POINT(5.649532 31.86498)'::geometry, ST_Transform('SRID=4326;POINT(5.649532 31.86498)'::geometry, 3857)), +(747, 'SRID=4326;POINT(5.650394 31.864659)'::geometry, ST_Transform('SRID=4326;POINT(5.650394 31.864659)'::geometry, 3857)), +(748, 'SRID=4326;POINT(5.650448 31.865148)'::geometry, ST_Transform('SRID=4326;POINT(5.650448 31.865148)'::geometry, 3857)), +(749, 'SRID=4326;POINT(5.649964 31.865283)'::geometry, ST_Transform('SRID=4326;POINT(5.649964 31.865283)'::geometry, 3857)), +(750, 'SRID=4326;POINT(5.650139 31.865148)'::geometry, ST_Transform('SRID=4326;POINT(5.650139 31.865148)'::geometry, 3857)), +(751, 'SRID=4326;POINT(5.650438 31.865057)'::geometry, ST_Transform('SRID=4326;POINT(5.650438 31.865057)'::geometry, 3857)), +(752, 'SRID=4326;POINT(5.649977 31.86457)'::geometry, ST_Transform('SRID=4326;POINT(5.649977 31.86457)'::geometry, 3857)), +(753, 'SRID=4326;POINT(5.649628 31.864566)'::geometry, ST_Transform('SRID=4326;POINT(5.649628 31.864566)'::geometry, 3857)), +(754, 'SRID=4326;POINT(-9.754618 33.438008)'::geometry, ST_Transform('SRID=4326;POINT(-9.754618 33.438008)'::geometry, 3857)), +(755, 'SRID=4326;POINT(-9.75386 33.437609)'::geometry, ST_Transform('SRID=4326;POINT(-9.75386 33.437609)'::geometry, 3857)), +(756, 'SRID=4326;POINT(-9.754443 33.437308)'::geometry, ST_Transform('SRID=4326;POINT(-9.754443 33.437308)'::geometry, 3857)), +(757, 'SRID=4326;POINT(-9.75421 33.437932)'::geometry, ST_Transform('SRID=4326;POINT(-9.75421 33.437932)'::geometry, 3857)), +(758, 'SRID=4326;POINT(-9.753773 33.437663)'::geometry, ST_Transform('SRID=4326;POINT(-9.753773 33.437663)'::geometry, 3857)), +(759, 'SRID=4326;POINT(-9.754267 33.437916)'::geometry, ST_Transform('SRID=4326;POINT(-9.754267 33.437916)'::geometry, 3857)), +(760, 'SRID=4326;POINT(-9.754199 33.437889)'::geometry, ST_Transform('SRID=4326;POINT(-9.754199 33.437889)'::geometry, 3857)), +(761, 'SRID=4326;POINT(-9.75385 33.437159)'::geometry, ST_Transform('SRID=4326;POINT(-9.75385 33.437159)'::geometry, 3857)), +(762, 'SRID=4326;POINT(-3.543263 37.732976)'::geometry, ST_Transform('SRID=4326;POINT(-3.543263 37.732976)'::geometry, 3857)), +(763, 'SRID=4326;POINT(-3.542739 37.73271)'::geometry, ST_Transform('SRID=4326;POINT(-3.542739 37.73271)'::geometry, 3857)), +(764, 'SRID=4326;POINT(-3.54322 37.733139)'::geometry, ST_Transform('SRID=4326;POINT(-3.54322 37.733139)'::geometry, 3857)), +(765, 'SRID=4326;POINT(-3.54322 37.732576)'::geometry, ST_Transform('SRID=4326;POINT(-3.54322 37.732576)'::geometry, 3857)), +(766, 'SRID=4326;POINT(-3.543006 37.732667)'::geometry, ST_Transform('SRID=4326;POINT(-3.543006 37.732667)'::geometry, 3857)), +(767, 'SRID=4326;POINT(-8.711766 37.59638)'::geometry, ST_Transform('SRID=4326;POINT(-8.711766 37.59638)'::geometry, 3857)), +(768, 'SRID=4326;POINT(-8.711754 37.596229)'::geometry, ST_Transform('SRID=4326;POINT(-8.711754 37.596229)'::geometry, 3857)), +(769, 'SRID=4326;POINT(-8.711602 37.596288)'::geometry, ST_Transform('SRID=4326;POINT(-8.711602 37.596288)'::geometry, 3857)), +(770, 'SRID=4326;POINT(-8.712524 37.59617)'::geometry, ST_Transform('SRID=4326;POINT(-8.712524 37.59617)'::geometry, 3857)), +(771, 'SRID=4326;POINT(-8.712334 37.596219)'::geometry, ST_Transform('SRID=4326;POINT(-8.712334 37.596219)'::geometry, 3857)), +(772, 'SRID=4326;POINT(-8.71181 37.596124)'::geometry, ST_Transform('SRID=4326;POINT(-8.71181 37.596124)'::geometry, 3857)), +(773, 'SRID=4326;POINT(-8.712069 37.596608)'::geometry, ST_Transform('SRID=4326;POINT(-8.712069 37.596608)'::geometry, 3857)), +(774, 'SRID=4326;POINT(-8.711985 37.596911)'::geometry, ST_Transform('SRID=4326;POINT(-8.711985 37.596911)'::geometry, 3857)), +(775, 'SRID=4326;POINT(-3.044214 35.702146)'::geometry, ST_Transform('SRID=4326;POINT(-3.044214 35.702146)'::geometry, 3857)), +(776, 'SRID=4326;POINT(-3.044209 35.702853)'::geometry, ST_Transform('SRID=4326;POINT(-3.044209 35.702853)'::geometry, 3857)), +(777, 'SRID=4326;POINT(-3.044276 35.703038)'::geometry, ST_Transform('SRID=4326;POINT(-3.044276 35.703038)'::geometry, 3857)), +(778, 'SRID=4326;POINT(-3.043811 35.702228)'::geometry, ST_Transform('SRID=4326;POINT(-3.043811 35.702228)'::geometry, 3857)), +(779, 'SRID=4326;POINT(-3.043957 35.702876)'::geometry, ST_Transform('SRID=4326;POINT(-3.043957 35.702876)'::geometry, 3857)), +(780, 'SRID=4326;POINT(-3.044306 35.70211)'::geometry, ST_Transform('SRID=4326;POINT(-3.044306 35.70211)'::geometry, 3857)), +(781, 'SRID=4326;POINT(-3.044272 35.702647)'::geometry, ST_Transform('SRID=4326;POINT(-3.044272 35.702647)'::geometry, 3857)), +(782, 'SRID=4326;POINT(-3.044 35.702192)'::geometry, ST_Transform('SRID=4326;POINT(-3.044 35.702192)'::geometry, 3857)), +(783, 'SRID=4326;POINT(-3.044468 35.702635)'::geometry, ST_Transform('SRID=4326;POINT(-3.044468 35.702635)'::geometry, 3857)), +(784, 'SRID=4326;POINT(-3.044076 35.702746)'::geometry, ST_Transform('SRID=4326;POINT(-3.044076 35.702746)'::geometry, 3857)), +(785, 'SRID=4326;POINT(-3.043738 35.702675)'::geometry, ST_Transform('SRID=4326;POINT(-3.043738 35.702675)'::geometry, 3857)), +(786, 'SRID=4326;POINT(-3.043795 35.702232)'::geometry, ST_Transform('SRID=4326;POINT(-3.043795 35.702232)'::geometry, 3857)), +(787, 'SRID=4326;POINT(-3.044209 35.702984)'::geometry, ST_Transform('SRID=4326;POINT(-3.044209 35.702984)'::geometry, 3857)), +(788, 'SRID=4326;POINT(-7.790389 34.460937)'::geometry, ST_Transform('SRID=4326;POINT(-7.790389 34.460937)'::geometry, 3857)), +(789, 'SRID=4326;POINT(-7.789629 34.460861)'::geometry, ST_Transform('SRID=4326;POINT(-7.789629 34.460861)'::geometry, 3857)), +(790, 'SRID=4326;POINT(-7.78971 34.460351)'::geometry, ST_Transform('SRID=4326;POINT(-7.78971 34.460351)'::geometry, 3857)), +(791, 'SRID=4326;POINT(-3.638793 31.769061)'::geometry, ST_Transform('SRID=4326;POINT(-3.638793 31.769061)'::geometry, 3857)), +(792, 'SRID=4326;POINT(-3.638466 31.768737)'::geometry, ST_Transform('SRID=4326;POINT(-3.638466 31.768737)'::geometry, 3857)), +(793, 'SRID=4326;POINT(-3.63824 31.768573)'::geometry, ST_Transform('SRID=4326;POINT(-3.63824 31.768573)'::geometry, 3857)), +(794, 'SRID=4326;POINT(-3.638398 31.768979)'::geometry, ST_Transform('SRID=4326;POINT(-3.638398 31.768979)'::geometry, 3857)), +(795, 'SRID=4326;POINT(-3.63876 31.768587)'::geometry, ST_Transform('SRID=4326;POINT(-3.63876 31.768587)'::geometry, 3857)), +(796, 'SRID=4326;POINT(-3.638016 31.769415)'::geometry, ST_Transform('SRID=4326;POINT(-3.638016 31.769415)'::geometry, 3857)), +(797, 'SRID=4326;POINT(-3.638079 31.768865)'::geometry, ST_Transform('SRID=4326;POINT(-3.638079 31.768865)'::geometry, 3857)), +(798, 'SRID=4326;POINT(-3.638309 31.768567)'::geometry, ST_Transform('SRID=4326;POINT(-3.638309 31.768567)'::geometry, 3857)), +(799, 'SRID=4326;POINT(-3.638519 31.76941)'::geometry, ST_Transform('SRID=4326;POINT(-3.638519 31.76941)'::geometry, 3857)), +(800, 'SRID=4326;POINT(-3.638692 31.768971)'::geometry, ST_Transform('SRID=4326;POINT(-3.638692 31.768971)'::geometry, 3857)), +(801, 'SRID=4326;POINT(-3.6379 31.768873)'::geometry, ST_Transform('SRID=4326;POINT(-3.6379 31.768873)'::geometry, 3857)), +(802, 'SRID=4326;POINT(-3.638416 31.768977)'::geometry, ST_Transform('SRID=4326;POINT(-3.638416 31.768977)'::geometry, 3857)), +(803, 'SRID=4326;POINT(3.482375 34.823772)'::geometry, ST_Transform('SRID=4326;POINT(3.482375 34.823772)'::geometry, 3857)), +(804, 'SRID=4326;POINT(3.482611 34.823862)'::geometry, ST_Transform('SRID=4326;POINT(3.482611 34.823862)'::geometry, 3857)), +(805, 'SRID=4326;POINT(3.482458 34.823835)'::geometry, ST_Transform('SRID=4326;POINT(3.482458 34.823835)'::geometry, 3857)), +(806, 'SRID=4326;POINT(3.482499 34.823217)'::geometry, ST_Transform('SRID=4326;POINT(3.482499 34.823217)'::geometry, 3857)), +(807, 'SRID=4326;POINT(3.481979 34.824033)'::geometry, ST_Transform('SRID=4326;POINT(3.481979 34.824033)'::geometry, 3857)), +(808, 'SRID=4326;POINT(-2.509218 34.847743)'::geometry, ST_Transform('SRID=4326;POINT(-2.509218 34.847743)'::geometry, 3857)), +(809, 'SRID=4326;POINT(-2.508889 34.847727)'::geometry, ST_Transform('SRID=4326;POINT(-2.508889 34.847727)'::geometry, 3857)), +(810, 'SRID=4326;POINT(-2.50892 34.846884)'::geometry, ST_Transform('SRID=4326;POINT(-2.50892 34.846884)'::geometry, 3857)), +(811, 'SRID=4326;POINT(-2.508925 34.847728)'::geometry, ST_Transform('SRID=4326;POINT(-2.508925 34.847728)'::geometry, 3857)), +(812, 'SRID=4326;POINT(-2.509686 34.847259)'::geometry, ST_Transform('SRID=4326;POINT(-2.509686 34.847259)'::geometry, 3857)), +(813, 'SRID=4326;POINT(-2.509642 34.847683)'::geometry, ST_Transform('SRID=4326;POINT(-2.509642 34.847683)'::geometry, 3857)), +(814, 'SRID=4326;POINT(-2.509494 34.847088)'::geometry, ST_Transform('SRID=4326;POINT(-2.509494 34.847088)'::geometry, 3857)), +(815, 'SRID=4326;POINT(-2.508858 34.847826)'::geometry, ST_Transform('SRID=4326;POINT(-2.508858 34.847826)'::geometry, 3857)), +(816, 'SRID=4326;POINT(-2.508911 34.84779)'::geometry, ST_Transform('SRID=4326;POINT(-2.508911 34.84779)'::geometry, 3857)), +(817, 'SRID=4326;POINT(-2.509036 34.847235)'::geometry, ST_Transform('SRID=4326;POINT(-2.509036 34.847235)'::geometry, 3857)), +(818, 'SRID=4326;POINT(-2.508977 34.847441)'::geometry, ST_Transform('SRID=4326;POINT(-2.508977 34.847441)'::geometry, 3857)), +(819, 'SRID=4326;POINT(-2.509094 34.847048)'::geometry, ST_Transform('SRID=4326;POINT(-2.509094 34.847048)'::geometry, 3857)), +(820, 'SRID=4326;POINT(-2.509022 34.847189)'::geometry, ST_Transform('SRID=4326;POINT(-2.509022 34.847189)'::geometry, 3857)), +(821, 'SRID=4326;POINT(-2.509208 34.847051)'::geometry, ST_Transform('SRID=4326;POINT(-2.509208 34.847051)'::geometry, 3857)), +(822, 'SRID=4326;POINT(-2.509642 34.847293)'::geometry, ST_Transform('SRID=4326;POINT(-2.509642 34.847293)'::geometry, 3857)), +(823, 'SRID=4326;POINT(0.326508 39.66647)'::geometry, ST_Transform('SRID=4326;POINT(0.326508 39.66647)'::geometry, 3857)), +(824, 'SRID=4326;POINT(0.325896 39.666548)'::geometry, ST_Transform('SRID=4326;POINT(0.325896 39.666548)'::geometry, 3857)), +(825, 'SRID=4326;POINT(0.326264 39.66692)'::geometry, ST_Transform('SRID=4326;POINT(0.326264 39.66692)'::geometry, 3857)), +(826, 'SRID=4326;POINT(0.326113 39.666649)'::geometry, ST_Transform('SRID=4326;POINT(0.326113 39.666649)'::geometry, 3857)), +(827, 'SRID=4326;POINT(0.326511 39.666485)'::geometry, ST_Transform('SRID=4326;POINT(0.326511 39.666485)'::geometry, 3857)), +(828, 'SRID=4326;POINT(0.326479 39.667199)'::geometry, ST_Transform('SRID=4326;POINT(0.326479 39.667199)'::geometry, 3857)), +(829, 'SRID=4326;POINT(0.325908 39.667345)'::geometry, ST_Transform('SRID=4326;POINT(0.325908 39.667345)'::geometry, 3857)), +(830, 'SRID=4326;POINT(0.326475 39.666531)'::geometry, ST_Transform('SRID=4326;POINT(0.326475 39.666531)'::geometry, 3857)), +(831, 'SRID=4326;POINT(0.325636 39.666852)'::geometry, ST_Transform('SRID=4326;POINT(0.325636 39.666852)'::geometry, 3857)), +(832, 'SRID=4326;POINT(0.326265 39.666438)'::geometry, ST_Transform('SRID=4326;POINT(0.326265 39.666438)'::geometry, 3857)), +(833, 'SRID=4326;POINT(9.174032 33.398054)'::geometry, ST_Transform('SRID=4326;POINT(9.174032 33.398054)'::geometry, 3857)), +(834, 'SRID=4326;POINT(9.174151 33.397592)'::geometry, ST_Transform('SRID=4326;POINT(9.174151 33.397592)'::geometry, 3857)), +(835, 'SRID=4326;POINT(9.173741 33.397925)'::geometry, ST_Transform('SRID=4326;POINT(9.173741 33.397925)'::geometry, 3857)), +(836, 'SRID=4326;POINT(9.173967 33.397743)'::geometry, ST_Transform('SRID=4326;POINT(9.173967 33.397743)'::geometry, 3857)), +(837, 'SRID=4326;POINT(9.173591 33.397683)'::geometry, ST_Transform('SRID=4326;POINT(9.173591 33.397683)'::geometry, 3857)), +(838, 'SRID=4326;POINT(9.17437 33.398353)'::geometry, ST_Transform('SRID=4326;POINT(9.17437 33.398353)'::geometry, 3857)), +(839, 'SRID=4326;POINT(1.83634 38.816707)'::geometry, ST_Transform('SRID=4326;POINT(1.83634 38.816707)'::geometry, 3857)), +(840, 'SRID=4326;POINT(1.836636 38.815905)'::geometry, ST_Transform('SRID=4326;POINT(1.836636 38.815905)'::geometry, 3857)), +(841, 'SRID=4326;POINT(1.836376 38.81682)'::geometry, ST_Transform('SRID=4326;POINT(1.836376 38.81682)'::geometry, 3857)), +(842, 'SRID=4326;POINT(1.836335 38.816239)'::geometry, ST_Transform('SRID=4326;POINT(1.836335 38.816239)'::geometry, 3857)), +(843, 'SRID=4326;POINT(1.83687 38.816413)'::geometry, ST_Transform('SRID=4326;POINT(1.83687 38.816413)'::geometry, 3857)), +(844, 'SRID=4326;POINT(1.837073 38.81631)'::geometry, ST_Transform('SRID=4326;POINT(1.837073 38.81631)'::geometry, 3857)), +(845, 'SRID=4326;POINT(1.836343 38.816733)'::geometry, ST_Transform('SRID=4326;POINT(1.836343 38.816733)'::geometry, 3857)), +(846, 'SRID=4326;POINT(1.836489 38.816262)'::geometry, ST_Transform('SRID=4326;POINT(1.836489 38.816262)'::geometry, 3857)), +(847, 'SRID=4326;POINT(1.83676 38.816723)'::geometry, ST_Transform('SRID=4326;POINT(1.83676 38.816723)'::geometry, 3857)), +(848, 'SRID=4326;POINT(-6.101184 30.891359)'::geometry, ST_Transform('SRID=4326;POINT(-6.101184 30.891359)'::geometry, 3857)), +(849, 'SRID=4326;POINT(-6.101891 30.891475)'::geometry, ST_Transform('SRID=4326;POINT(-6.101891 30.891475)'::geometry, 3857)), +(850, 'SRID=4326;POINT(-6.101454 30.890926)'::geometry, ST_Transform('SRID=4326;POINT(-6.101454 30.890926)'::geometry, 3857)), +(851, 'SRID=4326;POINT(-6.101107 30.891705)'::geometry, ST_Transform('SRID=4326;POINT(-6.101107 30.891705)'::geometry, 3857)), +(852, 'SRID=4326;POINT(-6.102024 30.891119)'::geometry, ST_Transform('SRID=4326;POINT(-6.102024 30.891119)'::geometry, 3857)), +(853, 'SRID=4326;POINT(-6.101783 30.891325)'::geometry, ST_Transform('SRID=4326;POINT(-6.101783 30.891325)'::geometry, 3857)), +(854, 'SRID=4326;POINT(-6.101777 30.891247)'::geometry, ST_Transform('SRID=4326;POINT(-6.101777 30.891247)'::geometry, 3857)), +(855, 'SRID=4326;POINT(-6.101719 30.891249)'::geometry, ST_Transform('SRID=4326;POINT(-6.101719 30.891249)'::geometry, 3857)), +(856, 'SRID=4326;POINT(-6.101544 30.891609)'::geometry, ST_Transform('SRID=4326;POINT(-6.101544 30.891609)'::geometry, 3857)), +(857, 'SRID=4326;POINT(-6.101199 30.891006)'::geometry, ST_Transform('SRID=4326;POINT(-6.101199 30.891006)'::geometry, 3857)), +(858, 'SRID=4326;POINT(-6.101879 30.891786)'::geometry, ST_Transform('SRID=4326;POINT(-6.101879 30.891786)'::geometry, 3857)), +(859, 'SRID=4326;POINT(0.467665 33.036704)'::geometry, ST_Transform('SRID=4326;POINT(0.467665 33.036704)'::geometry, 3857)), +(860, 'SRID=4326;POINT(0.46855 33.036736)'::geometry, ST_Transform('SRID=4326;POINT(0.46855 33.036736)'::geometry, 3857)), +(861, 'SRID=4326;POINT(0.467955 33.036171)'::geometry, ST_Transform('SRID=4326;POINT(0.467955 33.036171)'::geometry, 3857)), +(862, 'SRID=4326;POINT(0.46803 33.036307)'::geometry, ST_Transform('SRID=4326;POINT(0.46803 33.036307)'::geometry, 3857)), +(863, 'SRID=4326;POINT(0.467935 33.036645)'::geometry, ST_Transform('SRID=4326;POINT(0.467935 33.036645)'::geometry, 3857)), +(864, 'SRID=4326;POINT(0.468476 33.036343)'::geometry, ST_Transform('SRID=4326;POINT(0.468476 33.036343)'::geometry, 3857)), +(865, 'SRID=4326;POINT(-4.397995 38.108926)'::geometry, ST_Transform('SRID=4326;POINT(-4.397995 38.108926)'::geometry, 3857)), +(866, 'SRID=4326;POINT(-4.397981 38.10856)'::geometry, ST_Transform('SRID=4326;POINT(-4.397981 38.10856)'::geometry, 3857)), +(867, 'SRID=4326;POINT(-4.398207 38.107988)'::geometry, ST_Transform('SRID=4326;POINT(-4.398207 38.107988)'::geometry, 3857)), +(868, 'SRID=4326;POINT(9.353839 32.862791)'::geometry, ST_Transform('SRID=4326;POINT(9.353839 32.862791)'::geometry, 3857)), +(869, 'SRID=4326;POINT(4.939926 35.255665)'::geometry, ST_Transform('SRID=4326;POINT(4.939926 35.255665)'::geometry, 3857)), +(870, 'SRID=4326;POINT(4.940045 35.255507)'::geometry, ST_Transform('SRID=4326;POINT(4.940045 35.255507)'::geometry, 3857)), +(871, 'SRID=4326;POINT(4.94067 35.255616)'::geometry, ST_Transform('SRID=4326;POINT(4.94067 35.255616)'::geometry, 3857)), +(872, 'SRID=4326;POINT(4.940524 35.255542)'::geometry, ST_Transform('SRID=4326;POINT(4.940524 35.255542)'::geometry, 3857)), +(873, 'SRID=4326;POINT(4.940745 35.254987)'::geometry, ST_Transform('SRID=4326;POINT(4.940745 35.254987)'::geometry, 3857)), +(874, 'SRID=4326;POINT(4.939899 35.255589)'::geometry, ST_Transform('SRID=4326;POINT(4.939899 35.255589)'::geometry, 3857)), +(875, 'SRID=4326;POINT(4.940335 35.25572)'::geometry, ST_Transform('SRID=4326;POINT(4.940335 35.25572)'::geometry, 3857)), +(876, 'SRID=4326;POINT(4.93996 35.255052)'::geometry, ST_Transform('SRID=4326;POINT(4.93996 35.255052)'::geometry, 3857)), +(877, 'SRID=4326;POINT(4.940408 35.255539)'::geometry, ST_Transform('SRID=4326;POINT(4.940408 35.255539)'::geometry, 3857)), +(878, 'SRID=4326;POINT(4.940393 35.25571)'::geometry, ST_Transform('SRID=4326;POINT(4.940393 35.25571)'::geometry, 3857)), +(879, 'SRID=4326;POINT(4.940594 35.255653)'::geometry, ST_Transform('SRID=4326;POINT(4.940594 35.255653)'::geometry, 3857)), +(880, 'SRID=4326;POINT(4.940249 35.255422)'::geometry, ST_Transform('SRID=4326;POINT(4.940249 35.255422)'::geometry, 3857)), +(881, 'SRID=4326;POINT(4.940547 35.255623)'::geometry, ST_Transform('SRID=4326;POINT(4.940547 35.255623)'::geometry, 3857)), +(882, 'SRID=4326;POINT(4.940604 35.255766)'::geometry, ST_Transform('SRID=4326;POINT(4.940604 35.255766)'::geometry, 3857)), +(883, 'SRID=4326;POINT(-4.361161 35.792722)'::geometry, ST_Transform('SRID=4326;POINT(-4.361161 35.792722)'::geometry, 3857)), +(884, 'SRID=4326;POINT(-4.361616 35.792782)'::geometry, ST_Transform('SRID=4326;POINT(-4.361616 35.792782)'::geometry, 3857)), +(885, 'SRID=4326;POINT(-4.361326 35.793018)'::geometry, ST_Transform('SRID=4326;POINT(-4.361326 35.793018)'::geometry, 3857)), +(886, 'SRID=4326;POINT(-4.361662 35.793089)'::geometry, ST_Transform('SRID=4326;POINT(-4.361662 35.793089)'::geometry, 3857)), +(887, 'SRID=4326;POINT(-4.360844 35.793344)'::geometry, ST_Transform('SRID=4326;POINT(-4.360844 35.793344)'::geometry, 3857)), +(888, 'SRID=4326;POINT(-4.360797 35.792963)'::geometry, ST_Transform('SRID=4326;POINT(-4.360797 35.792963)'::geometry, 3857)), +(889, 'SRID=4326;POINT(-4.361643 35.792646)'::geometry, ST_Transform('SRID=4326;POINT(-4.361643 35.792646)'::geometry, 3857)), +(890, 'SRID=4326;POINT(-4.361294 35.792786)'::geometry, ST_Transform('SRID=4326;POINT(-4.361294 35.792786)'::geometry, 3857)), +(891, 'SRID=4326;POINT(-4.361255 35.792726)'::geometry, ST_Transform('SRID=4326;POINT(-4.361255 35.792726)'::geometry, 3857)), +(892, 'SRID=4326;POINT(-4.361299 35.793037)'::geometry, ST_Transform('SRID=4326;POINT(-4.361299 35.793037)'::geometry, 3857)), +(893, 'SRID=4326;POINT(-4.360759 35.793348)'::geometry, ST_Transform('SRID=4326;POINT(-4.360759 35.793348)'::geometry, 3857)), +(894, 'SRID=4326;POINT(-4.361492 35.792563)'::geometry, ST_Transform('SRID=4326;POINT(-4.361492 35.792563)'::geometry, 3857)), +(895, 'SRID=4326;POINT(-4.361138 35.792639)'::geometry, ST_Transform('SRID=4326;POINT(-4.361138 35.792639)'::geometry, 3857)), +(896, 'SRID=4326;POINT(-4.361626 35.793258)'::geometry, ST_Transform('SRID=4326;POINT(-4.361626 35.793258)'::geometry, 3857)), +(897, 'SRID=4326;POINT(-4.361442 35.792772)'::geometry, ST_Transform('SRID=4326;POINT(-4.361442 35.792772)'::geometry, 3857)), +(898, 'SRID=4326;POINT(9.523596 36.520863)'::geometry, ST_Transform('SRID=4326;POINT(9.523596 36.520863)'::geometry, 3857)), +(899, 'SRID=4326;POINT(9.524498 36.520605)'::geometry, ST_Transform('SRID=4326;POINT(9.524498 36.520605)'::geometry, 3857)), +(900, 'SRID=4326;POINT(9.524193 36.520504)'::geometry, ST_Transform('SRID=4326;POINT(9.524193 36.520504)'::geometry, 3857)), +(901, 'SRID=4326;POINT(9.523808 36.520676)'::geometry, ST_Transform('SRID=4326;POINT(9.523808 36.520676)'::geometry, 3857)), +(902, 'SRID=4326;POINT(9.523765 36.520077)'::geometry, ST_Transform('SRID=4326;POINT(9.523765 36.520077)'::geometry, 3857)), +(903, 'SRID=4326;POINT(9.524111 36.52008)'::geometry, ST_Transform('SRID=4326;POINT(9.524111 36.52008)'::geometry, 3857)), +(904, 'SRID=4326;POINT(9.523609 36.520475)'::geometry, ST_Transform('SRID=4326;POINT(9.523609 36.520475)'::geometry, 3857)), +(905, 'SRID=4326;POINT(9.523761 36.520034)'::geometry, ST_Transform('SRID=4326;POINT(9.523761 36.520034)'::geometry, 3857)), +(906, 'SRID=4326;POINT(2.691972 39.13515)'::geometry, ST_Transform('SRID=4326;POINT(2.691972 39.13515)'::geometry, 3857)), +(907, 'SRID=4326;POINT(2.692015 39.135473)'::geometry, ST_Transform('SRID=4326;POINT(2.692015 39.135473)'::geometry, 3857)), +(908, 'SRID=4326;POINT(2.691972 39.135047)'::geometry, ST_Transform('SRID=4326;POINT(2.691972 39.135047)'::geometry, 3857)), +(909, 'SRID=4326;POINT(2.692026 39.135081)'::geometry, ST_Transform('SRID=4326;POINT(2.692026 39.135081)'::geometry, 3857)), +(910, 'SRID=4326;POINT(0.008581 37.840553)'::geometry, ST_Transform('SRID=4326;POINT(0.008581 37.840553)'::geometry, 3857)), +(911, 'SRID=4326;POINT(0.008625 37.840396)'::geometry, ST_Transform('SRID=4326;POINT(0.008625 37.840396)'::geometry, 3857)), +(912, 'SRID=4326;POINT(0.00866 37.840515)'::geometry, ST_Transform('SRID=4326;POINT(0.00866 37.840515)'::geometry, 3857)), +(913, 'SRID=4326;POINT(0.008149 37.840567)'::geometry, ST_Transform('SRID=4326;POINT(0.008149 37.840567)'::geometry, 3857)), +(914, 'SRID=4326;POINT(0.008371 37.840179)'::geometry, ST_Transform('SRID=4326;POINT(0.008371 37.840179)'::geometry, 3857)), +(915, 'SRID=4326;POINT(0.008235 37.840314)'::geometry, ST_Transform('SRID=4326;POINT(0.008235 37.840314)'::geometry, 3857)), +(916, 'SRID=4326;POINT(0.008591 37.840371)'::geometry, ST_Transform('SRID=4326;POINT(0.008591 37.840371)'::geometry, 3857)), +(917, 'SRID=4326;POINT(0.007883 37.840346)'::geometry, ST_Transform('SRID=4326;POINT(0.007883 37.840346)'::geometry, 3857)), +(918, 'SRID=4326;POINT(0.007834 37.841039)'::geometry, ST_Transform('SRID=4326;POINT(0.007834 37.841039)'::geometry, 3857)), +(919, 'SRID=4326;POINT(-3.502093 32.72715)'::geometry, ST_Transform('SRID=4326;POINT(-3.502093 32.72715)'::geometry, 3857)), +(920, 'SRID=4326;POINT(-3.502619 32.726865)'::geometry, ST_Transform('SRID=4326;POINT(-3.502619 32.726865)'::geometry, 3857)), +(921, 'SRID=4326;POINT(-3.501994 32.726925)'::geometry, ST_Transform('SRID=4326;POINT(-3.501994 32.726925)'::geometry, 3857)), +(922, 'SRID=4326;POINT(-3.502067 32.726896)'::geometry, ST_Transform('SRID=4326;POINT(-3.502067 32.726896)'::geometry, 3857)), +(923, 'SRID=4326;POINT(-3.501996 32.727402)'::geometry, ST_Transform('SRID=4326;POINT(-3.501996 32.727402)'::geometry, 3857)), +(924, 'SRID=4326;POINT(-3.502351 32.727182)'::geometry, ST_Transform('SRID=4326;POINT(-3.502351 32.727182)'::geometry, 3857)), +(925, 'SRID=4326;POINT(-3.502569 32.727488)'::geometry, ST_Transform('SRID=4326;POINT(-3.502569 32.727488)'::geometry, 3857)), +(926, 'SRID=4326;POINT(-3.502554 32.727055)'::geometry, ST_Transform('SRID=4326;POINT(-3.502554 32.727055)'::geometry, 3857)), +(927, 'SRID=4326;POINT(-3.501757 32.726911)'::geometry, ST_Transform('SRID=4326;POINT(-3.501757 32.726911)'::geometry, 3857)), +(928, 'SRID=4326;POINT(-3.501867 32.7268)'::geometry, ST_Transform('SRID=4326;POINT(-3.501867 32.7268)'::geometry, 3857)), +(929, 'SRID=4326;POINT(-4.517406 37.456378)'::geometry, ST_Transform('SRID=4326;POINT(-4.517406 37.456378)'::geometry, 3857)), +(930, 'SRID=4326;POINT(-4.516774 37.456898)'::geometry, ST_Transform('SRID=4326;POINT(-4.516774 37.456898)'::geometry, 3857)), +(931, 'SRID=4326;POINT(-4.517543 37.456407)'::geometry, ST_Transform('SRID=4326;POINT(-4.517543 37.456407)'::geometry, 3857)), +(932, 'SRID=4326;POINT(-4.517597 37.456574)'::geometry, ST_Transform('SRID=4326;POINT(-4.517597 37.456574)'::geometry, 3857)), +(933, 'SRID=4326;POINT(-4.516927 37.456282)'::geometry, ST_Transform('SRID=4326;POINT(-4.516927 37.456282)'::geometry, 3857)), +(934, 'SRID=4326;POINT(-4.517612 37.456792)'::geometry, ST_Transform('SRID=4326;POINT(-4.517612 37.456792)'::geometry, 3857)), +(935, 'SRID=4326;POINT(-4.516852 37.456605)'::geometry, ST_Transform('SRID=4326;POINT(-4.516852 37.456605)'::geometry, 3857)), +(936, 'SRID=4326;POINT(-4.51704 37.456707)'::geometry, ST_Transform('SRID=4326;POINT(-4.51704 37.456707)'::geometry, 3857)), +(937, 'SRID=4326;POINT(-4.517468 37.456538)'::geometry, ST_Transform('SRID=4326;POINT(-4.517468 37.456538)'::geometry, 3857)), +(938, 'SRID=4326;POINT(-4.51699 37.456715)'::geometry, ST_Transform('SRID=4326;POINT(-4.51699 37.456715)'::geometry, 3857)), +(939, 'SRID=4326;POINT(-4.51686 37.45712)'::geometry, ST_Transform('SRID=4326;POINT(-4.51686 37.45712)'::geometry, 3857)), +(940, 'SRID=4326;POINT(-4.516981 37.456901)'::geometry, ST_Transform('SRID=4326;POINT(-4.516981 37.456901)'::geometry, 3857)), +(941, 'SRID=4326;POINT(-4.517565 37.45646)'::geometry, ST_Transform('SRID=4326;POINT(-4.517565 37.45646)'::geometry, 3857)), +(942, 'SRID=4326;POINT(-4.516979 37.456419)'::geometry, ST_Transform('SRID=4326;POINT(-4.516979 37.456419)'::geometry, 3857)), +(943, 'SRID=4326;POINT(-5.25281 39.208222)'::geometry, ST_Transform('SRID=4326;POINT(-5.25281 39.208222)'::geometry, 3857)), +(944, 'SRID=4326;POINT(-5.252193 39.208342)'::geometry, ST_Transform('SRID=4326;POINT(-5.252193 39.208342)'::geometry, 3857)), +(945, 'SRID=4326;POINT(-5.252944 39.208113)'::geometry, ST_Transform('SRID=4326;POINT(-5.252944 39.208113)'::geometry, 3857)), +(946, 'SRID=4326;POINT(-3.392779 38.996535)'::geometry, ST_Transform('SRID=4326;POINT(-3.392779 38.996535)'::geometry, 3857)), +(947, 'SRID=4326;POINT(-3.392354 38.996052)'::geometry, ST_Transform('SRID=4326;POINT(-3.392354 38.996052)'::geometry, 3857)), +(948, 'SRID=4326;POINT(-3.392873 38.996805)'::geometry, ST_Transform('SRID=4326;POINT(-3.392873 38.996805)'::geometry, 3857)), +(949, 'SRID=4326;POINT(7.450684 31.45342)'::geometry, ST_Transform('SRID=4326;POINT(7.450684 31.45342)'::geometry, 3857)), +(950, 'SRID=4326;POINT(7.451103 31.453188)'::geometry, ST_Transform('SRID=4326;POINT(7.451103 31.453188)'::geometry, 3857)), +(951, 'SRID=4326;POINT(7.451097 31.453074)'::geometry, ST_Transform('SRID=4326;POINT(7.451097 31.453074)'::geometry, 3857)), +(952, 'SRID=4326;POINT(7.451434 31.453789)'::geometry, ST_Transform('SRID=4326;POINT(7.451434 31.453789)'::geometry, 3857)), +(953, 'SRID=4326;POINT(7.451138 31.453362)'::geometry, ST_Transform('SRID=4326;POINT(7.451138 31.453362)'::geometry, 3857)), +(954, 'SRID=4326;POINT(7.450761 31.453573)'::geometry, ST_Transform('SRID=4326;POINT(7.450761 31.453573)'::geometry, 3857)), +(955, 'SRID=4326;POINT(7.451598 31.453288)'::geometry, ST_Transform('SRID=4326;POINT(7.451598 31.453288)'::geometry, 3857)), +(956, 'SRID=4326;POINT(7.450992 31.453536)'::geometry, ST_Transform('SRID=4326;POINT(7.450992 31.453536)'::geometry, 3857)), +(957, 'SRID=4326;POINT(7.450987 31.453982)'::geometry, ST_Transform('SRID=4326;POINT(7.450987 31.453982)'::geometry, 3857)), +(958, 'SRID=4326;POINT(7.45092 31.453151)'::geometry, ST_Transform('SRID=4326;POINT(7.45092 31.453151)'::geometry, 3857)), +(959, 'SRID=4326;POINT(-5.166299 39.804795)'::geometry, ST_Transform('SRID=4326;POINT(-5.166299 39.804795)'::geometry, 3857)), +(960, 'SRID=4326;POINT(-5.166162 39.804953)'::geometry, ST_Transform('SRID=4326;POINT(-5.166162 39.804953)'::geometry, 3857)), +(961, 'SRID=4326;POINT(-5.166126 39.804703)'::geometry, ST_Transform('SRID=4326;POINT(-5.166126 39.804703)'::geometry, 3857)), +(962, 'SRID=4326;POINT(-5.166944 39.80527)'::geometry, ST_Transform('SRID=4326;POINT(-5.166944 39.80527)'::geometry, 3857)), +(963, 'SRID=4326;POINT(-5.166758 39.805624)'::geometry, ST_Transform('SRID=4326;POINT(-5.166758 39.805624)'::geometry, 3857)), +(964, 'SRID=4326;POINT(-5.166371 39.805331)'::geometry, ST_Transform('SRID=4326;POINT(-5.166371 39.805331)'::geometry, 3857)), +(965, 'SRID=4326;POINT(-5.166318 39.805433)'::geometry, ST_Transform('SRID=4326;POINT(-5.166318 39.805433)'::geometry, 3857)), +(966, 'SRID=4326;POINT(-5.166562 39.804734)'::geometry, ST_Transform('SRID=4326;POINT(-5.166562 39.804734)'::geometry, 3857)), +(967, 'SRID=4326;POINT(-5.167058 39.805388)'::geometry, ST_Transform('SRID=4326;POINT(-5.167058 39.805388)'::geometry, 3857)), +(968, 'SRID=4326;POINT(-5.166405 39.805063)'::geometry, ST_Transform('SRID=4326;POINT(-5.166405 39.805063)'::geometry, 3857)), +(969, 'SRID=4326;POINT(-5.167102 39.805551)'::geometry, ST_Transform('SRID=4326;POINT(-5.167102 39.805551)'::geometry, 3857)), +(970, 'SRID=4326;POINT(5.52788 37.61853)'::geometry, ST_Transform('SRID=4326;POINT(5.52788 37.61853)'::geometry, 3857)), +(971, 'SRID=4326;POINT(5.527105 37.618486)'::geometry, ST_Transform('SRID=4326;POINT(5.527105 37.618486)'::geometry, 3857)), +(972, 'SRID=4326;POINT(5.527643 37.618122)'::geometry, ST_Transform('SRID=4326;POINT(5.527643 37.618122)'::geometry, 3857)), +(973, 'SRID=4326;POINT(6.030142 31.306772)'::geometry, ST_Transform('SRID=4326;POINT(6.030142 31.306772)'::geometry, 3857)), +(974, 'SRID=4326;POINT(6.030499 31.306908)'::geometry, ST_Transform('SRID=4326;POINT(6.030499 31.306908)'::geometry, 3857)), +(975, 'SRID=4326;POINT(6.030614 31.307568)'::geometry, ST_Transform('SRID=4326;POINT(6.030614 31.307568)'::geometry, 3857)), +(976, 'SRID=4326;POINT(6.030637 31.306666)'::geometry, ST_Transform('SRID=4326;POINT(6.030637 31.306666)'::geometry, 3857)), +(977, 'SRID=4326;POINT(6.030282 31.307541)'::geometry, ST_Transform('SRID=4326;POINT(6.030282 31.307541)'::geometry, 3857)), +(978, 'SRID=4326;POINT(6.030282 31.306832)'::geometry, ST_Transform('SRID=4326;POINT(6.030282 31.306832)'::geometry, 3857)), +(979, 'SRID=4326;POINT(6.03011 31.306838)'::geometry, ST_Transform('SRID=4326;POINT(6.03011 31.306838)'::geometry, 3857)), +(980, 'SRID=4326;POINT(1.829057 34.422718)'::geometry, ST_Transform('SRID=4326;POINT(1.829057 34.422718)'::geometry, 3857)), +(981, 'SRID=4326;POINT(8.782734 33.24252)'::geometry, ST_Transform('SRID=4326;POINT(8.782734 33.24252)'::geometry, 3857)), +(982, 'SRID=4326;POINT(8.782245 33.24248)'::geometry, ST_Transform('SRID=4326;POINT(8.782245 33.24248)'::geometry, 3857)), +(983, 'SRID=4326;POINT(8.78309 33.242807)'::geometry, ST_Transform('SRID=4326;POINT(8.78309 33.242807)'::geometry, 3857)), +(984, 'SRID=4326;POINT(8.783052 33.24202)'::geometry, ST_Transform('SRID=4326;POINT(8.783052 33.24202)'::geometry, 3857)), +(985, 'SRID=4326;POINT(8.782844 33.24273)'::geometry, ST_Transform('SRID=4326;POINT(8.782844 33.24273)'::geometry, 3857)), +(986, 'SRID=4326;POINT(8.782231 33.242443)'::geometry, ST_Transform('SRID=4326;POINT(8.782231 33.242443)'::geometry, 3857)), +(987, 'SRID=4326;POINT(8.782856 33.24207)'::geometry, ST_Transform('SRID=4326;POINT(8.782856 33.24207)'::geometry, 3857)), +(988, 'SRID=4326;POINT(8.783088 33.242078)'::geometry, ST_Transform('SRID=4326;POINT(8.783088 33.242078)'::geometry, 3857)), +(989, 'SRID=4326;POINT(8.782783 33.24224)'::geometry, ST_Transform('SRID=4326;POINT(8.782783 33.24224)'::geometry, 3857)), +(990, 'SRID=4326;POINT(8.783071 33.242071)'::geometry, ST_Transform('SRID=4326;POINT(8.783071 33.242071)'::geometry, 3857)), +(991, 'SRID=4326;POINT(8.783033 33.242419)'::geometry, ST_Transform('SRID=4326;POINT(8.783033 33.242419)'::geometry, 3857)), +(992, 'SRID=4326;POINT(8.782311 33.242637)'::geometry, ST_Transform('SRID=4326;POINT(8.782311 33.242637)'::geometry, 3857)), +(993, 'SRID=4326;POINT(4.39674 36.892468)'::geometry, ST_Transform('SRID=4326;POINT(4.39674 36.892468)'::geometry, 3857)), +(994, 'SRID=4326;POINT(4.396783 36.891769)'::geometry, ST_Transform('SRID=4326;POINT(4.396783 36.891769)'::geometry, 3857)), +(995, 'SRID=4326;POINT(4.396202 36.891833)'::geometry, ST_Transform('SRID=4326;POINT(4.396202 36.891833)'::geometry, 3857)), +(996, 'SRID=4326;POINT(4.396442 36.892369)'::geometry, ST_Transform('SRID=4326;POINT(4.396442 36.892369)'::geometry, 3857)), +(997, 'SRID=4326;POINT(4.396019 36.892199)'::geometry, ST_Transform('SRID=4326;POINT(4.396019 36.892199)'::geometry, 3857)), +(998, 'SRID=4326;POINT(4.396474 36.892466)'::geometry, ST_Transform('SRID=4326;POINT(4.396474 36.892466)'::geometry, 3857)), +(999, 'SRID=4326;POINT(4.396306 36.891886)'::geometry, ST_Transform('SRID=4326;POINT(4.396306 36.891886)'::geometry, 3857)), +(1000, 'SRID=4326;POINT(4.396362 36.89161)'::geometry, ST_Transform('SRID=4326;POINT(4.396362 36.89161)'::geometry, 3857)), +(1001, 'SRID=4326;POINT(-3.025791 39.730985)'::geometry, ST_Transform('SRID=4326;POINT(-3.025791 39.730985)'::geometry, 3857)), +(1002, 'SRID=4326;POINT(-3.025076 39.731156)'::geometry, ST_Transform('SRID=4326;POINT(-3.025076 39.731156)'::geometry, 3857)), +(1003, 'SRID=4326;POINT(-3.025444 39.731737)'::geometry, ST_Transform('SRID=4326;POINT(-3.025444 39.731737)'::geometry, 3857)), +(1004, 'SRID=4326;POINT(-3.025222 39.731439)'::geometry, ST_Transform('SRID=4326;POINT(-3.025222 39.731439)'::geometry, 3857)), +(1005, 'SRID=4326;POINT(-3.025759 39.731847)'::geometry, ST_Transform('SRID=4326;POINT(-3.025759 39.731847)'::geometry, 3857)), +(1006, 'SRID=4326;POINT(-3.025799 39.731368)'::geometry, ST_Transform('SRID=4326;POINT(-3.025799 39.731368)'::geometry, 3857)), +(1007, 'SRID=4326;POINT(3.297084 30.775964)'::geometry, ST_Transform('SRID=4326;POINT(3.297084 30.775964)'::geometry, 3857)), +(1008, 'SRID=4326;POINT(3.297041 30.775622)'::geometry, ST_Transform('SRID=4326;POINT(3.297041 30.775622)'::geometry, 3857)), +(1009, 'SRID=4326;POINT(3.297415 30.775269)'::geometry, ST_Transform('SRID=4326;POINT(3.297415 30.775269)'::geometry, 3857)), +(1010, 'SRID=4326;POINT(3.296819 30.775614)'::geometry, ST_Transform('SRID=4326;POINT(3.296819 30.775614)'::geometry, 3857)), +(1011, 'SRID=4326;POINT(1.946867 38.568477)'::geometry, ST_Transform('SRID=4326;POINT(1.946867 38.568477)'::geometry, 3857)), +(1012, 'SRID=4326;POINT(1.94724 38.568368)'::geometry, ST_Transform('SRID=4326;POINT(1.94724 38.568368)'::geometry, 3857)), +(1013, 'SRID=4326;POINT(1.946641 38.568434)'::geometry, ST_Transform('SRID=4326;POINT(1.946641 38.568434)'::geometry, 3857)), +(1014, 'SRID=4326;POINT(1.946387 38.568415)'::geometry, ST_Transform('SRID=4326;POINT(1.946387 38.568415)'::geometry, 3857)), +(1015, 'SRID=4326;POINT(1.947139 38.568329)'::geometry, ST_Transform('SRID=4326;POINT(1.947139 38.568329)'::geometry, 3857)), +(1016, 'SRID=4326;POINT(1.947311 38.568084)'::geometry, ST_Transform('SRID=4326;POINT(1.947311 38.568084)'::geometry, 3857)), +(1017, 'SRID=4326;POINT(1.946555 38.5683)'::geometry, ST_Transform('SRID=4326;POINT(1.946555 38.5683)'::geometry, 3857)), +(1018, 'SRID=4326;POINT(1.946498 38.568167)'::geometry, ST_Transform('SRID=4326;POINT(1.946498 38.568167)'::geometry, 3857)), +(1019, 'SRID=4326;POINT(3.078254 39.32079)'::geometry, ST_Transform('SRID=4326;POINT(3.078254 39.32079)'::geometry, 3857)), +(1020, 'SRID=4326;POINT(3.07886 39.321409)'::geometry, ST_Transform('SRID=4326;POINT(3.07886 39.321409)'::geometry, 3857)), +(1021, 'SRID=4326;POINT(3.078319 39.32066)'::geometry, ST_Transform('SRID=4326;POINT(3.078319 39.32066)'::geometry, 3857)), +(1022, 'SRID=4326;POINT(3.078967 39.321233)'::geometry, ST_Transform('SRID=4326;POINT(3.078967 39.321233)'::geometry, 3857)), +(1023, 'SRID=4326;POINT(3.079088 39.321035)'::geometry, ST_Transform('SRID=4326;POINT(3.079088 39.321035)'::geometry, 3857)), +(1024, 'SRID=4326;POINT(3.078989 39.32099)'::geometry, ST_Transform('SRID=4326;POINT(3.078989 39.32099)'::geometry, 3857)), +(1025, 'SRID=4326;POINT(-4.467508 33.62169)'::geometry, ST_Transform('SRID=4326;POINT(-4.467508 33.62169)'::geometry, 3857)), +(1026, 'SRID=4326;POINT(-4.467668 33.621298)'::geometry, ST_Transform('SRID=4326;POINT(-4.467668 33.621298)'::geometry, 3857)), +(1027, 'SRID=4326;POINT(-4.467722 33.621318)'::geometry, ST_Transform('SRID=4326;POINT(-4.467722 33.621318)'::geometry, 3857)), +(1028, 'SRID=4326;POINT(-4.467164 33.621939)'::geometry, ST_Transform('SRID=4326;POINT(-4.467164 33.621939)'::geometry, 3857)), +(1029, 'SRID=4326;POINT(-4.467144 33.621807)'::geometry, ST_Transform('SRID=4326;POINT(-4.467144 33.621807)'::geometry, 3857)), +(1030, 'SRID=4326;POINT(-4.467366 33.621429)'::geometry, ST_Transform('SRID=4326;POINT(-4.467366 33.621429)'::geometry, 3857)), +(1031, 'SRID=4326;POINT(-4.467878 33.622214)'::geometry, ST_Transform('SRID=4326;POINT(-4.467878 33.622214)'::geometry, 3857)), +(1032, 'SRID=4326;POINT(-4.467818 33.621395)'::geometry, ST_Transform('SRID=4326;POINT(-4.467818 33.621395)'::geometry, 3857)), +(1033, 'SRID=4326;POINT(-4.467505 33.621982)'::geometry, ST_Transform('SRID=4326;POINT(-4.467505 33.621982)'::geometry, 3857)), +(1034, 'SRID=4326;POINT(-4.467095 33.622136)'::geometry, ST_Transform('SRID=4326;POINT(-4.467095 33.622136)'::geometry, 3857)), +(1035, 'SRID=4326;POINT(-4.467018 33.62219)'::geometry, ST_Transform('SRID=4326;POINT(-4.467018 33.62219)'::geometry, 3857)), +(1036, 'SRID=4326;POINT(-9.386335 38.537964)'::geometry, ST_Transform('SRID=4326;POINT(-9.386335 38.537964)'::geometry, 3857)), +(1037, 'SRID=4326;POINT(-9.387058 38.537527)'::geometry, ST_Transform('SRID=4326;POINT(-9.387058 38.537527)'::geometry, 3857)), +(1038, 'SRID=4326;POINT(-9.386532 38.538384)'::geometry, ST_Transform('SRID=4326;POINT(-9.386532 38.538384)'::geometry, 3857)), +(1039, 'SRID=4326;POINT(-9.386851 38.538101)'::geometry, ST_Transform('SRID=4326;POINT(-9.386851 38.538101)'::geometry, 3857)), +(1040, 'SRID=4326;POINT(-9.38632 38.538314)'::geometry, ST_Transform('SRID=4326;POINT(-9.38632 38.538314)'::geometry, 3857)), +(1041, 'SRID=4326;POINT(1.724469 36.566868)'::geometry, ST_Transform('SRID=4326;POINT(1.724469 36.566868)'::geometry, 3857)), +(1042, 'SRID=4326;POINT(1.724216 36.567273)'::geometry, ST_Transform('SRID=4326;POINT(1.724216 36.567273)'::geometry, 3857)), +(1043, 'SRID=4326;POINT(1.725133 36.56699)'::geometry, ST_Transform('SRID=4326;POINT(1.725133 36.56699)'::geometry, 3857)), +(1044, 'SRID=4326;POINT(1.72427 36.566541)'::geometry, ST_Transform('SRID=4326;POINT(1.72427 36.566541)'::geometry, 3857)), +(1045, 'SRID=4326;POINT(1.724579 36.566727)'::geometry, ST_Transform('SRID=4326;POINT(1.724579 36.566727)'::geometry, 3857)), +(1046, 'SRID=4326;POINT(1.724377 36.566944)'::geometry, ST_Transform('SRID=4326;POINT(1.724377 36.566944)'::geometry, 3857)), +(1047, 'SRID=4326;POINT(1.724544 36.566997)'::geometry, ST_Transform('SRID=4326;POINT(1.724544 36.566997)'::geometry, 3857)), +(1048, 'SRID=4326;POINT(1.725159 36.567219)'::geometry, ST_Transform('SRID=4326;POINT(1.725159 36.567219)'::geometry, 3857)), +(1049, 'SRID=4326;POINT(1.724639 36.567126)'::geometry, ST_Transform('SRID=4326;POINT(1.724639 36.567126)'::geometry, 3857)), +(1050, 'SRID=4326;POINT(1.724887 36.566844)'::geometry, ST_Transform('SRID=4326;POINT(1.724887 36.566844)'::geometry, 3857)), +(1051, 'SRID=4326;POINT(1.7245 36.566783)'::geometry, ST_Transform('SRID=4326;POINT(1.7245 36.566783)'::geometry, 3857)), +(1052, 'SRID=4326;POINT(1.725173 36.566542)'::geometry, ST_Transform('SRID=4326;POINT(1.725173 36.566542)'::geometry, 3857)), +(1053, 'SRID=4326;POINT(-1.215975 32.547197)'::geometry, ST_Transform('SRID=4326;POINT(-1.215975 32.547197)'::geometry, 3857)), +(1054, 'SRID=4326;POINT(-1.215926 32.547507)'::geometry, ST_Transform('SRID=4326;POINT(-1.215926 32.547507)'::geometry, 3857)), +(1055, 'SRID=4326;POINT(-1.216752 32.546703)'::geometry, ST_Transform('SRID=4326;POINT(-1.216752 32.546703)'::geometry, 3857)), +(1056, 'SRID=4326;POINT(-1.216613 32.54718)'::geometry, ST_Transform('SRID=4326;POINT(-1.216613 32.54718)'::geometry, 3857)), +(1057, 'SRID=4326;POINT(-7.993157 37.187857)'::geometry, ST_Transform('SRID=4326;POINT(-7.993157 37.187857)'::geometry, 3857)), +(1058, 'SRID=4326;POINT(-7.992873 37.187745)'::geometry, ST_Transform('SRID=4326;POINT(-7.992873 37.187745)'::geometry, 3857)), +(1059, 'SRID=4326;POINT(-7.993091 37.18814)'::geometry, ST_Transform('SRID=4326;POINT(-7.993091 37.18814)'::geometry, 3857)), +(1060, 'SRID=4326;POINT(-7.992773 37.187507)'::geometry, ST_Transform('SRID=4326;POINT(-7.992773 37.187507)'::geometry, 3857)), +(1061, 'SRID=4326;POINT(-7.99343 37.18819)'::geometry, ST_Transform('SRID=4326;POINT(-7.99343 37.18819)'::geometry, 3857)), +(1062, 'SRID=4326;POINT(-7.992727 37.187234)'::geometry, ST_Transform('SRID=4326;POINT(-7.992727 37.187234)'::geometry, 3857)), +(1063, 'SRID=4326;POINT(-7.992672 37.188057)'::geometry, ST_Transform('SRID=4326;POINT(-7.992672 37.188057)'::geometry, 3857)), +(1064, 'SRID=4326;POINT(-7.99318 37.18763)'::geometry, ST_Transform('SRID=4326;POINT(-7.99318 37.18763)'::geometry, 3857)), +(1065, 'SRID=4326;POINT(8.900398 32.262535)'::geometry, ST_Transform('SRID=4326;POINT(8.900398 32.262535)'::geometry, 3857)), +(1066, 'SRID=4326;POINT(8.900427 32.262327)'::geometry, ST_Transform('SRID=4326;POINT(8.900427 32.262327)'::geometry, 3857)), +(1067, 'SRID=4326;POINT(8.899843 32.262289)'::geometry, ST_Transform('SRID=4326;POINT(8.899843 32.262289)'::geometry, 3857)), +(1068, 'SRID=4326;POINT(8.900334 32.261977)'::geometry, ST_Transform('SRID=4326;POINT(8.900334 32.261977)'::geometry, 3857)), +(1069, 'SRID=4326;POINT(8.900136 32.262758)'::geometry, ST_Transform('SRID=4326;POINT(8.900136 32.262758)'::geometry, 3857)), +(1070, 'SRID=4326;POINT(8.90022 32.262509)'::geometry, ST_Transform('SRID=4326;POINT(8.90022 32.262509)'::geometry, 3857)), +(1071, 'SRID=4326;POINT(8.899751 32.262215)'::geometry, ST_Transform('SRID=4326;POINT(8.899751 32.262215)'::geometry, 3857)), +(1072, 'SRID=4326;POINT(8.900191 32.262102)'::geometry, ST_Transform('SRID=4326;POINT(8.900191 32.262102)'::geometry, 3857)), +(1073, 'SRID=4326;POINT(8.899721 32.262195)'::geometry, ST_Transform('SRID=4326;POINT(8.899721 32.262195)'::geometry, 3857)), +(1074, 'SRID=4326;POINT(8.899932 32.262497)'::geometry, ST_Transform('SRID=4326;POINT(8.899932 32.262497)'::geometry, 3857)), +(1075, 'SRID=4326;POINT(8.899968 32.262464)'::geometry, ST_Transform('SRID=4326;POINT(8.899968 32.262464)'::geometry, 3857)), +(1076, 'SRID=4326;POINT(8.899792 32.262717)'::geometry, ST_Transform('SRID=4326;POINT(8.899792 32.262717)'::geometry, 3857)), +(1077, 'SRID=4326;POINT(8.899919 32.262467)'::geometry, ST_Transform('SRID=4326;POINT(8.899919 32.262467)'::geometry, 3857)), +(1078, 'SRID=4326;POINT(8.9004 32.262731)'::geometry, ST_Transform('SRID=4326;POINT(8.9004 32.262731)'::geometry, 3857)), +(1079, 'SRID=4326;POINT(8.900461 32.262179)'::geometry, ST_Transform('SRID=4326;POINT(8.900461 32.262179)'::geometry, 3857)), +(1080, 'SRID=4326;POINT(8.900539 32.262052)'::geometry, ST_Transform('SRID=4326;POINT(8.900539 32.262052)'::geometry, 3857)), +(1081, 'SRID=4326;POINT(4.408361 39.427357)'::geometry, ST_Transform('SRID=4326;POINT(4.408361 39.427357)'::geometry, 3857)), +(1082, 'SRID=4326;POINT(4.409058 39.42786)'::geometry, ST_Transform('SRID=4326;POINT(4.409058 39.42786)'::geometry, 3857)), +(1083, 'SRID=4326;POINT(4.4091 39.427155)'::geometry, ST_Transform('SRID=4326;POINT(4.4091 39.427155)'::geometry, 3857)), +(1084, 'SRID=4326;POINT(4.408596 39.427209)'::geometry, ST_Transform('SRID=4326;POINT(4.408596 39.427209)'::geometry, 3857)), +(1085, 'SRID=4326;POINT(4.40852 39.427486)'::geometry, ST_Transform('SRID=4326;POINT(4.40852 39.427486)'::geometry, 3857)), +(1086, 'SRID=4326;POINT(4.408387 39.427188)'::geometry, ST_Transform('SRID=4326;POINT(4.408387 39.427188)'::geometry, 3857)), +(1087, 'SRID=4326;POINT(4.408612 39.427674)'::geometry, ST_Transform('SRID=4326;POINT(4.408612 39.427674)'::geometry, 3857)), +(1088, 'SRID=4326;POINT(4.408695 39.427922)'::geometry, ST_Transform('SRID=4326;POINT(4.408695 39.427922)'::geometry, 3857)), +(1089, 'SRID=4326;POINT(4.408693 39.427178)'::geometry, ST_Transform('SRID=4326;POINT(4.408693 39.427178)'::geometry, 3857)), +(1090, 'SRID=4326;POINT(4.408216 39.427706)'::geometry, ST_Transform('SRID=4326;POINT(4.408216 39.427706)'::geometry, 3857)), +(1091, 'SRID=4326;POINT(4.408435 39.427732)'::geometry, ST_Transform('SRID=4326;POINT(4.408435 39.427732)'::geometry, 3857)), +(1092, 'SRID=4326;POINT(4.408737 39.42783)'::geometry, ST_Transform('SRID=4326;POINT(4.408737 39.42783)'::geometry, 3857)), +(1093, 'SRID=4326;POINT(4.408624 39.427073)'::geometry, ST_Transform('SRID=4326;POINT(4.408624 39.427073)'::geometry, 3857)), +(1094, 'SRID=4326;POINT(4.408561 39.427638)'::geometry, ST_Transform('SRID=4326;POINT(4.408561 39.427638)'::geometry, 3857)), +(1095, 'SRID=4326;POINT(4.408244 39.427218)'::geometry, ST_Transform('SRID=4326;POINT(4.408244 39.427218)'::geometry, 3857)), +(1096, 'SRID=4326;POINT(4.408828 39.427396)'::geometry, ST_Transform('SRID=4326;POINT(4.408828 39.427396)'::geometry, 3857)), +(1097, 'SRID=4326;POINT(3.576089 38.267499)'::geometry, ST_Transform('SRID=4326;POINT(3.576089 38.267499)'::geometry, 3857)), +(1098, 'SRID=4326;POINT(3.575583 38.267731)'::geometry, ST_Transform('SRID=4326;POINT(3.575583 38.267731)'::geometry, 3857)), +(1099, 'SRID=4326;POINT(3.576442 38.267889)'::geometry, ST_Transform('SRID=4326;POINT(3.576442 38.267889)'::geometry, 3857)), +(1100, 'SRID=4326;POINT(3.576552 38.267045)'::geometry, ST_Transform('SRID=4326;POINT(3.576552 38.267045)'::geometry, 3857)), +(1101, 'SRID=4326;POINT(3.576473 38.267962)'::geometry, ST_Transform('SRID=4326;POINT(3.576473 38.267962)'::geometry, 3857)), +(1102, 'SRID=4326;POINT(3.576205 38.267778)'::geometry, ST_Transform('SRID=4326;POINT(3.576205 38.267778)'::geometry, 3857)), +(1103, 'SRID=4326;POINT(3.575928 38.267777)'::geometry, ST_Transform('SRID=4326;POINT(3.575928 38.267777)'::geometry, 3857)), +(1104, 'SRID=4326;POINT(3.575696 38.267961)'::geometry, ST_Transform('SRID=4326;POINT(3.575696 38.267961)'::geometry, 3857)), +(1105, 'SRID=4326;POINT(3.57577 38.267063)'::geometry, ST_Transform('SRID=4326;POINT(3.57577 38.267063)'::geometry, 3857)), +(1106, 'SRID=4326;POINT(5.456027 39.062911)'::geometry, ST_Transform('SRID=4326;POINT(5.456027 39.062911)'::geometry, 3857)), +(1107, 'SRID=4326;POINT(5.456313 39.063416)'::geometry, ST_Transform('SRID=4326;POINT(5.456313 39.063416)'::geometry, 3857)), +(1108, 'SRID=4326;POINT(5.455901 39.063434)'::geometry, ST_Transform('SRID=4326;POINT(5.455901 39.063434)'::geometry, 3857)), +(1109, 'SRID=4326;POINT(5.455573 39.06381)'::geometry, ST_Transform('SRID=4326;POINT(5.455573 39.06381)'::geometry, 3857)), +(1110, 'SRID=4326;POINT(5.45574 39.063318)'::geometry, ST_Transform('SRID=4326;POINT(5.45574 39.063318)'::geometry, 3857)), +(1111, 'SRID=4326;POINT(-1.544808 33.33398)'::geometry, ST_Transform('SRID=4326;POINT(-1.544808 33.33398)'::geometry, 3857)), +(1112, 'SRID=4326;POINT(-1.544993 33.333714)'::geometry, ST_Transform('SRID=4326;POINT(-1.544993 33.333714)'::geometry, 3857)), +(1113, 'SRID=4326;POINT(-1.544859 33.333711)'::geometry, ST_Transform('SRID=4326;POINT(-1.544859 33.333711)'::geometry, 3857)), +(1114, 'SRID=4326;POINT(-1.544863 33.334479)'::geometry, ST_Transform('SRID=4326;POINT(-1.544863 33.334479)'::geometry, 3857)); +-- polygons table +CREATE TABLE polyg_t (cartodb_id integer, name text, the_geom geometry, the_geom_webmercator geometry); +INSERT INTO polyg_t VALUES +(1, 'A', 'SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, ST_Transform('SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, 3857)), +(2, 'B', 'SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, ST_Transform('SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, 3857)), +(3, 'C', 'SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, ST_Transform('SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, 3857)), +(4, 'D', 'SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, ST_Transform('SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, 3857)), +(5, 'E', 'SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, ST_Transform('SRID=4326;POLYGON((9 40,8 39,8.5 40,9 41,9 40))'::geometry, 3857)); + +CREATE TABLE column_types_t +AS SELECT cartodb_id, + the_geom, + the_geom_webmercator, + (CASE cartodb_id % 2 WHEN 0 THEN 'f' ELSE 't' END)::boolean AS is_odd +FROM base_bare_t; diff --git a/lib/sql/test/overviews/gen_points.rb b/lib/sql/test/overviews/gen_points.rb new file mode 100644 index 0000000..85cf622 --- /dev/null +++ b/lib/sql/test/overviews/gen_points.rb @@ -0,0 +1,43 @@ +# Ruby script to generate test/overviews/fixtures.sql for testing overviews +# Generated tables: +# * base_bare_t -- points without attributes (only PK, geometries) + +NUM_CLUSTERS = 128 +MAX_PER_CLUSTER = 16 +CLUSTER_RADIUS = 1E-3 +MIN_X = -10.0 +MAX_X = 10.0 +MIN_Y = 30.0 +MAX_Y = 40.0 +ATTRIBUTES = "number double precision, int_number integer, name text, start date" + +id = 0 +POINTS = (0...NUM_CLUSTERS).map{ + x = MIN_X + rand()*(MAX_X - MIN_X) + y = MIN_Y + rand()*(MAX_Y - MIN_Y) + (0..rand(MAX_PER_CLUSTER)).map{ + id += 1 + { + id: id, + x: (x + rand()*CLUSTER_RADIUS).round(6), + y: (y + rand()*CLUSTER_RADIUS).round(6) + } + } +}.flatten + +values = POINTS.map{ |point| + "#{point[:id]}, 'SRID=4326;POINT(#{point[:x]} #{point[:y]})'::geometry, ST_Transform('SRID=4326;POINT(#{point[:x]} #{point[:y]})'::geometry, 3857)" +} + +File.open('fixtures.sql', 'w') do |sql| + + sql.puts "-- bare table with no attribute columns" + sql.puts "CREATE TABLE base_bare_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry);" + sql.puts "INSERT INTO base_bare_t VALUES" + sql.puts values.map{|v| "(#{v})"}.join(",\n") + ";" + + sql.puts "-- table with attributes" + sql.puts "CREATE TABLE base_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry, #{ATTRIBUTES});" + sql.puts "INSERT INTO base_t VALUES" + sql.puts values.map{|v| "(#{v})"}.join(",\n") + ";" +end diff --git a/lib/sql/test/perf/CDB_HexagonGridPerf.sql b/lib/sql/test/perf/CDB_HexagonGridPerf.sql new file mode 100644 index 0000000..7557d8c --- /dev/null +++ b/lib/sql/test/perf/CDB_HexagonGridPerf.sql @@ -0,0 +1,6 @@ +-- 25690 cells covering full webmercator extent +-- real 0m9.448s -- as of e0e76843f785a420c277a6fb2f762601570ffb98 +-- real 0m0.243s -- as of 50c487b83837e4d5216fcc19d637dd8db6baa44a + +SELECT count(*) FROM ( + SELECT CDB_HexagonGrid(ST_MakeEnvelope(-20194051, -20194051, 20194051, 20194051), 156543) ) f; diff --git a/lib/sql/test/perf/CDB_TransformToWebmercatorPerf.sql b/lib/sql/test/perf/CDB_TransformToWebmercatorPerf.sql new file mode 100644 index 0000000..6f24b68 --- /dev/null +++ b/lib/sql/test/perf/CDB_TransformToWebmercatorPerf.sql @@ -0,0 +1,16 @@ +-- Run psql with -tA switches and expect +-- CDB_TransformToWebmercatorTest_expect +select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;LINESTRING(90 90, 0 80)'), 1)); +select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;LINESTRING(90 90, 0 90)'), 1)); +select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;POINT(0 90)'), 1)); +select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1)); +select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTIPOINT(10 3)'), 1)); +select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1)); +select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( + 'SRID=4326;POINT(5 3)'), 1)); diff --git a/lib/sql/util/create_from_unpackaged.sh b/lib/sql/util/create_from_unpackaged.sh new file mode 100755 index 0000000..109c9ae --- /dev/null +++ b/lib/sql/util/create_from_unpackaged.sh @@ -0,0 +1,77 @@ +#!/bin/sh + +ver=$1 +input=cartodb--${ver}.sql +output=cartodb--unpackaged--${ver}.sql + +echo "-- Script generated by $0 on `date`" > ${output} + +# Migrate CDB functions from public schema to cartodb schema +cat ${input} | + grep '^ *CREATE OR REPLACE FUNCTION' | + grep -v ' cartodb\.' | # should only match DDL hooks + sed 's/).*$/)/' | + sed 's/DEFAULT [^ ,)]*//g' | + sed 's/CREATE OR REPLACE FUNCTION /ALTER FUNCTION public./' | + sed 's/$/ SET SCHEMA cartodb;/' | + sed 's/^/DO LANGUAGE plpgsql \$\$ BEGIN /' | + sed "s/$/ EXCEPTION WHEN OTHERS THEN RAISE NOTICE 'Got % (%)', SQLERRM, SQLSTATE; END; \$\$;/" | + cat >> ${output} + +# Upgrade all functions +cat ${input} | grep -v 'duplicated extension$' >> ${output} + +# Migrate CDB_TableMetadata +cat >> ${output} <<'EOF' +ALTER TABLE cartodb.CDB_TableMetadata DISABLE TRIGGER ALL; +INSERT INTO cartodb.CDB_TableMetadata SELECT * FROM public.CDB_TableMetadata; +ALTER TABLE cartodb.CDB_TableMetadata ENABLE TRIGGER ALL; +DROP TABLE public.CDB_TableMetadata; + +-- Set user quota +-- NOTE: will fail if user quota wasn't set at database level, see +-- http://github.com/CartoDB/cartodb-postgresql/issues/18 +DO $$ +DECLARE + qmax int8; +BEGIN + BEGIN + qmax := public._CDB_UserQuotaInBytes(); + EXCEPTION WHEN undefined_function THEN + RAISE EXCEPTION 'Please set user quota before switching to cartodb extension'; + END; + PERFORM cartodb.CDB_SetUserQuotaInBytes(qmax); + DROP FUNCTION public._CDB_UserQuotaInBytes(); +END; +$$ LANGUAGE 'plpgsql'; +EOF + +## Cartodbfy tables with a trigger using 'CDB_CheckQuota' or +## 'CDB_TableMetadata_Trigger' from the 'public' schema +#cat >> ${output} <<'EOF' +#select cartodb.CDB_CartodbfyTable(relname::regclass) from ( +# -- names of tables using public.CDB_CheckQuota or +# -- public.CDB_TableMetadata_Trigger in their triggers +# SELECT distinct c.relname +# FROM +# pg_trigger t, +# pg_class c, +# pg_proc p, +# pg_namespace n +# WHERE +# n.nspname = 'public' AND +# p.pronamespace = n.oid AND +# p.proname IN ( 'cdb_checkquota', 'cdb_tablemetadata_trigger' ) AND +# t.tgrelid = c.oid AND +# p.oid = t.tgfoid +#) as foo; +#EOF + +## Drop any leftover function from public schema (there should be none) +#cat ${input} | +# grep '^ *CREATE OR REPLACE FUNCTION' | +# grep -v ' cartodb\.' | # should only match DDL hooks +# sed 's/).*$/);/' | +# sed 's/DEFAULT [^ ,)]*//g' | +# sed 's/CREATE OR REPLACE FUNCTION /DROP FUNCTION IF EXISTS public./' | +# cat >> ${output} diff --git a/lib/sql/util/create_upgrade.sh b/lib/sql/util/create_upgrade.sh new file mode 100755 index 0000000..8b49ceb --- /dev/null +++ b/lib/sql/util/create_upgrade.sh @@ -0,0 +1,9 @@ +#!/bin/sh + +fromver=$1 +ver=$2 +input=cartodb--${ver}.sql +output=cartodb--${fromver}--${ver}.sql + +cat ${input} | grep -v 'duplicated extension$' > ${output} +