├── .gitignore ├── .travis.yml ├── CONTRIBUTING.md ├── LICENSE ├── Makefile ├── NEWS.md ├── README.md ├── carto-package.json ├── cartodb.control.in ├── cartodb_version.sql.in ├── doc ├── CDB_ColumnNames.md ├── CDB_ColumnType.md ├── CDB_EstimateRowCount.md ├── CDB_GreatCircle.md ├── CDB_HeadsTailsBins.md ├── CDB_HexagonGrid.md ├── CDB_JenksBins.md ├── CDB_MakeHexagon.md ├── CDB_Overviews.md ├── CDB_QuantileBins.md ├── CDB_RectangleGrid.md ├── CDB_SetUserQuotaInBytes.md ├── CDB_SyncTable.md ├── CDB_TransformToWebmercator.md ├── CDB_UserTables.md ├── CDB_XYZ_Extent.md ├── CDB_XYZ_Resolution.md ├── CartoDB-PLpgSQL.md ├── CartoDB-user-table.rst ├── README.md └── cartodbfy-requirements.rst ├── expected └── test_setup.out ├── scripts-available ├── CDB_AnalysisCatalog.sql ├── CDB_AnalysisCheck.sql ├── CDB_AnalysisSupport.sql ├── CDB_CartodbfyTable.sql ├── CDB_ColumnNames.sql ├── CDB_ColumnType.sql ├── CDB_Conf.sql ├── CDB_DDLTriggers.sql ├── CDB_DateToNumber.sql ├── CDB_DigitSeparator.sql ├── CDB_DistType.sql ├── CDB_DistinctMeasure.sql ├── CDB_EqualIntervalBins.sql ├── CDB_EstimateRowCount.sql ├── CDB_ExtensionPost.sql ├── CDB_ExtensionUtils.sql ├── CDB_FederatedServer.sql ├── CDB_FederatedServerDiagnostics.sql ├── CDB_FederatedServerListRemote.sql ├── CDB_FederatedServerTables.sql ├── CDB_ForeignTable.sql ├── CDB_GhostTables.sql ├── CDB_GreatCircle.sql ├── CDB_Groups.sql ├── CDB_Groups_API.sql ├── CDB_HeadsTailsBins.sql ├── CDB_Helper.sql ├── CDB_Hexagon.sql ├── CDB_JenksBins.sql ├── CDB_LatLng.sql ├── CDB_Math.sql ├── CDB_OAuth.sql ├── CDB_Organizations.sql ├── CDB_Overviews.sql ├── CDB_OverviewsSupport.sql ├── CDB_QuantileBins.sql ├── CDB_QueryStatements.sql ├── CDB_QueryTables.sql ├── CDB_Quota.sql ├── CDB_RandomTids.sql ├── CDB_RectangleGrid.sql ├── CDB_RegenerateTable.sql ├── CDB_SearchPath.sql ├── CDB_Stats.sql ├── CDB_StringToDate.sql ├── CDB_SyncTable.sql ├── CDB_TableIndexes.sql ├── CDB_TableMetadata.sql ├── CDB_TransformToWebmercator.sql ├── CDB_UserTables.sql ├── CDB_Username.sql ├── CDB_XYZ.sql └── CDB_ZoomFromScale.sql ├── scripts-enabled ├── 000-CDB_DateToNumber.sql ├── 010-CDB_DigitSeparator.sql ├── 020-CDB_HeadsTailsBins.sql ├── 030-CDB_Hexagon.sql ├── 040-CDB_JenksBins.sql ├── 050-CDB_LatLng.sql ├── 060-CDB_QuantileBins.sql ├── 070-CDB_QueryStatements.sql ├── 080-CDB_QueryTables.sql ├── 085-CDB_OverviewsSupport.sql ├── 090-CDB_Quota.sql ├── 100-CDB_RandomTids.sql ├── 110-CDB_RectangleGrid.sql ├── 120-CDB_StringToDate.sql ├── 130-CDB_TableMetadata.sql ├── 140-CDB_TransformToWebmercator.sql ├── 150-CDB_UserTables.sql ├── 160-CDB_XYZ.sql ├── 170-CDB_ColumnNames.sql ├── 180-CDB_ColumnType.sql ├── 190-CDB_CartodbfyTable.sql ├── 200-CDB_TableIndexes.sql ├── 210-CDB_Organizations.sql ├── 220-CDB_Math.sql ├── 230-CDB_ZoomFromScale.sql ├── 240-CDB_EqualIntervalBins.sql ├── 241-CDB_GreatCircle.sql ├── 245-CDB_Overviews.sql ├── 250-CDB_ForeignTable.sql ├── 260-CDB_AnalysisCatalog.sql ├── 270-CDB_AnalysisSupport.sql ├── 275-CDB_AnalysisCheck.sql ├── 280-CDB_EstimateRowCount.sql ├── 290-CDB_GhostTables.sql ├── 300-CDB_OAuth.sql ├── 400-CDB_FederatedServer.sql ├── 401_CDB_FederatedServerTables.sql ├── 402_CDB_FederatedServerListRemote.sql ├── 403-CDB_FederatedServerDiagnostics.sql ├── 500-CDB_RegenerateTable.sql ├── 900-CDB_DDLTriggers.sql ├── 910-CDB_Conf.sql ├── 920-CDB_Username.sql ├── CDB_DistType.sql ├── CDB_DistinctMeasure.sql ├── CDB_Groups.sql ├── CDB_Groups_API.sql ├── CDB_Stats.sql └── CDB_SyncTable.sql ├── sql ├── test_setup.sql └── test_setup_expect ├── test ├── CDB_AnalysisCheckTest.sql ├── CDB_AnalysisCheckTest_expect ├── CDB_CartodbfyTableTest.sql ├── CDB_CartodbfyTableTest_expect ├── CDB_DateToNumberTest.sql ├── CDB_DateToNumberTest_expect ├── CDB_DigitSeparatorTest.sql ├── CDB_DigitSeparatorTest_expect ├── CDB_DistTypeTest.sql ├── CDB_DistTypeTest_expect ├── CDB_DistinctMeasureTest.sql ├── CDB_DistinctMeasureTest_expect ├── CDB_EqualIntervalBinsTest.sql ├── CDB_EqualIntervalBinsTest_expect ├── CDB_EstimateRowCountTest.sql ├── CDB_EstimateRowCountTest_expect ├── CDB_FederatedServer.sql ├── CDB_FederatedServerDiagnostics.sql ├── CDB_FederatedServerDiagnostics_expect ├── CDB_FederatedServerListRemote.sql ├── CDB_FederatedServerListRemote_expect ├── CDB_FederatedServerTables.sql ├── CDB_FederatedServerTables_expect ├── CDB_FederatedServer_expect ├── CDB_GhostTables.sql ├── CDB_GhostTables_expect ├── CDB_GreatCircle.sql ├── CDB_GreatCircle_expect ├── CDB_HeadsTailsBinsTest.sql ├── CDB_HeadsTailsBinsTest_expect ├── CDB_HelperTest.sql ├── CDB_HelperTest_expect ├── CDB_HexagonTest.sql ├── CDB_HexagonTest_expect ├── CDB_JenksBinsTest.sql ├── CDB_JenksBinsTest_expect ├── CDB_MathTest.sql ├── CDB_MathTest_expect ├── CDB_OAuth.sql ├── CDB_OAuth_expect ├── CDB_OverviewsTest.sql.deprecated ├── CDB_OverviewsTest_expect ├── CDB_QuantileBinsTest.sql ├── CDB_QuantileBinsTest_expect ├── CDB_QueryStatementsTest.sql ├── CDB_QueryStatementsTest_expect ├── CDB_QueryTablesTest.sql ├── CDB_QueryTablesTest_expect ├── CDB_QuotaTest.sql ├── CDB_QuotaTest_expect ├── CDB_RectangleTest.sql ├── CDB_RectangleTest_expect ├── CDB_RegenerateTable.sql ├── CDB_RegenerateTable_expect ├── CDB_StatsTest.sql ├── CDB_StatsTest_expect ├── CDB_SyncTableTest.sql ├── CDB_SyncTableTest_expect ├── CDB_TransformToWebmercatorTest.sql ├── CDB_TransformToWebmercatorTest_expect ├── CDB_UserTablesTest.sql ├── CDB_UserTablesTest_expect ├── CDB_Username.sql ├── CDB_Username_expect ├── CDB_XYZ_ExtentTest.sql ├── CDB_XYZ_ExtentTest_expect ├── Makefile ├── README ├── extension │ └── test.sh ├── organization │ └── test.sh ├── overviews │ ├── fixtures.sql │ └── gen_points.rb └── perf │ ├── CDB_HexagonGridPerf.sql │ └── CDB_TransformToWebmercatorPerf.sql └── util ├── create_from_unpackaged.sh └── create_upgrade.sh /.gitignore: -------------------------------------------------------------------------------- 1 | cartodb--*.sql 2 | cartodb_version.sql 3 | cartodb.control 4 | results/ 5 | regression.* 6 | expected/test 7 | sql/test 8 | .idea/* 9 | *.swp 10 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: c 2 | sudo: required 3 | 4 | env: 5 | global: 6 | - PGUSER=postgres 7 | - PGDATABASE=postgres 8 | - PGOPTIONS='-c client_min_messages=NOTICE' 9 | 10 | jobs: 11 | include: 12 | - env: POSTGRESQL_VERSION="11" POSTGIS_VERSION="2.5" 13 | dist: xenial 14 | - env: POSTGRESQL_VERSION="12" POSTGIS_VERSION="2.5" 15 | dist: bionic 16 | - env: POSTGRESQL_VERSION="12" POSTGIS_VERSION="3" 17 | dist: bionic 18 | - env: POSTGRESQL_VERSION="13" POSTGIS_VERSION="3" 19 | dist: bionic 20 | 21 | script: 22 | - sudo apt-get remove postgresql* -y 23 | - 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 24 | - if [[ $POSTGRESQL_VERSION == '9.6' ]]; then sudo apt-get install -y postgresql-contrib-9.6; fi; 25 | - sudo apt-get install -y --allow-unauthenticated postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION-scripts postgis 26 | # For pre12, install plpython2. For PG12 install plpython3 27 | - if [[ $POSTGRESQL_VERSION == '11' ]]; then sudo apt-get install -y postgresql-plpython-$POSTGRESQL_VERSION python python-redis; else sudo apt-get install -y postgresql-plpython3-$POSTGRESQL_VERSION python3 python3-redis; fi; 28 | - for i in $(pg_lsclusters | tail -n +2 | awk '{print $1}'); do sudo pg_dropcluster --stop $i main; done; 29 | - sudo rm -rf /etc/postgresql/$POSTGRESQL_VERSION /var/lib/postgresql/$POSTGRESQL_VERSION /var/ramfs/postgresql/$POSTGRESQL_VERSION 30 | - sudo pg_createcluster -u postgres $POSTGRESQL_VERSION main --start -- --auth-local trust --auth-host password 31 | - export PGPORT=$(pg_lsclusters | grep $POSTGRESQL_VERSION | awk '{print $3}') 32 | - make 33 | - sudo make install 34 | - make installcheck 35 | 36 | after_failure: 37 | - pg_lsclusters 38 | - cat regression.out 39 | - cat regression.diffs 40 | - echo $PGPORT 41 | - sudo cat /var/log/postgresql/postgresql-$POSTGRESQL_VERSION-main.log 42 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | The development tracker for cartodb-postgresql is on github: 2 | http://github.com/cartodb/cartodb-postgresql/ 3 | 4 | Bug fixes are best reported as pull requests over there. 5 | Features are best discussed on the mailing list: 6 | https://groups.google.com/d/forum/cartodb 7 | 8 | Adding features to the extension 9 | -------------------------------- 10 | 11 | Extension features are coded in scripts found under the 12 | "scripts-available" directory. A feature can be a single function 13 | or a group of function with a specific scope. 14 | 15 | The "scripts-enabled" directory contains symlinks to the scripts 16 | in "scripts-available". Any symlink in that directory is automatically 17 | included in the extension. Numbering can be used to enforce the order 18 | in which those scripts are loaded. 19 | 20 | Scripts would be best coded in a way to be usable both for creation 21 | and upgrade of the objects. This means using CREATE OR REPLACE for 22 | the functions, and whatever it takes to check existence of any previous 23 | version of objects in other cases. 24 | 25 | When adding a new function or modifying an exiting one make sure that the 26 | [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. 27 | 28 | 29 | Although the extension will usually be installed in the "cartodb" schema, please 30 | use @extschema@ to fully-qualify internal calls to avoid name clashes. 31 | When you use postgis functions or types, please fully-qualify them by using 32 | @postgisschema@ (it's changed to "public" by the install script) to avoid 33 | pg_upgrade issues. 34 | 35 | Every new feature (as well as bugfixes) should come with a test case, 36 | see the 'Writing testcases' section. 37 | 38 | Writing testcases 39 | ----------------- 40 | 41 | Tests reside in the test/ directory. 42 | You can find information about how to write tests in test/README 43 | 44 | Testing changes live 45 | -------------------- 46 | 47 | Testing changes made during development requires upgrading 48 | the extension into your test database. 49 | 50 | During development the cartodb extension version doesn't change with 51 | every commit, so testing latest change requires cheating with PostgreSQL 52 | as to enforce the scripts to reload. To help with cheating, "make install" 53 | also installs migration scripts to go from "V" to "V"next and from "V"next 54 | to "V". Example to upgrade a 0.2.0dev version: 55 | 56 | ```sql 57 | ALTER EXTENSION cartodb UPDATE TO '0.2.0next'; 58 | ALTER EXTENSION cartodb UPDATE TO '0.2.0dev'; 59 | ``` 60 | Starting with 0.2.0, the in-place reload can be done with an ad-hoc function: 61 | 62 | ```sql 63 | SELECT cartodb.cdb_extension_reload(); 64 | ``` 65 | 66 | A useful query: 67 | ```sql 68 | SELECT * FROM pg_extension_update_paths('cartodb') WHERE path IS NOT NULL AND source = cdb_version(); 69 | ``` 70 | 71 | ## Submitting Contributions 72 | 73 | * You will need to sign a Contributor License Agreement (CLA) before making a submission. [Learn more here](https://carto.com/contributions). 74 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2014, Vizzuality 2 | All rights reserved. 3 | 4 | Redistribution and use in source and binary forms, with or without 5 | modification, are permitted provided that the following conditions are met: 6 | 7 | 1. Redistributions of source code must retain the above copyright notice, this 8 | list of conditions and the following disclaimer. 9 | 10 | 2. Redistributions in binary form must reproduce the above copyright notice, 11 | this list of conditions and the following disclaimer in the documentation 12 | and/or other materials provided with the distribution. 13 | 14 | 3. Neither the name of the copyright holder nor the names of its contributors 15 | may be used to endorse or promote products derived from this software without 16 | specific prior written permission. 17 | 18 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 19 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 20 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 21 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 22 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 23 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 24 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 25 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 26 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 27 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 28 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # cartodb/Makefile 2 | 3 | EXTENSION = cartodb 4 | EXTVERSION = 0.37.1 5 | 6 | SED = sed 7 | AWK = awk 8 | 9 | CDBSCRIPTS = \ 10 | scripts-enabled/*.sql \ 11 | scripts-available/CDB_SearchPath.sql \ 12 | scripts-available/CDB_ExtensionPost.sql \ 13 | scripts-available/CDB_ExtensionUtils.sql \ 14 | scripts-available/CDB_Helper.sql \ 15 | $(END) 16 | 17 | UPGRADABLE = \ 18 | unpackaged \ 19 | 0.1.0 \ 20 | 0.1.1 \ 21 | 0.2.0 \ 22 | 0.2.1 \ 23 | 0.3.0 \ 24 | 0.3.0dev \ 25 | 0.3.1 \ 26 | 0.3.2 \ 27 | 0.3.3 \ 28 | 0.3.4 \ 29 | 0.3.5 \ 30 | 0.3.6 \ 31 | 0.4.0 \ 32 | 0.4.1 \ 33 | 0.5.0 \ 34 | 0.5.1 \ 35 | 0.5.2 \ 36 | 0.5.3 \ 37 | 0.6.0 \ 38 | 0.7.0 \ 39 | 0.7.1 \ 40 | 0.7.2 \ 41 | 0.7.3 \ 42 | 0.7.4 \ 43 | 0.8.0 \ 44 | 0.8.1 \ 45 | 0.8.2 \ 46 | 0.9.0 \ 47 | 0.9.1 \ 48 | 0.9.2 \ 49 | 0.9.3 \ 50 | 0.9.4 \ 51 | 0.10.0 \ 52 | 0.10.1 \ 53 | 0.10.2 \ 54 | 0.11.0 \ 55 | 0.11.1 \ 56 | 0.11.2 \ 57 | 0.11.3 \ 58 | 0.11.4 \ 59 | 0.11.5 \ 60 | 0.12.0 \ 61 | 0.13.0 \ 62 | 0.13.1 \ 63 | 0.14.0 \ 64 | 0.14.1 \ 65 | 0.14.2 \ 66 | 0.14.3 \ 67 | 0.14.4 \ 68 | 0.15.0 \ 69 | 0.15.1 \ 70 | 0.16.0 \ 71 | 0.16.1 \ 72 | 0.16.2 \ 73 | 0.16.3 \ 74 | 0.16.4 \ 75 | 0.17.0 \ 76 | 0.17.1 \ 77 | 0.18.0 \ 78 | 0.18.1 \ 79 | 0.18.2 \ 80 | 0.18.3 \ 81 | 0.18.4 \ 82 | 0.18.5 \ 83 | 0.19.0 \ 84 | 0.19.1 \ 85 | 0.19.2 \ 86 | 0.20.0 \ 87 | 0.21.0 \ 88 | 0.22.0 \ 89 | 0.22.1 \ 90 | 0.22.2 \ 91 | 0.23.0 \ 92 | 0.23.1 \ 93 | 0.23.2 \ 94 | 0.24.0 \ 95 | 0.24.1 \ 96 | 0.25.0 \ 97 | 0.26.0 \ 98 | 0.26.1 \ 99 | 0.27.0 \ 100 | 0.27.1 \ 101 | 0.27.2 \ 102 | 0.28.0 \ 103 | 0.28.1 \ 104 | 0.29.0 \ 105 | 0.30.0 \ 106 | 0.31.0 \ 107 | 0.32.0 \ 108 | 0.33.0 \ 109 | 0.34.0 \ 110 | 0.35.0 \ 111 | 0.36.0 \ 112 | 0.37.0 \ 113 | $(EXTVERSION)dev \ 114 | $(EXTVERSION)next \ 115 | $(END) 116 | 117 | UPGRADES = \ 118 | $(shell echo $(UPGRADABLE) | \ 119 | $(SED) 's/^/$(EXTENSION)--/' | \ 120 | $(SED) 's/$$/--$(EXTVERSION).sql/' | \ 121 | $(SED) 's/ /--$(EXTVERSION).sql $(EXTENSION)--/g') 122 | 123 | DATA_built = \ 124 | $(EXTENSION)--$(EXTVERSION).sql \ 125 | $(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql \ 126 | $(UPGRADES) \ 127 | $(EXTENSION).control 128 | 129 | EXTRA_CLEAN = cartodb_version.sql 130 | 131 | DOCS = README.md 132 | REGRESS_OLD = $(wildcard test/*.sql) 133 | REGRESS_LEGACY = $(REGRESS_OLD:.sql=) 134 | REGRESS = test/test_setup $(REGRESS_LEGACY) 135 | 136 | PG_CONFIG = pg_config 137 | PGXS := $(shell $(PG_CONFIG) --pgxs) 138 | include $(PGXS) 139 | 140 | PG_VERSION := $(shell $(PG_CONFIG) --version | $(AWK) '{split($$2,a,"."); print a[1]}') 141 | PG_12_GE := $(shell [ $(PG_VERSION) -ge 12 ] && echo true) 142 | PLPYTHONU := plpythonu 143 | ifeq ($(PG_12_GE), true) 144 | PLPYTHONU := plpython3u 145 | endif 146 | PGPORT ?= '5432' 147 | PGUSER ?= 'postgres' 148 | 149 | $(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile 150 | echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@ 151 | cat $(CDBSCRIPTS) | \ 152 | $(SED) -e 's/@extschema@/cartodb/g' \ 153 | -e 's/@postgisschema@/public/g' \ 154 | -e 's/@@plpythonu@@/$(PLPYTHONU)/g' >> $@ 155 | echo "GRANT USAGE ON SCHEMA cartodb TO public;" >> $@ 156 | cat cartodb_version.sql >> $@ 157 | 158 | $(EXTENSION)--unpackaged--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql util/create_from_unpackaged.sh Makefile 159 | ./util/create_from_unpackaged.sh $(EXTVERSION) 160 | 161 | $(EXTENSION)--%--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql 162 | cp $< $@ 163 | 164 | $(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql: $(EXTENSION)--$(EXTVERSION).sql 165 | cp $< $@ 166 | 167 | $(EXTENSION).control: $(EXTENSION).control.in Makefile 168 | $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/g' -e 's/@@plpythonu@@/$(PLPYTHONU)/g' $< > $@ 169 | 170 | cartodb_version.sql: cartodb_version.sql.in Makefile 171 | $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" -e 's/@@plpythonu@@/$(PLPYTHONU)/g' $< > $@ 172 | 173 | # Needed for consistent `echo` results with backslashes 174 | SHELL = bash 175 | 176 | legacy_regress: $(REGRESS_OLD) Makefile 177 | mkdir -p sql/test/ 178 | mkdir -p expected/test/ 179 | mkdir -p results/test/ 180 | cat sql/test_setup.sql | \ 181 | $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" -e 's/@@plpythonu@@/$(PLPYTHONU)/g' \ 182 | > sql/test/test_setup.sql 183 | cp sql/test_setup_expect expected/test/test_setup.out 184 | for f in $(REGRESS_OLD); do \ 185 | tn=`basename $${f} .sql`; \ 186 | of=sql/test/$${tn}.sql; \ 187 | echo '\set ECHO none' > $${of}; \ 188 | echo '\a' >> $${of}; \ 189 | echo '\t' >> $${of}; \ 190 | echo '\set QUIET off' >> $${of}; \ 191 | cat $${f} | \ 192 | $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' \ 193 | -e 's/@extschema@/cartodb/g' \ 194 | -e "s/@postgisschema@/public/g" \ 195 | -e 's/@@plpythonu@@/$(PLPYTHONU)/g' \ 196 | -e 's/@@PGPORT@@/$(PGPORT)/g' \ 197 | -e 's/@@PGUSER@@/$(PGUSER)/g' \ 198 | >> $${of}; \ 199 | exp=expected/test/$${tn}.out; \ 200 | echo '\set ECHO none' > $${exp}; \ 201 | cat test/$${tn}_expect | \ 202 | $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' \ 203 | -e 's/@extschema@/cartodb/g' \ 204 | -e "s/@postgisschema@/public/g" \ 205 | -e 's/@@plpythonu@@/$(PLPYTHONU)/g' \ 206 | -e 's/@@PGPORT@@/$(PGPORT)/g' \ 207 | -e 's/@@PGUSER@@/$(PGUSER)/g' \ 208 | >> $${exp}; \ 209 | done 210 | 211 | test_organization: 212 | bash test/organization/test.sh 213 | 214 | test_extension_new: 215 | bash test/extension/test.sh 216 | 217 | legacy_tests: legacy_regress $(EXTENSION)--unpackaged--$(EXTVERSION).sql 218 | 219 | PGREGRESS := $(shell dirname `$(PG_CONFIG) --pgxs`)/../../src/test/regress/pg_regress 220 | PGBINDIR := $(shell $(PG_CONFIG) --bindir) 221 | PGREGRESSDATABASE = 'contrib_regression' 222 | regress: legacy_tests 223 | PGUSER=$(PGUSER) \ 224 | PGPORT=$(PGPORT) \ 225 | $(PGREGRESS) --inputdir=./ --bindir='$(PGBINDIR)' --dbname=$(PGREGRESSDATABASE) $(REGRESS) 226 | 227 | installcheck: test_extension_new test_organization 228 | $(MAKE) -C . regress 229 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | cartodb-postgresql 2 | ================== 3 | 4 | [![Build Status](http://api.travis-ci.org/CartoDB/cartodb-postgresql.svg?branch=master)](http://travis-ci.org/CartoDB/cartodb-postgresql) 5 | 6 | PostgreSQL extension for CartoDB 7 | 8 | See [the cartodb-postgresql wiki](https://github.com/CartoDB/cartodb-postgresql/wiki). 9 | 10 | Dependencies 11 | ------------ 12 | 13 | * PostgreSQL 11+ (with plpythonu extension). For PostgreSQL 12+ plpython3u is required instead. Older versions might still work but they aren't actively tested or supported. 14 | * [PostGIS extension](http://postgis.net) 15 | * Python with [Redis module](https://pypi.org/project/redis/) 16 | 17 | Install 18 | ------- 19 | 20 | ```sh 21 | make all install 22 | ``` 23 | 24 | Test installation 25 | ----------------- 26 | 27 | ```sh 28 | make installcheck 29 | ``` 30 | 31 | NOTE: you need to run the installcheck as a superuser, use PGUSER 32 | env variable if needed, like: PGUSER=postgres make installcheck 33 | 34 | 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. 35 | 36 | Enable database 37 | --------------- 38 | 39 | In a database that needs to be turned into a "cartodb" user database, run: 40 | 41 | ```sql 42 | CREATE EXTENSION cartodb CASCADE; 43 | ``` 44 | 45 | Update cartodb extension 46 | ------------------------ 47 | 48 | Updating the version of cartodb extension installed in a database 49 | is done using ALTER EXTENSION. 50 | 51 | ```sql 52 | ALTER EXTENSION cartodb UPDATE TO '0.1.1'; 53 | ``` 54 | 55 | The target version needs to be installed on the system first 56 | (see Install section). 57 | 58 | If the "TO 'x.y.z'" part is omitted, the extension will be updated to the 59 | latest installed version, which you can find with the following command: 60 | 61 | ```sh 62 | grep default_version `pg_config --sharedir`/extension/cartodb.control 63 | ``` 64 | 65 | Updates are performed by PostgreSQL by loading one or more migration scripts 66 | as needed to go from the installed version S to the target version T. 67 | All migration scripts are in the "extension" directory of PostgreSQL: 68 | 69 | ```sh 70 | ls `pg_config --sharedir`/extension/cartodb* 71 | ``` 72 | 73 | During development the cartodb extension version doesn't change with 74 | every commit, so testing latest change requires special steps documented 75 | in the CONTRIBUTING document, under "Testing changes live". 76 | 77 | Limitations 78 | ----------- 79 | 80 | - The main schema of an organization user must have one only owner (the user). 81 | -------------------------------------------------------------------------------- /carto-package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "carto_postgresql_ext", 3 | "current_version": { 4 | "requires": { 5 | "postgresql": ">=10.0.0", 6 | "postgis": ">=2.4.0.0" 7 | }, 8 | "works_with": { 9 | } 10 | } 11 | } 12 | -------------------------------------------------------------------------------- /cartodb.control.in: -------------------------------------------------------------------------------- 1 | default_version = '@@VERSION@@' 2 | comment = 'Turn a database into a cartodb user database.' 3 | superuser = true 4 | relocatable = false 5 | schema = cartodb 6 | requires = '@@plpythonu@@, postgis' 7 | -------------------------------------------------------------------------------- /cartodb_version.sql.in: -------------------------------------------------------------------------------- 1 | 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 2 | 3 | CREATE OR REPLACE FUNCTION @extschema@.CDB_version() 4 | RETURNS text AS $$ 5 | SELECT '@@VERSION@@'::text; 6 | $$ language 'sql' IMMUTABLE STRICT; 7 | 8 | -------------------------------------------------------------------------------- /doc/CDB_ColumnNames.md: -------------------------------------------------------------------------------- 1 | Retrieve all column names in a particular table 2 | 3 | #### Using the function 4 | 5 | ```sql 6 | SELECT CDB_ColumnNames('table_name') 7 | --- Returns a set of rows with column names 8 | ``` 9 | 10 | #### Arguments 11 | 12 | CDB_ColumnNames(table_name) 13 | 14 | * **table_name** text -------------------------------------------------------------------------------- /doc/CDB_ColumnType.md: -------------------------------------------------------------------------------- 1 | Returns a column type for any column in a table 2 | 3 | #### Using the function 4 | 5 | ```sql 6 | SELECT CDB_ColumnType('column_name','table_name') 7 | --- Returns a set of rows with column types 8 | ``` 9 | 10 | #### Arguments 11 | 12 | CDB_ColumnType(column_name, table_name) 13 | 14 | * **column_name** text 15 | * **table_name** text 16 | -------------------------------------------------------------------------------- /doc/CDB_EstimateRowCount.md: -------------------------------------------------------------------------------- 1 | Estimate the number of rows of a query. 2 | 3 | 4 | #### Using the function 5 | 6 | ```sql 7 | SELECT CDB_EstimateRowCount($$ 8 | UPDATE addresses SET the_geom = cdb_geocode_street_point(addr, city, state, 'US'); 9 | $$) AS row_count; 10 | ``` 11 | 12 | Result: 13 | 14 | ``` 15 | row_count 16 | ----------- 17 | 5 18 | (1 row) 19 | ``` 20 | 21 | #### Arguments 22 | 23 | CDB_EstimateRowCount(query) 24 | 25 | * **query** text: the SQL query to estimate the row count for. 26 | -------------------------------------------------------------------------------- /doc/CDB_GreatCircle.md: -------------------------------------------------------------------------------- 1 | Based on Paul Ramsey's [blog post](http://blog.cartodb.com/jets-and-datelines/). 2 | #### Using the function 3 | 4 | Creates a great circle line. 5 | 6 | ```sql 7 | SELECT CDB_GreatCircle(start_point, end_point) FROM table_name 8 | -- Results a line reprsenting the great circle between the two points 9 | ``` 10 | 11 | #### Arguments 12 | 13 | CDB_GreatCircle(start_point, end_point) 14 | 15 | * **start_point** ST_Point indicating the start of the line. 16 | * **end_point** ST_point indicating the end of the line. 17 | -------------------------------------------------------------------------------- /doc/CDB_HeadsTailsBins.md: -------------------------------------------------------------------------------- 1 | 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. 2 | 3 | ![headtails](https://f.cloud.github.com/assets/370259/140655/6eebb918-7228-11e2-89fa-149745f25d34.png) 4 | 5 | #### Using the function 6 | 7 | We can determine the 7 most optimal breaks in a column of numerical data as follows, 8 | 9 | ```sql 10 | SELECT CDB_HeadsTailsBins(array_agg(numeric_column), 7) FROM table_name 11 | -- Results in an ordered array like, {7824,23492,52696,233857,666089,1001709,1638094} 12 | -- Each break happens up to, and equal, to a number: 13 | -- (bin1 is less than or equal to 7824, bin2 is less than or equal to 23492, etc.) 14 | ``` 15 | 16 | #### Arguments 17 | 18 | CDB_HeadsTailsBins(in_array, breaks) 19 | 20 | * **in_array** numeric[]. A NUMERIC array of values. 21 | * **breaks** int. The number of categories you want to create -------------------------------------------------------------------------------- /doc/CDB_HexagonGrid.md: -------------------------------------------------------------------------------- 1 | Fill given extent with an hexagonal coverage 2 | 3 | #### Using the function 4 | 5 | Create a hexagonal grid from a polygon geometry. For example, take the geometry 6 | 7 | ```sql 8 | ST_SetSRID( 9 | ST_Envelope( 10 | ST_Collect( 11 | ST_MakePoint(10000000,-10000000), 12 | ST_MakePoint(-10000000,10000000) 13 | ) 14 | ), 15 | 3857) 16 | ``` 17 | 18 | We can create a grid as follows, 19 | 20 | ```sql 21 | SELECT CDB_HexagonGrid( 22 | ST_SetSRID( 23 | ST_Envelope( 24 | ST_Collect( 25 | ST_MakePoint(10000000,-10000000), 26 | ST_MakePoint(-10000000,10000000) 27 | ) 28 | ), 29 | 3857), 30 | 1000000) the_geom_webmercator 31 | ``` 32 | 33 | Which will look something like this, 34 | 35 | ![grid tile](http://i.imgur.com/4rZXGMb.png) 36 | 37 | #### Arguments 38 | 39 | CDB_HexagonGrid(ext, side, origin) 40 | 41 | * **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. 42 | * **side** float. Side measure for the hexagon. Maximum diameter will be 2 * side. Measure is in the same projection as **ext** 43 | * **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. -------------------------------------------------------------------------------- /doc/CDB_JenksBins.md: -------------------------------------------------------------------------------- 1 | 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. 2 | 3 | ![Jenks](https://f.cloud.github.com/assets/370259/140093/b64a9382-7210-11e2-81a4-c65cce3c885e.png) 4 | 5 | #### Using the function 6 | 7 | We can determine the 7 most optimal breaks in a column of numerical data as follows, 8 | 9 | ```sql 10 | SELECT CDB_JenksBins(array_agg(numeric_column), 7) FROM table_name 11 | -- Results in an ordered array like, {0,73,2568,9408,29411,768230,1638094} 12 | -- Each break happens up to, and equal, to a number: 13 | -- (bin1 is less than or equal to 0, bin2 is less than or equal to 73, etc.) 14 | ``` 15 | 16 | #### Arguments 17 | 18 | CDB_JenksBins(in_array, breaks, invert) 19 | 20 | * **in_array** numeric[]. A NUMERIC array of values. 21 | * **breaks** int. The number of categories you want to create 22 | * **iterations** OPTIONAL int. The number of iterations used for calculating breaks. 23 | * **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 >=). -------------------------------------------------------------------------------- /doc/CDB_MakeHexagon.md: -------------------------------------------------------------------------------- 1 | Return an Hexagon with given center and side (or maximal radius) 2 | 3 | #### Using the function 4 | 5 | Running the following SQL 6 | 7 | ```sql 8 | SELECT CDB_MakeHexagon(ST_MakePoint(0,0),10000000) 9 | ``` 10 | 11 | Would give you back a single hexagon geometry, 12 | 13 | ![hexagon](http://i.imgur.com/6jeGStb.png) 14 | 15 | 16 | #### Arguments 17 | 18 | CDB_MakeHexagon(center, radius) 19 | 20 | * **center** geometry 21 | * **radius** float. Radius of hexagon measured in same projection as **center** 22 | -------------------------------------------------------------------------------- /doc/CDB_Overviews.md: -------------------------------------------------------------------------------- 1 | 2 | ============================ WARNING =================================== 3 | Creating overviews is no longer supported. 4 | ============================ WARNING =================================== 5 | 6 | Overviews are tables that represent a *reduced* version of a dataset intended 7 | for efficient rendering at certain zoom levels while preserving the 8 | general visual appearance of the complete dataset. 9 | 10 | The *reduction* consists in havig a fewer number of records 11 | (while each overview record may represent an aggregation of multiple records) 12 | and/or simplified record geometries. 13 | 14 | Overviews are created through the `CDB_CreateOverviews` function. 15 | The statement timeout may need to be adjusted before using this function, 16 | as overview creation for large tables is a time-consuming operation. 17 | 18 | The `CDB_Overviews` function can be used determine what overview tables 19 | exist for a given dataset table and which zoom levels correspond to it. 20 | 21 | The `CDB_DropOverviews` function removes a dataset's existing overviews. 22 | 23 | To know if overview tables exist for some base table, and to obtain 24 | a list of which overview tables are approrpiate for which zoom levels, 25 | the `CDB_Overviews` functions can be used. 26 | 27 | The zoom level we're referring here to are those used 28 | by the tiler: http://wiki.openstreetmap.org/wiki/Zoom_levels 29 | 30 | ### CDB_CreateOverviews 31 | 32 | Create overviews for vector dataset. 33 | 34 | #### Using the function 35 | 36 | The table for which overviews will be generated should be 37 | a Cartodbfied dataset with vector geometry. 38 | 39 | ```sql 40 | SELECT CDB_CreateOverviews('table_name'); 41 | --- Generates overview tables for the dataset 42 | ``` 43 | 44 | #### Arguments 45 | 46 | CDB_CreateOverviews(table_name, ref_z_strategy, reduction_strategy) 47 | 48 | * **table_name** regclass, table for which overviews will be generated 49 | * **ref_z_strategy** regproc, optional function that provides 50 | the Z-scale strategy. 51 | It returns the base Z level for the dataset. 52 | It should have these arguments: 53 | - **table_name** regclass, table to compute the reference Z scale for 54 | * **reduction_strategy** regproc, optional function that provides 55 | the reduction strategy to generate an overview table from a table 56 | for a smaller scale (higher Z number). 57 | It returns the name of the generated table. 58 | It should have these arguments: 59 | - **base_table_name** regclass, base table to be reduced. 60 | - **base_z** integer, base Z level assigned to the base table. 61 | - **overview_z** integer, Z level for which to generate the overview. 62 | 63 | #### Tolerance / level of detail 64 | 65 | The level of detail to be representable by each overview layer can 66 | be specified as a tolerance in pixels (if different from the default of 1 pixel) 67 | with the function `CDB_CreateOverviewsWithToleranceInPixels` 68 | which has as a second additional argument the desired tolerance. 69 | 70 | This tolerance defines the maximum deviation in pixels of the overviews 71 | geometries with respect to the original geometries when overview tables 72 | are used for their intendend zoom level. 73 | 74 | ### CDB_Overviews 75 | 76 | Obtain overview metadata for a given table (existing overviews). 77 | The returned relation will be empty if the table has no overviews. 78 | 79 | The function can be applied to a single table: 80 | 81 | ```sql 82 | SELECT CDB_Overviews('table_name'); 83 | --- Return existing overview Z levels and corresponding tables 84 | ``` 85 | 86 | Or to multiple tables passed as an array; this can be used 87 | to obtain the overviews that can be applied to a query by 88 | combining it with `CDB_QueryTablesText`: 89 | 90 | ```sql 91 | SELECT CDB_Overviews(CDB_QueryTablesText('SELECT * FROM table1, table2')); 92 | --- Return existing overview Z levels and corresponding tables 93 | ``` 94 | 95 | The result of `CDB_Overviews` has three columns: 96 | 97 | | base_table | z | overview_table | 98 | | ---------- | - | -------------- | 99 | | table1 | 1 | table1_ov1 | 100 | | table1 | 2 | table1_ov2 | 101 | | table1 | 4 | table1_ov4 | 102 | | table2 | 1 | table1_ov1 | 103 | | table2 | 2 | table1_ov2 | 104 | 105 | #### Arguments 106 | 107 | CDB_Overviews(table_name) 108 | 109 | * **table_name** regclass, oid of table to obtain existing overviews for 110 | 111 | CDB_Overviews(table_names) 112 | 113 | * **table_names** regclass[], array of table oids 114 | 115 | 116 | ### CDB_DropOverviews 117 | 118 | Remove the overviews of a table, if present. 119 | 120 | ```sql 121 | SELECT CDB_DropOverviews('table_name'); 122 | ``` 123 | 124 | #### Arguments 125 | 126 | CDB_Overviews(table_name) 127 | 128 | * **table_name** regclass, table for which to drop existing overviews. 129 | -------------------------------------------------------------------------------- /doc/CDB_QuantileBins.md: -------------------------------------------------------------------------------- 1 | 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. 2 | 3 | ![qunatile](https://f.cloud.github.com/assets/370259/140714/932ed0e6-722b-11e2-9807-ffbd0fddb9ac.png) 4 | 5 | #### Using the function 6 | 7 | We can determine the 7 most optimal breaks in a column of numerical data as follows, 8 | 9 | ```sql 10 | SELECT CDB_QuantileBins(array_agg(numeric_column), 7) FROM table_name 11 | -- Results in an ordered array like, {80,2281,7162,17652,39730,91077,1638094} 12 | -- Each break happens up to, and equal, to a number: 13 | -- (bin1 is less than or equal to 80, bin2 is less than or equal to 2281, etc.) 14 | ``` 15 | 16 | #### Arguments 17 | 18 | CDB_QuantileBins(in_array, breaks) 19 | 20 | * **in_array** numeric[]. A NUMERIC array of values. 21 | * **breaks** int. The number of categories you want to create -------------------------------------------------------------------------------- /doc/CDB_RectangleGrid.md: -------------------------------------------------------------------------------- 1 | Fill given extent with a rectangular coverage 2 | 3 | #### Using the function 4 | 5 | Create a rectangular grid from a polygon geometry. For example, take the geometry 6 | 7 | ```sql 8 | ST_SetSRID( 9 | ST_Envelope( 10 | ST_Collect( 11 | ST_MakePoint(10000000,-10000000), 12 | ST_MakePoint(-10000000,10000000) 13 | ) 14 | ), 15 | 3857) 16 | ``` 17 | 18 | We can create a grid as follows, 19 | 20 | ```sql 21 | SELECT CDB_RectangleGrid( 22 | ST_SetSRID( 23 | ST_Envelope( 24 | ST_Collect( 25 | ST_MakePoint(10000000,-10000000), 26 | ST_MakePoint(-10000000,10000000) 27 | ) 28 | ), 29 | 3857), 30 | 1000000, 31 | 1000000 32 | ) the_geom_webmercator 33 | ``` 34 | 35 | Which will look something like this, 36 | 37 | ![rect grid](http://i.imgur.com/HuhOJRs.png) 38 | 39 | #### Arguments 40 | 41 | CDB_RectangleGrid(ext, width, height, origin) 42 | 43 | * **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. 44 | * **width** float. Width of each rectangle. Measure is in the same projection as **ext** 45 | * **height** float. Height of each rectangle. Measure is in the same projection as **ext** 46 | * **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. -------------------------------------------------------------------------------- /doc/CDB_SetUserQuotaInBytes.md: -------------------------------------------------------------------------------- 1 | Sets user quota in bytes (superuser only) 2 | 3 | #### Using the function 4 | 5 | ```sql 6 | SELECT CDB_SetUserQuotaInBytes(10485760); 7 | --- Returns the previously set quota. 8 | --- Use 0 to disable quota. 9 | ``` 10 | 11 | REF: https://github.com/CartoDB/cartodb-postgresql/blob/master/scripts-available/CDB_Quota.sql 12 | -------------------------------------------------------------------------------- /doc/CDB_SyncTable.md: -------------------------------------------------------------------------------- 1 | Synchronize two tables. This function will synchronize a *destination* table with a *source* table. 2 | The idea is that the *destination* is a replica of *source* and *source* has been subject to 3 | modifications that are to be applied to *destination*. 4 | 5 | This will be achieved by deleting the rows in the destination not present 6 | in the source, inserting rows of the source not in the destination and updating modified rows. 7 | If the destination table does not exist it will be created and all the rows of the source inserted into it. 8 | 9 | Both tables must have a consistent `cartodb_id` primary key column which will be used to match 10 | the source and destination rows. 11 | 12 | Note that both tables do not necessarily become identical after the synchronization, since additional columns 13 | may have been added to the destination; those columns will not be altered by the synchronization. 14 | 15 | In addition some source columns may be skipped by listing them in the optional last argument; such columns 16 | will not be updated in the destination, so if they are present in it their values won't be altered. 17 | 18 | 19 | #### Using the function 20 | 21 | Import some data using COPY FROM into a temporary table, then synchronize a table with the data and 22 | finally delete the temporary table. This could be used import and update some data periodically while 23 | allowing to add columns to the data that will be preserved across updates. 24 | 25 | ```sql 26 | CREATE tmp_pois(cartodb_id int, name text, type text, longitude double precision, latitude double precision, rank int); 27 | COPY tmp_pois FROM '/tmp/pois.csv'; 28 | SELECT CDB_SyncTable('tmp_pois', 'public', 'pois'); 29 | DROP TABLE tmp_pois; 30 | ``` 31 | 32 | Now we could perform some changes to the `pois` to maintain our own ranking: 33 | 34 | ```sql 35 | UPDATE pois SET rank = random()*4 + 1; 36 | ``` 37 | 38 | Then, if the source were updated at `/tmp/pois.csv` we could synchronize with it while preserving our `rank` values with: 39 | 40 | ```sql 41 | CREATE tmp_pois(cartodb_id int, name text, type text, longitude double precision, latitude double precision, rank int); 42 | COPY tmp_pois FROM '/tmp/pois.csv'; 43 | SELECT CDB_SyncTable('tmp_pois', 'public', 'pois', '{rank}'); 44 | DROP TABLE tmp_pois; 45 | ``` 46 | 47 | #### Arguments 48 | 49 | ``` 50 | CDB_SyncTable(src_table, dst_schema, dst_table, skip_cols) 51 | ``` 52 | 53 | * **src_table** REGCLASS the source data for the synchronization 54 | * **dst_scgena** REGNAMESPACE the destination schema 55 | * **dst_table** NAME the destination table to be updated 56 | * **skip_cols** NAME[] an array of column names, empty by default, which will be skipped 57 | -------------------------------------------------------------------------------- /doc/CDB_TransformToWebmercator.md: -------------------------------------------------------------------------------- 1 | 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. 2 | 3 | #### Using the function 4 | 5 | Using a box that is nearly the full globe, 6 | 7 | ```sql 8 | ST_SetSRID( 9 | ST_Envelope( 10 | ST_Collect( 11 | ST_MakePoint(-180,60), 12 | ST_MakePoint(180,-60) 13 | ) 14 | ), 15 | 4326 16 | ) 17 | ``` 18 | 19 | We can then convert it to a renderable webmercator geometry. 20 | 21 | ```sql 22 | SELECT CDB_TransformToWebmercator( 23 | ST_SetSRID( 24 | ST_Envelope( 25 | ST_Collect( 26 | ST_MakePoint(-10,60), 27 | ST_MakePoint(300,-60) 28 | ) 29 | ), 30 | 4326 31 | ) 32 | ) 33 | ``` 34 | 35 | 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) 36 | 37 | ![valid geom](http://i.imgur.com/EFdXiqt.png) 38 | 39 | 40 | #### Arguments 41 | 42 | CDB_TransformToWebmercator(geom) 43 | 44 | * **geom** geometry -------------------------------------------------------------------------------- /doc/CDB_UserTables.md: -------------------------------------------------------------------------------- 1 | List the name of available tables (only the usable ones) 2 | 3 | #### Using the function 4 | 5 | ```sql 6 | --- Returns a row for each table having given permission with the table name. 7 | --- It also returns tables from others users if you've permission to see them. For example, consider the following scenario: 8 | --- User X and User Y at account C. 9 | --- User X has a public table T. 10 | --- User Y will see table T. 11 | --- Currently accepted permissions are: 'public', 'private' or 'all' 12 | SELECT CDB_UserTables(perms) 13 | ``` 14 | 15 | REF: https://github.com/CartoDB/cartodb-postgresql/blob/master/scripts-available/CDB_UserTables.sql 16 | -------------------------------------------------------------------------------- /doc/CDB_XYZ_Extent.md: -------------------------------------------------------------------------------- 1 | Determine the spatial extent of a tile based on the tile's XYZ coordinate. 2 | 3 | #### Using the function 4 | 5 | Take a common tile with coordinates x=3, y=2, z=2, 6 | 7 | ![2/3/2](https://viz2.cartodb.com/tiles/quantile_breaks/2/3/2.png) 8 | 9 | To determine its extent you would run, 10 | 11 | ```sql 12 | SELECT CDB_XYZ_Extent(3,2,2) 13 | --- Returns a WKB polygon in Webmercator (SRID 3857) 14 | ``` 15 | 16 | #### Arguments 17 | 18 | CDB_XYZ_Extent(x,y,z) 19 | 20 | * **x** integer 21 | * **y** integer 22 | * **z** integer -------------------------------------------------------------------------------- /doc/CDB_XYZ_Resolution.md: -------------------------------------------------------------------------------- 1 | Return pixel resolution of tiles at a given zoom level 2 | 3 | #### Using the function 4 | 5 | Take a common tile with zoom, z=2, 6 | 7 | ![2/3/2](https://viz2.cartodb.com/tiles/quantile_breaks/2/3/2.png) 8 | 9 | To determine the resolution of these pixels, 10 | 11 | ```sql 12 | SELECT CDB_XYZ_Resolution(2) 13 | --- Returns a float, 39135.7587890625 14 | ``` 15 | 16 | #### Arguments 17 | 18 | CDB_XYZ_Resolution(z) 19 | 20 | * **z** integer -------------------------------------------------------------------------------- /doc/CartoDB-PLpgSQL.md: -------------------------------------------------------------------------------- 1 | INTRODUCTION 2 | ============ 3 | 4 | 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. 5 | 6 | ## Spatial functions 7 | 8 | [CDB_HexagonGrid](CDB_HexagonGrid) - create hexagonal grid from extent and size 9 | 10 | [CDB_MakeHexagon](CDB_MakeHexagon) - make a hexagon with given center and side 11 | 12 | [CDB_RectangleGrid](CDB_RectangleGrid) - fill given extent with a rectangular coverage 13 | 14 | ##### Tile based 15 | 16 | [CDB_XYZ_Extent](CDB_XYZ_Extent) - Find the extent of a tile by XYZ 17 | 18 | [CDB_XYZ_Resolution](CDB_XYZ_Resolution) - Find the pixel resolution of tiles 19 | 20 | [CDB_TransformToWebmercator](CDB_TransformToWebmercator) - Convert a geometry to valid webmercator 21 | 22 | ## Statistical functions 23 | 24 | [CDB_JenksBins](CDB_JenksBins) - Find breaks in an array of numbers using Jenks method 25 | 26 | [CDB_HeadsTailsBins](CDB_HeadsTailsBins) - Find breaks in an array of numbers using Heads/Tails method 27 | 28 | [CDB_QuantileBins](CDB_QuantileBins) - Find quantile breaks in an array of numbers 29 | 30 | ## System functions 31 | 32 | [CDB_UserTables](CDB_UserTables) - Get a list of all tables in your account 33 | 34 | [[CDB_SetUserQuotaInBytes]] - Set maximum user quota in bytes 35 | 36 | column names - now returned in JSON response 37 | 38 | column types - now returned in JSON response 39 | -------------------------------------------------------------------------------- /doc/CartoDB-user-table.rst: -------------------------------------------------------------------------------- 1 | CartoDB User Table 2 | ================== 3 | 4 | Introduction 5 | ---------- 6 | A CartoDB user table is a table with a well-known set of columns and a well-known set of triggers attached on. 7 | 8 | Columns 9 | ---------- 10 | The required columns of a CartoDB table are: 11 | 12 | - ``cartodb_id`` 13 | - This column will be used as the primary key of the table and it has a sequence as default value 14 | - Its values must be integer, non-zero, non-null and unique 15 | - B-Tree indexed 16 | - ``the_geom`` 17 | - This column stores the main geometric features of a table 18 | - The type of the column in the Postgres database is ``geometry(Geometry,4326)``` 19 | - GiST indexed 20 | - geometry, GiST indexed, constrained (see below) 21 | - ``the_geom_webmercator`` 22 | - This column stores the geometries used for rendering purposes 23 | - The type of the column in the Postgres database is ``geometry(Geometry,3857)`` 24 | - GiST indexed 25 | - 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) 26 | 27 | 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. 28 | 29 | Described table example 30 | ^^^^^^^^^^ 31 | :: 32 | 33 | Column | Type | Modifiers 34 | ----------------------+-------------------------+-------------------------------------------------------- 35 | cartodb_id | bigint | not null default nextval('t_cartodb_id_seq'::regclass) 36 | the_geom | geometry(Geometry,4326) | 37 | the_geom_webmercator | geometry(Geometry,3857) | 38 | Indexes: 39 | "table_name_pkey" PRIMARY KEY, btree (cartodb_id) 40 | "table_name_the_geom_idx" gist (the_geom) 41 | "table_name_the_geom_webmercator_idx" gist (the_geom_webmercator) 42 | 43 | Triggers 44 | ---------- 45 | The triggers generated in each CartoDB table are: 46 | 47 | - ``track_updates`` after modifying statement updates ``cdb_tablemetadata`` 48 | - ``test_quota`` before changing statement to forbid if overquota 49 | - ``test_quota_per_row`` before insert ot update row to forbid if overquota (checked on a probabilistic basis) 50 | - ``update_the_geom_webmercator`` before insert or update row to maintain the ``the_geom_webmercator`` updated with the contents in ``the_geom`` 51 | 52 | Described triggers example 53 | ^^^^^^^^^^ 54 | :: 55 | 56 | test_quota BEFORE INSERT OR UPDATE ON t FOR EACH STATEMENT EXECUTE PROCEDURE cdb_checkquota('0.1', '-1', 'public') 57 | test_quota_per_row BEFORE INSERT OR UPDATE ON t FOR EACH ROW EXECUTE PROCEDURE cdb_checkquota('0.001', '-1', 'public') 58 | track_updates AFTER INSERT OR DELETE OR UPDATE OR TRUNCATE ON t FOR EACH STATEMENT EXECUTE PROCEDURE cdb_tablemetadata_trigger() 59 | update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON t FOR EACH ROW EXECUTE PROCEDURE _cdb_update_the_geom_webmercator() 60 | 61 | 62 | Further details 63 | ---------- 64 | 65 | Some conversions will be attempted to perform upon cartodbfication when certain fields appear: 66 | 67 | - ``cartodb_id``: If found type TEXT will be attempted to cast to integer. If not casteable, an eror will be raised. 68 | - ``the_geom``: If found type TEXT will be attempted to cast to geometry(Geometry,4326). 69 | -------------------------------------------------------------------------------- /doc/README.md: -------------------------------------------------------------------------------- 1 | # Contents 2 | 3 | * [CartoDB-user-table](CartoDB-user-table.md) 4 | * [CartoDB-PLpgSQL](CartoDB-PLpgSQL.md) 5 | * [CDB_ColumnNames](CDB_ColumnNames.md) 6 | * [CDB_ColumnType](CDB_ColumnType.md) 7 | * [CDB_HeadsTailsBins](CDB_HeadsTailsBins.md) 8 | * [CDB_HexagonGrid](CDB_HexagonGrid.md) 9 | * [CDB_JenksBins](CDB_JenksBins.md) 10 | * [CDB_MakeHexagon](CDB_MakeHexagon.md) 11 | * [CDB_QuantileBins](CDB_QuantileBins.md) 12 | * [CDB_RectangleGrid](CDB_RectangleGrid.md) 13 | * [CDB_SetUserQuotaInBytes](CDB_SetUserQuotaInBytes.md) 14 | * [CDB_TransformToWebmercator](CDB_TransformToWebmercator.md) 15 | * [CDB_UserTables](CDB_UserTables.md) 16 | * [CDB_XYZ_Extent](CDB_XYZ_Extent.md) 17 | * [CDB_XYZ_Resolution](CDB_XYZ_Resolution.md) 18 | 19 | The CartoDB PostgreSQL extension is a module to load into each CartoDB user database to perform cartodb-specific security and functionality checks. 20 | 21 | # Checks 22 | 23 | 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. 24 | -------------------------------------------------------------------------------- /doc/cartodbfy-requirements.rst: -------------------------------------------------------------------------------- 1 | CartoDBfy Requirements 2 | ====================== 3 | 4 | Introduction 5 | ------------ 6 | 7 | This document aims at describing what the CartoDBfication is and what its formal requirements are, with the following goals in mind: 8 | 9 | - Clarify what are the expectations of the "cartodbfycation process". 10 | - Define an important part of what should be a stable, public API 11 | - Allow for better testing, which should in turn... 12 | - ...ease modifications and increase quality of the code 13 | 14 | 15 | What is the CartoDBfycation 16 | --------------------------- 17 | 18 | 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. 19 | 20 | It is performed by running the function ``CDB_CartodbfyTable(reloid REGCLASS)`` over a target table. 21 | 22 | Valid CartoDB tables 23 | -------------------- 24 | 25 | A valid CartoDB table shall meet the following conditions: 26 | 27 | - Have a ``cartodb_id`` column with integer, unique, non-zero and non-null values as primary key with a sequence as default value 28 | - Have a ``the_geom`` column of type ``Geometry`` with SRID 4326 29 | - Have a ``the_geom_webmercator`` column of type ``Geometry`` with SRID 3857 30 | - The columns ``the_geom`` and ``the_geom_webmercator`` shall be in sync (task of the ``update_the_geom_webmercator`` trigger) 31 | 32 | Additionally, a CartoDB table can contain other columns. 33 | 34 | See the `CartoDB User Table documentation`_ 35 | 36 | .. _CartoDB User Table documentation: https://github.com/CartoDB/cartodb-postgresql/blob/master/doc/CartoDB-user-table.rst 37 | for further information. 38 | 39 | High level requirements 40 | ----------------------- 41 | 42 | Here is a list of high level requirments for the public function ``CDB_CartodbfyTable()``: 43 | 44 | - A call to the function shall modify/rewrite the table and produce a valid CartoDB table with the same name. 45 | - A call to the function shall cause the registration of the table into the platform. 46 | - It shall be idempotent, meaning that successive calls to the function shall not produce any visible effect in the system. 47 | - If there's a column containing a geometry, it shall be used to generate ``the_geom`` and the ``the_geom_webmercator`` columns. 48 | - Exporting and re-importing the same table in CartoDB shall produce equivalent tables, with the same features associated to the same ``cartodb_id``'s. 49 | 50 | 51 | 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. 52 | 53 | 54 | Low-level requirements 55 | ---------------------- 56 | 57 | - If the original table contains a valid (integer, unique, non-zero and not null) ``cartodb_id`` column, it shall be used 58 | - 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. 59 | - A modification of a cartodbfy'ed table shall insert or update a row in ``CDB_TableMetadata`` 60 | - A cartodbfy'ed table shall have a ``btree`` index on ``cartodb_id`` 61 | - A cartodbfy'ed table shall have ``gist`` indices on ``the_geom`` and ``the_geom_webmercator`` 62 | - Cartodbfy shall deal with text columns for imports, regarding CartoDB columns (``cartodb_id``, ``the_geom``, ``the_geom_webmercator``) 63 | 64 | -------------------------------------------------------------------------------- /expected/test_setup.out: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO error; 2 | CREATE EXTENSION cartodb CASCADE; 3 | CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) 4 | RETURNS void AS $$ 5 | BEGIN 6 | RAISE NOTICE 'cdb_invalidate_varnish(%) called', table_name; 7 | END; 8 | $$ LANGUAGE 'plpgsql'; 9 | -------------------------------------------------------------------------------- /scripts-available/CDB_AnalysisCatalog.sql: -------------------------------------------------------------------------------- 1 | -- Table to register analysis nodes from https://github.com/cartodb/camshaft 2 | CREATE TABLE IF NOT EXISTS 3 | @extschema@.cdb_analysis_catalog ( 4 | -- md5 hex hash 5 | node_id char(40) CONSTRAINT cdb_analysis_catalog_pkey PRIMARY KEY, 6 | -- being json allows to do queries like analysis_def->>'type' = 'buffer' 7 | analysis_def json NOT NULL, 8 | -- can reference other nodes in this very same table, allowing recursive queries 9 | input_nodes char(40) ARRAY NOT NULL DEFAULT '{}', 10 | status TEXT NOT NULL DEFAULT 'pending', 11 | CONSTRAINT valid_status CHECK ( 12 | status IN ( 'pending', 'waiting', 'running', 'canceled', 'failed', 'ready' ) 13 | ), 14 | created_at timestamp with time zone NOT NULL DEFAULT now(), 15 | -- should be updated when some operation was performed in the node 16 | -- and anything associated to it might have changed 17 | updated_at timestamp with time zone DEFAULT NULL, 18 | -- should register last time the node was used 19 | used_at timestamp with time zone NOT NULL DEFAULT now(), 20 | -- should register the number of times the node was used 21 | hits NUMERIC DEFAULT 0, 22 | -- should register what was the last node using current node 23 | last_used_from char(40), 24 | -- last job modifying the node 25 | last_modified_by uuid, 26 | -- store error message for failures 27 | last_error_message text, 28 | -- cached tables involved in the analysis 29 | cache_tables regclass[] NOT NULL DEFAULT '{}', 30 | -- useful for multi account deployments 31 | username text 32 | ); 33 | 34 | -- This can only be called from an SQL script executed by CREATE EXTENSION 35 | DO LANGUAGE 'plpgsql' $$ 36 | BEGIN 37 | PERFORM pg_catalog.pg_extension_config_dump('@extschema@.cdb_analysis_catalog', ''); 38 | END 39 | $$; 40 | 41 | -- Migrations to add new columns from old versions. 42 | -- IMPORTANT: Those columns will be added in order of creation. To be consistent 43 | -- in column order, ensure that new columns are added at the end and in the same order. 44 | 45 | DO $$ 46 | BEGIN 47 | BEGIN 48 | ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN last_modified_by uuid; 49 | EXCEPTION 50 | WHEN duplicate_column THEN END; 51 | END; 52 | $$; 53 | 54 | DO $$ 55 | BEGIN 56 | BEGIN 57 | ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN last_error_message text; 58 | EXCEPTION 59 | WHEN duplicate_column THEN END; 60 | END; 61 | $$; 62 | 63 | DO $$ 64 | BEGIN 65 | BEGIN 66 | ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN cache_tables regclass[] NOT NULL DEFAULT '{}'; 67 | EXCEPTION 68 | WHEN duplicate_column THEN END; 69 | END; 70 | $$; 71 | 72 | DO $$ 73 | BEGIN 74 | BEGIN 75 | ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN username text; 76 | EXCEPTION 77 | WHEN duplicate_column THEN END; 78 | END; 79 | $$; 80 | 81 | -- We want the "username" column to be moved to the last position if it was on a position from other versions 82 | -- see https://github.com/CartoDB/cartodb-postgresql/issues/276 83 | DO LANGUAGE 'plpgsql' $$ 84 | DECLARE 85 | column_index int; 86 | BEGIN 87 | SELECT ordinal_position FROM information_schema.columns WHERE table_name='cdb_analysis_catalog' AND table_schema='@extschema@' AND column_name='username' INTO column_index; 88 | IF column_index = 1 OR column_index = 10 THEN 89 | ALTER TABLE @extschema@.cdb_analysis_catalog ADD COLUMN username_final text; 90 | UPDATE @extschema@.cdb_analysis_catalog SET username_final = username; 91 | ALTER TABLE @extschema@.cdb_analysis_catalog DROP COLUMN username; 92 | ALTER TABLE @extschema@.cdb_analysis_catalog RENAME COLUMN username_final TO username; 93 | END IF; 94 | END; 95 | $$; 96 | -------------------------------------------------------------------------------- /scripts-available/CDB_AnalysisCheck.sql: -------------------------------------------------------------------------------- 1 | -- Read configuration parameter analysis_quota_factor, making it 2 | -- accessible to regular users (which don't have access to cdb_conf) 3 | CREATE OR REPLACE FUNCTION @extschema@._CDB_GetConfAnalysisQuotaFactor() 4 | RETURNS float8 AS 5 | $$ 6 | BEGIN 7 | RETURN @extschema@.CDB_Conf_GetConf('analysis_quota_factor')::text::float8; 8 | END; 9 | $$ LANGUAGE 'plpgsql' 10 | STABLE 11 | PARALLEL SAFE 12 | SECURITY DEFINER 13 | SET search_path = pg_temp; 14 | 15 | 16 | -- Get the factor (fraction of the quota) for Camshaft cached analysis tables 17 | CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisQuotaFactor() 18 | RETURNS float8 AS 19 | $$ 20 | DECLARE 21 | factor float8; 22 | BEGIN 23 | -- We use a floating point cdb_conf parameter 24 | factor := @extschema@._CDB_GetConfAnalysisQuotaFactor(); 25 | -- With a default value 26 | IF factor IS NULL THEN 27 | factor := 2; 28 | END IF; 29 | RETURN factor; 30 | END; 31 | $$ 32 | LANGUAGE 'plpgsql' STABLE PARALLEL SAFE; 33 | 34 | -- This checks the space used up by Camshaft cached analysis tables. 35 | -- An exception will be raised if the limits are exceeded. 36 | -- The name of an analysis table is passed; this, in addition to the 37 | -- db role that executes this function is used to determined which 38 | -- analysis tables will be considered. 39 | CREATE OR REPLACE FUNCTION @extschema@.CDB_CheckAnalysisQuota(table_name TEXT) 40 | RETURNS void AS 41 | $$ 42 | DECLARE 43 | schema_name TEXT; 44 | user_name TEXT; 45 | nominal_quota int8; 46 | cache_size float8; 47 | BEGIN 48 | -- We rely on the search_path to determine the user's schema and 49 | -- check for all analysis tables in that schema. 50 | -- An alternative would be to use cdb_analysis_catalog to 51 | -- select analysis tables (cache_tables) from the same user, analysis or node. 52 | -- For example: 53 | -- SELECT unnest(cache_tables) FROM cdb_analysis_catalog 54 | -- WHERE username IN (SELECT username FROM cdb_analysis_catalog 55 | -- WHERE table_name::regclass = ANY (cache_tables)); 56 | -- At the moment we're not using the provided table_name. 57 | 58 | SELECT current_schema() INTO schema_name; 59 | EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO nominal_quota; 60 | IF nominal_quota * @extschema@._CDB_AnalysisQuotaFactor() < @extschema@._CDB_AnalysisDataSize(schema_name) THEN 61 | -- The limit is defined by a factor applied to the total space quota for the user 62 | RAISE EXCEPTION 'Analysis cache space limits exceeded'; 63 | END IF; 64 | END; 65 | $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; 66 | -------------------------------------------------------------------------------- /scripts-available/CDB_AnalysisSupport.sql: -------------------------------------------------------------------------------- 1 | -- Internal auxiliar functions to deal with [Camshaft](https://github.com/cartodb/camshaft) cached analysis tables. 2 | 3 | -- This function returns TRUE if a given table name corresponds to a Camshaft cached analysis table 4 | -- Scope: private. 5 | CREATE OR REPLACE FUNCTION @extschema@._CDB_IsAnalysisTableName(table_name TEXT) 6 | RETURNS BOOLEAN 7 | AS $$ 8 | BEGIN 9 | RETURN table_name SIMILAR TO '\Aanalysis_[0-9a-f]{10}_[0-9a-f]{40}\Z'; 10 | END; 11 | $$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; 12 | 13 | -- This function returns a relation of Camshaft cached analysis tables in the given schema. 14 | -- If the schema name parameter is NULL, then tables from all schemas 15 | -- that may contain user tables are returned. 16 | -- For each table, the regclass, schema name and table name are returned. 17 | -- Scope: private. 18 | CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisTablesInSchema(schema_name text DEFAULT NULL) 19 | RETURNS TABLE(table_regclass REGCLASS, schema_name TEXT, table_name TEXT) 20 | AS $$ 21 | SELECT * FROM @extschema@._CDB_UserTablesInSchema(schema_name) WHERE @extschema@._CDB_IsAnalysisTableName(table_name); 22 | $$ LANGUAGE 'sql' STABLE PARALLEL SAFE; 23 | 24 | -- This function returns a relation user tables excluding analysis tables 25 | -- If the schema name parameter is NULL, then tables from all schemas 26 | -- that may contain user tables are returned. 27 | -- For each table, the regclass, schema name and table name are returned. 28 | -- Scope: private. 29 | CREATE OR REPLACE FUNCTION @extschema@._CDB_NonAnalysisTablesInSchema(schema_name text DEFAULT NULL) 30 | RETURNS TABLE(table_regclass REGCLASS, schema_name TEXT, table_name TEXT) 31 | AS $$ 32 | SELECT * FROM @extschema@._CDB_UserTablesInSchema(schema_name) WHERE Not @extschema@._CDB_IsAnalysisTableName(table_name); 33 | $$ LANGUAGE 'sql' STABLE PARALLEL SAFE; 34 | 35 | -- Total spaced used up by Camshaft cached analysis tables in the given schema. 36 | -- Scope: private. 37 | CREATE OR REPLACE FUNCTION @extschema@._CDB_AnalysisDataSize(schema_name TEXT DEFAULT NULL) 38 | RETURNS bigint AS 39 | $$ 40 | DECLARE 41 | total_size bigint; 42 | BEGIN 43 | WITH analysis_tables AS ( 44 | SELECT t.schema_name, t.table_name FROM @extschema@._CDB_AnalysisTablesInSchema(schema_name) t 45 | ) 46 | SELECT COALESCE(INT8(SUM(@extschema@._CDB_total_relation_size(analysis_tables.schema_name, analysis_tables.table_name))))::int8 47 | INTO total_size FROM analysis_tables; 48 | IF total_size IS NOT NULL THEN 49 | RETURN total_size; 50 | ELSE 51 | RETURN 0; 52 | END IF; 53 | END; 54 | $$ 55 | LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; 56 | -------------------------------------------------------------------------------- /scripts-available/CDB_ColumnNames.sql: -------------------------------------------------------------------------------- 1 | -- Function returning the column names of a table 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_ColumnNames(REGCLASS) 3 | RETURNS SETOF information_schema.sql_identifier 4 | AS $$ 5 | SELECT 6 | a.attname::information_schema.sql_identifier column_name 7 | FROM pg_class c 8 | LEFT JOIN pg_attribute a ON a.attrelid = c.oid 9 | WHERE c.oid = $1::oid 10 | AND a.attstattarget < 0 -- exclude system columns 11 | ORDER BY a.attnum; 12 | $$ LANGUAGE SQL STABLE PARALLEL SAFE; 13 | 14 | -- This is to migrate from pre-0.2.0 version 15 | -- See http://github.com/CartoDB/cartodb-postgresql/issues/36 16 | GRANT EXECUTE ON FUNCTION @extschema@.CDB_ColumnNames(REGCLASS) TO PUBLIC; 17 | -------------------------------------------------------------------------------- /scripts-available/CDB_ColumnType.sql: -------------------------------------------------------------------------------- 1 | -- Function returning the type of a column 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_ColumnType(REGCLASS, TEXT) 3 | RETURNS information_schema.character_data 4 | AS $$ 5 | SELECT 6 | format_type(a.atttypid, NULL)::information_schema.character_data data_type 7 | FROM pg_class c 8 | LEFT JOIN pg_attribute a ON a.attrelid = c.oid 9 | WHERE c.oid = $1::oid 10 | AND a.attname = $2 11 | AND a.attstattarget < 0; -- exclude system columns 12 | $$ LANGUAGE SQL STABLE PARALLEL SAFE; 13 | 14 | -- This is to migrate from pre-0.2.0 version 15 | -- See http://github.com/CartoDB/cartodb-postgresql/issues/36 16 | GRANT EXECUTE ON FUNCTION @extschema@.CDB_ColumnType(REGCLASS, TEXT) TO public; 17 | -------------------------------------------------------------------------------- /scripts-available/CDB_Conf.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------- 2 | -- CONF MANAGEMENT FUNCTIONS 3 | -- 4 | -- Meant to be used by superadmin user. 5 | -- Functions needing reading configuration should use SECURITY DEFINER. 6 | ---------------------------------- 7 | 8 | -- This will trigger NOTICE if @extschema@.CDB_CONF already exists 9 | DO LANGUAGE 'plpgsql' $$ 10 | BEGIN 11 | CREATE TABLE IF NOT EXISTS @extschema@.CDB_CONF ( KEY TEXT PRIMARY KEY, VALUE JSON NOT NULL ); 12 | END 13 | $$; 14 | 15 | -- This can only be called from an SQL script executed by CREATE EXTENSION 16 | DO LANGUAGE 'plpgsql' $$ 17 | BEGIN 18 | PERFORM pg_catalog.pg_extension_config_dump('@extschema@.CDB_CONF', ''); 19 | END 20 | $$; 21 | 22 | CREATE OR REPLACE 23 | FUNCTION @extschema@.CDB_Conf_SetConf(key text, value JSON) 24 | RETURNS void AS $$ 25 | BEGIN 26 | PERFORM @extschema@.CDB_Conf_RemoveConf(key); 27 | EXECUTE 'INSERT INTO @extschema@.CDB_CONF (KEY, VALUE) VALUES ($1, $2);' USING key, value; 28 | END 29 | $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; 30 | 31 | CREATE OR REPLACE 32 | FUNCTION @extschema@.CDB_Conf_RemoveConf(key text) 33 | RETURNS void AS $$ 34 | BEGIN 35 | EXECUTE 'DELETE FROM @extschema@.CDB_CONF WHERE KEY = $1;' USING key; 36 | END 37 | $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; 38 | 39 | CREATE OR REPLACE 40 | FUNCTION @extschema@.CDB_Conf_GetConf(key text) 41 | RETURNS JSON AS $$ 42 | DECLARE 43 | value JSON; 44 | BEGIN 45 | EXECUTE 'SELECT VALUE FROM @extschema@.CDB_CONF WHERE KEY = $1;' INTO value USING key; 46 | RETURN value; 47 | END 48 | $$ LANGUAGE PLPGSQL STABLE PARALLEL SAFE; 49 | -------------------------------------------------------------------------------- /scripts-available/CDB_DDLTriggers.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Legacy file 3 | -- Introduced again to make sure that updates do not leave dangling functions 4 | -- 5 | 6 | DROP FUNCTION IF EXISTS @extschema@.cdb_handle_create_table(); 7 | DROP FUNCTION IF EXISTS @extschema@.cdb_handle_drop_table(); 8 | DROP FUNCTION IF EXISTS @extschema@.cdb_handle_alter_column(); 9 | DROP FUNCTION IF EXISTS @extschema@.cdb_handle_drop_column(); 10 | DROP FUNCTION IF EXISTS @extschema@.cdb_handle_add_column(); 11 | DROP FUNCTION IF EXISTS @extschema@.cdb_disable_ddl_hooks(); 12 | DROP FUNCTION IF EXISTS @extschema@.cdb_enable_ddl_hooks(); 13 | 14 | 15 | -------------------------------------------------------------------------------- /scripts-available/CDB_DateToNumber.sql: -------------------------------------------------------------------------------- 1 | -- Convert timestamp to double precision 2 | -- 3 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DateToNumber(input timestamp) 4 | RETURNS double precision AS $$ 5 | DECLARE output double precision; 6 | BEGIN 7 | BEGIN 8 | SELECT extract (EPOCH FROM input) INTO output; 9 | EXCEPTION WHEN OTHERS THEN 10 | RETURN NULL; 11 | END; 12 | RETURN output; 13 | END; 14 | $$ 15 | LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; 16 | 17 | -- Convert timestamp with time zone to double precision 18 | -- 19 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DateToNumber(input timestamp with time zone) 20 | RETURNS double precision AS $$ 21 | DECLARE output double precision; 22 | BEGIN 23 | BEGIN 24 | SELECT extract (EPOCH FROM input) INTO output; 25 | EXCEPTION WHEN OTHERS THEN 26 | RETURN NULL; 27 | END; 28 | RETURN output; 29 | END; 30 | $$ 31 | LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; 32 | -------------------------------------------------------------------------------- /scripts-available/CDB_DigitSeparator.sql: -------------------------------------------------------------------------------- 1 | -- Find thousand and decimal digits separators 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DigitSeparator (rel REGCLASS, fld TEXT, OUT t CHAR, OUT d CHAR) 3 | as $$ 4 | DECLARE 5 | sql TEXT; 6 | rec RECORD; 7 | BEGIN 8 | 9 | -- We're only interested in rows with either "," or '.' 10 | sql := 'SELECT ' || quote_ident(fld) || ' as f FROM ' || rel::text 11 | || ' WHERE ' || quote_ident(fld) || ' ~ ''[,.]'''; 12 | 13 | FOR rec IN EXECUTE sql 14 | LOOP 15 | -- Any separator appearing more than once 16 | -- will be assumed to be thousand separator 17 | IF rec.f ~ ',.*,' THEN 18 | t := ','; d := '.'; 19 | RETURN; 20 | ELSIF rec.f ~ '\..*\.' THEN 21 | t := '.'; d := ','; 22 | RETURN; 23 | END IF; 24 | 25 | -- If both separator are present, rightmost 26 | -- will be assumed to be decimal separator 27 | IF rec.f ~ '\.' AND rec.f ~ ',' THEN 28 | rec.f = reverse(rec.f); 29 | IF strpos(rec.f, ',') < strpos(rec.f, '.') THEN 30 | t := '.'; d := ','; 31 | ELSE 32 | t := ','; d := '.'; 33 | END IF; 34 | RETURN; 35 | END IF; 36 | 37 | -- A separator NOT followed by 3 digits 38 | -- will be assumed to be decimal separator 39 | IF rec.f ~ ',' AND rec.f !~ '(,[0-9]{3}$)|(,[0-9]{3}[,.])' THEN 40 | t := '.'; d := ','; 41 | RETURN; 42 | ELSIF rec.f ~ '\.' AND rec.f !~ '(\.[0-9]{3}$)|(\.[0-9]{3}[,.])' THEN 43 | t := ','; d := '.'; 44 | RETURN; 45 | END IF; 46 | 47 | -- Otherwise continue looking 48 | 49 | END LOOP; 50 | 51 | END 52 | $$ 53 | LANGUAGE 'plpgsql' STABLE STRICT PARALLEL SAFE; 54 | -------------------------------------------------------------------------------- /scripts-available/CDB_DistType.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- CDB_DistType classifies the histograms of a column into 3 | -- one of the basic types listed by Galtung: http://druedin.com/2012/12/08/galtungs-ajus-system/ 4 | -- 5 | -- Future improvements: 6 | -- variable number of bins (7 is baked in right now) 7 | -- catch the number of items to ensure that the sample is large enough 8 | -- 9 | -- Refs: 10 | -- 1. width_bucket/histograms: http://tapoueh.org/blog/2014/02/21-PostgreSQL-histogram 11 | -- 2. R implementation: https://github.com/cran/agrmt 12 | 13 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DistType ( in_array NUMERIC[] ) RETURNS text as $$ 14 | DECLARE 15 | element_count INT4; 16 | minv numeric; 17 | maxv numeric; 18 | bins numeric[]; 19 | freqs numeric[]; 20 | ajus INT[]; 21 | freq INT4; 22 | signature text; 23 | i INT := 1; 24 | BEGIN 25 | SELECT min(e), max(e), count(e) INTO minv, maxv, element_count FROM ( SELECT unnest(in_array) e ) x; 26 | 27 | IF abs(maxv - minv) < 1e-7 THEN -- if max and min are nearly equal, call if 'F' (make relative to maxv?) 28 | signature = 'F'; 29 | ELSE 30 | -- Calculate bins and count in bins 31 | EXECUTE 'WITH stats as ( 32 | SELECT min(e) as minv, 33 | max(e) as maxv, 34 | count(e) as total 35 | FROM (SELECT unnest($1) e) x 36 | WHERE e is not null 37 | ), 38 | hist as ( 39 | SELECT width_bucket(e, s.minv, s.maxv, 7) bucket, 40 | count(*) freq 41 | FROM (SELECT unnest($1) e) x, stats s 42 | WHERE e is not null 43 | GROUP BY 1 44 | ORDER BY 1 45 | ) 46 | SELECT array_agg(round(100.0 * hist.freq::numeric / stats.total::numeric,1)) freqs, 47 | array_agg(hist.bucket) buckets 48 | FROM hist, stats' 49 | INTO freqs, bins 50 | USING in_array; 51 | 52 | LOOP 53 | IF i < 7 THEN 54 | ajus[i] = CASE WHEN freqs[i] > freqs[i+1] THEN -1 55 | WHEN abs(freqs[i] - freqs[i+1]) <= 0.05 THEN 0 56 | ELSE 1 END; 57 | ELSE 58 | EXIT; 59 | END IF; 60 | i := i + 1; 61 | END LOOP; 62 | 63 | signature = @extschema@._CDB_DistTypeClassify(ajus); 64 | END IF; 65 | 66 | RETURN signature; 67 | END; 68 | $$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; 69 | 70 | -- Classify data into AJUSFL 71 | 72 | CREATE OR REPLACE FUNCTION @extschema@._CDB_DistTypeClassify ( in_array INT[] ) RETURNS text as $$ 73 | DECLARE 74 | element_count INT4; 75 | maxv numeric; 76 | minv numeric; 77 | uniques INT[]; 78 | type text; 79 | BEGIN 80 | SELECT max(e), min(e) INTO maxv, minv FROM ( SELECT unnest(in_array) e ) x; 81 | 82 | IF (maxv = 0 AND minv = 0) THEN 83 | type = 'F'; 84 | ELSIF maxv < 1 THEN 85 | type = 'L'; 86 | ELSIF minv > -1 THEN 87 | type = 'J'; 88 | ELSE 89 | -- Get distinct elements ordered by original position 90 | EXECUTE 'WITH b AS ( 91 | SELECT a 92 | FROM (SELECT unnest($1) a) x 93 | ), 94 | c AS ( 95 | SELECT a, row_number() OVER () r 96 | FROM b 97 | ), 98 | d AS ( 99 | SELECT DISTINCT a 100 | FROM c 101 | ), 102 | e AS ( 103 | SELECT a FROM d ORDER BY ( 104 | SELECT r FROM c WHERE d.a = c.a ORDER BY r ASC LIMIT 1 105 | ) ASC) 106 | SELECT array_agg(a) FROM e' 107 | INTO uniques 108 | USING in_array; 109 | 110 | -- Decide if it's an A, U, or other 111 | IF (uniques = ARRAY[1,-1] OR uniques = ARRAY[1,0,-1] OR uniques = ARRAY[1,-1,0] OR uniques = ARRAY[0,1,-1]) THEN 112 | type = 'A'; 113 | ELSIF (uniques = ARRAY[-1,1] OR uniques = ARRAY[-1,0,1] OR uniques = ARRAY[-1,1,0] OR uniques = ARRAY[0,-1,1]) THEN 114 | type = 'U'; 115 | ELSE 116 | type = 'S'; 117 | END IF; 118 | END IF; 119 | 120 | RETURN type; 121 | END; 122 | $$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; 123 | -------------------------------------------------------------------------------- /scripts-available/CDB_DistinctMeasure.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- CDB_DistinctMeasure 3 | -- calculates the fraction of rows in the 10 most common distinct categories 4 | -- returns true if the number of rows in these 10 categories is >= 0.9 * total number of rows 5 | -- 6 | -- 7 | 8 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DistinctMeasure ( in_array text[], threshold numeric DEFAULT null ) RETURNS numeric as $$ 9 | DECLARE 10 | element_count INT4; 11 | maxval numeric; 12 | passes numeric; 13 | BEGIN 14 | SELECT count(e) INTO element_count FROM ( SELECT unnest(in_array) e ) x; 15 | 16 | -- count number of occurrences per bin 17 | -- calculate the normalized cumulative sum 18 | -- return the max value: which corresponds nth entry 19 | -- for n <= 10 depending on # of distinct values 20 | EXECUTE 'WITH a As ( 21 | SELECT 22 | count(*) cnt 23 | FROM 24 | (SELECT * FROM unnest($2) e ) x 25 | WHERE e is not null 26 | GROUP BY e 27 | ORDER BY cnt DESC 28 | ), 29 | b As ( 30 | SELECT 31 | sum(cnt) OVER (ORDER BY cnt DESC) / $1 As cumsum 32 | FROM a 33 | LIMIT 10 34 | ) 35 | SELECT max(cumsum) maxval FROM b' 36 | INTO maxval 37 | USING element_count, in_array; 38 | IF threshold is null THEN 39 | passes = maxval; 40 | ELSE 41 | passes = CASE WHEN (maxval >= threshold) THEN 1 ELSE 0 END; 42 | END IF; 43 | 44 | RETURN passes; 45 | END; 46 | $$ language plpgsql IMMUTABLE PARALLEL SAFE; 47 | -------------------------------------------------------------------------------- /scripts-available/CDB_EqualIntervalBins.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Calculate the equal interval bins for a given column 3 | -- 4 | -- @param in_array An array of numbers to determine the best 5 | -- bin boundary 6 | -- 7 | -- @param breaks The number of bins you want to find. 8 | -- 9 | -- 10 | -- Returns: upper edges of bins 11 | -- 12 | -- 13 | 14 | CREATE OR REPLACE FUNCTION @extschema@.CDB_EqualIntervalBins ( in_array anyarray, breaks INT ) RETURNS anyarray as $$ 15 | WITH stats AS ( 16 | SELECT min(e), (max(e)-min(e))/breaks AS del 17 | FROM (SELECT unnest(in_array) e) AS p) 18 | SELECT array_agg(bins) 19 | FROM ( 20 | SELECT min + generate_series(1,breaks)*del AS bins 21 | FROM stats) q; 22 | $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE; 23 | 24 | DROP FUNCTION IF EXISTS @extschema@.CDB_EqualIntervalBins( numeric[], integer); 25 | -------------------------------------------------------------------------------- /scripts-available/CDB_EstimateRowCount.sql: -------------------------------------------------------------------------------- 1 | -- Internal function to generate stats for a table if they don't exist 2 | CREATE OR REPLACE FUNCTION @extschema@._CDB_GenerateStats(reloid REGCLASS) 3 | RETURNS VOID 4 | AS $$ 5 | DECLARE 6 | has_stats BOOLEAN; 7 | BEGIN 8 | SELECT EXISTS ( 9 | SELECT * FROM pg_catalog.pg_statistic WHERE starelid = reloid 10 | ) INTO has_stats; 11 | IF NOT has_stats THEN 12 | EXECUTE Format('ANALYZE %s;', reloid); 13 | END IF; 14 | END 15 | $$ LANGUAGE 'plpgsql' 16 | VOLATILE 17 | STRICT 18 | PARALLEL UNSAFE 19 | SECURITY DEFINER 20 | SET search_path = pg_temp; 21 | 22 | -- Return a row count estimate of the result of a query using statistics 23 | CREATE OR REPLACE FUNCTION @extschema@.CDB_EstimateRowCount(query text) 24 | RETURNS Numeric 25 | AS $$ 26 | DECLARE 27 | plan JSON; 28 | BEGIN 29 | -- Make sure statistics exist for all the tables of the query 30 | PERFORM @extschema@._CDB_GenerateStats(tabname) FROM unnest(@extschema@.CDB_QueryTablesText(query)) AS tabname; 31 | 32 | -- Use the query planner to obtain an estimate of the number of result rows 33 | EXECUTE 'EXPLAIN (FORMAT JSON) ' || query INTO STRICT plan; 34 | RETURN plan->0->'Plan'->'Plan Rows'; 35 | END 36 | $$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 37 | -------------------------------------------------------------------------------- /scripts-available/CDB_ExtensionPost.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.cdb_tablemetadata',''); 2 | 3 | -------------------------------------------------------------------------------- /scripts-available/CDB_ExtensionUtils.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION @extschema@.cdb_extension_reload() RETURNS void 2 | AS $$ 3 | DECLARE 4 | ver TEXT; 5 | sql TEXT; 6 | BEGIN 7 | ver := split_part(@extschema@.cdb_version(), ' ', 1); 8 | sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || 'next'''; 9 | EXECUTE sql; 10 | sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || ''''; 11 | EXECUTE sql; 12 | END; 13 | $$ language 'plpgsql' VOLATILE PARALLEL UNSAFE; 14 | 15 | CREATE OR REPLACE FUNCTION @extschema@.schema_exists(schema_name text) 16 | RETURNS boolean AS 17 | $$ 18 | SELECT EXISTS(SELECT 1 FROM pg_namespace WHERE nspname = schema_name::text); 19 | $$ 20 | language sql STABLE PARALLEL SAFE; 21 | -------------------------------------------------------------------------------- /scripts-available/CDB_GhostTables.sql: -------------------------------------------------------------------------------- 1 | -- Enqueues a job to run Ghost tables linking process for the provided username 2 | CREATE OR REPLACE FUNCTION @extschema@._CDB_LinkGhostTables(username text, db_name text, event_name text) 3 | RETURNS void 4 | AS $$ 5 | if not username: 6 | return 7 | 8 | if 'json' not in GD: 9 | import json 10 | GD['json'] = json 11 | else: 12 | json = GD['json'] 13 | 14 | tis_config = plpy.execute("select @extschema@.CDB_Conf_GetConf('invalidation_service');")[0]['cdb_conf_getconf'] 15 | if not tis_config: 16 | plpy.warning('Invalidation service configuration not found. Skipping Ghost Tables linking.') 17 | return 18 | 19 | tis_config_dict = json.loads(tis_config) 20 | tis_host = tis_config_dict.get('host') 21 | tis_port = tis_config_dict.get('port') 22 | tis_timeout = tis_config_dict.get('timeout', 5) 23 | tis_retry = tis_config_dict.get('retry', 5) 24 | 25 | client = GD.get('invalidation', None) 26 | 27 | while True: 28 | 29 | if not client: 30 | try: 31 | import redis 32 | client = redis.Redis(host=tis_host, port=tis_port, socket_timeout=tis_timeout) 33 | GD['invalidation'] = client 34 | except Exception as err: 35 | # NOTE: no retries on connection error 36 | plpy.warning('Error trying to connect to Invalidation Service to link Ghost Tables: ' + str(err)) 37 | break 38 | 39 | try: 40 | client.execute_command('DBSCH', db_name, username, event_name) 41 | break 42 | except Exception as err: 43 | client = GD['invalidation'] = None # force reconnect 44 | if not tis_retry: 45 | plpy.warning('Error calling Invalidation Service to link Ghost Tables: ' + str(err)) 46 | break 47 | tis_retry -= 1 # try reconnecting 48 | $$ LANGUAGE '@@plpythonu@@' VOLATILE PARALLEL UNSAFE; 49 | 50 | -- Enqueues a job to run Ghost tables linking process for the current user 51 | CREATE OR REPLACE FUNCTION @extschema@.CDB_LinkGhostTables(event_name text DEFAULT 'USER') 52 | RETURNS void 53 | AS $$ 54 | DECLARE 55 | username TEXT; 56 | db_name TEXT; 57 | BEGIN 58 | EXECUTE 'SELECT @extschema@.CDB_Username();' INTO username; 59 | EXECUTE 'SELECT current_database();' INTO db_name; 60 | 61 | PERFORM @extschema@._CDB_LinkGhostTables(username, db_name, event_name); 62 | RAISE INFO '_CDB_LinkGhostTables() called with username=%, event_name=%', username, event_name; 63 | END; 64 | $$ LANGUAGE plpgsql 65 | VOLATILE 66 | PARALLEL UNSAFE 67 | SECURITY DEFINER 68 | SET search_path = pg_temp; 69 | 70 | -- Trigger function to call CDB_LinkGhostTables() 71 | CREATE OR REPLACE FUNCTION @extschema@._CDB_LinkGhostTablesTrigger() 72 | RETURNS trigger 73 | AS $$ 74 | DECLARE 75 | ddl_tag TEXT; 76 | BEGIN 77 | EXECUTE 'DELETE FROM @extschema@.cdb_ddl_execution WHERE txid = txid_current() RETURNING tag;' INTO ddl_tag; 78 | PERFORM @extschema@.CDB_LinkGhostTables(ddl_tag); 79 | RETURN NULL; 80 | END; 81 | $$ LANGUAGE plpgsql 82 | VOLATILE 83 | PARALLEL UNSAFE 84 | SECURITY DEFINER 85 | SET search_path = pg_temp; 86 | 87 | -- Event trigger to save the current transaction in @extschema@.cdb_ddl_execution 88 | CREATE OR REPLACE FUNCTION @extschema@.CDB_SaveDDLTransaction() 89 | RETURNS event_trigger 90 | AS $$ 91 | BEGIN 92 | INSERT INTO @extschema@.cdb_ddl_execution VALUES (txid_current(), tg_tag) ON CONFLICT ON CONSTRAINT cdb_ddl_execution_pkey DO NOTHING; 93 | END; 94 | $$ LANGUAGE plpgsql 95 | VOLATILE 96 | PARALLEL UNSAFE 97 | SECURITY DEFINER 98 | SET search_path = pg_temp; 99 | 100 | -- Creates the trigger on DDL events to link ghost tables 101 | CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableGhostTablesTrigger() 102 | RETURNS void 103 | AS $$ 104 | BEGIN 105 | DROP EVENT TRIGGER IF EXISTS link_ghost_tables; 106 | DROP TRIGGER IF EXISTS check_ddl_update ON @extschema@.cdb_ddl_execution; 107 | 108 | -- Table to store the transaction id from DDL events to avoid multiple executions 109 | CREATE TABLE IF NOT EXISTS @extschema@.cdb_ddl_execution(txid bigint PRIMARY KEY, tag text); 110 | 111 | CREATE CONSTRAINT TRIGGER check_ddl_update 112 | AFTER INSERT ON @extschema@.cdb_ddl_execution 113 | INITIALLY DEFERRED 114 | FOR EACH ROW 115 | EXECUTE PROCEDURE @extschema@._CDB_LinkGhostTablesTrigger(); 116 | 117 | CREATE EVENT TRIGGER link_ghost_tables 118 | ON ddl_command_end 119 | WHEN TAG IN ('CREATE TABLE', 120 | 'SELECT INTO', 121 | 'DROP TABLE', 122 | 'ALTER TABLE', 123 | 124 | 'CREATE TRIGGER', 125 | 'DROP TRIGGER', 126 | 'ALTER TRIGGER', 127 | 128 | 'CREATE VIEW', 129 | 'DROP VIEW', 130 | 'ALTER VIEW', 131 | 132 | 'CREATE FOREIGN TABLE', 133 | 'ALTER FOREIGN TABLE', 134 | 'DROP FOREIGN TABLE', 135 | 136 | 'ALTER MATERIALIZED VIEW', 137 | 'CREATE MATERIALIZED VIEW', 138 | 'DROP MATERIALIZED VIEW', 139 | 140 | 'IMPORT FOREIGN SCHEMA', 141 | 142 | 'DROP EXTENSION', 143 | 'DROP SCHEMA', 144 | 'DROP SERVER', 145 | 'DROP TYPE') 146 | EXECUTE PROCEDURE @extschema@.CDB_SaveDDLTransaction(); 147 | END; 148 | $$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; 149 | 150 | -- Drops the trigger on DDL events to link ghost tables 151 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DisableGhostTablesTrigger() 152 | RETURNS void 153 | AS $$ 154 | BEGIN 155 | DROP EVENT TRIGGER IF EXISTS link_ghost_tables; 156 | DROP TRIGGER IF EXISTS check_ddl_update ON @extschema@.cdb_ddl_execution; 157 | DROP TABLE IF EXISTS @extschema@.cdb_ddl_execution; 158 | END; 159 | $$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; 160 | -------------------------------------------------------------------------------- /scripts-available/CDB_GreatCircle.sql: -------------------------------------------------------------------------------- 1 | -- Great circle point-to-point routes, based on: 2 | -- http://blog.cartodb.com/jets-and-datelines/ 3 | -- 4 | CREATE OR REPLACE FUNCTION @extschema@.CDB_GreatCircle(start_point @postgisschema@.geometry, end_point @postgisschema@.geometry, max_segment_length NUMERIC DEFAULT 100000) 5 | RETURNS @postgisschema@.geometry AS $$ 6 | DECLARE 7 | line @postgisschema@.geometry; 8 | BEGIN 9 | line = @postgisschema@.ST_Segmentize( 10 | @postgisschema@.ST_Makeline( 11 | start_point, 12 | end_point 13 | )::geography, 14 | max_segment_length 15 | )::geometry; 16 | 17 | IF @postgisschema@.ST_XMax(line) - @postgisschema@.ST_XMin(line) > 180 THEN 18 | line = @postgisschema@.ST_Difference( 19 | @postgisschema@.ST_ShiftLongitude(line), 20 | @postgisschema@.ST_Buffer(@postgisschema@.ST_GeomFromText('LINESTRING(180 90, 180 -90)', 4326), 0.00001) 21 | ); 22 | END IF; 23 | RETURN line; 24 | END; 25 | $$ 26 | LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL SAFE; 27 | -------------------------------------------------------------------------------- /scripts-available/CDB_HeadsTailsBins.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Determine the Heads/Tails classifications from a numeric array 3 | -- 4 | -- @param in_array A numeric array of numbers to determine the best 5 | -- bins based on the Heads/Tails method. 6 | -- 7 | -- @param breaks The number of bins you want to find. 8 | -- 9 | -- 10 | 11 | CREATE OR REPLACE FUNCTION @extschema@.CDB_HeadsTailsBins ( in_array NUMERIC[], breaks INT) RETURNS NUMERIC[] as $$ 12 | DECLARE 13 | element_count INT4; 14 | arr_mean numeric; 15 | i INT := 2; 16 | reply numeric[]; 17 | BEGIN 18 | -- get the total size of our row 19 | element_count := array_upper(in_array, 1) - array_lower(in_array, 1); 20 | -- ensure the ordering of in_array 21 | SELECT array_agg(e) INTO in_array FROM (SELECT unnest(in_array) e ORDER BY e) x; 22 | -- stop if no rows 23 | IF element_count IS NULL THEN 24 | RETURN NULL; 25 | END IF; 26 | -- stop if our breaks are more than our input array size 27 | IF element_count < breaks THEN 28 | RETURN in_array; 29 | END IF; 30 | 31 | -- get our mean value 32 | SELECT avg(v) INTO arr_mean FROM ( SELECT unnest(in_array) as v ) x; 33 | 34 | reply = Array[arr_mean]; 35 | -- slice our bread 36 | LOOP 37 | IF i > breaks THEN EXIT; END IF; 38 | SELECT avg(e) INTO arr_mean FROM ( SELECT unnest(in_array) e) x WHERE e > reply[i-1]; 39 | IF arr_mean IS NOT NULL THEN 40 | reply = array_append(reply, arr_mean); 41 | END IF; 42 | i := i+1; 43 | END LOOP; 44 | RETURN reply; 45 | END; 46 | $$ language plpgsql IMMUTABLE PARALLEL SAFE; 47 | -------------------------------------------------------------------------------- /scripts-available/CDB_Helper.sql: -------------------------------------------------------------------------------- 1 | -- Create a sequence that belongs to the schema of the extension. 2 | -- It will be used to generate unique identifiers within the 3 | 4 | 5 | -- UTF8 safe and length aware. Find a unique identifier with a given prefix 6 | -- and/or suffix and withing a schema. If a schema is not specified, the identifier 7 | -- is guaranteed to be unique for all schemas. 8 | CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Identifier(prefix TEXT, relname TEXT, suffix TEXT, schema TEXT DEFAULT NULL) 9 | RETURNS TEXT 10 | AS $$ 11 | DECLARE 12 | maxlen CONSTANT INTEGER := 63; 13 | 14 | rec RECORD; 15 | usedspace INTEGER; 16 | ident TEXT; 17 | origident TEXT; 18 | candrelname TEXT; 19 | 20 | i INTEGER; 21 | BEGIN 22 | -- Accounts for the XXXX incremental suffix in case the identifier is taken 23 | usedspace := 4; 24 | usedspace := usedspace + coalesce(octet_length(prefix), 0); 25 | usedspace := usedspace + coalesce(octet_length(suffix), 0); 26 | 27 | candrelname := @extschema@._CDB_Octet_Truncate(relname, maxlen - usedspace); 28 | 29 | IF candrelname = '' THEN 30 | PERFORM @extschema@._CDB_Error('prefixes are to long to generate a valid identifier', '_CDB_Unique_Identifier'); 31 | END IF; 32 | 33 | ident := coalesce(prefix, '') || candrelname || coalesce(suffix, ''); 34 | 35 | i := 0; 36 | origident := ident; 37 | 38 | WHILE i < 10000 LOOP 39 | IF schema IS NOT NULL THEN 40 | SELECT c.relname, n.nspname 41 | INTO rec 42 | FROM pg_class c 43 | JOIN pg_namespace n ON c.relnamespace = n.oid 44 | WHERE c.relname = ident 45 | AND n.nspname = schema; 46 | ELSE 47 | SELECT c.relname, n.nspname 48 | INTO rec 49 | FROM pg_class c 50 | JOIN pg_namespace n ON c.relnamespace = n.oid 51 | WHERE c.relname = ident; 52 | END IF; 53 | 54 | IF NOT FOUND THEN 55 | RETURN ident; 56 | END IF; 57 | 58 | ident := origident || i; 59 | i := i + 1; 60 | END LOOP; 61 | 62 | PERFORM @extschema@._CDB_Error('looping too far', '_CDB_Unique_Identifier'); 63 | END; 64 | $$ LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; 65 | 66 | 67 | -- UTF8 safe and length aware. Find a unique identifier for a column with a given prefix 68 | -- and/or suffix based on colname and within a relation specified via reloid. 69 | CREATE OR REPLACE FUNCTION @extschema@._CDB_Unique_Column_Identifier(prefix TEXT, colname TEXT, suffix TEXT, reloid REGCLASS) 70 | RETURNS TEXT 71 | AS $$ 72 | DECLARE 73 | maxlen CONSTANT INTEGER := 63; 74 | 75 | rec RECORD; 76 | candcolname TEXT; 77 | usedspace INTEGER; 78 | ident TEXT; 79 | origident TEXT; 80 | 81 | i INTEGER; 82 | BEGIN 83 | -- Accounts for the XXXX incremental suffix in case the identifier is taken 84 | usedspace := 4; 85 | usedspace := usedspace + coalesce(octet_length(prefix), 0); 86 | usedspace := usedspace + coalesce(octet_length(suffix), 0); 87 | 88 | candcolname := @extschema@._CDB_Octet_Truncate(colname, maxlen - usedspace); 89 | 90 | IF candcolname = '' THEN 91 | PERFORM @extschema@._CDB_Error('prefixes are to long to generate a valid identifier', '_CDB_Unique_Column_Identifier'); 92 | END IF; 93 | 94 | ident := coalesce(prefix, '') || candcolname || coalesce(suffix, ''); 95 | 96 | i := 0; 97 | origident := ident; 98 | 99 | WHILE i < 10000 LOOP 100 | SELECT a.attname 101 | INTO rec 102 | FROM pg_class c 103 | JOIN pg_attribute a ON a.attrelid = c.oid 104 | WHERE NOT a.attisdropped 105 | AND a.attnum > 0 106 | AND c.oid = reloid 107 | AND a.attname = ident; 108 | 109 | IF NOT FOUND THEN 110 | RETURN ident; 111 | END IF; 112 | 113 | ident := origident || i; 114 | i := i + 1; 115 | END LOOP; 116 | 117 | PERFORM @extschema@._CDB_Error('looping too far', '_CDB_Unique_Column_Identifier'); 118 | END; 119 | $$ LANGUAGE 'plpgsql' VOLATILE PARALLEL SAFE; 120 | 121 | 122 | -- Truncates a given string to a max_octets octets taking care 123 | -- not to leave characters in half. UTF8 safe. 124 | CREATE OR REPLACE FUNCTION @extschema@._CDB_Octet_Truncate(string TEXT, max_octets INTEGER) 125 | RETURNS TEXT 126 | AS $$ 127 | DECLARE 128 | extcharlen CONSTANT INTEGER := octet_length('ñ'); 129 | 130 | expected INTEGER; 131 | examined INTEGER; 132 | strlen INTEGER; 133 | 134 | i INTEGER; 135 | BEGIN 136 | 137 | IF max_octets <= 0 THEN 138 | RETURN ''; 139 | ELSIF max_octets >= octet_length(string) THEN 140 | RETURN string; 141 | END IF; 142 | 143 | strlen := char_length(string); 144 | 145 | expected := char_length(string); 146 | examined := octet_length(string); 147 | 148 | IF expected = examined THEN 149 | RETURN left(string, max_octets); 150 | END IF; 151 | 152 | i := max_octets / extcharlen; 153 | 154 | WHILE octet_length(left(string, i)) <= max_octets LOOP 155 | i := i + 1; 156 | END LOOP; 157 | 158 | RETURN left(string, (i - 1)); 159 | END; 160 | $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; 161 | 162 | 163 | -- Checks if a given text representing a qualified or unqualified table name (relation) 164 | -- actually exists in the database. It is meant to be used as a guard for other function/queries. 165 | CREATE OR REPLACE FUNCTION @extschema@._CDB_Table_Exists(table_name_with_optional_schema TEXT) 166 | RETURNS bool 167 | AS $$ 168 | DECLARE 169 | table_exists bool := false; 170 | BEGIN 171 | table_exists := EXISTS(SELECT * FROM pg_class WHERE table_name_with_optional_schema::regclass::oid = oid AND relkind = 'r'); 172 | RETURN table_exists; 173 | EXCEPTION 174 | WHEN invalid_schema_name OR undefined_table THEN 175 | RETURN false; 176 | END; 177 | $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; 178 | -------------------------------------------------------------------------------- /scripts-available/CDB_Hexagon.sql: -------------------------------------------------------------------------------- 1 | -- Return an Hexagon with given center and side (or maximal radius) 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_MakeHexagon(center GEOMETRY, radius FLOAT8) 3 | RETURNS GEOMETRY 4 | AS $$ 5 | SELECT @postgisschema@.ST_MakePolygon(@postgisschema@.ST_MakeLine(geom)) 6 | FROM 7 | ( 8 | SELECT (@postgisschema@.ST_DumpPoints(@postgisschema@.ST_ExteriorRing(@postgisschema@.ST_Buffer($1, $2, 3)))).* 9 | ) as points 10 | WHERE path[1] % 2 != 0 11 | $$ LANGUAGE 'sql' IMMUTABLE STRICT PARALLEL SAFE; 12 | 13 | 14 | -- In older versions of the extension, CDB_HexagonGrid had a different signature 15 | DROP FUNCTION IF EXISTS @extschema@.CDB_HexagonGrid(GEOMETRY, FLOAT8, GEOMETRY); 16 | 17 | -- 18 | -- Fill given extent with an hexagonal coverage 19 | -- 20 | -- @param ext Extent to fill. Only hexagons with center point falling 21 | -- inside the extent (or at the lower or leftmost edge) will 22 | -- be emitted. The returned hexagons will have the same SRID 23 | -- as this extent. 24 | -- 25 | -- @param side Side measure for the hexagon. 26 | -- Maximum diameter will be 2 * side. 27 | -- 28 | -- @param origin Optional origin to allow for exact tiling. 29 | -- If omitted the origin will be 0,0. 30 | -- The parameter is checked for having the same SRID 31 | -- as the extent. 32 | -- 33 | -- @param maxcells Optional maximum number of grid cells to generate; 34 | -- if the grid requires more cells to cover the extent 35 | -- and exception will occur. 36 | ---- 37 | -- DROP FUNCTION IF EXISTS CDB_HexagonGrid(ext GEOMETRY, side FLOAT8); 38 | CREATE OR REPLACE FUNCTION @extschema@.CDB_HexagonGrid(ext GEOMETRY, side FLOAT8, origin GEOMETRY DEFAULT NULL, maxcells INTEGER DEFAULT 512*512) 39 | RETURNS SETOF GEOMETRY 40 | AS $$ 41 | DECLARE 42 | h GEOMETRY; -- hexagon 43 | c GEOMETRY; -- center point 44 | rec RECORD; 45 | hstep FLOAT8; -- horizontal step 46 | vstep FLOAT8; -- vertical step 47 | vstart FLOAT8; 48 | vstartary FLOAT8[]; 49 | vstartidx INTEGER; 50 | hskip BIGINT; 51 | hstart FLOAT8; 52 | hend FLOAT8; 53 | vend FLOAT8; 54 | xoff FLOAT8; 55 | yoff FLOAT8; 56 | xgrd FLOAT8; 57 | ygrd FLOAT8; 58 | srid INTEGER; 59 | BEGIN 60 | 61 | -- | | 62 | -- |hstep| 63 | -- ______ ___ | 64 | -- vstep / \ ___ / 65 | -- ______ \ ___ / \ 66 | -- / \ ___ / 67 | -- 68 | -- 69 | RAISE DEBUG 'Side: %', side; 70 | 71 | vstep := side * sqrt(3); -- x 2 ? 72 | hstep := side * 1.5; 73 | 74 | RAISE DEBUG 'vstep: %', vstep; 75 | RAISE DEBUG 'hstep: %', hstep; 76 | 77 | srid := ST_SRID(ext); 78 | 79 | xoff := 0; 80 | yoff := 0; 81 | 82 | IF origin IS NOT NULL THEN 83 | IF @postgisschema@.ST_SRID(origin) != srid THEN 84 | RAISE EXCEPTION 'SRID mismatch between extent (%) and origin (%)', srid, ST_SRID(origin); 85 | END IF; 86 | xoff := @postgisschema@.ST_X(origin); 87 | yoff := @postgisschema@.ST_Y(origin); 88 | END IF; 89 | 90 | RAISE DEBUG 'X offset: %', xoff; 91 | RAISE DEBUG 'Y offset: %', yoff; 92 | 93 | xgrd := side * 0.5; 94 | ygrd := ( side * sqrt(3) ) / 2.0; 95 | RAISE DEBUG 'X grid size: %', xgrd; 96 | RAISE DEBUG 'Y grid size: %', ygrd; 97 | 98 | -- Tweak horizontal start on hstep*2 grid from origin 99 | hskip := ceil((@postgisschema@.ST_XMin(ext)-xoff)/hstep); 100 | RAISE DEBUG 'hskip: %', hskip; 101 | hstart := xoff + hskip*hstep; 102 | RAISE DEBUG 'hstart: %', hstart; 103 | 104 | -- Tweak vertical start on hstep grid from origin 105 | vstart := yoff + ceil((@postgisschema@.ST_Ymin(ext)-yoff)/vstep)*vstep; 106 | RAISE DEBUG 'vstart: %', vstart; 107 | 108 | hend := @postgisschema@.ST_XMax(ext); 109 | vend := @postgisschema@.ST_YMax(ext); 110 | 111 | IF vstart - (vstep/2.0) < @postgisschema@.ST_YMin(ext) THEN 112 | vstartary := ARRAY[ vstart + (vstep/2.0), vstart ]; 113 | ELSE 114 | vstartary := ARRAY[ vstart - (vstep/2.0), vstart ]; 115 | END IF; 116 | 117 | If maxcells IS NOT NULL AND maxcells > 0 THEN 118 | IF CEIL((CEIL((vend-vstart)/(vstep/2.0)) * CEIL((hend-hstart)/(hstep*2.0/3.0)))/3.0)::integer > maxcells THEN 119 | RAISE EXCEPTION 'The requested grid is too big to be rendered'; 120 | END IF; 121 | END IF; 122 | 123 | vstartidx := abs(hskip)%2; 124 | 125 | RAISE DEBUG 'vstartary: % : %', vstartary[1], vstartary[2]; 126 | RAISE DEBUG 'vstartidx: %', vstartidx; 127 | 128 | c := @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(hstart, vstartary[vstartidx+1]), srid); 129 | h := @postgisschema@.ST_SnapToGrid(@extschema@.CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); 130 | vstartidx := (vstartidx + 1) % 2; 131 | WHILE @postgisschema@.ST_X(c) < hend LOOP -- over X 132 | --RAISE DEBUG 'X loop starts, center point: %', ST_AsText(c); 133 | WHILE @postgisschema@.ST_Y(c) < vend LOOP -- over Y 134 | --RAISE DEBUG 'Center: %', ST_AsText(c); 135 | --h := ST_SnapToGrid(CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); 136 | RETURN NEXT h; 137 | h := @postgisschema@.ST_SnapToGrid(ST_Translate(h, 0, vstep), xoff, yoff, xgrd, ygrd); 138 | c := @postgisschema@.ST_Translate(c, 0, vstep); -- TODO: drop ? 139 | END LOOP; 140 | -- TODO: translate h direcly ... 141 | c := @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(ST_X(c)+hstep, vstartary[vstartidx+1]), srid); 142 | h := @postgisschema@.ST_SnapToGrid(@extschema@.CDB_MakeHexagon(c, side), xoff, yoff, xgrd, ygrd); 143 | vstartidx := (vstartidx + 1) % 2; 144 | END LOOP; 145 | 146 | RETURN; 147 | END 148 | $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; 149 | -------------------------------------------------------------------------------- /scripts-available/CDB_LatLng.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Create a valid GEOMETRY in 4326 from a lat/lng pair 3 | -- 4 | -- @param lat A numeric latitude value. 5 | -- 6 | -- @param lng A numeric longitude value. 7 | -- 8 | -- 9 | 10 | CREATE OR REPLACE FUNCTION @extschema@.CDB_LatLng (lat NUMERIC, lng NUMERIC) RETURNS @postgisschema@.geometry as $$ 11 | SELECT @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(lng,lat), 4326); 12 | $$ language SQL IMMUTABLE PARALLEL SAFE; 13 | 14 | CREATE OR REPLACE FUNCTION @extschema@.CDB_LatLng (lat FLOAT8, lng FLOAT8) RETURNS @postgisschema@.geometry as $$ 15 | SELECT @postgisschema@.ST_SetSRID(@postgisschema@.ST_MakePoint(lng,lat), 4326); 16 | $$ language SQL IMMUTABLE PARALLEL SAFE; 17 | 18 | -------------------------------------------------------------------------------- /scripts-available/CDB_Math.sql: -------------------------------------------------------------------------------- 1 | -- CartoDB Math SQL functions 2 | 3 | 4 | -- Mode 5 | -- https://wiki.postgresql.org/wiki/Aggregate_Mode 6 | 7 | CREATE OR REPLACE FUNCTION @extschema@._CDB_Math_final_mode(anyarray) 8 | RETURNS anyelement AS 9 | $BODY$ 10 | SELECT a 11 | FROM unnest($1) a 12 | GROUP BY 1 13 | ORDER BY COUNT(1) DESC, 1 14 | LIMIT 1; 15 | $BODY$ 16 | LANGUAGE 'sql' IMMUTABLE PARALLEL SAFE; 17 | 18 | DROP AGGREGATE IF EXISTS @extschema@.CDB_Math_Mode(anyelement); 19 | 20 | CREATE AGGREGATE @extschema@.CDB_Math_Mode(anyelement) ( 21 | SFUNC=array_append, 22 | STYPE=anyarray, 23 | FINALFUNC=@extschema@._CDB_Math_final_mode, 24 | PARALLEL = SAFE, 25 | INITCOND='{}' 26 | ); 27 | 28 | -------------------------------------------------------------------------------- /scripts-available/CDB_OAuth.sql: -------------------------------------------------------------------------------- 1 | -- Function that reassign the owner of a table to their ownership_role 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_OAuthReassignTableOwnerOnCreation() 3 | RETURNS event_trigger 4 | AS $$ 5 | DECLARE 6 | obj record; 7 | owner_role text; 8 | creator_role text; 9 | BEGIN 10 | FOR obj IN SELECT * FROM pg_event_trigger_ddl_commands() 11 | LOOP 12 | RAISE DEBUG '% ddl object: % % % %', 13 | tg_tag, 14 | obj.command_tag, 15 | obj.object_type, 16 | obj.schema_name, 17 | obj.object_identity; 18 | IF obj.object_type = 'function' THEN 19 | SELECT rolname FROM pg_proc JOIN pg_roles ON proowner = pg_roles.oid WHERE pg_proc.oid = obj.objid INTO creator_role; 20 | ELSE 21 | SELECT rolname FROM pg_class JOIN pg_roles ON relowner = pg_roles.oid WHERE pg_class.oid = obj.objid INTO creator_role; 22 | END IF; 23 | SELECT value->>'ownership_role_name' from @extschema@.CDB_Conf_GetConf('api_keys_' || quote_ident(creator_role)) value INTO owner_role; 24 | IF owner_role IS NULL OR owner_role = '' THEN 25 | RAISE DEBUG 'owner_role not found'; 26 | CONTINUE; 27 | ELSE 28 | EXECUTE 'ALTER ' || obj.object_type || ' ' || obj.object_identity || ' OWNER TO ' || quote_ident(owner_role); 29 | IF obj.object_type = 'function' THEN 30 | EXECUTE 'GRANT ALL ON FUNCTION ' || obj.object_identity || ' TO ' || QUOTE_IDENT(creator_role); 31 | ELSE 32 | EXECUTE 'GRANT ALL ON ' || obj.object_identity || ' TO ' || QUOTE_IDENT(creator_role); 33 | END IF; 34 | RAISE DEBUG 'Changing ownership from % to %', creator_role, owner_role; 35 | END IF; 36 | END LOOP; 37 | END; 38 | $$ LANGUAGE plpgsql 39 | VOLATILE 40 | PARALLEL UNSAFE 41 | SECURITY DEFINER 42 | SET search_path = pg_temp; 43 | 44 | -- Creates the trigger on DDL events in order to reassign the owner 45 | CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableOAuthReassignTablesTrigger() 46 | RETURNS void 47 | AS $$ 48 | BEGIN 49 | DROP EVENT TRIGGER IF EXISTS oauth_reassign_tables_trigger; 50 | 51 | CREATE EVENT TRIGGER oauth_reassign_tables_trigger 52 | ON ddl_command_end 53 | WHEN TAG IN ('CREATE TABLE', 'CREATE TABLE AS', 'SELECT INTO', 'CREATE VIEW', 'CREATE FOREIGN TABLE', 'CREATE MATERIALIZED VIEW', 'CREATE SEQUENCE', 'CREATE FUNCTION') 54 | EXECUTE PROCEDURE @extschema@.CDB_OAuthReassignTableOwnerOnCreation(); 55 | END; 56 | $$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; 57 | 58 | -- Deletes the trigger on DDL events in order to reassign the owner 59 | CREATE OR REPLACE FUNCTION @extschema@.CDB_DisableOAuthReassignTablesTrigger() 60 | RETURNS void 61 | AS $$ 62 | BEGIN 63 | DROP EVENT TRIGGER IF EXISTS oauth_reassign_tables_trigger; 64 | END; 65 | $$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; 66 | -------------------------------------------------------------------------------- /scripts-available/CDB_QuantileBins.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Determine the Quantile classifications from a numeric array 3 | -- 4 | -- @param in_array A numeric array of numbers to determine the best 5 | -- bins based on the Quantile method. 6 | -- 7 | -- @param breaks The number of bins you want to find. 8 | -- 9 | -- 10 | CREATE OR REPLACE FUNCTION @extschema@.CDB_QuantileBins(in_array numeric[], breaks int) 11 | RETURNS numeric[] 12 | AS $$ 13 | SELECT 14 | percentile_disc(Array(SELECT generate_series(1, breaks) / breaks::numeric)) 15 | WITHIN GROUP (ORDER BY x ASC) AS p 16 | FROM 17 | unnest(in_array) AS x; 18 | $$ language SQL IMMUTABLE STRICT PARALLEL SAFE; 19 | -------------------------------------------------------------------------------- /scripts-available/CDB_QueryStatements.sql: -------------------------------------------------------------------------------- 1 | -- Return an array of statements found in the given query text 2 | -- 3 | -- Regexp curtesy of Hubert Lubaczewski (depesz) 4 | -- Implemented in plpython for performance reasons 5 | -- 6 | CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryStatements(query text) 7 | RETURNS SETOF TEXT AS $$ 8 | import re 9 | pat = re.compile( r'''((?:[^'"$;]+|"[^"]*"|'[^']*'|(\$[^$]*\$).*?\2)+)''', re.DOTALL ) 10 | for match in pat.findall(query): 11 | cleaned = match[0].strip() 12 | if ( cleaned ): 13 | yield cleaned 14 | $$ language '@@plpythonu@@' IMMUTABLE STRICT PARALLEL SAFE; 15 | -------------------------------------------------------------------------------- /scripts-available/CDB_QueryTables.sql: -------------------------------------------------------------------------------- 1 | -- Return an array of table names scanned by a given query 2 | -- 3 | -- Requires PostgreSQL 9.x+ 4 | -- 5 | CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTablesText(query text) 6 | RETURNS text[] 7 | AS $$ 8 | DECLARE 9 | exp XML; 10 | tables text[]; 11 | rec RECORD; 12 | rec2 RECORD; 13 | BEGIN 14 | 15 | tables := '{}'; 16 | 17 | FOR rec IN SELECT @extschema@.CDB_QueryStatements(query) q LOOP 18 | BEGIN 19 | EXECUTE 'EXPLAIN (FORMAT XML, VERBOSE) ' || rec.q INTO STRICT exp; 20 | EXCEPTION WHEN syntax_error THEN 21 | -- We can get a syntax error if the user tries to EXPLAIN a DDL 22 | CONTINUE; 23 | WHEN others THEN 24 | -- TODO: if error is 'relation "xxxxxx" does not exist', take xxxxxx as 25 | -- the affected table ? 26 | RAISE WARNING 'CDB_QueryTables cannot explain query: % (%: %)', rec.q, SQLSTATE, SQLERRM; 27 | RAISE EXCEPTION '%', SQLERRM; 28 | CONTINUE; 29 | END; 30 | 31 | -- Now need to extract all values of 32 | 33 | -- RAISE DEBUG 'Explain: %', exp; 34 | 35 | FOR rec2 IN WITH 36 | inp AS ( 37 | SELECT 38 | xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x, 39 | xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s 40 | ) 41 | SELECT unnest(x)::text as p, unnest(s)::text as sc from inp 42 | LOOP 43 | -- RAISE DEBUG 'tab: %', rec2.p; 44 | -- RAISE DEBUG 'sc: %', rec2.sc; 45 | tables := array_append(tables, format('%s.%s', quote_ident(rec2.sc), quote_ident(rec2.p))); 46 | END LOOP; 47 | 48 | -- RAISE DEBUG 'Tables: %', tables; 49 | 50 | END LOOP; 51 | 52 | -- RAISE DEBUG 'Tables: %', tables; 53 | 54 | -- Remove duplicates and sort by name 55 | IF array_upper(tables, 1) > 0 THEN 56 | WITH dist as ( SELECT DISTINCT unnest(tables)::text as p ORDER BY p ) 57 | SELECT array_agg(p) from dist into tables; 58 | END IF; 59 | 60 | --RAISE DEBUG 'Tables: %', tables; 61 | 62 | return tables; 63 | END 64 | $$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 65 | 66 | 67 | -- Keep CDB_QueryTables with same signature for backwards compatibility. 68 | -- It should probably be removed in the future. 69 | CREATE OR REPLACE FUNCTION @extschema@.CDB_QueryTables(query text) 70 | RETURNS name[] 71 | AS $$ 72 | BEGIN 73 | RETURN @extschema@.CDB_QueryTablesText(query)::name[]; 74 | END 75 | $$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 76 | -------------------------------------------------------------------------------- /scripts-available/CDB_Quota.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION @extschema@._CDB_total_relation_size(_schema_name TEXT, _table_name TEXT) 2 | RETURNS bigint AS 3 | $$ 4 | DECLARE relation_size bigint := 0; 5 | BEGIN 6 | BEGIN 7 | SELECT pg_total_relation_size(format('"%s"."%s"', _schema_name, _table_name)) INTO relation_size; 8 | EXCEPTION 9 | WHEN undefined_table OR OTHERS THEN 10 | RAISE NOTICE '@extschema@._CDB_total_relation_size(''%'', ''%'') caught error: % (%)', _schema_name, _table_name, SQLERRM, SQLSTATE; 11 | END; 12 | RETURN relation_size; 13 | END; 14 | $$ 15 | LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; 16 | 17 | -- Return the estimated size of user data. Used for quota checking. 18 | CREATE OR REPLACE FUNCTION @extschema@.CDB_UserDataSize(schema_name TEXT) 19 | RETURNS bigint AS 20 | $$ 21 | DECLARE 22 | total_size INT8; 23 | raster_available BOOLEAN; 24 | raster_read_query TEXT; 25 | BEGIN 26 | -- Postgis 3+ might not install raster 27 | raster_available := EXISTS ( 28 | SELECT 1 29 | FROM pg_views 30 | WHERE schemaname = '@postgisschema@' 31 | AND viewname = 'raster_overviews' 32 | ); 33 | 34 | IF raster_available THEN 35 | raster_read_query := Format('SELECT o_table_name, r_table_name FROM @postgisschema@.raster_overviews 36 | WHERE o_table_schema = %L AND o_table_catalog = current_database()', schema_name); 37 | ELSE 38 | raster_read_query := 'SELECT NULL::text AS o_table_name, NULL::text AS r_table_name'; 39 | END IF; 40 | EXECUTE Format(' 41 | WITH raster_tables AS ( 42 | %s 43 | ), 44 | user_tables AS ( 45 | SELECT table_name FROM @extschema@._CDB_NonAnalysisTablesInSchema(%L) 46 | ), 47 | table_cat AS ( 48 | SELECT 49 | table_name, 50 | ( 51 | EXISTS(select * from raster_tables where o_table_name = table_name) 52 | OR table_name SIMILAR TO @extschema@._CDB_OverviewTableDiscriminator() || ''[\w\d]*'' 53 | ) AS is_overview, 54 | EXISTS(SELECT * FROM raster_tables WHERE r_table_name = table_name) AS is_raster 55 | FROM user_tables 56 | ), 57 | sizes AS ( 58 | SELECT COALESCE(INT8(SUM(@extschema@._CDB_total_relation_size(%L, table_name)))) table_size, 59 | CASE 60 | WHEN is_overview THEN 0 61 | WHEN is_raster THEN 1 62 | ELSE 0.5 -- Division by 2 is for not counting the_geom_webmercator 63 | END AS multiplier FROM table_cat GROUP BY is_overview, is_raster 64 | ) 65 | SELECT sum(table_size*multiplier)::int8 FROM sizes 66 | ', raster_read_query, schema_name, schema_name) INTO total_size; 67 | 68 | IF total_size IS NOT NULL THEN 69 | RETURN total_size; 70 | ELSE 71 | RETURN 0; 72 | END IF; 73 | END; 74 | $$ 75 | LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; 76 | 77 | 78 | -- Return the estimated size of user data. Used for quota checking. 79 | -- Implicit schema version for backwards compatibility 80 | CREATE OR REPLACE FUNCTION @extschema@.CDB_UserDataSize() 81 | RETURNS bigint AS 82 | $$ 83 | SELECT @extschema@.CDB_UserDataSize('public'); 84 | $$ 85 | LANGUAGE 'sql' VOLATILE PARALLEL UNSAFE; 86 | 87 | -- Triggers cannot have declared arguments: pbfact float8, qmax int8, schema_name text 88 | CREATE OR REPLACE FUNCTION @extschema@.CDB_CheckQuota() 89 | RETURNS trigger AS 90 | $$ 91 | DECLARE 92 | pbfact float8; 93 | qmax int8; 94 | schema_name text; 95 | dice float8; 96 | quota float8; 97 | BEGIN 98 | IF TG_NARGS = 3 THEN 99 | schema_name := TG_ARGV[2]; 100 | IF @extschema@.schema_exists(schema_name) = false THEN 101 | RAISE EXCEPTION 'Invalid schema name "%"', schema_name; 102 | END IF; 103 | ELSE 104 | schema_name := 'public'; 105 | END IF; 106 | 107 | -- By default try to use quota function, and if not present then rely on the one specified by params 108 | BEGIN 109 | EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO qmax; 110 | EXCEPTION WHEN undefined_function THEN 111 | BEGIN 112 | IF TG_NARGS >= 2 AND TG_ARGV[1] <> '-1' THEN 113 | qmax := TG_ARGV[1]; 114 | ELSE 115 | RAISE EXCEPTION 'Missing "%"._CDB_UserQuotaInBytes()', schema_name; 116 | END IF; 117 | END; 118 | END; 119 | 120 | pbfact := TG_ARGV[0]; 121 | 122 | dice := random(); 123 | 124 | IF dice < pbfact THEN 125 | RAISE DEBUG 'Checking quota on table % (dice:%, needed:<%)', TG_RELID::text, dice, pbfact; 126 | 127 | IF qmax = 0 THEN 128 | RETURN NEW; 129 | END IF; 130 | 131 | SELECT @extschema@.CDB_UserDataSize(schema_name) INTO quota; 132 | IF quota > qmax THEN 133 | RAISE EXCEPTION 'Quota exceeded by %KB', (quota-qmax)/1024; 134 | ELSE RAISE DEBUG 'User quota in bytes: % < % (max allowed)', quota, qmax; 135 | END IF; 136 | END IF; 137 | 138 | RETURN NEW; 139 | END; 140 | $$ 141 | LANGUAGE 'plpgsql' VOLATILE PARALLEL UNSAFE; 142 | 143 | 144 | CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUserQuotaInBytes(schema_name text, bytes int8) 145 | RETURNS int8 AS 146 | $$ 147 | DECLARE 148 | sql text; 149 | BEGIN 150 | IF @extschema@.schema_exists(schema_name::text) = false THEN 151 | RAISE EXCEPTION 'Invalid schema name "%"', schema_name::text; 152 | END IF; 153 | 154 | sql := 'CREATE OR REPLACE FUNCTION "' || schema_name::text || '"._CDB_UserQuotaInBytes() ' 155 | || 'RETURNS int8 AS $X$ SELECT ' || bytes 156 | || '::int8 $X$ LANGUAGE sql IMMUTABLE'; 157 | EXECUTE sql; 158 | 159 | return bytes; 160 | END 161 | $$ 162 | LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 163 | 164 | 165 | CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUserQuotaInBytes(bytes int8) 166 | RETURNS int8 AS 167 | $$ 168 | BEGIN 169 | return @extschema@.CDB_SetUserQuotaInBytes('public', bytes); 170 | END; 171 | $$ 172 | LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 173 | -------------------------------------------------------------------------------- /scripts-available/CDB_RandomTids.sql: -------------------------------------------------------------------------------- 1 | 2 | -- { 3 | -- 4 | -- Return random TIDs in a table. 5 | -- 6 | -- You can use like this: 7 | -- 8 | -- SELECT * FROM lots_of_points WHERE ctid = ANY ( 9 | -- ARRAY[ (SELECT CDB_RandomTids('lots_of_points', 100000)) ] 10 | -- ); 11 | -- 12 | -- NOTE: 13 | -- It currently doesn't really do it random, but in a 14 | -- equally-distributed way among all tuples. 15 | -- 16 | -- 17 | -- }{ 18 | CREATE OR REPLACE FUNCTION @extschema@.CDB_RandomTids(in_table regclass, in_nsamples integer) 19 | RETURNS tid[] 20 | AS $$ 21 | DECLARE 22 | class_info RECORD; 23 | tuples_per_page INTEGER; 24 | needed_pages INTEGER; 25 | skip_pages INTEGER; 26 | tidlist TID[]; 27 | pnrec RECORD; 28 | BEGIN 29 | 30 | -- (#) estimate pages and tuples-per-page 31 | -- HINT: pg_class.relpages, pg_class.reltuples 32 | SELECT relpages, reltuples 33 | FROM pg_class WHERE oid = in_table 34 | INTO class_info; 35 | 36 | RAISE DEBUG 'Table % has % pages and % tuples', 37 | in_table::text, class_info.relpages, class_info.reltuples; 38 | 39 | IF in_nsamples > class_info.reltuples THEN 40 | RAISE WARNING 'Table has less tuples than requested'; 41 | -- should just perform a sequencial scan here... 42 | END IF; 43 | 44 | tuples_per_page := floor(class_info.reltuples/class_info.relpages); 45 | needed_pages := ceil(in_nsamples::real/tuples_per_page); 46 | 47 | RAISE DEBUG '% tuples per page, we need % pages for % tuples', 48 | tuples_per_page, needed_pages, in_nsamples; 49 | 50 | -- (#) select random pages 51 | -- TODO: see how good this is first 52 | 53 | skip_pages := floor( (class_info.relpages-needed_pages)/(needed_pages+1) ); 54 | 55 | RAISE DEBUG 'we are going to skip % pages at each iteration', 56 | skip_pages; 57 | 58 | SELECT array_agg(t) FROM ( 59 | SELECT '(' || pn || ',' || tn || ')' as t 60 | FROM generate_series(1, tuples_per_page) x(tn), 61 | generate_series(skip_pages+1, class_info.relpages, skip_pages) y(pn) ) f 62 | INTO tidlist; 63 | 64 | RETURN tidlist; 65 | 66 | END 67 | $$ LANGUAGE 'plpgsql' STABLE STRICT PARALLEL SAFE; 68 | -- } 69 | 70 | -------------------------------------------------------------------------------- /scripts-available/CDB_RectangleGrid.sql: -------------------------------------------------------------------------------- 1 | -- In older versions of the extension, CDB_RectangleGrid had a different signature 2 | DROP FUNCTION IF EXISTS @extschema@.CDB_RectangleGrid(GEOMETRY, FLOAT8, FLOAT8, GEOMETRY); 3 | 4 | -- 5 | -- Fill given extent with a rectangular coverage 6 | -- 7 | -- @param ext Extent to fill. Only rectangles with center point falling 8 | -- inside the extent (or at the lower or leftmost edge) will 9 | -- be emitted. The returned hexagons will have the same SRID 10 | -- as this extent. 11 | -- 12 | -- @param width Width of each rectangle 13 | -- 14 | -- @param height Height of each rectangle 15 | -- 16 | -- @param origin Optional origin to allow for exact tiling. 17 | -- If omitted the origin will be 0,0. 18 | -- The parameter is checked for having the same SRID 19 | -- as the extent. 20 | -- 21 | -- @param maxcells Optional maximum number of grid cells to generate; 22 | -- if the grid requires more cells to cover the extent 23 | -- and exception will occur. 24 | -- 25 | CREATE OR REPLACE FUNCTION @extschema@.CDB_RectangleGrid(ext GEOMETRY, width FLOAT8, height FLOAT8, origin GEOMETRY DEFAULT NULL, maxcells INTEGER DEFAULT 512*512) 26 | RETURNS SETOF GEOMETRY 27 | AS $$ 28 | DECLARE 29 | h GEOMETRY; -- rectangle cell 30 | hstep FLOAT8; -- horizontal step 31 | vstep FLOAT8; -- vertical step 32 | hw FLOAT8; -- half width 33 | hh FLOAT8; -- half height 34 | vstart FLOAT8; 35 | hstart FLOAT8; 36 | hend FLOAT8; 37 | vend FLOAT8; 38 | xoff FLOAT8; 39 | yoff FLOAT8; 40 | xgrd FLOAT8; 41 | ygrd FLOAT8; 42 | x FLOAT8; 43 | y FLOAT8; 44 | srid INTEGER; 45 | BEGIN 46 | 47 | srid := @postgisschema@.ST_SRID(ext); 48 | 49 | xoff := 0; 50 | yoff := 0; 51 | 52 | IF origin IS NOT NULL THEN 53 | IF @postgisschema@.ST_SRID(origin) != srid THEN 54 | RAISE EXCEPTION 'SRID mismatch between extent (%) and origin (%)', srid, ST_SRID(origin); 55 | END IF; 56 | xoff := @postgisschema@.ST_X(origin); 57 | yoff := @postgisschema@.ST_Y(origin); 58 | END IF; 59 | 60 | --RAISE DEBUG 'X offset: %', xoff; 61 | --RAISE DEBUG 'Y offset: %', yoff; 62 | 63 | hw := width/2.0; 64 | hh := height/2.0; 65 | 66 | xgrd := hw; 67 | ygrd := hh; 68 | --RAISE DEBUG 'X grid size: %', xgrd; 69 | --RAISE DEBUG 'Y grid size: %', ygrd; 70 | 71 | hstep := width; 72 | vstep := height; 73 | 74 | -- Tweak horizontal start on hstep grid from origin 75 | hstart := xoff + ceil((@postgisschema@.ST_XMin(ext)-xoff)/hstep)*hstep; 76 | --RAISE DEBUG 'hstart: %', hstart; 77 | 78 | -- Tweak vertical start on vstep grid from origin 79 | vstart := yoff + ceil((@postgisschema@.ST_Ymin(ext)-yoff)/vstep)*vstep; 80 | --RAISE DEBUG 'vstart: %', vstart; 81 | 82 | hend := ST_XMax(ext); 83 | vend := ST_YMax(ext); 84 | 85 | --RAISE DEBUG 'hend: %', hend; 86 | --RAISE DEBUG 'vend: %', vend; 87 | 88 | If maxcells IS NOT NULL AND maxcells > 0 THEN 89 | IF ((hend - hstart)/hstep * (vend - vstart)/vstep)::integer > maxcells THEN 90 | RAISE EXCEPTION 'The requested grid is too big to be rendered'; 91 | END IF; 92 | END IF; 93 | 94 | x := hstart; 95 | WHILE x < hend LOOP -- over X 96 | y := vstart; 97 | h := @postgisschema@.ST_MakeEnvelope(x-hw, y-hh, x+hw, y+hh, srid); 98 | WHILE y < vend LOOP -- over Y 99 | RETURN NEXT h; 100 | h := @postgisschema@.ST_Translate(h, 0, vstep); 101 | y := yoff + round(((y + vstep)-yoff)/ygrd)*ygrd; -- round to grid 102 | END LOOP; 103 | x := xoff + round(((x + hstep)-xoff)/xgrd)*xgrd; -- round to grid 104 | END LOOP; 105 | 106 | RETURN; 107 | END 108 | $$ LANGUAGE 'plpgsql' IMMUTABLE PARALLEL SAFE; 109 | -------------------------------------------------------------------------------- /scripts-available/CDB_SearchPath.sql: -------------------------------------------------------------------------------- 1 | ---- Make sure '@extschema@' is in database search path 2 | DO 3 | $$ 4 | DECLARE 5 | var_result text; 6 | var_cur_search_path text; 7 | BEGIN 8 | SELECT reset_val INTO var_cur_search_path 9 | FROM pg_settings WHERE name = 'search_path'; 10 | 11 | IF var_cur_search_path LIKE '%@extschema@%' THEN 12 | RAISE DEBUG '"@extschema@" already in database search_path'; 13 | ELSE 14 | var_cur_search_path := var_cur_search_path || ', "@extschema@"'; 15 | EXECUTE 'ALTER DATABASE ' || quote_ident(current_database()) || 16 | ' SET search_path = ' || var_cur_search_path; 17 | RAISE DEBUG '"@extschema@" has been added to end of database search_path'; 18 | END IF; 19 | 20 | -- Reset search_path 21 | EXECUTE 'SET search_path = ' || var_cur_search_path; 22 | 23 | END 24 | $$ LANGUAGE 'plpgsql'; 25 | -------------------------------------------------------------------------------- /scripts-available/CDB_Stats.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Calculate basic statistics of a given dataset 3 | -- 4 | -- @param in_array A numeric array of numbers 5 | -- 6 | -- Returns: statistical quantity chosen 7 | -- 8 | -- References: http://www.itl.nist.gov/div898/handbook/eda/section3/eda35b.htm 9 | -- 10 | 11 | -- Calculate kurtosis 12 | CREATE OR REPLACE FUNCTION @extschema@.CDB_Kurtosis ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ 13 | DECLARE 14 | a numeric; 15 | c numeric; 16 | k numeric; 17 | BEGIN 18 | SELECT AVG(e), COUNT(e)::numeric * power(stddev(e),4) INTO a, c FROM ( SELECT unnest(in_array) e ) x; 19 | 20 | IF c=0 THEN 21 | RETURN 0; 22 | ELSE 23 | 24 | EXECUTE 'SELECT sum(power($1 - e, 4)) / ($2 ) - 3 25 | FROM (SELECT unnest($3) e ) x' 26 | INTO k 27 | USING a, c, in_array; 28 | 29 | RETURN k; 30 | END IF; 31 | END; 32 | $$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; 33 | 34 | -- Calculate skewness 35 | CREATE OR REPLACE FUNCTION @extschema@.CDB_Skewness ( in_array NUMERIC[] ) RETURNS NUMERIC as $$ 36 | DECLARE 37 | a numeric; 38 | c numeric; 39 | sk numeric; 40 | BEGIN 41 | SELECT AVG(e), COUNT(e)::numeric * power(stddev(e),3) INTO a, c FROM ( SELECT unnest(in_array) e ) x; 42 | IF c=0 THEN 43 | RETURN 0; 44 | ELSE 45 | EXECUTE 'SELECT sum(power($1 - e, 3)) / ( $2 ) 46 | FROM (SELECT unnest($3) e ) x' 47 | INTO sk 48 | USING a, c, in_array; 49 | 50 | RETURN sk; 51 | END IF; 52 | END; 53 | $$ language plpgsql IMMUTABLE STRICT PARALLEL SAFE; 54 | -------------------------------------------------------------------------------- /scripts-available/CDB_StringToDate.sql: -------------------------------------------------------------------------------- 1 | -- Convert string to date 2 | -- 3 | DROP FUNCTION IF EXISTS @extschema@.CDB_StringToDate(character varying); 4 | CREATE OR REPLACE FUNCTION @extschema@.CDB_StringToDate(input character varying) 5 | RETURNS TIMESTAMP AS $$ 6 | DECLARE output TIMESTAMP; 7 | BEGIN 8 | BEGIN 9 | output := input::date; 10 | EXCEPTION WHEN OTHERS THEN 11 | BEGIN 12 | SELECT to_timestamp(input::integer) INTO output; 13 | EXCEPTION WHEN OTHERS THEN 14 | RETURN NULL; 15 | END; 16 | END; 17 | RETURN output; 18 | END; 19 | $$ 20 | LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; 21 | -------------------------------------------------------------------------------- /scripts-available/CDB_SyncTable.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Gets the column names of a given table. 3 | 4 | Sample usage: 5 | 6 | SELECT @extschema@._CDB_GetColumns('public.films'); 7 | */ 8 | CREATE OR REPLACE FUNCTION @extschema@._CDB_GetColumns(src_table REGCLASS) 9 | RETURNS SETOF NAME 10 | AS $$ 11 | SELECT 12 | a.attname as "colname" 13 | FROM 14 | pg_catalog.pg_attribute a 15 | WHERE 16 | a.attnum > 0 17 | AND NOT a.attisdropped 18 | AND a.attrelid = ( 19 | SELECT c.oid 20 | FROM pg_catalog.pg_class c 21 | LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 22 | WHERE c.oid = src_table::oid 23 | AND pg_catalog.pg_table_is_visible(c.oid) 24 | ) 25 | ORDER BY a.attnum; 26 | $$ LANGUAGE sql STABLE PARALLEL UNSAFE; 27 | 28 | 29 | /* 30 | Given an array of quoted column names, it generates an UPDATE SET 31 | clause with the following form: 32 | 33 | the_geom = changed.the_geom, 34 | id = changed.id, 35 | elevation = changed.elevation 36 | 37 | Example of usage: 38 | 39 | SELECT @extschema@.__CDB_GetUpdateSetClause('{the_geom, id, elevation}', 'changed'); 40 | */ 41 | CREATE OR REPLACE FUNCTION @extschema@.__CDB_GetUpdateSetClause(colnames TEXT[], update_source TEXT) 42 | RETURNS TEXT 43 | AS $$ 44 | DECLARE 45 | set_clause_list TEXT[]; 46 | col TEXT; 47 | BEGIN 48 | FOREACH col IN ARRAY colnames 49 | LOOP 50 | set_clause_list := array_append(set_clause_list, format('%1$s = %2$s.%1$s', col, update_source)); 51 | END lOOP; 52 | RETURN array_to_string(set_clause_list, ', '); 53 | END; 54 | $$ LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE; 55 | 56 | 57 | /* 58 | Given a prefix, generate a safe unique NAME for a temp table. 59 | 60 | Example of usage: 61 | 62 | SELECT @extschema@.__CDB_GenerateUniqueName('src_sync'); --> src_sync_718794_120106 63 | 64 | */ 65 | CREATE OR REPLACE FUNCTION @extschema@.__CDB_GenerateUniqueName(prefix TEXT) 66 | RETURNS NAME 67 | AS $$ 68 | SELECT format('%s_%s_%s', prefix, txid_current(), (random()*1000000)::int)::NAME; 69 | $$ LANGUAGE sql VOLATILE PARALLEL UNSAFE; 70 | 71 | /* 72 | Given a table name and an array of column names, 73 | return array of column names qualified with the table name and quoted when necessary 74 | tablename and colnames should be properly quoted, and for this reason the type NAME is not 75 | used for them (with quotes they could exceed the maximum identifier length) 76 | 77 | Example of usage: 78 | 79 | SELECT @extschema@.__CDB_QualifyColumns('t', ARRAY['a','"b-1"']); --> ARRAY['t.a','t."b-1"'] 80 | 81 | */ 82 | CREATE OR REPLACE FUNCTION @extschema@.__CDB_QualifyColumns(tablename NAME, colnames NAME[]) RETURNS TEXT[] AS 83 | $$ 84 | SELECT array_agg(tablename || '.' || _colname) from unnest(colnames) _colname; 85 | $$ LANGUAGE sql IMMUTABLE PARALLEL SAFE; 86 | 87 | /* 88 | A Table Syncer 89 | 90 | Assumptions: 91 | - Both tables contain a consistent cartodb_id column 92 | - Destination table has all columns of the source or does not exist 93 | 94 | Sample usage: 95 | 96 | SELECT CDB_SyncTable('radar_stations', 'public', 'syncdest'); 97 | SELECT CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest', '{the_geom, the_geom_webmercator}'); 98 | 99 | */ 100 | CREATE OR REPLACE FUNCTION @extschema@.CDB_SyncTable(src_table REGCLASS, dst_schema REGNAMESPACE, dst_table NAME, skip_cols NAME[] = '{}') 101 | RETURNS void 102 | AS $$ 103 | DECLARE 104 | fq_dest_table TEXT; 105 | 106 | colnames TEXT[]; 107 | dst_colnames TEXT; 108 | src_colnames TEXT; 109 | 110 | update_set_clause TEXT; 111 | 112 | num_rows BIGINT; 113 | err_context text; 114 | 115 | t timestamptz; 116 | BEGIN 117 | -- If the destination table does not exist, just copy the source table 118 | fq_dest_table := format('%s.%I', dst_schema, dst_table); 119 | EXECUTE format('CREATE TABLE IF NOT EXISTS %s as TABLE %s', fq_dest_table, src_table); 120 | GET DIAGNOSTICS num_rows = ROW_COUNT; 121 | IF num_rows > 0 THEN 122 | RAISE NOTICE 'INSERTED % row(s)', num_rows; 123 | RETURN; 124 | END IF; 125 | 126 | skip_cols := skip_cols || '{cartodb_id}'; 127 | 128 | -- Get the list of columns from the source table, excluding skip_cols 129 | SELECT ARRAY(SELECT quote_ident(c) FROM @extschema@._CDB_GetColumns(src_table) as c EXCEPT SELECT unnest(skip_cols)) INTO colnames; 130 | 131 | -- Deal with deleted rows: ids in dest but not in source 132 | t := clock_timestamp(); 133 | EXECUTE format( 134 | 'DELETE FROM %1$s _dst WHERE NOT EXISTS (SELECT * FROM %2$s _src WHERE _src.cartodb_id=_dst.cartodb_id)', 135 | fq_dest_table, src_table); 136 | GET DIAGNOSTICS num_rows = ROW_COUNT; 137 | RAISE NOTICE 'DELETED % row(s)', num_rows; 138 | RAISE DEBUG 'DELETE time (s): %', clock_timestamp() - t; 139 | 140 | -- Deal with inserted rows: ids in source but not in dest 141 | t := clock_timestamp(); 142 | EXECUTE format(' 143 | INSERT INTO %1$s(cartodb_id, %2$s) 144 | SELECT cartodb_id, %2$s FROM %3$s _src WHERE NOT EXISTS (SELECT * FROM %1$s _dst WHERE _src.cartodb_id=_dst.cartodb_id) 145 | ', fq_dest_table, array_to_string(colnames, ','), src_table); 146 | GET DIAGNOSTICS num_rows = ROW_COUNT; 147 | RAISE NOTICE 'INSERTED % row(s)', num_rows; 148 | RAISE DEBUG 'INSERT time (s): %', clock_timestamp() - t; 149 | 150 | -- Deal with modified rows: ids in source and dest but different hashes 151 | t := clock_timestamp(); 152 | update_set_clause := @extschema@.__CDB_GetUpdateSetClause(colnames, '_changed'); 153 | dst_colnames := array_to_string(@extschema@.__CDB_QualifyColumns('_dst', colnames), ','); 154 | src_colnames := array_to_string(@extschema@.__CDB_QualifyColumns('_src', colnames), ','); 155 | EXECUTE format(' 156 | UPDATE %1$s _update SET %2$s 157 | FROM ( 158 | SELECT _src.* FROM %3$s _src JOIN %1$s _dst ON (_dst.cartodb_id = _src.cartodb_id) 159 | WHERE md5(ROW(%4$s)::text) <> md5(ROW(%5$s)::text) 160 | ) _changed 161 | WHERE _update.cartodb_id = _changed.cartodb_id; 162 | ', fq_dest_table, update_set_clause, src_table, dst_colnames, src_colnames); 163 | GET DIAGNOSTICS num_rows = ROW_COUNT; 164 | RAISE NOTICE 'MODIFIED % row(s)', num_rows; 165 | RAISE DEBUG 'UPDATE time (s): %', clock_timestamp() - t; 166 | END; 167 | $$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE; 168 | -------------------------------------------------------------------------------- /scripts-available/CDB_TableIndexes.sql: -------------------------------------------------------------------------------- 1 | -- Function returning indexes for a table 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_TableIndexes(REGCLASS) 3 | RETURNS TABLE(index_name name, index_unique bool, index_primary bool, index_keys text array) 4 | AS $$ 5 | 6 | SELECT pg_class.relname as index_name, 7 | idx.indisunique as index_unique, 8 | idx.indisprimary as index_primary, 9 | ARRAY( 10 | SELECT pg_get_indexdef(idx.indexrelid, k + 1, true) 11 | FROM generate_subscripts(idx.indkey, 1) as k 12 | ORDER BY k 13 | ) as index_keys 14 | FROM pg_indexes, 15 | pg_index as idx 16 | JOIN pg_class 17 | ON pg_class.oid = idx.indexrelid 18 | WHERE pg_indexes.tablename = '' || $1 || '' 19 | AND '' || $1 || '' IN (SELECT @extschema@.CDB_UserTables()) 20 | AND pg_class.relname=pg_indexes.indexname 21 | ; 22 | 23 | $$ LANGUAGE SQL STABLE PARALLEL SAFE; 24 | 25 | -- This is to migrate from pre-0.2.0 version 26 | -- See http://github.com/CartoDB/cartodb-postgresql/issues/36 27 | GRANT EXECUTE ON FUNCTION @extschema@.CDB_TableIndexes(REGCLASS) TO public; 28 | -------------------------------------------------------------------------------- /scripts-available/CDB_TableMetadata.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE TABLE IF NOT EXISTS 3 | @extschema@.CDB_TableMetadata ( 4 | tabname regclass not null primary key, 5 | updated_at timestamp with time zone not null default now() 6 | ); 7 | 8 | CREATE OR REPLACE VIEW @extschema@.CDB_TableMetadata_Text AS 9 | SELECT FORMAT('%I.%I', n.nspname::text, c.relname::text) tabname, updated_at 10 | FROM @extschema@.CDB_TableMetadata m JOIN pg_catalog.pg_class c ON m.tabname::oid = c.oid 11 | LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid; 12 | 13 | -- No one can see this 14 | -- Updates are only possible trough the security definer trigger 15 | -- GRANT SELECT ON @extschema@.CDB_TableMetadata TO public; 16 | 17 | -- 18 | -- Trigger logging updated_at in the CDB_TableMetadata 19 | -- and notifying cdb_tabledata_update with table name as payload. 20 | -- 21 | -- Attach to tables like this: 22 | -- 23 | -- CREATE trigger track_updates 24 | -- AFTER INSERT OR UPDATE OR TRUNCATE OR DELETE ON 25 | -- FOR EACH STATEMENT 26 | -- EXECUTE PROCEDURE cdb_tablemetadata_trigger(); 27 | -- 28 | -- NOTE: _never_ attach to CDB_TableMetadata ... 29 | -- 30 | CREATE OR REPLACE FUNCTION @extschema@.CDB_TableMetadata_Trigger() 31 | RETURNS trigger AS 32 | $$ 33 | BEGIN 34 | -- Guard against infinite loop 35 | IF TG_RELID = '@extschema@.CDB_TableMetadata'::regclass::oid THEN 36 | RETURN NULL; 37 | END IF; 38 | 39 | -- Cleanup stale entries 40 | DELETE FROM @extschema@.CDB_TableMetadata 41 | WHERE NOT EXISTS ( 42 | SELECT oid FROM pg_class WHERE oid = tabname 43 | ); 44 | 45 | WITH nv as ( 46 | SELECT TG_RELID as tabname, now() as t 47 | ), updated as ( 48 | UPDATE @extschema@.CDB_TableMetadata x SET updated_at = nv.t 49 | FROM nv WHERE x.tabname = nv.tabname 50 | RETURNING x.tabname 51 | ) 52 | INSERT INTO @extschema@.CDB_TableMetadata SELECT nv.* 53 | FROM nv LEFT JOIN updated USING(tabname) 54 | WHERE updated.tabname IS NULL; 55 | 56 | RETURN NULL; 57 | END; 58 | $$ LANGUAGE plpgsql 59 | VOLATILE 60 | PARALLEL UNSAFE 61 | SECURITY DEFINER 62 | SET search_path = pg_temp; 63 | 64 | -- 65 | -- Trigger invalidating varnish whenever CDB_TableMetadata 66 | -- record change. 67 | -- 68 | CREATE OR REPLACE FUNCTION @extschema@._CDB_TableMetadata_Updated() 69 | RETURNS trigger AS 70 | $$ 71 | DECLARE 72 | tabname regclass; 73 | rec RECORD; 74 | found BOOL; 75 | schema_name TEXT; 76 | table_name TEXT; 77 | BEGIN 78 | 79 | IF TG_OP = 'UPDATE' or TG_OP = 'INSERT' THEN 80 | tabname = NEW.tabname; 81 | ELSE 82 | tabname = OLD.tabname; 83 | END IF; 84 | 85 | -- Notify table data update 86 | -- This needs a little bit more of research regarding security issues 87 | -- see https://github.com/CartoDB/cartodb/pull/241 88 | -- PERFORM pg_notify('cdb_tabledata_update', tabname); 89 | 90 | --RAISE NOTICE 'Table % was updated', tabname; 91 | 92 | -- This will be needed until we'll have someone listening 93 | -- on the event we just broadcasted: 94 | -- 95 | -- LISTEN cdb_tabledata_update; 96 | -- 97 | 98 | -- Call the first varnish invalidation function owned 99 | -- by a superuser found in @extschema@ or public schema 100 | -- (in that order) 101 | found := false; 102 | FOR rec IN SELECT u.usesuper, u.usename, n.nspname, p.proname 103 | FROM pg_proc p, pg_namespace n, pg_user u 104 | WHERE p.proname = 'cdb_invalidate_varnish' 105 | AND p.pronamespace = n.oid 106 | AND n.nspname IN ('public', '@extschema@') 107 | AND u.usesysid = p.proowner 108 | AND u.usesuper 109 | ORDER BY n.nspname 110 | LOOP 111 | 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; 112 | EXECUTE 'SELECT ' || quote_ident(rec.nspname) || '.' 113 | || quote_ident(rec.proname) 114 | || '(' || quote_literal(quote_ident(schema_name) || '.' || quote_ident(table_name)) || ')'; 115 | found := true; 116 | EXIT; 117 | END LOOP; 118 | IF NOT found THEN RAISE WARNING 'Missing cdb_invalidate_varnish()'; END IF; 119 | 120 | RETURN NULL; 121 | END; 122 | $$ LANGUAGE plpgsql 123 | VOLATILE 124 | PARALLEL UNSAFE 125 | SECURITY DEFINER 126 | SET search_path = pg_temp; 127 | 128 | DROP TRIGGER IF EXISTS table_modified ON @extschema@.CDB_TableMetadata; 129 | -- NOTE: on DELETE we would be unable to convert the table 130 | -- oid (regclass) to its name 131 | CREATE TRIGGER table_modified AFTER INSERT OR UPDATE 132 | ON @extschema@.CDB_TableMetadata FOR EACH ROW EXECUTE PROCEDURE 133 | @extschema@._CDB_TableMetadata_Updated(); 134 | 135 | 136 | -- similar to TOUCH(1) in unix filesystems but for table in cdb_tablemetadata 137 | CREATE OR REPLACE FUNCTION @extschema@.CDB_TableMetadataTouch(tablename regclass) 138 | RETURNS void AS 139 | $$ 140 | BEGIN 141 | WITH upsert AS ( 142 | UPDATE @extschema@.cdb_tablemetadata 143 | SET updated_at = NOW() 144 | WHERE tabname = tablename 145 | RETURNING * 146 | ) 147 | INSERT INTO @extschema@.cdb_tablemetadata (tabname, updated_at) 148 | SELECT tablename, NOW() 149 | WHERE NOT EXISTS (SELECT * FROM upsert); 150 | END; 151 | $$ 152 | LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE; 153 | -------------------------------------------------------------------------------- /scripts-available/CDB_TransformToWebmercator.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Function to "safely" transform to webmercator 3 | -- 4 | -- This function works around the existance of a valid range 5 | -- for web mercator by "clipping" anything outside to the valid 6 | -- range. 7 | -- 8 | CREATE OR REPLACE FUNCTION @extschema@.CDB_TransformToWebmercator(geom @postgisschema@.geometry) 9 | RETURNS @postgisschema@.geometry 10 | AS 11 | $$ 12 | DECLARE 13 | valid_extent @postgisschema@.GEOMETRY; 14 | latlon_input @postgisschema@.GEOMETRY; 15 | clipped_input @postgisschema@.GEOMETRY; 16 | to_webmercator @postgisschema@.GEOMETRY; 17 | ret @postgisschema@.GEOMETRY; 18 | BEGIN 19 | 20 | IF @postgisschema@.ST_Srid(geom) = 3857 THEN 21 | RETURN geom; 22 | END IF; 23 | 24 | -- This is the valid web mercator extent 25 | -- 26 | -- NOTE: some sources set the valid latitude range 27 | -- to -85.0511 to 85.0511 but as long as proj 28 | -- does not complain we are happy 29 | -- 30 | valid_extent := @postgisschema@.ST_MakeEnvelope(-180, -89, 180, 89, 4326); 31 | 32 | -- Then we transform to WGS84 latlon, which is 33 | -- where we have known coordinates for the clipping 34 | -- 35 | latlon_input := @postgisschema@.ST_Transform(geom, 4326); 36 | 37 | -- Don't bother clipping if the geometry boundary doesn't 38 | -- go outside the valid extent. 39 | IF @postgisschema@.geometry_within(latlon_input, valid_extent) THEN 40 | BEGIN 41 | RETURN @postgisschema@.ST_Transform(latlon_input, 3857); 42 | EXCEPTION WHEN OTHERS THEN 43 | RETURN NULL; 44 | END; 45 | END IF; 46 | 47 | -- Since we're going to use ST_Intersection on input 48 | -- we'd better ensure the input is valid 49 | -- TODO: only do this if the first ST_Intersection fails ? 50 | IF @postgisschema@.ST_Dimension(geom) != 0 AND 51 | -- See http://trac.osgeo.org/postgis/ticket/1719 52 | @postgisschema@.GeometryType(geom) != 'GEOMETRYCOLLECTION' 53 | THEN 54 | BEGIN 55 | latlon_input := @postgisschema@.ST_MakeValid(latlon_input); 56 | EXCEPTION 57 | WHEN OTHERS THEN 58 | -- See http://github.com/Vizzuality/cartodb/issues/931 59 | RAISE WARNING 'Could not clean input geometry: %', SQLERRM; 60 | RETURN NULL; 61 | END; 62 | latlon_input := @postgisschema@.ST_CollectionExtract(latlon_input, ST_Dimension(geom)+1); 63 | END IF; 64 | 65 | -- Then we clip, trying to retain the input type 66 | -- TODO: catch exceptions here too ? 67 | clipped_input := @postgisschema@.ST_Intersection(latlon_input, valid_extent); 68 | 69 | -- We transform to web mercator 70 | to_webmercator := @postgisschema@.ST_Transform(clipped_input, 3857); 71 | 72 | -- Finally we convert EMPTY to NULL 73 | -- See https://github.com/Vizzuality/cartodb/issues/706 74 | -- And retain "multi" status 75 | ret := CASE WHEN @postgisschema@.ST_IsEmpty(to_webmercator) THEN NULL::@postgisschema@.geometry 76 | WHEN @postgisschema@.GeometryType(geom) LIKE 'MULTI%' THEN @postgisschema@.ST_Multi(to_webmercator) 77 | ELSE to_webmercator 78 | END; 79 | 80 | RETURN ret; 81 | END 82 | $$ LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL UNSAFE; 83 | -------------------------------------------------------------------------------- /scripts-available/CDB_UserTables.sql: -------------------------------------------------------------------------------- 1 | -- Function returning list of cartodb user tables 2 | -- 3 | -- The optional argument restricts the result to tables 4 | -- of the specified access type. 5 | -- 6 | -- Currently accepted permissions are: 'public', 'private' or 'all' 7 | -- 8 | DROP FUNCTION IF EXISTS @extschema@.CDB_UserTables(text); 9 | CREATE OR REPLACE FUNCTION @extschema@.CDB_UserTables(perm text DEFAULT 'all') 10 | RETURNS SETOF name 11 | AS $$ 12 | 13 | SELECT c.relname 14 | FROM pg_class c 15 | JOIN pg_namespace n ON n.oid = c.relnamespace 16 | WHERE c.relkind = 'r' 17 | AND c.relname NOT IN ('cdb_tablemetadata', 'cdb_analysis_catalog', 'cdb_conf', 'spatial_ref_sys') 18 | AND n.nspname NOT IN ('pg_catalog', 'information_schema', 'topology', '@extschema@') 19 | AND CASE WHEN perm = 'public' THEN has_table_privilege('publicuser', c.oid, 'SELECT') 20 | WHEN perm = 'private' THEN has_table_privilege(current_user, c.oid, 'SELECT') AND NOT has_table_privilege('publicuser', c.oid, 'SELECT') 21 | WHEN perm = 'all' THEN has_table_privilege(current_user, c.oid, 'SELECT') OR has_table_privilege('publicuser', c.oid, 'SELECT') 22 | ELSE false END; 23 | 24 | $$ LANGUAGE 'sql' STABLE PARALLEL SAFE; 25 | 26 | -- This is to migrate from pre-0.2.0 version 27 | -- See http://github.com/CartoDB/cartodb-postgresql/issues/36 28 | GRANT EXECUTE ON FUNCTION @extschema@.CDB_UserTables(text) TO public; 29 | -------------------------------------------------------------------------------- /scripts-available/CDB_Username.sql: -------------------------------------------------------------------------------- 1 | -- Returns the cartodb username of the current PostgreSQL session 2 | CREATE OR REPLACE FUNCTION @extschema@.CDB_Username() 3 | RETURNS text 4 | AS $$ 5 | SELECT @extschema@.CDB_Conf_GetConf(concat('api_keys_', session_user))->>'username'; 6 | $$ LANGUAGE SQL 7 | STABLE 8 | PARALLEL SAFE 9 | SECURITY DEFINER 10 | SET search_path = pg_temp; 11 | -------------------------------------------------------------------------------- /scripts-available/CDB_XYZ.sql: -------------------------------------------------------------------------------- 1 | -- { 2 | -- Return pixel resolution at the given zoom level 3 | -- }{ 4 | CREATE OR REPLACE FUNCTION @extschema@.CDB_XYZ_Resolution(z INTEGER) 5 | RETURNS FLOAT8 6 | AS $$ 7 | -- circumference divided by 256 is z0 resolution, then divide by 2^z 8 | SELECT 6378137.0*2.0*pi() / 256.0 / power(2.0, z); 9 | $$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE STRICT; 10 | -- } 11 | 12 | -- { 13 | -- Returns a polygon representing the bounding box of a given XYZ tile 14 | -- 15 | -- SRID of the returned polygon is forceably 3857 16 | -- 17 | -- }{ 18 | CREATE OR REPLACE FUNCTION @extschema@.CDB_XYZ_Extent(x INTEGER, y INTEGER, z INTEGER) 19 | RETURNS GEOMETRY 20 | AS $$ 21 | DECLARE 22 | origin_shift FLOAT8; 23 | initial_resolution FLOAT8; 24 | tile_geo_size FLOAT8; 25 | pixres FLOAT8; 26 | xmin FLOAT8; 27 | ymin FLOAT8; 28 | xmax FLOAT8; 29 | ymax FLOAT8; 30 | earth_circumference FLOAT8; 31 | tile_size INTEGER; 32 | BEGIN 33 | 34 | -- Size of each tile in pixels (1:1 aspect ratio) 35 | tile_size := 256; 36 | 37 | initial_resolution := @extschema@.CDB_XYZ_Resolution(0); 38 | --RAISE DEBUG 'Initial resolution: %', initial_resolution; 39 | 40 | origin_shift := (initial_resolution * tile_size) / 2.0; 41 | -- RAISE DEBUG 'Origin shift (after): %', origin_shift; 42 | 43 | pixres := initial_resolution / (power(2,z)); 44 | --RAISE DEBUG 'Pixel resolution: %', pixres; 45 | 46 | tile_geo_size = tile_size * pixres; 47 | --RAISE DEBUG 'Tile_geo_size: %', tile_geo_size; 48 | 49 | xmin := -origin_shift + x*tile_geo_size; 50 | xmax := -origin_shift + (x+1)*tile_geo_size; 51 | --RAISE DEBUG 'xmin: %', xmin; 52 | --RAISE DEBUG 'xmax: %', xmax; 53 | 54 | ymin := origin_shift - y*tile_geo_size; 55 | ymax := origin_shift - (y+1)*tile_geo_size; 56 | --RAISE DEBUG 'ymin: %', ymin; 57 | --RAISE DEBUG 'ymax: %', ymax; 58 | 59 | RETURN @postgisschema@.ST_MakeEnvelope(xmin, ymin, xmax, ymax, 3857); 60 | END 61 | $$ LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL SAFE; 62 | -- } 63 | -------------------------------------------------------------------------------- /scripts-available/CDB_ZoomFromScale.sql: -------------------------------------------------------------------------------- 1 | -- Maximum supported zoom level 2 | CREATE OR REPLACE FUNCTION @extschema@._CDB_MaxSupportedZoom() 3 | RETURNS int 4 | LANGUAGE SQL 5 | IMMUTABLE PARALLEL SAFE 6 | AS $$ 7 | -- The maximum zoom level has to be limited for various reasons, 8 | -- e.g. zoom levels greater than 31 would require tile coordinates 9 | -- that would not fit in an INTEGER (which is signed, 32 bits long). 10 | -- We'll choose 20 as a limit which is safe also when the JavaScript shift 11 | -- operator (<<) is used for computing powers of two. 12 | SELECT 29; 13 | $$; 14 | 15 | CREATE OR REPLACE FUNCTION @extschema@.CDB_ZoomFromScale(scaleDenominator numeric) 16 | RETURNS int 17 | LANGUAGE SQL 18 | IMMUTABLE PARALLEL SAFE 19 | AS $$ 20 | SELECT 21 | CASE 22 | WHEN scaleDenominator > 600000000 THEN 23 | -- Scale is smaller than zoom level 0 24 | NULL 25 | WHEN scaleDenominator = 0 THEN 26 | -- Actual zoom level would be infinite 27 | @extschema@._CDB_MaxSupportedZoom() 28 | ELSE 29 | CAST ( 30 | LEAST( 31 | ROUND(LOG(2, 559082264.028/scaleDenominator)), 32 | @extschema@._CDB_MaxSupportedZoom() 33 | ) 34 | AS INTEGER) 35 | END; 36 | $$; 37 | -------------------------------------------------------------------------------- /scripts-enabled/000-CDB_DateToNumber.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_DateToNumber.sql -------------------------------------------------------------------------------- /scripts-enabled/010-CDB_DigitSeparator.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_DigitSeparator.sql -------------------------------------------------------------------------------- /scripts-enabled/020-CDB_HeadsTailsBins.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_HeadsTailsBins.sql -------------------------------------------------------------------------------- /scripts-enabled/030-CDB_Hexagon.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Hexagon.sql -------------------------------------------------------------------------------- /scripts-enabled/040-CDB_JenksBins.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_JenksBins.sql -------------------------------------------------------------------------------- /scripts-enabled/050-CDB_LatLng.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_LatLng.sql -------------------------------------------------------------------------------- /scripts-enabled/060-CDB_QuantileBins.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_QuantileBins.sql -------------------------------------------------------------------------------- /scripts-enabled/070-CDB_QueryStatements.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_QueryStatements.sql -------------------------------------------------------------------------------- /scripts-enabled/080-CDB_QueryTables.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_QueryTables.sql -------------------------------------------------------------------------------- /scripts-enabled/085-CDB_OverviewsSupport.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_OverviewsSupport.sql -------------------------------------------------------------------------------- /scripts-enabled/090-CDB_Quota.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Quota.sql -------------------------------------------------------------------------------- /scripts-enabled/100-CDB_RandomTids.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_RandomTids.sql -------------------------------------------------------------------------------- /scripts-enabled/110-CDB_RectangleGrid.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_RectangleGrid.sql -------------------------------------------------------------------------------- /scripts-enabled/120-CDB_StringToDate.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_StringToDate.sql -------------------------------------------------------------------------------- /scripts-enabled/130-CDB_TableMetadata.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_TableMetadata.sql -------------------------------------------------------------------------------- /scripts-enabled/140-CDB_TransformToWebmercator.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_TransformToWebmercator.sql -------------------------------------------------------------------------------- /scripts-enabled/150-CDB_UserTables.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_UserTables.sql -------------------------------------------------------------------------------- /scripts-enabled/160-CDB_XYZ.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_XYZ.sql -------------------------------------------------------------------------------- /scripts-enabled/170-CDB_ColumnNames.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_ColumnNames.sql -------------------------------------------------------------------------------- /scripts-enabled/180-CDB_ColumnType.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_ColumnType.sql -------------------------------------------------------------------------------- /scripts-enabled/190-CDB_CartodbfyTable.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_CartodbfyTable.sql -------------------------------------------------------------------------------- /scripts-enabled/200-CDB_TableIndexes.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_TableIndexes.sql -------------------------------------------------------------------------------- /scripts-enabled/210-CDB_Organizations.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Organizations.sql -------------------------------------------------------------------------------- /scripts-enabled/220-CDB_Math.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Math.sql -------------------------------------------------------------------------------- /scripts-enabled/230-CDB_ZoomFromScale.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_ZoomFromScale.sql -------------------------------------------------------------------------------- /scripts-enabled/240-CDB_EqualIntervalBins.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_EqualIntervalBins.sql -------------------------------------------------------------------------------- /scripts-enabled/241-CDB_GreatCircle.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_GreatCircle.sql -------------------------------------------------------------------------------- /scripts-enabled/245-CDB_Overviews.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Overviews.sql -------------------------------------------------------------------------------- /scripts-enabled/250-CDB_ForeignTable.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_ForeignTable.sql -------------------------------------------------------------------------------- /scripts-enabled/260-CDB_AnalysisCatalog.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_AnalysisCatalog.sql -------------------------------------------------------------------------------- /scripts-enabled/270-CDB_AnalysisSupport.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_AnalysisSupport.sql -------------------------------------------------------------------------------- /scripts-enabled/275-CDB_AnalysisCheck.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_AnalysisCheck.sql -------------------------------------------------------------------------------- /scripts-enabled/280-CDB_EstimateRowCount.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_EstimateRowCount.sql -------------------------------------------------------------------------------- /scripts-enabled/290-CDB_GhostTables.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_GhostTables.sql -------------------------------------------------------------------------------- /scripts-enabled/300-CDB_OAuth.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_OAuth.sql -------------------------------------------------------------------------------- /scripts-enabled/400-CDB_FederatedServer.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_FederatedServer.sql -------------------------------------------------------------------------------- /scripts-enabled/401_CDB_FederatedServerTables.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_FederatedServerTables.sql -------------------------------------------------------------------------------- /scripts-enabled/402_CDB_FederatedServerListRemote.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_FederatedServerListRemote.sql -------------------------------------------------------------------------------- /scripts-enabled/403-CDB_FederatedServerDiagnostics.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_FederatedServerDiagnostics.sql -------------------------------------------------------------------------------- /scripts-enabled/500-CDB_RegenerateTable.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_RegenerateTable.sql -------------------------------------------------------------------------------- /scripts-enabled/900-CDB_DDLTriggers.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_DDLTriggers.sql -------------------------------------------------------------------------------- /scripts-enabled/910-CDB_Conf.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Conf.sql -------------------------------------------------------------------------------- /scripts-enabled/920-CDB_Username.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Username.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_DistType.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_DistType.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_DistinctMeasure.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_DistinctMeasure.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_Groups.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Groups.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_Groups_API.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Groups_API.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_Stats.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_Stats.sql -------------------------------------------------------------------------------- /scripts-enabled/CDB_SyncTable.sql: -------------------------------------------------------------------------------- 1 | ../scripts-available/CDB_SyncTable.sql -------------------------------------------------------------------------------- /sql/test_setup.sql: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | \set QUIET on 3 | SET client_min_messages TO error; 4 | CREATE EXTENSION postgis; 5 | CREATE EXTENSION @@plpythonu@@; 6 | CREATE SCHEMA cartodb; 7 | \i 'cartodb--unpackaged--@@VERSION@@.sql' 8 | CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) 9 | RETURNS void AS $$ 10 | BEGIN 11 | RAISE NOTICE 'cdb_invalidate_varnish(%) called', table_name; 12 | END; 13 | $$ LANGUAGE 'plpgsql'; 14 | \set QUIET off 15 | -------------------------------------------------------------------------------- /sql/test_setup_expect: -------------------------------------------------------------------------------- 1 | \set ECHO none 2 | -------------------------------------------------------------------------------- /test/CDB_AnalysisCheckTest.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO error; 2 | \set VERBOSITY terse 3 | 4 | SELECT CDB_SetUserQuotaInBytes(1000000); 5 | SELECT _CDB_AnalysisTablesInSchema('public'); 6 | SELECT _CDB_AnalysisDataSize('public'); 7 | CREATE TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5(id int); 8 | CREATE TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94(id int); 9 | CREATE TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da9(id int); 10 | SELECT _CDB_AnalysisTablesInSchema('public') t ORDER BY t; 11 | SELECT _CDB_AnalysisDataSize('public'); 12 | SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); 13 | SELECT CDB_SetUserQuotaInBytes(1); 14 | SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); 15 | INSERT INTO analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5(id) VALUES (1),(2),(3),(4),(5); 16 | SELECT CDB_CheckAnalysisQuota('analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94'); 17 | DROP TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5; 18 | DROP TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94; 19 | DROP TABLE analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da9; 20 | DROP FUNCTION "public"._CDB_UserQuotaInBytes(); 21 | -------------------------------------------------------------------------------- /test/CDB_AnalysisCheckTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | 1000000 3 | 0 4 | CREATE TABLE 5 | CREATE TABLE 6 | CREATE TABLE 7 | (analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5,public,analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d5) 8 | (analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94,public,analysis_2f13a3dbd7_f00cee44e9e6152b450bde3a92eb9ae0d099da94) 9 | 0 10 | 11 | 1 12 | 13 | INSERT 0 5 14 | ERROR: Analysis cache space limits exceeded 15 | DROP TABLE 16 | DROP TABLE 17 | DROP TABLE 18 | DROP FUNCTION 19 | -------------------------------------------------------------------------------- /test/CDB_CartodbfyTableTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | CREATE FUNCTION 3 | SELECT 1 4 | ERROR: Please set user quota before cartodbfying tables. 5 | 0 6 | single non-geometrical column cartodbfied fine 7 | DROP TABLE 8 | SELECT 1 9 | check function idempotence cartodbfied fine 10 | 1|0101000020E6100000000000000000F0BF000000000000F0BF|this is a sentence 11 | check function idempotence cartodbfied fine 12 | 1|0101000020E6100000000000000000F0BF000000000000F0BF|this is a sentence 13 | DROP TABLE 14 | SELECT 1 15 | srid-unconstrained the_geom cartodbfied fine 16 | DROP TABLE 17 | SELECT 2 18 | mixed-srid the_geom cartodbfied fine 19 | extent|BOX(-1 -1,0 0) 20 | DROP TABLE 21 | SELECT 1 22 | wrong srid-constrained the_geom cartodbfied fine 23 | extent|BOX(1 1,2 2)|BOX(111319 111325,222639 222684) 24 | DROP TABLE 25 | SELECT 1 26 | wrong srid-constrained the_geom_webmercator cartodbfied fine 27 | extent|BOX(1 1,2 2) 28 | DROP TABLE 29 | SELECT 1 30 | CREATE TRIGGER 31 | trigger-protected the_geom cartodbfied fine 32 | extent|BOX(1 1,2 2) 33 | DROP TABLE 34 | SELECT 1 35 | text cartodb_id cartodbfied fine 36 | 5 37 | DROP TABLE 38 | SELECT 1 39 | 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); 40 | DROP TABLE 41 | SELECT 1 42 | 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); 43 | 44 | DROP TABLE 45 | SELECT 1 46 | unsequenced cartodb_id cartodbfied fine 47 | 1 48 | DROP TABLE 49 | SELECT 1 50 | text the_geom column cartodbfied fine 51 | 1 52 | DROP TABLE 53 | SELECT 1 54 | text the_geom column, no srs cartodbfied fine 55 | 1 56 | DROP TABLE 57 | SELECT 1 58 | text the_geom column, srs = 26819 cartodbfied fine 59 | 1 60 | DROP TABLE 61 | SELECT 1 62 | text the_geom column, unparseable content cartodbfied fine 63 | 1 64 | DROP TABLE 65 | CREATE TABLE 66 | cartodb_id serial primary key cartodbfied fine 67 | t_pkey|cartodb_id 68 | DROP TABLE 69 | CREATE TABLE 70 | original 71 | ALTER TABLE 72 | CREATE TABLE 73 | original 74 | DROP TABLE 75 | DROP TABLE 76 | CREATE TABLE 77 | Table always have a default seq value after cartodbfy #138 cartodbfied fine 78 | INSERT 0 1 79 | DROP TABLE 80 | CREATE TABLE 81 | INSERT 0 3 82 | Existing cartodb_id values are respected #138 cartodbfied fine 83 | 10|||a| 84 | 20|||b| 85 | 30|||c| 86 | DROP TABLE 87 | CREATE TABLE 88 | INSERT 0 2 89 | Table with both the_geom and wkb_geometry #141 cartodbfied fine 90 | 1|0104000020E61000000100000001010000007108B023698052C03CEEA53A2E5D4440|0104000020110F00000100000001010000004A9F662B456D5FC11392690DC3F75241| 91 | 2|0104000020E6100000010000000101000000864C9E57618052C0994F0C7F3C5B4440|0104000020110F00000100000001010000002858E0EC376D5FC1CAE8DB4B95F55241| 92 | DROP TABLE 93 | CREATE TABLE 94 | INSERT 0 1 95 | 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); 96 | DROP TABLE 97 | CREATE TABLE 98 | INSERT 0 4 99 | 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); 100 | 1 101 | 2 102 | 103 | 3 104 | DROP TABLE 105 | CREATE TABLE 106 | INSERT 0 3 107 | 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); 108 | 1 109 | 2 110 | 2 111 | DROP TABLE 112 | CREATE TABLE 113 | INSERT 0 4 114 | 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); 115 | 1 116 | 2 117 | 118 | 2 119 | DROP TABLE 120 | CREATE TABLE 121 | CREATE INDEX 122 | CREATE INDEX 123 | ALTER TABLE 124 | INSERT 0 3 125 | Table with primary key and unique index on it #174 cartodbfied fine 126 | 1 127 | 2 128 | 3 129 | DROP TABLE 130 | CREATE TABLE 131 | INSERT 0 2 132 | Table with dots in name columns (cartodb #6114) cartodbfied fine 133 | one|1 134 | two|3 135 | DROP TABLE 136 | SET 137 | CREATE TABLE 138 | NOTICE: Column cartodb_id already exists 139 | NOTICE: Existing cartodb_id field does not have an associated sequence, renaming 140 | NOTICE: Trying to recover data from _cartodb_id0 column 141 | 142 | DROP TABLE 143 | CREATE TABLE 144 | NOTICE: Column cartodb_id already exists 145 | NOTICE: Existing cartodb_id field is of invalid type text (need int2, int4 or int8), renaming 146 | NOTICE: Trying to recover data from _cartodb_id0 column 147 | 148 | DROP TABLE 149 | SET 150 | BEGIN 151 | DO 152 | ROLLBACK 153 | CREATE TABLE 154 | Long table name could cause sequence collision while renaming #325 cartodbfied fine 155 | DROP TABLE 156 | DROP FUNCTION 157 | DROP FUNCTION 158 | -------------------------------------------------------------------------------- /test/CDB_DateToNumberTest.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM CDB_DateToNumber('1999-01-08 00:00:00'::timestamp); 2 | SELECT * FROM CDB_DateToNumber('1999-01-08 00:00:00+05'::timestamp with time zone); 3 | -------------------------------------------------------------------------------- /test/CDB_DateToNumberTest_expect: -------------------------------------------------------------------------------- 1 | 915753600 2 | 915735600 3 | -------------------------------------------------------------------------------- /test/CDB_DigitSeparatorTest.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE TEMP TABLE "_CDB_DigitSeparatorTest" ( 3 | none text, 4 | only_com_dec text, 5 | only_dot_dec text, 6 | only_com_tho text, 7 | only_dot_tho text, 8 | both_com_dec text, 9 | both_dot_dec text, 10 | "only_com_AMB" text, 11 | "only_dot_AMB" text 12 | ); 13 | COPY "_CDB_DigitSeparatorTest" FROM STDIN; 14 | 123456 123,1235 123.12345 1,234,231 1.234.234 1.234,23 1,234.23 1,123 1.123 15 | 123456 123,12 123.12 231 234 1.121.234,230 3,111,234.230 123,123 123.123 16 | 123456 123,12 123.12 231 234 1.121.234,2 3,111,234.230 123,123 123.123 17 | \. 18 | 19 | SELECT 'none', * FROM 20 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'none'); 21 | SELECT 'only_com_dec', * FROM 22 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_dec'); 23 | SELECT 'only_dot_dec', * FROM 24 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_dec'); 25 | SELECT 'only_com_tho', * FROM 26 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_tho'); 27 | SELECT 'only_dot_tho', * FROM 28 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_tho'); 29 | SELECT 'both_com_dec', * FROM 30 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_com_dec'); 31 | SELECT 'both_dot_dec', * FROM 32 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_dot_dec'); 33 | SELECT 'only_com_AMB', * FROM 34 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_AMB'); 35 | SELECT 'only_dot_AMB', * FROM 36 | CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_AMB'); 37 | 38 | DROP TABLE "_CDB_DigitSeparatorTest"; 39 | COMMIT; 40 | -------------------------------------------------------------------------------- /test/CDB_DigitSeparatorTest_expect: -------------------------------------------------------------------------------- 1 | BEGIN 2 | CREATE TABLE 3 | COPY 3 4 | none|| 5 | only_com_dec|.|, 6 | only_dot_dec|,|. 7 | only_com_tho|,|. 8 | only_dot_tho|.|, 9 | both_com_dec|.|, 10 | both_dot_dec|,|. 11 | only_com_AMB|| 12 | only_dot_AMB|| 13 | DROP TABLE 14 | COMMIT 15 | -------------------------------------------------------------------------------- /test/CDB_DistTypeTest.sql: -------------------------------------------------------------------------------- 1 | WITH data AS ( 2 | SELECT pow(x,3)::numeric x FROM generate_series(-100,100) x 3 | ) 4 | SELECT CDB_DistType(array_agg(x)) FROM data 5 | -------------------------------------------------------------------------------- /test/CDB_DistTypeTest_expect: -------------------------------------------------------------------------------- 1 | A 2 | -------------------------------------------------------------------------------- /test/CDB_DistinctMeasureTest.sql: -------------------------------------------------------------------------------- 1 | -- a - j add up to 89%, k-m add up to 11% 2 | WITH a As ( 3 | SELECT ( 4 | repeat('a',12) || 5 | repeat('b',11) || 6 | repeat('c',11) || 7 | repeat('d',10) || 8 | repeat('e',10) || 9 | repeat('f',9) || 10 | repeat('g',8) || 11 | repeat('h',7) || 12 | repeat('i',6) || 13 | repeat('j',5) || 14 | repeat('k',4) || 15 | repeat('l',4) || 16 | repeat('m',3) 17 | )::text AS x 18 | ) 19 | 20 | SELECT CDB_DistinctMeasure(string_to_array(x,null),0.90) from a 21 | -------------------------------------------------------------------------------- /test/CDB_DistinctMeasureTest_expect: -------------------------------------------------------------------------------- 1 | 0 2 | -------------------------------------------------------------------------------- /test/CDB_EqualIntervalBinsTest.sql: -------------------------------------------------------------------------------- 1 | WITH data AS ( 2 | SELECT array_agg(x::numeric) s FROM generate_series(1,300) x 3 | WHERE x % 5 != 0 AND x % 7 != 0 4 | ) 5 | SELECT round(unnest(CDB_EqualIntervalBins(s, 7)),7) FROM data; 6 | 7 | WITH data_nulls AS ( 8 | SELECT array_agg(CASE WHEN x % 2 != 0 THEN x ELSE NULL END::numeric) s FROM generate_series(1,100) x 9 | WHERE x % 5 != 0 AND x % 7 != 0 10 | ) 11 | SELECT round(unnest(CDB_EqualIntervalBins(s, 7)),7) FROM data_nulls; 12 | -------------------------------------------------------------------------------- /test/CDB_EqualIntervalBinsTest_expect: -------------------------------------------------------------------------------- 1 | 43.5714286 2 | 86.1428571 3 | 128.7142857 4 | 171.2857143 5 | 213.8571429 6 | 256.4285714 7 | 299.0000000 8 | 15.0000000 9 | 29.0000000 10 | 43.0000000 11 | 57.0000000 12 | 71.0000000 13 | 85.0000000 14 | 99.0000000 15 | -------------------------------------------------------------------------------- /test/CDB_EstimateRowCountTest.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO error; 2 | \set VERBOSITY terse 3 | CREATE TABLE tmptab1(id INT); 4 | INSERT INTO tmptab1(id) VALUES (1), (2), (3); 5 | CREATE TABLE tmptab2(id INT, value NUMERIC); 6 | INSERT INTO tmptab2(id, value) VALUES (1, 10.0), (2, 20.0); 7 | SELECT CDB_EstimateRowCount('SELECT SUM(value) FROM tmptab1 INNER JOIN tmptab2 ON (tmptab1.id = tmptab2.id);') AS row_count; 8 | SELECT CDB_EstimateRowCount('UPDATE tmptab2 SET value = 30 WHERE id=2;') AS row_count; 9 | DROP TABLE tmptab2; 10 | DROP TABLE tmptab1; 11 | -------------------------------------------------------------------------------- /test/CDB_EstimateRowCountTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | CREATE TABLE 3 | INSERT 0 3 4 | CREATE TABLE 5 | INSERT 0 2 6 | 1 7 | 1 8 | DROP TABLE 9 | DROP TABLE 10 | -------------------------------------------------------------------------------- /test/CDB_FederatedServerDiagnostics.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create FDW objects 3 | -- =================================================================== 4 | \set QUIET on 5 | SET client_min_messages TO error; 6 | \set VERBOSITY terse 7 | CREATE EXTENSION postgres_fdw; 8 | 9 | CREATE ROLE cdb_fs_tester LOGIN PASSWORD 'cdb_fs_passwd'; 10 | GRANT CONNECT ON DATABASE contrib_regression TO cdb_fs_tester; 11 | 12 | -- Create database to be used as remote 13 | CREATE DATABASE cdb_fs_tester OWNER cdb_fs_tester; 14 | 15 | SELECT 'C1', cartodb.CDB_Federated_Server_Register_PG(server => 'loopback'::text, config => '{ 16 | "server": { 17 | "host": "localhost", 18 | "port": @@PGPORT@@ 19 | }, 20 | "credentials": { 21 | "username": "cdb_fs_tester", 22 | "password": "cdb_fs_passwd" 23 | } 24 | }'::jsonb); 25 | 26 | SELECT 'C2', cartodb.CDB_Federated_Server_Register_PG(server => 'wrong-port'::text, config => '{ 27 | "server": { 28 | "host": "localhost", 29 | "port": "12345" 30 | }, 31 | "credentials": { 32 | "username": "cdb_fs_tester", 33 | "password": "cdb_fs_passwd" 34 | } 35 | }'::jsonb); 36 | 37 | SELECT 'C3', cartodb.CDB_Federated_Server_Register_PG(server => 'loopback-no-port'::text, config => '{ 38 | "server": { 39 | "host": "localhost" 40 | }, 41 | "credentials": { 42 | "username": "cdb_fs_tester", 43 | "password": "cdb_fs_passwd" 44 | } 45 | }'::jsonb); 46 | 47 | \c cdb_fs_tester postgres 48 | CREATE EXTENSION postgis; 49 | \c contrib_regression postgres 50 | \set QUIET off 51 | 52 | 53 | -- =================================================================== 54 | -- Test server diagnostics function(s) 55 | -- =================================================================== 56 | \echo '%% It raises an error if the server does not exist' 57 | SELECT '1.1', cartodb.CDB_Federated_Server_Diagnostics(server => 'doesNotExist'); 58 | 59 | \echo '%% It returns a jsonb object' 60 | SELECT '1.2', pg_typeof(cartodb.CDB_Federated_Server_Diagnostics(server => 'loopback')); 61 | 62 | \echo '%% It returns the server version' 63 | SELECT '1.3', cartodb.CDB_Federated_Server_Diagnostics(server => 'loopback') @> format('{"server_version": "%s"}', setting)::jsonb 64 | FROM pg_settings WHERE name = 'server_version'; 65 | 66 | \echo '%% It returns the postgis version' 67 | SELECT '1.4', cartodb.CDB_Federated_Server_Diagnostics(server => 'loopback') @> format('{"postgis_version": "%s"}', extversion)::jsonb 68 | FROM pg_extension WHERE extname = 'postgis'; 69 | 70 | \echo '%% It returns null as the postgis version if it is not installed' 71 | \set QUIET on 72 | \c cdb_fs_tester postgres 73 | DROP EXTENSION postgis; 74 | \c contrib_regression postgres 75 | \set QUIET off 76 | SELECT '1.5', cartodb.CDB_Federated_Server_Diagnostics(server => 'loopback') @> '{"postgis_version": null}'::jsonb; 77 | 78 | \echo '%% It returns the remote server options' 79 | SELECT '1.6', cartodb.CDB_Federated_Server_Diagnostics(server => 'loopback') @> '{"server_options": {"host": "localhost", "port": "@@PGPORT@@", "updatable": "false", "extensions": "postgis", "fetch_size": "1000", "use_remote_estimate": "true"}}'::jsonb; 80 | 81 | \echo '%% It returns network latency stats to the remote server: min <= avg <= max' 82 | WITH latency AS ( 83 | SELECT CDB_Federated_Server_Diagnostics('loopback')->'server_latency_ms' ms 84 | ) SELECT '2.1', (latency.ms->'min')::text::float <= (latency.ms->'avg')::text::float, (latency.ms->'avg')::text::float <= (latency.ms->'max')::text::float 85 | FROM latency; 86 | 87 | \echo '%% Latency stats: 0 <= min <= max <= 1000 ms (local connection)' 88 | WITH latency AS ( 89 | SELECT CDB_Federated_Server_Diagnostics('loopback')->'server_latency_ms' ms 90 | ) SELECT '2.2', 0.0 <= (latency.ms->'min')::text::float, (latency.ms->'max')::text::float <= 1000.0 91 | FROM latency; 92 | 93 | \echo '%% Latency stats: stdev > 0' 94 | WITH latency AS ( 95 | SELECT CDB_Federated_Server_Diagnostics('loopback')->'server_latency_ms' ms 96 | ) SELECT '2.3', (latency.ms->'stdev')::text::float >= 0.0 97 | FROM latency; 98 | 99 | \echo '%% It raises an error if the wrong port is provided' 100 | SELECT '3.0', cartodb.CDB_Federated_Server_Diagnostics(server => 'wrong-port'); 101 | 102 | -- Disabled: It's not compatible with Travis since the target database (self) might be in a different port 103 | -- \echo '%% Latency stats: can get them on default PG port 5432 when not provided' 104 | -- WITH latency AS ( 105 | -- SELECT CDB_Federated_Server_Diagnostics('loopback-no-port')->'server_latency_ms' ms 106 | -- ) SELECT '2.4', 0.0 <= (latency.ms->'min')::text::float, (latency.ms->'max')::text::float <= 1000.0 107 | -- FROM latency; 108 | 109 | 110 | -- =================================================================== 111 | -- Cleanup 112 | -- =================================================================== 113 | \set QUIET on 114 | SELECT 'D1', cartodb.CDB_Federated_Server_Unregister(server => 'loopback'::text); 115 | SELECT 'D2', cartodb.CDB_Federated_Server_Unregister(server => 'wrong-port'::text); 116 | SELECT 'D3', cartodb.CDB_Federated_Server_Unregister(server => 'loopback-no-port'::text); 117 | -- Reconnect, using a new session in order to close FDW connections 118 | \connect 119 | DROP DATABASE cdb_fs_tester; 120 | 121 | -- Drop role 122 | REVOKE CONNECT ON DATABASE contrib_regression FROM cdb_fs_tester; 123 | DROP ROLE cdb_fs_tester; 124 | 125 | DROP EXTENSION postgres_fdw; 126 | \set QUIET off 127 | -------------------------------------------------------------------------------- /test/CDB_FederatedServerDiagnostics_expect: -------------------------------------------------------------------------------- 1 | C1| 2 | C2| 3 | C3| 4 | %% It raises an error if the server does not exist 5 | ERROR: Server "doesNotExist" does not exist 6 | %% It returns a jsonb object 7 | 1.2|jsonb 8 | %% It returns the server version 9 | 1.3|t 10 | %% It returns the postgis version 11 | 1.4|t 12 | %% It returns null as the postgis version if it is not installed 13 | 1.5|t 14 | %% It returns the remote server options 15 | 1.6|t 16 | %% It returns network latency stats to the remote server: min <= avg <= max 17 | 2.1|t|t 18 | %% Latency stats: 0 <= min <= max <= 1000 ms (local connection) 19 | 2.2|t|t 20 | %% Latency stats: stdev > 0 21 | 2.3|t 22 | %% It raises an error if the wrong port is provided 23 | ERROR: could not connect to server "cdb_fs_wrong-port" 24 | D1| 25 | D2| 26 | D3| 27 | -------------------------------------------------------------------------------- /test/CDB_FederatedServer_expect: -------------------------------------------------------------------------------- 1 | ## List empty servers shows nothing 2 | ## List non-existent server shows nothing 3 | ## Create and list a server works 4 | 1.3| 5 | 1.4|(myRemote,postgres_fdw,localhost,@@PGPORT@@,,read-only,fdw_user) 6 | ## Create and list a second server works 7 | 2.1| 8 | 2.2|(myRemote,postgres_fdw,localhost,@@PGPORT@@,,read-only,fdw_user) 9 | 2.2|(myRemote2,postgres_fdw,localhost,@@PGPORT@@,fdw_target,read-only,fdw_user) 10 | ## List server by name works 11 | 2.3|(myRemote,postgres_fdw,localhost,@@PGPORT@@,,read-only,fdw_user) 12 | ## Re-register a second server works 13 | 3.1| 14 | 3.2|(myRemote,postgres_fdw,localhost,@@PGPORT@@,,read-only,fdw_user) 15 | 3.2|(myRemote2,postgres_fdw,localhost,@@PGPORT@@,fdw_target,read-only,other_remote_user) 16 | ## Unregister server 1 works 17 | 4.1| 18 | 4.2|(myRemote2,postgres_fdw,localhost,@@PGPORT@@,fdw_target,read-only,other_remote_user) 19 | ## Unregistering a server that does not exist fails 20 | ERROR: Server "doesNotExist" does not exist 21 | ## Unregister the second server works 22 | 6.1| 23 | ## Create a server with NULL name fails 24 | ERROR: Server name cannot be NULL 25 | ## Create a server with NULL config fails 26 | 7.01| 27 | ## Create a server with empty config fails 28 | ERROR: Server information is mandatory 29 | ## Create a server without credentials fails 30 | ERROR: Credentials are mandatory 31 | ## Create a server with empty credentials works 32 | 7.3| 33 | 7.4|(empty,postgres_fdw,localhost,@@PGPORT@@,fdw_target,read-only,) 34 | 7.5| 35 | ## Create a server without options fails 36 | ERROR: Server information is mandatory 37 | ## Create a server with special characters works 38 | 8.1| 39 | 8.2|("myRemote"" or'not",postgres_fdw,localhost,@@PGPORT@@,"fdw target",read-only,"fdw user") 40 | 8.3| 41 | 9.1| 42 | You are now connected to database "contrib_regression" as user "cdb_fs_tester". 43 | ## All users are able to list servers 44 | 9.2|(myRemote3,postgres_fdw,localhost,@@PGPORT@@,,read-only,) 45 | ## Only superadmins can create servers 46 | ERROR: Could not create server myRemote4: permission denied for foreign-data wrapper postgres_fdw 47 | You are now connected to database "contrib_regression" as user "postgres". 48 | ## Granting access to a user works 49 | 9.5| 50 | You are now connected to database "contrib_regression" as user "cdb_fs_tester". 51 | 9.55|(myRemote3,postgres_fdw,localhost,@@PGPORT@@,,read-only,fdw_user) 52 | You are now connected to database "contrib_regression" as user "postgres". 53 | ERROR: Server "does not exist" does not exist 54 | ERROR: Could not grant access on "myRemote3" to "does not exist": role "does not exist" does not exist 55 | ## Granting access again raises a notice 56 | NOTICE: role "cdb_fs_tester" is already a member of role "cdb_fs_role_95b63382aabca4433e7bd9cba6c30368" 57 | 9.8| 58 | ## Revoking access to a user works 59 | 9.9| 60 | 9.10| 61 | ## Unregistering a server with active grants works 62 | 9.11| 63 | ## A user with granted access can not drop a server 64 | 10.1| 65 | 10.2| 66 | You are now connected to database "contrib_regression" as user "cdb_fs_tester". 67 | ERROR: Not enough permissions to drop the server "myRemote4" 68 | You are now connected to database "contrib_regression" as user "postgres". 69 | 10.4| 70 | -------------------------------------------------------------------------------- /test/CDB_GhostTables.sql: -------------------------------------------------------------------------------- 1 | -- Create user and enable Ghost tables trigger 2 | \set QUIET on 3 | SET client_min_messages TO error; 4 | 5 | -- Recreate the function without extra error messages as it changes depending on the python-redis version 6 | CREATE OR REPLACE FUNCTION cartodb._CDB_LinkGhostTables(username text, db_name text, event_name text) 7 | RETURNS void 8 | AS $$ 9 | if not username: 10 | return 11 | 12 | if 'json' not in GD: 13 | import json 14 | GD['json'] = json 15 | else: 16 | json = GD['json'] 17 | 18 | tis_config = plpy.execute("select cartodb.CDB_Conf_GetConf('invalidation_service');")[0]['cdb_conf_getconf'] 19 | if not tis_config: 20 | plpy.warning('Invalidation service configuration not found. Skipping Ghost Tables linking.') 21 | return 22 | 23 | tis_config_dict = json.loads(tis_config) 24 | tis_host = tis_config_dict.get('host') 25 | tis_port = tis_config_dict.get('port') 26 | tis_timeout = tis_config_dict.get('timeout', 5) 27 | tis_retry = tis_config_dict.get('retry', 5) 28 | 29 | client = GD.get('invalidation', None) 30 | 31 | while True: 32 | 33 | if not client: 34 | try: 35 | import redis 36 | client = redis.Redis(host=tis_host, port=tis_port, socket_timeout=tis_timeout) 37 | GD['invalidation'] = client 38 | except Exception as err: 39 | # NOTE: no retries on connection error 40 | plpy.warning('Error trying to connect to Invalidation Service to link Ghost Tables') 41 | break 42 | 43 | try: 44 | client.execute_command('DBSCH', db_name, username, event_name) 45 | break 46 | except Exception as err: 47 | client = GD['invalidation'] = None # force reconnect 48 | if not tis_retry: 49 | plpy.warning('Error calling Invalidation Service to link Ghost Tables') 50 | break 51 | tis_retry -= 1 # try reconnecting 52 | $$ LANGUAGE '@@plpythonu@@' VOLATILE PARALLEL UNSAFE; 53 | 54 | SELECT CDB_EnableGhostTablesTrigger(); 55 | CREATE ROLE "fulano" LOGIN; 56 | GRANT ALL ON SCHEMA cartodb TO "fulano"; 57 | GRANT SELECT ON cartodb.cdb_ddl_execution TO "fulano"; 58 | GRANT EXECUTE ON FUNCTION CDB_Username() TO "fulano"; 59 | GRANT EXECUTE ON FUNCTION CDB_LinkGhostTables(text) TO "fulano"; 60 | SELECT cartodb.CDB_Conf_SetConf('api_keys_fulano', '{"username": "fulanito", "permissions":[]}'); 61 | DELETE FROM cdb_conf WHERE key = 'invalidation_service'; 62 | SET SESSION AUTHORIZATION "fulano"; 63 | SET client_min_messages TO notice; 64 | \set QUIET off 65 | 66 | SELECT CDB_LinkGhostTables(); -- _CDB_LinkGhostTables called (configuration not found) 67 | 68 | -- Add TIS configuration 69 | \set QUIET on 70 | SET SESSION AUTHORIZATION postgres; 71 | SELECT cartodb.CDB_Conf_SetConf('invalidation_service', '{"host": "fake-tis-host", "port": 3142}'); 72 | SET SESSION AUTHORIZATION "fulano"; 73 | \set QUIET off 74 | 75 | SELECT CDB_LinkGhostTables(); -- _CDB_LinkGhostTables called 76 | 77 | BEGIN; 78 | SELECT to_regclass('cartodb.cdb_ddl_execution'); -- exists 79 | SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 0 80 | CREATE TABLE tmp(id INT); 81 | SELECT COUNT(*) FROM cartodb.cdb_ddl_execution; -- 1 82 | END; -- _CDB_LinkGhostTables called 83 | 84 | -- Disable Ghost tables trigger 85 | \set QUIET on 86 | SET SESSION AUTHORIZATION postgres; 87 | SELECT CDB_DisableGhostTablesTrigger(); 88 | SET SESSION AUTHORIZATION "fulano"; 89 | \set QUIET off 90 | 91 | SELECT to_regclass('cartodb.cdb_ddl_execution'); -- not exists 92 | DROP TABLE tmp; -- _CDB_LinkGhostTables not called 93 | 94 | -- Cleanup 95 | \set QUIET on 96 | SET SESSION AUTHORIZATION postgres; 97 | REVOKE EXECUTE ON FUNCTION CDB_LinkGhostTables(text) FROM "fulano"; 98 | REVOKE EXECUTE ON FUNCTION CDB_Username() FROM "fulano"; 99 | REVOKE ALL ON SCHEMA cartodb FROM "fulano"; 100 | DROP ROLE "fulano"; 101 | DELETE FROM cdb_conf WHERE key = 'api_keys_fulano' OR key = 'invalidation_service'; 102 | \set QUIET off 103 | -------------------------------------------------------------------------------- /test/CDB_GhostTables_expect: -------------------------------------------------------------------------------- 1 | 2 | 3 | WARNING: Invalidation service configuration not found. Skipping Ghost Tables linking. 4 | INFO: _CDB_LinkGhostTables() called with username=fulanito, event_name=USER 5 | 6 | 7 | WARNING: Error calling Invalidation Service to link Ghost Tables 8 | INFO: _CDB_LinkGhostTables() called with username=fulanito, event_name=USER 9 | 10 | BEGIN 11 | cdb_ddl_execution 12 | 0 13 | CREATE TABLE 14 | 1 15 | WARNING: Error calling Invalidation Service to link Ghost Tables 16 | INFO: _CDB_LinkGhostTables() called with username=fulanito, event_name=CREATE TABLE 17 | COMMIT 18 | 19 | 20 | DROP TABLE 21 | -------------------------------------------------------------------------------- /test/CDB_GreatCircle.sql: -------------------------------------------------------------------------------- 1 | select ST_AsText(CDB_GreatCircle(CDB_LatLng(55.8580,4.2590), CDB_LatLng(40.7127,74.0059)), 3); 2 | select ST_AsText(CDB_GreatCircle(CDB_LatLng(55.8580,4.2590), CDB_LatLng(40.7127,74.0059), 50000), 3); 3 | -------------------------------------------------------------------------------- /test/CDB_GreatCircle_expect: -------------------------------------------------------------------------------- 1 | LINESTRING(4.259 55.858,5.533 56.001,6.817 56.13,8.109 56.246,9.408 56.349,10.713 56.437,12.025 56.513,13.341 56.574,14.661 56.621,15.983 56.654,17.308 56.674,18.633 56.679,19.958 56.67,21.282 56.647,22.604 56.61,23.923 56.559,25.238 56.494,26.548 56.415,27.852 56.323,29.149 56.217,30.439 56.097,31.72 55.964,32.992 55.818,34.254 55.659,35.505 55.487,36.745 55.302,37.974 55.105,39.189 54.896,40.392 54.674,41.582 54.441,42.758 54.197,43.919 53.941,45.066 53.674,46.199 53.396,47.316 53.107,48.418 52.809,49.505 52.5,50.577 52.181,51.633 51.853,52.673 51.515,53.698 51.169,54.708 50.813,55.702 50.449,56.681 50.077,57.644 49.697,58.593 49.308,59.526 48.912,60.445 48.509,61.349 48.098,62.238 47.681,63.114 47.257,63.975 46.826,64.822 46.388,65.656 45.945,66.477 45.496,67.284 45.041,68.079 44.58,68.861 44.114,69.631 43.642,70.389 43.166,71.135 42.684,71.869 42.198,72.592 41.708,73.304 41.212,74.006 40.713) 2 | LINESTRING(4.259 55.858,4.895 55.931,5.533 56.001,6.174 56.067,6.817 56.13,7.462 56.19,8.109 56.246,8.757 56.299,9.408 56.349,10.06 56.395,10.713 56.437,11.368 56.477,12.025 56.513,12.682 56.545,13.341 56.574,14 56.599,14.661 56.621,15.322 56.639,15.983 56.654,16.645 56.666,17.308 56.674,17.97 56.678,18.633 56.679,19.296 56.676,19.958 56.67,20.62 56.66,21.282 56.647,21.943 56.63,22.604 56.61,23.264 56.586,23.923 56.559,24.581 56.528,25.238 56.494,25.893 56.456,26.548 56.415,27.2 56.371,27.852 56.323,28.501 56.271,29.149 56.217,29.795 56.159,30.439 56.097,31.08 56.032,31.72 55.964,32.357 55.893,32.992 55.818,33.624 55.74,34.254 55.659,34.881 55.574,35.505 55.487,36.127 55.396,36.745 55.302,37.361 55.205,37.974 55.105,38.583 55.002,39.189 54.896,39.792 54.787,40.392 54.674,40.989 54.559,41.582 54.441,42.171 54.32,42.758 54.197,43.34 54.07,43.919 53.941,44.494 53.809,45.066 53.674,45.634 53.536,46.199 53.396,46.759 53.253,47.316 53.107,47.869 52.959,48.418 52.809,48.964 52.655,49.505 52.5,50.043 52.342,50.577 52.181,51.107 52.018,51.633 51.853,52.155 51.685,52.673 51.515,53.188 51.343,53.698 51.169,54.205 50.992,54.708 50.813,55.207 50.632,55.702 50.449,56.193 50.264,56.681 50.077,57.164 49.888,57.644 49.697,58.12 49.503,58.593 49.308,59.061 49.111,59.526 48.912,59.987 48.712,60.445 48.509,60.899 48.305,61.349 48.098,61.795 47.89,62.238 47.681,62.678 47.47,63.114 47.257,63.546 47.042,63.975 46.826,64.4 46.608,64.822 46.388,65.241 46.168,65.656 45.945,66.068 45.721,66.477 45.496,66.882 45.269,67.284 45.041,67.683 44.811,68.079 44.58,68.472 44.348,68.861 44.114,69.248 43.879,69.631 43.642,70.011 43.405,70.389 43.166,70.763 42.926,71.135 42.684,71.503 42.442,71.869 42.198,72.232 41.953,72.592 41.708,72.95 41.46,73.304 41.212,73.657 40.963,74.006 40.713) 3 | -------------------------------------------------------------------------------- /test/CDB_HeadsTailsBinsTest.sql: -------------------------------------------------------------------------------- 1 | WITH data AS ( 2 | SELECT array_agg(x::numeric) s FROM generate_series(1,100) x 3 | WHERE x % 5 != 0 AND x % 7 != 0 4 | ) 5 | SELECT round(unnest(CDB_HeadsTailsBins(s, 7)),2) FROM data; 6 | 7 | WITH data_nulls AS ( 8 | SELECT array_agg(CASE WHEN x % 2 != 0 THEN x ELSE NULL END::numeric) s FROM generate_series(1,100) x 9 | WHERE x % 5 != 0 AND x % 7 != 0 10 | ) 11 | SELECT round(unnest(CDB_HeadsTailsBins(s, 7)),2) FROM data_nulls; 12 | -------------------------------------------------------------------------------- /test/CDB_HeadsTailsBinsTest_expect: -------------------------------------------------------------------------------- 1 | 49.56 2 | 74.44 3 | 87.50 4 | 93.50 5 | 96.50 6 | 98.00 7 | 99.00 8 | 49.76 9 | 74.65 10 | 88.50 11 | 94.50 12 | 98.00 13 | 99.00 14 | -------------------------------------------------------------------------------- /test/CDB_HelperTest_expect: -------------------------------------------------------------------------------- 1 | relname 2 | prefix_relname 3 | relname_suffix 4 | largolargolargolargolargolargolargolargolargolargolargolarg 5 | prefix_largolargolargolargolargolargolargolargolargolargola 6 | CREATE TABLE 7 | prefix_largolargolargolargolargolargolargolargolargolargola0 8 | DROP TABLE 9 | largolargolargolargolargolargolargolargolargolargola_suffix 10 | CREATE TABLE 11 | largolargolargolargolargolargolargolargolargolargola_suffix0 12 | DROP TABLE 13 | piraña 14 | prefix_piraña 15 | piraña_suffix 16 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaáci 17 | prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi 18 | CREATE TABLE 19 | prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi0 20 | DROP TABLE 21 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix 22 | CREATE TABLE 23 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix0 24 | DROP TABLE 25 | CREATE TABLE 26 | colname 27 | prefix_colname 28 | colname_suffix 29 | largolargolargolargolargolargolargolargolargolargolargolarg 30 | prefix_largolargolargolargolargolargolargolargolargolargola 31 | DROP TABLE 32 | CREATE TABLE 33 | prefix_largolargolargolargolargolargolargolargolargolargola0 34 | DROP TABLE 35 | CREATE TABLE 36 | largolargolargolargolargolargolargolargolargolargola_suffix 37 | DROP TABLE 38 | CREATE TABLE 39 | largolargolargolargolargolargolargolargolargolargola_suffix0 40 | DROP TABLE 41 | CREATE TABLE 42 | piraña 43 | prefix_piraña 44 | piraña_suffix 45 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpiñaáci 46 | prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi 47 | DROP TABLE 48 | CREATE TABLE 49 | prefix_piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi0 50 | DROP TABLE 51 | CREATE TABLE 52 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix 53 | DROP TABLE 54 | CREATE TABLE 55 | piñaácidpiñaácidpiñaácidpiñaácidpiñaácidpi_suffix0 56 | DROP TABLE 57 | pira 58 | pirañ 59 | piraña 60 | CREATE TABLE 61 | f 62 | f 63 | t 64 | t 65 | f 66 | f 67 | DROP TABLE 68 | -------------------------------------------------------------------------------- /test/CDB_HexagonTest.sql: -------------------------------------------------------------------------------- 1 | set client_min_messages to error; 2 | \set VERBOSITY TERSE 3 | 4 | -- Check correctness of an hexagons grid 5 | -- 6 | -- Cells must have no overlaps and have a number of 7 | -- intersections with other cells between 2 and 6 8 | -- 9 | 10 | WITH 11 | params AS ( SELECT ST_MakeEnvelope(10, 10, 20, 20) as env, 2 as radius ), 12 | grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params), 13 | igrid AS ( SELECT row_number() over (), cell from grid ) 14 | 15 | SELECT count(row_number) as r1, sum(st_npoints(cell)) as r2, 'count / npoints' as err 16 | FROM igrid g1 17 | 18 | UNION ALL 19 | 20 | SELECT g1.row_number as r1, g2.row_number as r2, 'overlap' as err 21 | FROM igrid g1, igrid g2 22 | WHERE g2.row_number > g1.row_number AND 23 | ST_Overlaps(g1.cell, g2.cell) 24 | 25 | UNION ALL 26 | 27 | SELECT g1.row_number, count(g2.row_number) as r2, 'n intersections' as err 28 | FROM igrid g1, igrid g2 29 | WHERE g1.row_number != g2.row_number AND 30 | ST_Intersects(g1.cell, g2.cell) 31 | GROUP BY g1.row_number 32 | HAVING count(g2.row_number) > 6 OR count(g2.row_number) < 2 33 | 34 | UNION ALL 35 | 36 | SELECT g1.row_number, null::integer, 'centroid out of extent' as err 37 | FROM igrid g1, params 38 | WHERE NOT ST_Intersects(ST_Centroid(g1.cell), params.env) 39 | 40 | ; 41 | 42 | 43 | -- Check robustness of HexagonGrid generation 44 | 45 | WITH 46 | params AS ( SELECT 47 | ST_MakeEnvelope(-20037508.5,20037507,-20037508,20037507.5) as env, 48 | 0.002 as radius ), 49 | grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params) 50 | SELECT '#160', count(cell) > 23000 from grid; 51 | 52 | -- Check small grids are generated... 53 | SELECT COUNT(*) FROM cartodb.CDB_HexagonGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 10); 54 | 55 | -- But large grids produce an error 56 | SELECT COUNT(*) FROM cartodb.CDB_HexagonGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 1); 57 | -------------------------------------------------------------------------------- /test/CDB_HexagonTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | 9|63|count / npoints 3 | #160|t 4 | 3886 5 | ERROR: The requested grid is too big to be rendered 6 | -------------------------------------------------------------------------------- /test/CDB_JenksBinsTest.sql: -------------------------------------------------------------------------------- 1 | WITH data AS ( 2 | SELECT Array[0.99, 1.0, 1.01, 3 | 4.99, 5.01, 4 | 10.01, 10.01, 5 | 15.01, 14.99, 6 | 20.1, 19.9]::numeric[] AS s 7 | ) 8 | SELECT unnest(CDB_JenksBins(s, 5)) FROM data; 9 | 10 | 11 | WITH data_nulls AS ( 12 | SELECT Array[0.99, 1.0, 1.01, 13 | 4.99, 5.01, 14 | null, null, 15 | 10.01, 10.01, 16 | 15.01, 14.99, 17 | null, null, 18 | 20.1, 19.9]::numeric[] AS s 19 | ) 20 | SELECT unnest(CDB_JenksBins(s, 5)) FROM data_nulls; 21 | 22 | 23 | WITH data_inverse AS ( 24 | SELECT Array[0.99, 1.0, 1.01, 25 | 4.99, 5.01, 26 | 10.01, 10.01, 27 | 15.01, 14.99, 28 | 20.1, 19.9]::numeric[] AS s 29 | ) 30 | SELECT unnest(CDB_JenksBins(s, 5, 0, true)) FROM data_inverse; 31 | 32 | 33 | WITH data_small AS ( 34 | SELECT Array[0.99, 1.0, 10.01, 10.01, 10.01, 10.01]::numeric[] AS s 35 | ) 36 | SELECT unnest(CDB_JenksBins(s, 4)) FROM data_small; 37 | -------------------------------------------------------------------------------- /test/CDB_JenksBinsTest_expect: -------------------------------------------------------------------------------- 1 | 1.01 2 | 5.01 3 | 10.01 4 | 15.01 5 | 20.1 6 | 1.01 7 | 5.01 8 | 10.01 9 | 15.01 10 | 20.1 11 | 0.99 12 | 4.99 13 | 10.01 14 | 14.99 15 | 19.9 16 | 0.99 17 | 1.0 18 | 10.01 19 | -------------------------------------------------------------------------------- /test/CDB_MathTest.sql: -------------------------------------------------------------------------------- 1 | 2 | SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,2,3]) a; 3 | SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,3]) a; 4 | SELECT cdb_math_mode(a) from unnest(ARRAY[1]) a; 5 | -------------------------------------------------------------------------------- /test/CDB_MathTest_expect: -------------------------------------------------------------------------------- 1 | 2 2 | 1 3 | 1 4 | -------------------------------------------------------------------------------- /test/CDB_OAuth_expect: -------------------------------------------------------------------------------- 1 | 2 | CREATE TABLE 3 | INSERT 0 1 4 | SELECT 1 5 | CREATE VIEW 6 | SELECT 1 7 | SELECT 1 8 | CREATE FUNCTION 9 | 1 10 | 1 11 | 1 12 | 1 13 | 1 14 | 1 15 | DROP FUNCTION 16 | denied_table|t 17 | denied_tableas|t 18 | denied_view|t 19 | denied_mview|t 20 | denied_selectinto|t 21 | 1 22 | denied_function|t 23 | DROP TABLE 24 | DROP VIEW 25 | DROP MATERIALIZED VIEW 26 | DROP TABLE 27 | DROP TABLE 28 | DROP FUNCTION 29 | NOTICE: event trigger "oauth_reassign_tables_trigger" does not exist, skipping 30 | 31 | CREATE TABLE 32 | INSERT 0 1 33 | SELECT 1 34 | CREATE VIEW 35 | SELECT 1 36 | SELECT 1 37 | CREATE FUNCTION 38 | 1 39 | 1 40 | 1 41 | 1 42 | 1 43 | 1 44 | DROP FUNCTION 45 | denied_table2|t 46 | denied_tableas2|t 47 | denied_view2|t 48 | denied_mview2|t 49 | denied_selectinto2|t 50 | 1 51 | denied_function2|t 52 | DROP TABLE 53 | DROP VIEW 54 | DROP MATERIALIZED VIEW 55 | DROP TABLE 56 | DROP TABLE 57 | DROP FUNCTION 58 | 59 | CREATE TABLE 60 | INSERT 0 1 61 | SELECT 1 62 | CREATE VIEW 63 | SELECT 1 64 | SELECT 1 65 | CREATE FUNCTION 66 | 1 67 | 1 68 | 1 69 | 1 70 | 1 71 | 1 72 | DROP FUNCTION 73 | denied_table3|t 74 | denied_tableas3|t 75 | denied_view3|t 76 | denied_mview3|t 77 | denied_selectinto3|t 78 | 1 79 | denied_function3|t 80 | DROP TABLE 81 | DROP VIEW 82 | DROP MATERIALIZED VIEW 83 | DROP TABLE 84 | DROP TABLE 85 | DROP FUNCTION 86 | 87 | CREATE TABLE 88 | INSERT 0 1 89 | SELECT 1 90 | CREATE VIEW 91 | SELECT 1 92 | SELECT 1 93 | CREATE FUNCTION 94 | 1 95 | 1 96 | 1 97 | 1 98 | 1 99 | 1 100 | denied_function4|t 101 | 1 102 | 1 103 | 1 104 | 1 105 | 1 106 | 1 107 | DROP TABLE 108 | DROP VIEW 109 | DROP MATERIALIZED VIEW 110 | DROP TABLE 111 | DROP TABLE 112 | DROP FUNCTION 113 | 114 | -------------------------------------------------------------------------------- /test/CDB_OverviewsTest.sql.deprecated: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO error; 2 | \set VERBOSITY default 3 | 4 | \i test/overviews/fixtures.sql 5 | vacuum ANALYZE; -- Make sure there are metrics for ST_EstimatedExtent 6 | 7 | SELECT _CDB_Aggregable_Attributes_Expression('base_bare_t'::regclass); 8 | SELECT _CDB_Aggregated_Attributes_Expression('base_bare_t'::regclass); 9 | SELECT _CDB_Aggregated_Attributes_Expression('base_bare_t'::regclass, 'tab'); 10 | 11 | SELECT CDB_CreateOverviews('base_bare_t'::regclass); 12 | SELECT count(*) FROM _vovw_2_base_bare_t; 13 | 14 | 15 | SELECT _CDB_Aggregable_Attributes_Expression('base_t'::regclass); 16 | SELECT _CDB_Aggregated_Attributes_Expression('base_t'::regclass); 17 | SELECT _CDB_Aggregated_Attributes_Expression('base_t'::regclass, 'tab'); 18 | 19 | SELECT CDB_CreateOverviews('base_t'::regclass); 20 | SELECT count(*) FROM _vovw_2_base_t; 21 | 22 | SELECT CDB_CreateOverviews('polyg_t'::regclass); 23 | 24 | SELECT CDB_CreateOverviews('column_types_t'::regclass); 25 | 26 | SELECT CDB_Overviews('base_t'::regclass); 27 | SELECT CDB_Overviews('"public"."base_t"'::regclass); 28 | SELECT CDB_Overviews(ARRAY['base_t'::regclass, 'base_bare_t'::regclass]); 29 | SELECT CDB_Overviews('polyg_t'::regclass); 30 | SELECT CDB_Overviews('column_types_t'::regclass); 31 | 32 | SELECT CDB_DropOverviews('column_types_t'::regclass); 33 | SELECT CDB_DropOverviews('base_bare_t'::regclass); 34 | SELECT CDB_DropOverviews('base_t'::regclass); 35 | SELECT count(*) FROM _vovw_2_base_t; 36 | 37 | SELECT CDB_CreateOverviewsWithToleranceInPixels('base_t'::regclass, 7.5); 38 | SELECT count(*) FROM _vovw_2_base_t; 39 | SELECT CDB_DropOverviews('base_t'::regclass); 40 | 41 | DROP TABLE column_types_t; 42 | DROP TABLE base_bare_t; 43 | DROP TABLE base_t; 44 | DROP TABLE polyg_t; 45 | -------------------------------------------------------------------------------- /test/CDB_OverviewsTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | CREATE TABLE 3 | INSERT 0 1114 4 | CREATE TABLE 5 | INSERT 0 1114 6 | CREATE TABLE 7 | INSERT 0 5 8 | SELECT 1114 9 | VACUUM 10 | 11 | 12 | 13 | {_vovw_2_base_bare_t,_vovw_1_base_bare_t,_vovw_0_base_bare_t} 14 | 126 15 | number,int_number,name,start 16 | 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 17 | 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 18 | {_vovw_2_base_t,_vovw_1_base_t,_vovw_0_base_t} 19 | 126 20 | 21 | {_vovw_2_column_types_t,_vovw_1_column_types_t,_vovw_0_column_types_t} 22 | (base_t,0,_vovw_0_base_t) 23 | (base_t,1,_vovw_1_base_t) 24 | (base_t,2,_vovw_2_base_t) 25 | (base_t,0,_vovw_0_base_t) 26 | (base_t,1,_vovw_1_base_t) 27 | (base_t,2,_vovw_2_base_t) 28 | (base_bare_t,0,_vovw_0_base_bare_t) 29 | (base_bare_t,1,_vovw_1_base_bare_t) 30 | (base_bare_t,2,_vovw_2_base_bare_t) 31 | (base_t,0,_vovw_0_base_t) 32 | (base_t,1,_vovw_1_base_t) 33 | (base_t,2,_vovw_2_base_t) 34 | (column_types_t,0,_vovw_0_column_types_t) 35 | (column_types_t,1,_vovw_1_column_types_t) 36 | (column_types_t,2,_vovw_2_column_types_t) 37 | 38 | 39 | 40 | ERROR: relation "_vovw_2_base_t" does not exist 41 | LINE 1: SELECT count(*) FROM _vovw_2_base_t; 42 | ^ 43 | {_vovw_5_base_t,_vovw_4_base_t,_vovw_3_base_t,_vovw_2_base_t,_vovw_1_base_t,_vovw_0_base_t} 44 | 38 45 | 46 | DROP TABLE 47 | DROP TABLE 48 | DROP TABLE 49 | DROP TABLE 50 | -------------------------------------------------------------------------------- /test/CDB_QuantileBinsTest.sql: -------------------------------------------------------------------------------- 1 | WITH data AS ( 2 | SELECT array_agg(x::numeric) AS s 3 | FROM generate_series(0, 99) AS x 4 | ) 5 | SELECT unnest(CDB_QuantileBins(s, 10)) 6 | FROM data; 7 | 8 | WITH data_nulls AS ( 9 | SELECT array_agg(x::numeric) AS s 10 | FROM ( 11 | SELECT x FROM generate_series(0, 99) AS x 12 | UNION ALL 13 | SELECT null AS x FROM generate_series(1, 10) AS x 14 | ) _wrap 15 | ) 16 | SELECT unnest(CDB_QuantileBins(s, 10)) 17 | FROM data_nulls; 18 | -------------------------------------------------------------------------------- /test/CDB_QuantileBinsTest_expect: -------------------------------------------------------------------------------- 1 | 9 2 | 19 3 | 29 4 | 39 5 | 49 6 | 59 7 | 69 8 | 79 9 | 89 10 | 99 11 | 9 12 | 19 13 | 29 14 | 39 15 | 49 16 | 59 17 | 69 18 | 79 19 | 89 20 | 99 21 | -------------------------------------------------------------------------------- /test/CDB_QueryStatementsTest.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO error; 2 | \set VERBOSITY terse 3 | 4 | WITH q AS ( SELECT CDB_QueryStatements(' 5 | SELECT * FROM geometry_columns; 6 | ') as statement ) 7 | SELECT '1', row_number() over (), statement FROM q; 8 | 9 | WITH q AS ( SELECT CDB_QueryStatements(' 10 | SELECT * FROM geometry_columns 11 | ') as statement ) 12 | SELECT '2', row_number() over (), statement FROM q; 13 | 14 | WITH q AS ( SELECT CDB_QueryStatements(' 15 | ;;;SELECT * FROM geometry_columns 16 | ') as statement ) 17 | SELECT '3', row_number() over (), statement FROM q; 18 | 19 | WITH q AS ( SELECT CDB_QueryStatements($the_param$ 20 | CREATE table "my'tab;le" ("$" int); 21 | SELECT '1','$$', '$hello$', "$" FROM "my'tab;le"; 22 | CREATE function "hi'there" ("'" text default '$') returns void as $h$ declare a int; b text; begin b='hi'; return; end; $h$ language 'plpgsql'; 23 | SELECT 5; 24 | $the_param$) as statement ) 25 | SELECT '4', row_number() over (), statement FROM q; 26 | 27 | WITH q AS ( SELECT CDB_QueryStatements($the_param$ 28 | INSER INTO "my''""t" values ('''','""'';;'); 29 | SELECT $qu;oted$ hi $qu;oted$; 30 | $the_param$) as statement ) 31 | SELECT '5', row_number() over (), statement FROM q; 32 | 33 | WITH q AS ( SELECT CDB_QueryStatements($the_param$ 34 | SELECT 35 | 1 ; SELECT 36 | 2 37 | $the_param$) as statement ) 38 | SELECT '6', row_number() over (), statement FROM q; 39 | 40 | -- This is an insane input, illegal sql 41 | -- we are really only testing that it does not 42 | -- take forever to process.. 43 | -- The actual result is not correct, so if the function 44 | -- ever gets fixed check if it's better 45 | WITH q AS ( SELECT CDB_QueryStatements($the_param$ 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | /a 55 | $b$ 56 | $c$d 57 | ; 58 | $the_param$) as statement ) 59 | SELECT '7', row_number() over (), statement FROM q; 60 | 61 | 62 | WITH q AS ( SELECT CDB_QueryStatements($the_param$ 63 | SELECT $quoted$ hi 64 | $quoted$; 65 | $the_param$) as statement ) 66 | SELECT '8', row_number() over (), statement FROM q; 67 | -------------------------------------------------------------------------------- /test/CDB_QueryStatementsTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | 1|1|SELECT * FROM geometry_columns 3 | 2|1|SELECT * FROM geometry_columns 4 | 3|1|SELECT * FROM geometry_columns 5 | 4|1|CREATE table "my'tab;le" ("$" int) 6 | 4|2|SELECT '1','$$', '$hello$', "$" FROM "my'tab;le" 7 | 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' 8 | 4|4|SELECT 5 9 | 5|1|INSER INTO "my''""t" values ('''','""'';;') 10 | 5|2|SELECT $qu;oted$ hi $qu;oted$ 11 | 6|1|SELECT 12 | 1 13 | 6|2|SELECT 14 | 2 15 | 7|1|/a 16 | 7|2|b 17 | 7|3|c 18 | 7|4|d 19 | 8|1|SELECT $quoted$ hi 20 | $quoted$ 21 | -------------------------------------------------------------------------------- /test/CDB_QueryTablesTest.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO warning; 2 | \set VERBOSITY terse 3 | 4 | WITH inp AS ( select 'SELECT * FROM geometry_columns'::text as q ) 5 | SELECT q, CDB_QueryTables(q) from inp; 6 | 7 | WITH inp AS ( select 'SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)'::text as q ) 8 | SELECT q, CDB_QueryTables(q) from inp; 9 | 10 | WITH inp AS ( select $quote$CREATE table "my'tab;le" as select 1$quote$::text as q ) 11 | SELECT q, CDB_QueryTables(q) from inp; 12 | 13 | WITH inp AS ( select 'SELECT a.oid, b.oid FROM pg_class a, pg_class b'::text as q ) 14 | SELECT q, CDB_QueryTables(q) from inp; 15 | 16 | WITH inp AS ( select 'SELECT 1 as col1; select 2 as col2'::text as q ) 17 | SELECT q, CDB_QueryTables(q) from inp; 18 | 19 | WITH inp AS ( select 'select 1 from nonexistant'::text as q ) 20 | SELECT q, CDB_QueryTables(q) from inp; 21 | 22 | WITH inp AS ( select 'begin; select * from pg_class; commit;'::text as q ) 23 | SELECT q, CDB_QueryTables(q) from inp; 24 | 25 | WITH inp AS ( select 'create table test (a int); insert into test values (1); select * from test;'::text as q ) 26 | SELECT q, CDB_QueryTables(q) from inp; 27 | 28 | WITH inp AS ( select 'WITH a AS (select * from pg_class) select * from a'::text as q ) 29 | SELECT q, CDB_QueryTables(q) from inp; 30 | 31 | CREATE SCHEMA sc; 32 | create table sc.test (a int); 33 | insert into sc.test values (1); 34 | WITH inp AS ( select 'select * from sc.test'::text as q ) 35 | SELECT q, CDB_QueryTables(q) from inp; 36 | DROP TABLE sc.test; 37 | DROP SCHEMA sc; 38 | 39 | WITH inp AS ( select 'SELECT 40 | * FROM geometry_columns'::text as q ) 41 | SELECT q, CDB_QueryTables(q) from inp; 42 | -------------------------------------------------------------------------------- /test/CDB_QueryTablesTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | SELECT * FROM geometry_columns|{pg_catalog.pg_attribute,pg_catalog.pg_class,pg_catalog.pg_constraint,pg_catalog.pg_namespace,pg_catalog.pg_type} 3 | SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)|{pg_catalog.pg_attribute,pg_catalog.pg_class} 4 | CREATE table "my'tab;le" as select 1|{} 5 | SELECT a.oid, b.oid FROM pg_class a, pg_class b|{pg_catalog.pg_class} 6 | SELECT 1 as col1; select 2 as col2|{} 7 | WARNING: CDB_QueryTables cannot explain query: select 1 from nonexistant (42P01: relation "nonexistant" does not exist) 8 | ERROR: relation "nonexistant" does not exist 9 | begin; select * from pg_class; commit;|{pg_catalog.pg_class} 10 | WARNING: CDB_QueryTables cannot explain query: insert into test values (1) (42P01: relation "test" does not exist) 11 | ERROR: relation "test" does not exist 12 | WITH a AS (select * from pg_class) select * from a|{pg_catalog.pg_class} 13 | CREATE SCHEMA 14 | CREATE TABLE 15 | INSERT 0 1 16 | select * from sc.test|{sc.test} 17 | DROP TABLE 18 | DROP SCHEMA 19 | SELECT 20 | * FROM geometry_columns|{pg_catalog.pg_attribute,pg_catalog.pg_class,pg_catalog.pg_constraint,pg_catalog.pg_namespace,pg_catalog.pg_type} 21 | -------------------------------------------------------------------------------- /test/CDB_QuotaTest.sql: -------------------------------------------------------------------------------- 1 | set client_min_messages to error; 2 | \set VERBOSITY TERSE 3 | -- Runs a query and returns whether an error was thrown 4 | -- Useful when the error message depends on the execution plan or db settings 5 | -- The error message outputs the extra quota, and this might depend on the database setup and version 6 | CREATE OR REPLACE FUNCTION catch_error(query text) 7 | RETURNS bool 8 | AS $$ 9 | BEGIN 10 | EXECUTE query; 11 | RETURN FALSE; 12 | EXCEPTION 13 | WHEN OTHERS THEN 14 | RETURN TRUE; 15 | END 16 | $$ LANGUAGE 'plpgsql'; 17 | 18 | CREATE TABLE big(a int); 19 | -- Try the legacy interface 20 | -- See https://github.com/CartoDB/cartodb-postgresql/issues/13 21 | CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big 22 | EXECUTE PROCEDURE cartodb.CDB_CheckQuota(2, 1, 'public'); 23 | INSERT INTO big VALUES (1); -- allowed, check runs before 24 | SELECT 'excess1', catch_error($$INSERT INTO big VALUES (2); $$); -- disallowed, quota exceeds before 25 | SELECT cartodb.CDB_SetUserQuotaInBytes(0); 26 | SELECT cartodb.CDB_CartodbfyTable('big'); 27 | -- Creating the trigger should fail as it was created by CDB_CartodbfyTable 28 | CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big 29 | EXECUTE PROCEDURE cartodb.CDB_CheckQuota(2, 1, 'public'); 30 | -- Drop the trigger and recreate it forcing a 100% checks 31 | DROP TRIGGER test_quota ON big; 32 | CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big 33 | EXECUTE PROCEDURE cartodb.CDB_CheckQuota(2, 1, 'public'); 34 | INSERT INTO big SELECT generate_series(2049,4096); 35 | INSERT INTO big SELECT generate_series(4097,6144); 36 | INSERT INTO big SELECT generate_series(6145,8192); 37 | -- Test for #108: https://github.com/CartoDB/cartodb-postgresql/issues/108 38 | SELECT cartodb.CDB_UserDataSize() < 500000 AND cartodb.CDB_UserDataSize() > 0; 39 | SELECT cartodb._CDB_total_relation_size('public', 'big') < 1000000; 40 | SELECT cartodb._CDB_total_relation_size('public', 'nonexistent_table_name'); 41 | -- END Test for #108 42 | 43 | SELECT cartodb.CDB_SetUserQuotaInBytes(2); 44 | SELECT 'excess2', catch_error($$INSERT INTO big VALUES (8193);$$); 45 | SELECT cartodb.CDB_SetUserQuotaInBytes(0); 46 | INSERT INTO big VALUES (8194); 47 | DROP TABLE big; 48 | 49 | 50 | --analysis tables should be excluded from quota: 51 | CREATE TABLE big(a int); 52 | CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big 53 | EXECUTE PROCEDURE cartodb.CDB_CheckQuota(2, 1, 'public'); 54 | SELECT cartodb.CDB_SetUserQuotaInBytes(1); 55 | CREATE TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4(id int); 56 | INSERT INTO analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4(id) VALUES (1),(2),(3),(4),(5); 57 | INSERT INTO big VALUES (1); -- allowed, check runs before 58 | DROP TABLE analysis_2f13a3dbd7_41bd92976fc6dd97072afe4ee450054f4c0715d4; 59 | SELECT 'excess3', catch_error($$INSERT INTO big VALUES (3);$$); -- disallowed, quota exceeds before 60 | DROP TABLE big; 61 | SELECT CDB_SetUserQuotaInBytes(0); 62 | 63 | CREATE SCHEMA "complex-name%_with'quotes"""; 64 | SELECT CDB_UserDataSize('"complex-name%_with''quotes"'); 65 | DROP SCHEMA "complex-name%_with'quotes"""; 66 | 67 | set client_min_messages to NOTICE; 68 | DROP FUNCTION catch_error(text); 69 | DROP FUNCTION _CDB_UserQuotaInBytes(); 70 | -------------------------------------------------------------------------------- /test/CDB_QuotaTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | CREATE FUNCTION 3 | CREATE TABLE 4 | CREATE TRIGGER 5 | INSERT 0 1 6 | excess1|t 7 | 0 8 | big 9 | ERROR: trigger "test_quota" for relation "big" already exists 10 | DROP TRIGGER 11 | CREATE TRIGGER 12 | INSERT 0 2048 13 | INSERT 0 2048 14 | INSERT 0 2048 15 | t 16 | t 17 | 0 18 | 2 19 | excess2|t 20 | 0 21 | INSERT 0 1 22 | DROP TABLE 23 | CREATE TABLE 24 | CREATE TRIGGER 25 | 1 26 | CREATE TABLE 27 | INSERT 0 5 28 | INSERT 0 1 29 | DROP TABLE 30 | excess3|t 31 | DROP TABLE 32 | 0 33 | CREATE SCHEMA 34 | 0 35 | DROP SCHEMA 36 | SET 37 | DROP FUNCTION 38 | DROP FUNCTION 39 | -------------------------------------------------------------------------------- /test/CDB_RectangleTest.sql: -------------------------------------------------------------------------------- 1 | set client_min_messages to error; 2 | \set VERBOSITY TERSE 3 | 4 | -- Check small grids are generated... 5 | SELECT COUNT(*) FROM cartodb.CDB_RectangleGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 10, 10); 6 | 7 | -- But large grids produce an error 8 | SELECT COUNT(*) FROM cartodb.CDB_RectangleGrid(ST_MakeEnvelope(0,0,1000,1000,3857), 1, 1); 9 | -------------------------------------------------------------------------------- /test/CDB_RectangleTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | 10000 3 | ERROR: The requested grid is too big to be rendered 4 | -------------------------------------------------------------------------------- /test/CDB_StatsTest.sql: -------------------------------------------------------------------------------- 1 | -- continuous uniform distribution has kurtosis = -6/5, skewness = 0.0 2 | -- http://mathworld.wolfram.com/UniformDistribution.html 3 | set client_min_messages to ERROR; 4 | 5 | WITH dist AS ( 6 | SELECT generate_series(0,10000)::numeric / 10000.0 i 7 | ) 8 | SELECT 9 | abs(CDB_Kurtosis(array_agg(i)) + 1.2) < 1e-3 AS kurtosis, 10 | abs(CDB_Skewness(array_agg(i))) < 1e-3 AS skewness 11 | FROM dist; 12 | 13 | set client_min_messages to NOTICE; 14 | -------------------------------------------------------------------------------- /test/CDB_StatsTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | t|t 3 | SET 4 | -------------------------------------------------------------------------------- /test/CDB_SyncTableTest.sql: -------------------------------------------------------------------------------- 1 | -- Setup: create and populate a table to test the syncs 2 | \set QUIET on 3 | BEGIN; 4 | SET client_min_messages TO error; 5 | CREATE TABLE test_sync_source ( 6 | cartodb_id bigint, 7 | lat double precision, 8 | lon double precision, 9 | name text 10 | ); 11 | INSERT INTO test_sync_source VALUES 12 | (1, 1.0, 1.0, 'foo'), 13 | (2, 2.0, 2.0, 'bar'), 14 | (3, 3.0, 3.0, 'patata'), 15 | (4, 4.0, 4.0, 'melon'); 16 | SET client_min_messages TO notice; 17 | \set QUIET off 18 | 19 | 20 | \echo 'First table sync: it should be simply just copied to the destination' 21 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); 22 | 23 | \echo 'Next table sync: there shall be no changes' 24 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); 25 | 26 | \echo 'Remove a row from the source and check it is deleted from the dest table' 27 | DELETE FROM test_sync_source WHERE cartodb_id = 3; 28 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); 29 | 30 | \echo 'Insert a new row and check that it is inserted in the dest table' 31 | INSERT INTO test_sync_source VALUES (5, 5.0, 5.0, 'sandia'); 32 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); 33 | 34 | \echo 'Modify row and check that it is modified in the dest table' 35 | UPDATE test_sync_source SET name = 'cantaloupe' WHERE cartodb_id = 4; 36 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest'); 37 | 38 | \echo 'Sanity check: the end result is the same source table' 39 | SELECT * FROM test_sync_source ORDER BY cartodb_id; 40 | SELECT * FROM test_sync_dest ORDER BY cartodb_id; 41 | 42 | 43 | \echo 'It shall exclude geom columns if instructed to do so' 44 | \set QUIET on 45 | SET client_min_messages TO error; 46 | SELECT cartodb.CDB_SetUserQuotaInBytes(0); -- Set user quota to infinite 47 | SELECT cartodb.CDB_CartodbfyTable('test_sync_source'); 48 | SELECT cartodb.CDB_CartodbfyTable('test_sync_dest'); 49 | UPDATE test_sync_dest SET the_geom = cartodb.CDB_LatLng(lat, lon); -- A "gecoding" 50 | \set QUIET off 51 | SET client_min_messages TO notice; 52 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest', '{the_geom, the_geom_webmercator}'); 53 | SELECT * FROM test_sync_source ORDER BY cartodb_id; 54 | SELECT cartodb_id, the_geom, lat, lon, name FROM test_sync_dest ORDER BY cartodb_id; 55 | 56 | \echo 'It will work with schemas that need quoting' 57 | \set QUIET on 58 | SET client_min_messages TO error; 59 | CREATE SCHEMA "sch-ema"; 60 | CREATE TABLE "test_sync_source2" AS SELECT * FROM test_sync_source; 61 | \set QUIET off 62 | SELECT cartodb.CDB_SyncTable('test_sync_source2', 'sch-ema', 'test_sync_dest'); 63 | INSERT INTO test_sync_source2(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); 64 | DELETE FROM test_sync_source2 WHERE cartodb_id = 4; 65 | UPDATE test_sync_source2 SET lat = 2.5 WHERE cartodb_id = 2; 66 | SET client_min_messages TO notice; 67 | SELECT cartodb.CDB_SyncTable('test_sync_source2', 'sch-ema', 'test_sync_dest'); 68 | 69 | \echo 'It will work with table names that need quoting' 70 | \set QUIET on 71 | SET client_min_messages TO error; 72 | CREATE TABLE "test-sync-source" AS SELECT * FROM test_sync_source; 73 | \set QUIET off 74 | SELECT cartodb.CDB_SyncTable('test-sync-source', 'public', 'test-sync-dest'); 75 | INSERT INTO "test-sync-source"(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); 76 | DELETE FROM "test-sync-source" WHERE cartodb_id = 4; 77 | UPDATE "test-sync-source" SET lat = 2.5 WHERE cartodb_id = 2; 78 | SET client_min_messages TO notice; 79 | SELECT cartodb.CDB_SyncTable('test-sync-source', 'public', 'test-sync-dest'); 80 | 81 | \echo 'It will work with column names that need quoting' 82 | \set QUIET on 83 | SET client_min_messages TO error; 84 | ALTER TABLE test_sync_source ADD COLUMN "a-column" int; 85 | \set QUIET off 86 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest2'); 87 | INSERT INTO test_sync_source(cartodb_id, lat, lon, name) VALUES (6, 6.0, 6.0, 'papaya'); 88 | DELETE FROM test_sync_source WHERE cartodb_id = 4; 89 | UPDATE test_sync_source SET lat = 2.5 WHERE cartodb_id = 2; 90 | SET client_min_messages TO notice; 91 | SELECT cartodb.CDB_SyncTable('test_sync_source', 'public', 'test_sync_dest2'); 92 | 93 | -- Cleanup 94 | ROLLBACK; 95 | -------------------------------------------------------------------------------- /test/CDB_SyncTableTest_expect: -------------------------------------------------------------------------------- 1 | First table sync: it should be simply just copied to the destination 2 | NOTICE: INSERTED 4 row(s) 3 | 4 | Next table sync: there shall be no changes 5 | NOTICE: relation "test_sync_dest" already exists, skipping 6 | NOTICE: DELETED 0 row(s) 7 | NOTICE: INSERTED 0 row(s) 8 | NOTICE: MODIFIED 0 row(s) 9 | 10 | Remove a row from the source and check it is deleted from the dest table 11 | DELETE 1 12 | NOTICE: relation "test_sync_dest" already exists, skipping 13 | NOTICE: DELETED 1 row(s) 14 | NOTICE: INSERTED 0 row(s) 15 | NOTICE: MODIFIED 0 row(s) 16 | 17 | Insert a new row and check that it is inserted in the dest table 18 | INSERT 0 1 19 | NOTICE: relation "test_sync_dest" already exists, skipping 20 | NOTICE: DELETED 0 row(s) 21 | NOTICE: INSERTED 1 row(s) 22 | NOTICE: MODIFIED 0 row(s) 23 | 24 | Modify row and check that it is modified in the dest table 25 | UPDATE 1 26 | NOTICE: relation "test_sync_dest" already exists, skipping 27 | NOTICE: DELETED 0 row(s) 28 | NOTICE: INSERTED 0 row(s) 29 | NOTICE: MODIFIED 1 row(s) 30 | 31 | Sanity check: the end result is the same source table 32 | 1|1|1|foo 33 | 2|2|2|bar 34 | 4|4|4|cantaloupe 35 | 5|5|5|sandia 36 | 1|1|1|foo 37 | 2|2|2|bar 38 | 4|4|4|cantaloupe 39 | 5|5|5|sandia 40 | It shall exclude geom columns if instructed to do so 41 | 0 42 | test_sync_source 43 | test_sync_dest 44 | SET 45 | NOTICE: relation "test_sync_dest" already exists, skipping 46 | NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called 47 | NOTICE: DELETED 0 row(s) 48 | NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called 49 | NOTICE: INSERTED 0 row(s) 50 | NOTICE: cdb_invalidate_varnish(public.test_sync_dest) called 51 | NOTICE: MODIFIED 0 row(s) 52 | 53 | 1|||1|1|foo 54 | 2|||2|2|bar 55 | 4|||4|4|cantaloupe 56 | 5|||5|5|sandia 57 | 1|0101000020E6100000000000000000F03F000000000000F03F|1|1|foo 58 | 2|0101000020E610000000000000000000400000000000000040|2|2|bar 59 | 4|0101000020E610000000000000000010400000000000001040|4|4|cantaloupe 60 | 5|0101000020E610000000000000000014400000000000001440|5|5|sandia 61 | It will work with schemas that need quoting 62 | 63 | INSERT 0 1 64 | DELETE 1 65 | UPDATE 1 66 | SET 67 | NOTICE: relation "test_sync_dest" already exists, skipping 68 | NOTICE: DELETED 1 row(s) 69 | NOTICE: INSERTED 1 row(s) 70 | NOTICE: MODIFIED 1 row(s) 71 | 72 | It will work with table names that need quoting 73 | 74 | INSERT 0 1 75 | DELETE 1 76 | UPDATE 1 77 | SET 78 | NOTICE: relation "test-sync-dest" already exists, skipping 79 | NOTICE: DELETED 1 row(s) 80 | NOTICE: INSERTED 1 row(s) 81 | NOTICE: MODIFIED 1 row(s) 82 | 83 | It will work with column names that need quoting 84 | 85 | INSERT 0 1 86 | DELETE 1 87 | UPDATE 1 88 | SET 89 | NOTICE: relation "test_sync_dest2" already exists, skipping 90 | NOTICE: DELETED 1 row(s) 91 | NOTICE: INSERTED 1 row(s) 92 | NOTICE: MODIFIED 1 row(s) 93 | 94 | ROLLBACK 95 | -------------------------------------------------------------------------------- /test/CDB_TransformToWebmercatorTest.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET client_min_messages TO error; 3 | 4 | -- Run psql with -tA switches and expect 5 | -- CDB_TransformToWebmercatorTest_expect 6 | select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 7 | 'SRID=4326;LINESTRING(90 90, 0 80)'), 1)); 8 | select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 9 | 'SRID=4326;LINESTRING(90 90, 0 90)'), 1)); 10 | select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 11 | 'SRID=4326;POINT(0 90)'), 1)); 12 | select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 13 | 'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1)); 14 | select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 15 | 'SRID=4326;MULTIPOINT(10 3)'), 1)); 16 | select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 17 | 'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1)); 18 | select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 19 | 'SRID=4326;POINT(5 3)'), 1)); 20 | -- See https://github.com/Vizzuality/cartodb/issues/901 21 | select '8', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 22 | 'SRID=4326;POLYGON((100 0, -100 -100, 100 -100, -100 0, 100 00))'), 1)); 23 | -- See https://github.com/Vizzuality/cartodb/issues/931 24 | select '9', CDB_TransformToWebmercator( 25 | '0106000020E61000000100000001030000000100000007000000010000000000F87F9CDFD01E32095341010000000000F87F193B6F0A30095341010000000000F87FA10FBF4C1D095341010000000000F87F38E258111C095341010000000000F87F5196BAFF17095341010000000000F87F4F0550911B095341010000000000F87F9CDFD01E32095341'::geometry); 26 | -- Already in webmercator, doun't touch, even if out of valid bounds 27 | select '10', ST_AsEWKT(CDB_TransformToWebmercator('SRID=3857;POINT(-20037510 -30240972)'::geometry)); 28 | END; 29 | -------------------------------------------------------------------------------- /test/CDB_TransformToWebmercatorTest_expect: -------------------------------------------------------------------------------- 1 | BEGIN 2 | SET 3 | 1|SRID=3857;LINESTRING(9016879 30240972,0 15538711) 4 | 2| 5 | 3| 6 | 4|SRID=3857;MULTIPOINT(0 445640,1113195 334111) 7 | 5|SRID=3857;MULTIPOINT(1113195 334111) 8 | 6|SRID=3857;MULTILINESTRING((0 445640,-445278 557305)) 9 | 7|SRID=3857;POINT(556597 334111) 10 | 8|SRID=3857;MULTIPOLYGON(((0 -6446276,8682920 -30240972,-8682920 -30240972,0 -6446276)),((11131949 0,0 -6446276,-11131949 0,11131949 0))) 11 | 9| 12 | 10|SRID=3857;POINT(-20037510 -30240972) 13 | COMMIT 14 | -------------------------------------------------------------------------------- /test/CDB_UserTablesTest.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages TO ERROR; 2 | DO 3 | $do$ 4 | BEGIN 5 | IF NOT EXISTS ( 6 | SELECT * 7 | FROM pg_catalog.pg_user 8 | WHERE usename = 'publicuser') THEN 9 | 10 | CREATE ROLE publicuser LOGIN; 11 | END IF; 12 | END 13 | $do$; 14 | SET client_min_messages TO NOTICE; 15 | 16 | CREATE TABLE pub(a int); 17 | CREATE TABLE prv(a int); 18 | GRANT SELECT ON TABLE pub TO publicuser; 19 | REVOKE SELECT ON TABLE prv FROM publicuser; 20 | SELECT cartodb.CDB_UserTables() ORDER BY 1; 21 | SELECT 'all', cartodb.CDB_UserTables('all') ORDER BY 2; 22 | SELECT 'public', cartodb.CDB_UserTables('public') ORDER BY 2; 23 | SELECT 'private', cartodb.CDB_UserTables('private') ORDER BY 2; 24 | SELECT '--unsupported--', cartodb.CDB_UserTables('--unsupported--') ORDER BY 2; 25 | -- now tests with public user 26 | \c contrib_regression publicuser 27 | SELECT 'all_publicuser', cartodb.CDB_UserTables('all') ORDER BY 2; 28 | SELECT 'public_publicuser', cartodb.CDB_UserTables('public') ORDER BY 2; 29 | SELECT 'private_publicuser', cartodb.CDB_UserTables('private') ORDER BY 2; 30 | \c contrib_regression postgres 31 | DROP TABLE pub; 32 | DROP TABLE prv; 33 | -------------------------------------------------------------------------------- /test/CDB_UserTablesTest_expect: -------------------------------------------------------------------------------- 1 | SET 2 | DO 3 | SET 4 | CREATE TABLE 5 | CREATE TABLE 6 | GRANT 7 | REVOKE 8 | prv 9 | pub 10 | all|prv 11 | all|pub 12 | public|pub 13 | private|prv 14 | You are now connected to database "contrib_regression" as user "publicuser". 15 | all_publicuser|pub 16 | public_publicuser|pub 17 | You are now connected to database "contrib_regression" as user "postgres". 18 | DROP TABLE 19 | DROP TABLE 20 | -------------------------------------------------------------------------------- /test/CDB_Username.sql: -------------------------------------------------------------------------------- 1 | SELECT session_user; -- postgres 2 | SELECT CDB_Username(); -- (NULL) 3 | 4 | -- Add the role fulano with api_key and connect with it 5 | \set QUIET on 6 | CREATE ROLE fulano LOGIN; 7 | GRANT USAGE ON SCHEMA cartodb TO fulano; 8 | GRANT EXECUTE ON FUNCTION CDB_Username() TO fulano; 9 | INSERT INTO cdb_conf (key, value) VALUES ('api_keys_fulano', '{"username": "fulanito", "permissions":[]}'); 10 | SET SESSION AUTHORIZATION fulano; 11 | \set QUIET off 12 | 13 | SELECT session_user; -- fulano 14 | SELECT CDB_Username(); -- fulanito 15 | 16 | -- Remove fulano 17 | \set QUIET on 18 | SET SESSION AUTHORIZATION postgres; 19 | REVOKE USAGE ON SCHEMA cartodb FROM fulano; 20 | REVOKE EXECUTE ON FUNCTION CDB_Username() FROM fulano; 21 | DROP ROLE fulano; 22 | DELETE FROM cdb_conf WHERE key = 'api_keys_fulano'; 23 | \set QUIET off -------------------------------------------------------------------------------- /test/CDB_Username_expect: -------------------------------------------------------------------------------- 1 | @@PGUSER@@ 2 | 3 | fulano 4 | fulanito 5 | -------------------------------------------------------------------------------- /test/CDB_XYZ_ExtentTest.sql: -------------------------------------------------------------------------------- 1 | 2 | WITH zoom AS ( select generate_series(0,2) as Z ), 3 | range AS ( select z, generate_series(0, pow(2,z)::int-1) as r FROM zoom), 4 | 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 ), 5 | ext AS ( select x,y,z,CDB_XYZ_Extent(x,y,z) as g from inp ) 6 | select X::text || ',' || Y::text || ',' || Z::text as xyz, 7 | round(st_xmin(g)), round(st_xmax(g)), round(st_ymin(g)), round(st_ymax(g)) 8 | from ext order by xyz; 9 | 10 | -------------------------------------------------------------------------------- /test/CDB_XYZ_ExtentTest_expect: -------------------------------------------------------------------------------- 1 | 0,0,0|-20037508|20037508|-20037508|20037508 2 | 0,0,1|-20037508|0|0|20037508 3 | 0,0,2|-20037508|-10018754|10018754|20037508 4 | 0,1,1|-20037508|0|-20037508|0 5 | 0,1,2|-20037508|-10018754|0|10018754 6 | 0,2,2|-20037508|-10018754|-10018754|0 7 | 0,3,2|-20037508|-10018754|-20037508|-10018754 8 | 1,0,1|0|20037508|0|20037508 9 | 1,0,2|-10018754|0|10018754|20037508 10 | 1,1,1|0|20037508|-20037508|0 11 | 1,1,2|-10018754|0|0|10018754 12 | 1,2,2|-10018754|0|-10018754|0 13 | 1,3,2|-10018754|0|-20037508|-10018754 14 | 2,0,2|0|10018754|10018754|20037508 15 | 2,1,2|0|10018754|0|10018754 16 | 2,2,2|0|10018754|-10018754|0 17 | 2,3,2|0|10018754|-20037508|-10018754 18 | 3,0,2|10018754|20037508|10018754|20037508 19 | 3,1,2|10018754|20037508|0|10018754 20 | 3,2,2|10018754|20037508|-10018754|0 21 | 3,3,2|10018754|20037508|-20037508|-10018754 22 | -------------------------------------------------------------------------------- /test/Makefile: -------------------------------------------------------------------------------- 1 | all: 2 | @echo "Try make check" 3 | 4 | check: 5 | bundle exec rspec ../../../spec/lib/sql_test_spec.rb 6 | -------------------------------------------------------------------------------- /test/README: -------------------------------------------------------------------------------- 1 | Adding tests consists in adding 2 files in this directory: one file 2 | containing the sql code and another containing the expected output. 3 | 4 | Example, to add a test for CDB_Something function, you'd add: 5 | 6 | - CDB_SomethingTest.sql 7 | - CDB_SomethingTest_expect 8 | 9 | 10 | To easy the generation of the expected file you can initially omit it, 11 | then run "make -C .. installcheck" from the top-level dir and copy 12 | ../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping 13 | off the first line: 14 | 15 | make -C .. installcheck 16 | tail -n +2 ../results/test/CDB_SomethingTest.out > CDB_SomethingTest_expect 17 | -------------------------------------------------------------------------------- /test/overviews/gen_points.rb: -------------------------------------------------------------------------------- 1 | # Ruby script to generate test/overviews/fixtures.sql for testing overviews 2 | # Generated tables: 3 | # * base_bare_t -- points without attributes (only PK, geometries) 4 | 5 | NUM_CLUSTERS = 128 6 | MAX_PER_CLUSTER = 16 7 | CLUSTER_RADIUS = 1E-3 8 | MIN_X = -10.0 9 | MAX_X = 10.0 10 | MIN_Y = 30.0 11 | MAX_Y = 40.0 12 | ATTRIBUTES = "number double precision, int_number integer, name text, start date" 13 | 14 | id = 0 15 | POINTS = (0...NUM_CLUSTERS).map{ 16 | x = MIN_X + rand()*(MAX_X - MIN_X) 17 | y = MIN_Y + rand()*(MAX_Y - MIN_Y) 18 | (0..rand(MAX_PER_CLUSTER)).map{ 19 | id += 1 20 | { 21 | id: id, 22 | x: (x + rand()*CLUSTER_RADIUS).round(6), 23 | y: (y + rand()*CLUSTER_RADIUS).round(6) 24 | } 25 | } 26 | }.flatten 27 | 28 | values = POINTS.map{ |point| 29 | "#{point[:id]}, 'SRID=4326;POINT(#{point[:x]} #{point[:y]})'::geometry, ST_Transform('SRID=4326;POINT(#{point[:x]} #{point[:y]})'::geometry, 3857)" 30 | } 31 | 32 | File.open('fixtures.sql', 'w') do |sql| 33 | 34 | sql.puts "-- bare table with no attribute columns" 35 | sql.puts "CREATE TABLE base_bare_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry);" 36 | sql.puts "INSERT INTO base_bare_t VALUES" 37 | sql.puts values.map{|v| "(#{v})"}.join(",\n") + ";" 38 | 39 | sql.puts "-- table with attributes" 40 | sql.puts "CREATE TABLE base_t (cartodb_id integer, the_geom geometry, the_geom_webmercator geometry, #{ATTRIBUTES});" 41 | sql.puts "INSERT INTO base_t VALUES" 42 | sql.puts values.map{|v| "(#{v})"}.join(",\n") + ";" 43 | end 44 | -------------------------------------------------------------------------------- /test/perf/CDB_HexagonGridPerf.sql: -------------------------------------------------------------------------------- 1 | -- 25690 cells covering full webmercator extent 2 | -- real 0m9.448s -- as of e0e76843f785a420c277a6fb2f762601570ffb98 3 | -- real 0m0.243s -- as of 50c487b83837e4d5216fcc19d637dd8db6baa44a 4 | 5 | SELECT count(*) FROM ( 6 | SELECT CDB_HexagonGrid(ST_MakeEnvelope(-20194051, -20194051, 20194051, 20194051), 156543) ) f; 7 | -------------------------------------------------------------------------------- /test/perf/CDB_TransformToWebmercatorPerf.sql: -------------------------------------------------------------------------------- 1 | -- Run psql with -tA switches and expect 2 | -- CDB_TransformToWebmercatorTest_expect 3 | select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 4 | 'SRID=4326;LINESTRING(90 90, 0 80)'), 1)); 5 | select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 6 | 'SRID=4326;LINESTRING(90 90, 0 90)'), 1)); 7 | select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 8 | 'SRID=4326;POINT(0 90)'), 1)); 9 | select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 10 | 'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1)); 11 | select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 12 | 'SRID=4326;MULTIPOINT(10 3)'), 1)); 13 | select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 14 | 'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1)); 15 | select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator( 16 | 'SRID=4326;POINT(5 3)'), 1)); 17 | -------------------------------------------------------------------------------- /util/create_from_unpackaged.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | ver=$1 4 | input=cartodb--${ver}.sql 5 | output=cartodb--unpackaged--${ver}.sql 6 | 7 | echo "-- Script generated by $0 on `date`" > ${output} 8 | 9 | # Migrate CDB functions from public schema to cartodb schema 10 | cat ${input} | 11 | grep '^ *CREATE OR REPLACE FUNCTION' | 12 | grep -v ' cartodb\.' | # should only match DDL hooks 13 | grep -v '.*\quit.*' | 14 | sed 's/).*$/)/' | 15 | sed 's/DEFAULT [^ ,)]*//g' | 16 | sed 's/CREATE OR REPLACE FUNCTION /ALTER FUNCTION public./' | 17 | sed 's/$/ SET SCHEMA cartodb;/' | 18 | sed 's/^/DO LANGUAGE plpgsql \$\$ BEGIN /' | 19 | sed "s/$/ EXCEPTION WHEN OTHERS THEN RAISE NOTICE 'Got % (%)', SQLERRM, SQLSTATE; END; \$\$;/" | 20 | cat >> ${output} 21 | 22 | # Upgrade all functions 23 | cat ${input} | grep -v 'duplicated extension$' | grep -v '\quit$' | grep -v 'pg_extension_config_dump' >> ${output} 24 | -------------------------------------------------------------------------------- /util/create_upgrade.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | fromver=$1 4 | ver=$2 5 | input=cartodb--${ver}.sql 6 | output=cartodb--${fromver}--${ver}.sql 7 | 8 | cat ${input} | grep -v 'duplicated extension$' > ${output} 9 | 10 | --------------------------------------------------------------------------------