Thread: Collation versioning
Hello, While reviewing the ICU versioning work a while back, I mentioned the idea of using a user-supplied command to get a collversion string for the libc collation provider. I was reminded about that by recent news about an upcoming glibc/CLDR resync that is likely to affect PostgreSQL users (though, I guess, probably only when they do a major OS upgrade). Here's an experimental patch to try that idea out. For example, you might set it like this: libc_collation_version_command = 'md5 /usr/share/locale/@LC_COLLATE@/LC_COLLATE | sed "s/.* = //"' ... or, on a Debian system using the locales package, like this: libc_collation_version_command = 'dpkg -s locales | grep Version: | sed "s/Version: //"' Using the checksum approach, it works like this: postgres=# alter collation "xx_XX" refresh version; NOTICE: changing version from b88d621596b7e61337e832f7841066a9 to 7b008442fbaf5dfe7a10fb3d82a634ab ALTER COLLATION postgres=# select * from pg_collation where collname = 'xx_XX'; -[ RECORD 1 ]-+--------------------------------- collname | xx_XX collnamespace | 2200 collowner | 10 collprovider | c collencoding | 6 collcollate | en_US.UTF-8 collctype | UTF-8 collversion | 7b008442fbaf5dfe7a10fb3d82a634ab When the collation definition changes you get the desired scary warning on next attempt to use it in a fresh backend: postgres=# select * from t order by v; WARNING: collation "xx_XX" has version mismatch DETAIL: The collation in the database was created using version b88d621596b7e61337e832f7841066a9, but the operating system provides version 7b008442fbaf5dfe7a10fb3d82a634ab. HINT: Rebuild all objects affected by this collation and run ALTER COLLATION public."xx_XX" REFRESH VERSION, or build PostgreSQL with the right library version. The problem is that it isn't in effect at initdb time so if you add that later it only affects new locales. You'd need a way to do that during init to capture the imported system locale versions, and that's a really ugly string to have to pass into some initdb option. Ugh. Another approach would be to decide that we're willing to put non-portable version extracting magic in pg_locale.c. On a long flight I hacked my libc to store a version string (based on CLDR version or whatever) in its binary locale definitions and provide a proper interface to ask for it, modelled on querylocale(3): const char *querylocaleversion(int mask, locale_t locale); Then the patch for pg_locale.c is trivial, see attached. While I could conceivably try to convince my local friendly OS to take such a patch, the real question is how to deal with glibc. Does anyone know of a way to extract a version string from glibc using existing interfaces? I heard there was an undocumented way but I haven't been able to find it -- probably because I was, erm, looking in the documentation. Or maybe this isn't worth bothering with, and we should just build out the ICU support and then make it the default and be done with it. In passing, here's a patch to add tab completion for ALTER COLLATION ... REFRESH VERSION. -- Thomas Munro http://www.enterprisedb.com
Attachment
On Tue, Sep 4, 2018 at 10:02 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > const char *querylocaleversion(int mask, locale_t locale); > > Then the patch for pg_locale.c is trivial, see attached. Oops, here's that one, FWIW. -- Thomas Munro http://www.enterprisedb.com
Attachment
Re: Thomas Munro 2018-09-04 <CAEepm=0uEQCpfq_+LYFBdArCe4Ot98t1aR4eYiYTe=yavQygiQ@mail.gmail.com> > I was reminded about that by recent news > about an upcoming glibc/CLDR resync that is likely to affect > PostgreSQL users (though, I guess, probably only when they do a major > OS upgrade). Or replicating/restoring a database to a newer host. > ... or, on a Debian system using the locales package, like this: > > libc_collation_version_command = 'dpkg -s locales | grep Version: | > sed "s/Version: //"' Ugh. This sounds horribly easy to get wrong on the user side. I could of course put that preconfigured into the Debian packages, but that would leave everyone not using any of the standard distro packagings in the rain. > Does anyone know > of a way to extract a version string from glibc using existing > interfaces? I heard there was an undocumented way but I haven't been > able to find it -- probably because I was, erm, looking in the > documentation. That sounds more robust. Googling around: https://www.linuxquestions.org/questions/linux-software-2/how-to-check-glibc-version-263103/ #include <stdio.h> #include <gnu/libc-version.h> int main (void) { puts (gnu_get_libc_version ()); return 0; } $ ./a.out 2.27 Hopefully that version info is fine-grained enough. Christoph
On Wed, Sep 5, 2018 at 3:35 AM Christoph Berg <myon@debian.org> wrote: > Re: Thomas Munro 2018-09-04 <CAEepm=0uEQCpfq_+LYFBdArCe4Ot98t1aR4eYiYTe=yavQygiQ@mail.gmail.com> > > I was reminded about that by recent news > > about an upcoming glibc/CLDR resync that is likely to affect > > PostgreSQL users (though, I guess, probably only when they do a major > > OS upgrade). > > Or replicating/restoring a database to a newer host. Yeah. > > Does anyone know > > of a way to extract a version string from glibc using existing > > interfaces? I heard there was an undocumented way but I haven't been > > able to find it -- probably because I was, erm, looking in the > > documentation. > > That sounds more robust. Googling around: > > https://www.linuxquestions.org/questions/linux-software-2/how-to-check-glibc-version-263103/ > > #include <stdio.h> > #include <gnu/libc-version.h> > int main (void) { puts (gnu_get_libc_version ()); return 0; } > > $ ./a.out > 2.27 > > Hopefully that version info is fine-grained enough. Hmm. I was looking for locale data version, not libc.so itself. I realise they come ultimately from the same source package, but are the locale definitions and libc6 guaranteed to be updated at the same time? I see that the locales package depends on libc-bin >> 2.27 (no upper bound), which in turn depends on libc6 >> 2.27, << 2.28. So perhaps you can have a system with locales 2.27 and libc6 2.28? I also wonder if there are some configurations where they could get out of sync because of manual use of locale-gen or something like that. Clearly most systems would have them in sync through apt-get upgrade though, so maybe gnu_get_libc_version() would work well in practice? -- Thomas Munro http://www.enterprisedb.com
On Wed, Sep 5, 2018 at 8:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > On Wed, Sep 5, 2018 at 3:35 AM Christoph Berg <myon@debian.org> wrote: > > int main (void) { puts (gnu_get_libc_version ()); return 0; } > > > > $ ./a.out > > 2.27 > > Hmm. I was looking for locale data version, not libc.so itself. I > realise they come ultimately from the same source package, but are the > locale definitions and libc6 guaranteed to be updated at the same > time? And even if they are, what if your cluster is still running and still has the older libc.so.6 mapped in? Newly forked backends will see new locale data but gnu_get_libc_version() will return the old string. (Pointed out off-list by Andres.) Eventually you restart your cluster and start seeing the error. So, it's not ideal but perhaps worth considering on the grounds that it's better than nothing? -- Thomas Munro http://www.enterprisedb.com
Re: Thomas Munro 2018-09-05 <CAEepm=3a5BC7CwsXZo3V4fw6YuAMT2nJ1krwtqOatb=vDqRWEA@mail.gmail.com> > > Hopefully that version info is fine-grained enough. > > Hmm. I was looking for locale data version, not libc.so itself. I > realise they come ultimately from the same source package, but are the > locale definitions and libc6 guaranteed to be updated at the same > time? I see that the locales package depends on libc-bin >> 2.27 (no > upper bound), which in turn depends on libc6 >> 2.27, << 2.28. So > perhaps you can have a system with locales 2.27 and libc6 2.28? No because libc6.deb "breaks" locales << 2.27: Package: libc6 Source: glibc Version: 2.27-5 Breaks: [...] locales (<< 2.27), locales-all (<< 2.27), (I can't tell off-hand why this isn't just a stricter dependency in locales.deb, but it's probably because this variant works better for upgrades.) > I also wonder if there are some configurations where they could get out > of sync because of manual use of locale-gen or something like that. > Clearly most systems would have them in sync through apt-get upgrade > though, so maybe gnu_get_libc_version() would work well in practice? I'd hope so. I'm more worried about breakage because of fixes applied within one glibc version (2.27-5 vs 2.27-6), but I guess Debian's glibc maintainers are clueful enough not to do that. Re: Thomas Munro 2018-09-05 <CAEepm=0hoACQLFn8ro7jCO9-wTth2mXXS3K=s09gxKqN2jy8pA@mail.gmail.com> > And even if they are, what if your cluster is still running and still > has the older libc.so.6 mapped in? Newly forked backends will see new > locale data but gnu_get_libc_version() will return the old string. > (Pointed out off-list by Andres.) Eventually you restart your cluster > and start seeing the error. That problem isn't protected against by PG itself. I've seen clusters that were upgraded on disk but not restarted yet where every plpgsql invocation was throwing symbol errors. So I guess we don't have to try harder for libc. > So, it's not ideal but perhaps worth considering on the grounds that > it's better than nothing? Ack. Christoph
On Wed, Sep 5, 2018 at 12:10 PM Christoph Berg <myon@debian.org> wrote: > > So, it's not ideal but perhaps worth considering on the grounds that > > it's better than nothing? > > Ack. Ok, here's a little patch like that. postgres=# select collname, collcollate, collversion from pg_collation where collname = 'en_NZ'; collname | collcollate | collversion ----------+-------------+------------- en_NZ | en_NZ.utf8 | 2.24 (1 row) -- Thomas Munro http://www.enterprisedb.com
Attachment
On 05/09/2018 23:18, Thomas Munro wrote: > On Wed, Sep 5, 2018 at 12:10 PM Christoph Berg <myon@debian.org> wrote: >>> So, it's not ideal but perhaps worth considering on the grounds that >>> it's better than nothing? >> >> Ack. > > Ok, here's a little patch like that. > > postgres=# select collname, collcollate, collversion from pg_collation > where collname = 'en_NZ'; > collname | collcollate | collversion > ----------+-------------+------------- > en_NZ | en_NZ.utf8 | 2.24 > (1 row) But wouldn't that also have the effect that glibc updates that don't change anything about the locales would trigger the version incompatibility warning? Also, note that this mechanism only applies to collation objects, not to database-global locales. So most users wouldn't be helped by this approach. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Thu, Sep 6, 2018 at 12:01 PM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 05/09/2018 23:18, Thomas Munro wrote: > > On Wed, Sep 5, 2018 at 12:10 PM Christoph Berg <myon@debian.org> wrote: > >>> So, it's not ideal but perhaps worth considering on the grounds that > >>> it's better than nothing? > >> > >> Ack. > > > > Ok, here's a little patch like that. > > > > postgres=# select collname, collcollate, collversion from pg_collation > > where collname = 'en_NZ'; > > collname | collcollate | collversion > > ----------+-------------+------------- > > en_NZ | en_NZ.utf8 | 2.24 > > (1 row) > > But wouldn't that also have the effect that glibc updates that don't > change anything about the locales would trigger the version > incompatibility warning? Right. And likewise, a glibc update that does change some locales but not the locales that you are actually using will trigger false alarm warnings. The same goes for the ICU provider, which appears to return the same collversion for every collation, even though presumably some don't change from one ICU version to the next. I wonder if someone here knows how many "locales" packages have been released over the lifetime of (say) the current Debian stable distro, whether any LC_COLLATE files changed over those releases, and whether libc6 had the same MAJOR.MINOR for the whole lifetime. That is, even though they might have been through 2.19-17+blah, 2.19-18+blah, ... did they all report "2.19" and were the collations actually stable? If that's the case, I think it'd be quite good: we'd only raise the alarm after a big dist-upgrade Debian 8->9, or when doing streaming replication from a Debian 8 box to a Debian 9 box. > Also, note that this mechanism only applies to collation objects, not to > database-global locales. So most users wouldn't be helped by this approach. Yeah, right, that would have to work for this to be useful. I will look into that. -- Thomas Munro http://www.enterprisedb.com
Fwiw, I was doing some tests with LC_COLLATE last year: https://github.com/ChristophBerg/lc_collate_testsuite Iirc the outcome was that everything except de_DE.UTF-8 was stable. Christoph
On Thu, Sep 6, 2018 at 5:36 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > On Thu, Sep 6, 2018 at 12:01 PM Peter Eisentraut > <peter.eisentraut@2ndquadrant.com> wrote: > > Also, note that this mechanism only applies to collation objects, not to > > database-global locales. So most users wouldn't be helped by this approach. > > Yeah, right, that would have to work for this to be useful. I will > look into that. We could perform a check up front in (say) CheckMyDatabase(), or maybe defer until the first string comparison. The tricky question is where to store it. 1. We could add datcollversion to pg_database. 2. We could remove datcollate and datctype and instead store a collation OID. I'm not sure what problems would come up, but for starters it seems a bit weird to have a shared catalog pointing to rows in a non-shared catalog. The same question comes up if we want to support ICU as a database level default. Add datcollprovider, or point to a pg_collation row? -- Thomas Munro http://www.enterprisedb.com
On 07/09/2018 23:34, Thomas Munro wrote: > On Thu, Sep 6, 2018 at 5:36 PM Thomas Munro > <thomas.munro@enterprisedb.com> wrote: >> On Thu, Sep 6, 2018 at 12:01 PM Peter Eisentraut >> <peter.eisentraut@2ndquadrant.com> wrote: >>> Also, note that this mechanism only applies to collation objects, not to >>> database-global locales. So most users wouldn't be helped by this approach. >> >> Yeah, right, that would have to work for this to be useful. I will >> look into that. > > We could perform a check up front in (say) CheckMyDatabase(), or maybe > defer until the first string comparison. The tricky question is where > to store it. > > 1. We could add datcollversion to pg_database. > > 2. We could remove datcollate and datctype and instead store a > collation OID. I'm not sure what problems would come up, but for > starters it seems a bit weird to have a shared catalog pointing to > rows in a non-shared catalog. > > The same question comes up if we want to support ICU as a database > level default. Add datcollprovider, or point to a pg_collation row? This was previously discussed here: https://www.postgresql.org/message-id/f689322a-4fc5-10cc-4a60-81f1ff0166c9@2ndquadrant.com -- without a conclusion. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Re: Thomas Munro 2018-09-07 <CAEepm=1xGTsLDx63UEdcJ8MdG63CNJ-tsDWHbH9djtvxRH5ZWw@mail.gmail.com> > 2. We could remove datcollate and datctype and instead store a > collation OID. I'm not sure what problems would come up, but for > starters it seems a bit weird to have a shared catalog pointing to > rows in a non-shared catalog. Naive idea: make that catalog shared? Collations are system-wide after all. Christoph
On 12/09/2018 10:15, Christoph Berg wrote: > Re: Thomas Munro 2018-09-07 <CAEepm=1xGTsLDx63UEdcJ8MdG63CNJ-tsDWHbH9djtvxRH5ZWw@mail.gmail.com> >> 2. We could remove datcollate and datctype and instead store a >> collation OID. I'm not sure what problems would come up, but for >> starters it seems a bit weird to have a shared catalog pointing to >> rows in a non-shared catalog. > > Naive idea: make that catalog shared? Collations are system-wide after > all. By the same argument, extensions should be shared, but they are not. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Re: Peter Eisentraut 2018-09-12 <0447ec7b-cdb6-7252-7943-88a4664e7bb7@2ndquadrant.com> > > Naive idea: make that catalog shared? Collations are system-wide after > > all. > > By the same argument, extensions should be shared, but they are not. But extensions put a lot of visible stuff into a database, whereas a collation is just a line in some table that doesn't get into the way. Christoph
On 12/09/2018 13:25, Christoph Berg wrote: > Re: Peter Eisentraut 2018-09-12 <0447ec7b-cdb6-7252-7943-88a4664e7bb7@2ndquadrant.com> >>> Naive idea: make that catalog shared? Collations are system-wide after >>> all. >> >> By the same argument, extensions should be shared, but they are not. > > But extensions put a lot of visible stuff into a database, whereas a > collation is just a line in some table that doesn't get into the way. How about C functions? They are just a system catalog representation of something that exists on the OS. Anyway, we also want to support application-specific collation definitions, so that users can CREATE COLLATION "my_specific_requirements" and use that that in their application, so global collations wouldn't be appropriate for that. Moreover, the fix for a collation version mismatch is, in the simplest case, to go around and REINDEX everything. Making the collation or collation version global doesn't fix that. It would actually make it harder because you couldn't run ALTER COLLATION REFRESH VERSION until after you have rebuilt all affected objects *in all databases*. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Re: Peter Eisentraut 2018-09-13 <4f60612c-a7b5-092d-1532-21ff7a106bd5@2ndquadrant.com> > Moreover, the fix for a collation version mismatch is, in the simplest > case, to go around and REINDEX everything. Making the collation or > collation version global doesn't fix that. It would actually make it > harder because you couldn't run ALTER COLLATION REFRESH VERSION until > after you have rebuilt all affected objects *in all databases*. Btw, I think a "reindexdb --all --collation" (and the SQL per-database equivalent) that only rebuilds indexes that are affected by collations would be immensely useful to have. Christoph
Greetings, * Christoph Berg (myon@debian.org) wrote: > Re: Peter Eisentraut 2018-09-13 <4f60612c-a7b5-092d-1532-21ff7a106bd5@2ndquadrant.com> > > Moreover, the fix for a collation version mismatch is, in the simplest > > case, to go around and REINDEX everything. Making the collation or > > collation version global doesn't fix that. It would actually make it > > harder because you couldn't run ALTER COLLATION REFRESH VERSION until > > after you have rebuilt all affected objects *in all databases*. > > Btw, I think a "reindexdb --all --collation" (and the SQL per-database > equivalent) that only rebuilds indexes that are affected by collations > would be immensely useful to have. As I was discussing w/ Peter G during PostgresOpen, we'd have to wait until that reindexdb is complete before actually using anything in the system and that's pretty painful. While it sounds like it'd be a good bit of work, it seems like we really need to have a way to support multiple collation versions concurrently and to do that we'll need to have the library underneath actually providing that to us. Once we have that, we can build new indexes concurrently and swap to them (or, ideally, just issue REINDEX CONCURRENTLY once we support that..). Until then, it seems like we really need to have a way to realize that a given upgrade is going to require a big reindex, before actually doing the reindex and suddenly discovering that we can't use a bunch of indexes because they're out of date and extending the downtime for the upgrade to be however long it takes to rebuild those indexes... Thanks! Stephen
Attachment
On Thu, Sep 13, 2018 at 7:03 PM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 12/09/2018 13:25, Christoph Berg wrote: > > Re: Peter Eisentraut 2018-09-12 <0447ec7b-cdb6-7252-7943-88a4664e7bb7@2ndquadrant.com> > >>> Naive idea: make that catalog shared? Collations are system-wide after > >>> all. > >> > >> By the same argument, extensions should be shared, but they are not. > > > > But extensions put a lot of visible stuff into a database, whereas a > > collation is just a line in some table that doesn't get into the way. > > How about C functions? They are just a system catalog representation of > something that exists on the OS. > > Anyway, we also want to support application-specific collation > definitions, so that users can CREATE COLLATION > "my_specific_requirements" and use that that in their application, so > global collations wouldn't be appropriate for that. > > Moreover, the fix for a collation version mismatch is, in the simplest > case, to go around and REINDEX everything. Making the collation or > collation version global doesn't fix that. It would actually make it > harder because you couldn't run ALTER COLLATION REFRESH VERSION until > after you have rebuilt all affected objects *in all databases*. Here's one idea I came up with. It involves a new kind of magic. The goals are: 1. Support versioning for the libc provider, including for the default collation. 2. Support ICU for the default collation. 3. Fix the tracking of when reindexes need to be rebuilt, so that you can't get it wrong (as you're alluding to above). Changes: 1. Drop the datcollate and datctype columns from pg_database. 2. In CheckMyDatabase() or elsewhere in backend initialisation, get that information instead by loading the pg_collation row with OID = DEFAULT_COLLATION_OID. 3. Don't put COLLPROVIDER_DEFAULT into the default collation collprovider column, instead give it a concrete provider value, ie COLLPROVIDER_LIBC. 4. After creating a new database, update that row as appropriate in the new database (!). Or find some other way to write a new table out and switch it around, or something like that. That is, if you say CREATE DATABASE foo LC_COLLATE = 'xx_XX', COLLATION_PROVIDER = libc then those values somehow get written into the default pg_collation row in the *new* database (so at that point it's not a simple copy of the template database). 5. Drop the collversion column from pg_collation. Get rid of the REFRESH VERSION command. Instead, add a new column indcollversion to pg_index. It needs to be an array of text (not sure if that is a problem in a catalog), with elements that correspond to the elements of indcollation. 6. Do the check and log warnings when we first open each index. 7. Update indcollversion at index creation and whenever we REINDEX. I haven't actually tried any of this so I'm not sure if I'm missing something other than the inherent difficulty of updating a row in a table in a database you're not connected to... -- Thomas Munro http://www.enterprisedb.com
On Sun, Sep 16, 2018 at 1:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote:
3. Fix the tracking of when reindexes need to be rebuilt, so that you
can't get it wrong (as you're alluding to above).
I've mentioned this in the past, but didn't seem to get any traction, so I'll try it again ;-)
The focus on indexes when a collation changes is, in my opinion, the least of the problems. You definitely have to worry about indexes, but they can be easily rebuilt. What about other places where collation is hardened into the system, such as constraints?
For example, in ICU 4.6 the handling of accents changed for French. Previously accents were considered right-to-left but ICU 4.6 reversed this. So consider a constraint like CHECK COL < 'coté' (last letter is U+00E9, small letter e with acute). Prior to ICU 4.6 the value 'côte' (second letter is U+00F4, small letter o with circumflex) would have passed this constraint. With 4.6 or later it would be rejected because of the accent ordering change. As soon as the collation changes, this table becomes inconsistent and a reindex isn't going to help it. This becomes a data cleansing problem at this point (which sucks for the user because their data was clean immediately prior to the "upgrade").
There have similarly been cases where ICU changes have caused equal characters to become unequal and vice versa. (Unfortunately all my ICU notes with examples are at my previous employer.) Consider the effect on RI constraints. The primary key can be fixed with a reindex (although dealing with two existing values becoming equal is a pain). But then the user also has to deal with the foreign keys since they may now have foreign keys which have no match in the primary key.
And constraints problems are even easier than triggers. Consider a database with complex BI rules that are implemented through triggers that fire when values are/are not equal. If the equality of strings change, there could be bad data throughout the tables. (At least with constraints the inter-column dependencies are explicit in the catalogs. With triggers anything goes.)
All this collation stuff is great, and I know users want it, but it feels like were pushing them out of an airplane with a ripped parachute every time the collation libraries change. Maybe they'll land safely or maybe things will get very messy.
- Doug
Salesforce
>>>>> "Douglas" == Douglas Doole <dougdoole@gmail.com> writes: Douglas> And constraints problems are even easier than triggers. Douglas> Consider a database with complex BI rules that are implemented Douglas> through triggers that fire when values are/are not equal. If Douglas> the equality of strings change, there could be bad data Douglas> throughout the tables. Perhaps fortunately, collation changes cannot (in PG) affect the equality or non-equality of strings (at least of text/varchar/char types, citext is a different matter). For the builtin string types, PG follows the rule that if the collation calls the values equal, they are ordered secondarily in codepoint order; only byte-identical values can actually be equal (we need this in order for hashing to work in the absence of a strxfrm implementation that we can trust). (This is the same rule used for string comparisons in Perl.) -- Andrew (irc:RhodiumToad)
Oh good. I'd missed that detail. So that eases the RI constraint concern. (In my previous job, we wanted case/accent insensitive collations, so equal did not mean binary equal which added a whole extra level of fun.)
On Sun, Sep 16, 2018 at 11:39 AM Andrew Gierth <andrew@tao11.riddles.org.uk> wrote:
>>>>> "Douglas" == Douglas Doole <dougdoole@gmail.com> writes:
Douglas> And constraints problems are even easier than triggers.
Douglas> Consider a database with complex BI rules that are implemented
Douglas> through triggers that fire when values are/are not equal. If
Douglas> the equality of strings change, there could be bad data
Douglas> throughout the tables.
Perhaps fortunately, collation changes cannot (in PG) affect the
equality or non-equality of strings (at least of text/varchar/char
types, citext is a different matter). For the builtin string types, PG
follows the rule that if the collation calls the values equal, they are
ordered secondarily in codepoint order; only byte-identical values can
actually be equal (we need this in order for hashing to work in the
absence of a strxfrm implementation that we can trust).
(This is the same rule used for string comparisons in Perl.)
--
Andrew (irc:RhodiumToad)
On Mon, Sep 17, 2018 at 6:13 AM Douglas Doole <dougdoole@gmail.com> wrote: > > On Sun, Sep 16, 2018 at 1:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: >> >> 3. Fix the tracking of when reindexes need to be rebuilt, so that you >> can't get it wrong (as you're alluding to above). > > > I've mentioned this in the past, but didn't seem to get any traction, so I'll try it again ;-) Hi Doug, Probably because we agree with you, but don't have all the answers :-) > The focus on indexes when a collation changes is, in my opinion, the least of the problems. You definitely have to worryabout indexes, but they can be easily rebuilt. What about other places where collation is hardened into the system,such as constraints? We have to start somewhere and indexes are the first thing that people notice, and are much likely to actually be a problem (personally I've encountered many cases of index corruption due to collation changes in the wild, but never a constraint corruption, though I fully understand the theoretical concern). Several of us have observed specifically that the same problems apply to CHECK constraints and PARTITION boundaries, and there may be other things like that. You could imagine tracking collation dependencies on those, requiring a RECHECK or REPARTITION operation to update them after a depended-on collation version changes. Perhaps that suggests that there should be a more general way to store collation dependencies -- something more like pg_depend, rather than bolting something like indcollversion onto indexes and every other kind of catalog that might need it. I don't know. > For example, in ICU 4.6 the handling of accents changed for French. Previously accents were considered right-to-left butICU 4.6 reversed this. So consider a constraint like CHECK COL < 'coté' (last letter is U+00E9, small letter e with acute).Prior to ICU 4.6 the value 'côte' (second letter is U+00F4, small letter o with circumflex) would have passed thisconstraint. With 4.6 or later it would be rejected because of the accent ordering change. As soon as the collation changes,this table becomes inconsistent and a reindex isn't going to help it. This becomes a data cleansing problem at thispoint (which sucks for the user because their data was clean immediately prior to the "upgrade"). Yeah, that's a fun case. I haven't checked recently, but last time I looked[1] and if I understood that byte sequence correctly, they were still using that whacky right-to-left accent sorting logic for fr_CA, but had given up on it in fr_FR (though there was still a way to ask for it). Vive le Québec libre. > ... > > And constraints problems are even easier than triggers. Consider a database with complex BI rules that are implementedthrough triggers that fire when values are/are not equal. If the equality of strings change, there could be baddata throughout the tables. (At least with constraints the inter-column dependencies are explicit in the catalogs. Withtriggers anything goes.) Once you get into downstream effects of changes (whether they are recorded in the database or elsewhere), I think it's basically beyond our event horizon. Why and when did the collation definition change (bug fix in CLDR, decree by the Académie Française taking effect on 1 January 2019, ...)? We could all use bitemporal databases and multi-version ICU, but at some point it all starts to look like an episode of Dr Who. I think we should make a clear distinction between things that invalidate the correct working of the database, and more nebulous effects that we can't possibly track in general. [1] https://www.postgresql.org/message-id/CAEepm%3D30SQpEUjau%3DdScuNeVZaK2kJ6QQDCHF75u5W%3DCz%3D3Scw%40mail.gmail.com -- Thomas Munro http://www.enterprisedb.com
Greetings, * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > On Mon, Sep 17, 2018 at 6:13 AM Douglas Doole <dougdoole@gmail.com> wrote: > > On Sun, Sep 16, 2018 at 1:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > >> 3. Fix the tracking of when reindexes need to be rebuilt, so that you > >> can't get it wrong (as you're alluding to above). > > > > I've mentioned this in the past, but didn't seem to get any traction, so I'll try it again ;-) > > Probably because we agree with you, but don't have all the answers :-) Agreed. > > The focus on indexes when a collation changes is, in my opinion, the least of the problems. You definitely have to worryabout indexes, but they can be easily rebuilt. What about other places where collation is hardened into the system,such as constraints? > > We have to start somewhere and indexes are the first thing that people > notice, and are much likely to actually be a problem (personally I've > encountered many cases of index corruption due to collation changes in > the wild, but never a constraint corruption, though I fully understand > the theoretical concern). Several of us have observed specifically > that the same problems apply to CHECK constraints and PARTITION > boundaries, and there may be other things like that. You could > imagine tracking collation dependencies on those, requiring a RECHECK > or REPARTITION operation to update them after a depended-on collation > version changes. > > Perhaps that suggests that there should be a more general way to store > collation dependencies -- something more like pg_depend, rather than > bolting something like indcollversion onto indexes and every other > kind of catalog that might need it. I don't know. Agreed. If we start thinking about pg_depend then maybe we realize that this all comes back to pg_attribute as the holder of the column-level information and maybe what we should be thinking about is a way to encode version information into the typmod for text-based types... > > And constraints problems are even easier than triggers. Consider a database with complex BI rules that are implementedthrough triggers that fire when values are/are not equal. If the equality of strings change, there could be baddata throughout the tables. (At least with constraints the inter-column dependencies are explicit in the catalogs. Withtriggers anything goes.) > > Once you get into downstream effects of changes (whether they are > recorded in the database or elsewhere), I think it's basically beyond > our event horizon. Why and when did the collation definition change > (bug fix in CLDR, decree by the Académie Française taking effect on 1 > January 2019, ...)? We could all use bitemporal databases and > multi-version ICU, but at some point it all starts to look like an > episode of Dr Who. I think we should make a clear distinction between > things that invalidate the correct working of the database, and more > nebulous effects that we can't possibly track in general. I tend to agree in general, but I don't think it's beyond us to consider multi-version ICU and being able to perform online reindexing (such that a given system could be migrated from one collation to another over a time while the system is still online, instead of having to take a potentially long downtime hit to rebuild indexes after an upgrade, or having to rebuild the entire system using some kind of logical replication...). Thanks! Stephen
Attachment
On Mon, Sep 17, 2018 at 9:02 AM Stephen Frost <sfrost@snowman.net> wrote: > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > Once you get into downstream effects of changes (whether they are > > recorded in the database or elsewhere), I think it's basically beyond > > our event horizon. Why and when did the collation definition change > > (bug fix in CLDR, decree by the Académie Française taking effect on 1 > > January 2019, ...)? We could all use bitemporal databases and > > multi-version ICU, but at some point it all starts to look like an > > episode of Dr Who. I think we should make a clear distinction between > > things that invalidate the correct working of the database, and more > > nebulous effects that we can't possibly track in general. > > I tend to agree in general, but I don't think it's beyond us to consider > multi-version ICU and being able to perform online reindexing (such that > a given system could be migrated from one collation to another over a > time while the system is still online, instead of having to take a > potentially long downtime hit to rebuild indexes after an upgrade, or > having to rebuild the entire system using some kind of logical > replication...). It's a very interesting idea with a high nerd-sniping factor[1]. Practically speaking, I wonder if you can actually do that with typical Linux distributions where the ICU data is in a shared library (eg libicudata.so.57), and may also be dependent on the ICU code version (?) -- do you run into problems linking to several of them at the same time? Maybe you have to ship your own ICU collations in "data" form to pull that off. But someone mentioned that distributions don't like you to do that (likewise for tzinfo and other such things that no one wants 42 copies of on their system). Actually, if I had infinite resources I'd really like to go and make libc support multiple collation versions with a standard interface (technically easy, bureaucratically hard); I don't really like leaving libc behind. But I digress. I'd like to propose the 3 more humble goals I mentioned a few messages back as earlier steps. OS collation changes aren't really like Monty Python's Spanish Inquisition: they usually hit you when you're doing major operating system upgrades or setting up a streaming replica to a different OS version IIUC. That is, they probably happen during maintenance windows when REINDEX would hopefully be plausible, and presumably critical systems get tested on the new OS version before production is upgraded. It'd be kind to our users to make the problem non-silent at that time so they can plan for it (and of course also alert them if it happens when nobody expects it, because knowing you have a problem is better than not knowing). [1] https://xkcd.com/356/ -- Thomas Munro http://www.enterprisedb.com
Greetings, * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > I'd like to propose the 3 more humble goals I mentioned a few messages > back as earlier steps. OS collation changes aren't really like Monty > Python's Spanish Inquisition: they usually hit you when you're doing > major operating system upgrades or setting up a streaming replica to a > different OS version IIUC. That is, they probably happen during > maintenance windows when REINDEX would hopefully be plausible, and > presumably critical systems get tested on the new OS version before > production is upgraded. It'd be kind to our users to make the problem > non-silent at that time so they can plan for it (and of course also > alert them if it happens when nobody expects it, because knowing you > have a problem is better than not knowing). Just to be clear, I'm all for this, but wanted to bring up the farther out goal to make sure we're thinking about how to eventually get there from here- and to make sure we aren't making it more difficult to get there with the proposed catalog changes for these shorter-term goals. Thanks! Stephen
Attachment
On Sun, Sep 16, 2018 at 1:14 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote:
We have to start somewhere and indexes are the first thing that people
notice, and are much likely to actually be a problem (personally I've
encountered many cases of index corruption due to collation changes in
the wild, but never a constraint corruption,
Problems that people notice are good - it's the ones that they don't notice that cause real grief ;-)
Given that PostgreSQL requires equal values to be binary identical I think that you'll avoid a lot of the problems that caused me so much trouble in DB2. Even if someone creates a range constraint or partitioned table, the boundary values aren't typically going to be impacted (my French example was a little contrived). That said, there have been a few changes that would have much more obvious impacts. One language stopped treating 'ch' as a single collating element that came somewhere after 'c'+'z' and treated it as 'c'+'h' instead. And and one of the North Germanic languages moved an accented character from after 'z' to before 'z' (or maybe it was vice versa - I miss my library of Unicode presentations).
Once you get into downstream effects of changes (whether they are
recorded in the database or elsewhere), I think it's basically beyond
our event horizon.
...
I think we should make a clear distinction between
things that invalidate the correct working of the database, and more
nebulous effects that we can't possibly track in general.
I agree that PostgreSQL can't resolve the downstream changes, but that's a very subtle distinction. As a user, if an upgrade caused my data to no longer comply with my carefully architected and database enforced BI rules, I would definitely argue that the correct working of the database has been invalidated. (You can make technical arguments about the OS upgrading the library, but the fundamental issue is that my PostgreSQL database is broken.)
You can probably argue that PostgreSQL and DB2 users look at the world differently, but that's why DB2 ended up shipping its own copies of the ICU library. Once a user creates an object using ICU vX, we made sure that version of the library was always available to avoid these problems. (The libraries were on a private path with non-standard names so there was no collision with the OS library. Fortunately I'd moved on before anyone really started complaining about why 5 copies of ICU were being installed when they weren't even using Unicode.)
[1] https://www.postgresql.org/message-id/CAEepm%3D30SQpEUjau%3DdScuNeVZaK2kJ6QQDCHF75u5W%3DCz%3D3Scw%40mail.gmail.com
I'd missed this post. In it you asked:
rule which requires you to consider diacritics in reverse order --
apparently abandoned in France but still used in Canada -- using a fixed
size space for state between calls.
ucol_nextSortKeyPart() only keeps track of the current position in the generated sort key as its state. So, if you call it multiple times to generate the sort key piecemeal, it recomputes the entire sort key until it has enough bytes to satisfy your request. (That is, if you're doing 4 bytes at a time, on the first call it generates and returns bytes 1-4. On the second call it generates 1-8 and returns 5-8. Next it generates 1-12 and returns 9-12.) Needless to say, this gets very expensive very fast.
On Mon 17 Sep 2018, 13:02 Douglas Doole, <dougdoole@gmail.com> wrote:
On Sun, Sep 16, 2018 at 1:14 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote:We have to start somewhere and indexes are the first thing that people
notice, and are much likely to actually be a problem (personally I've
encountered many cases of index corruption due to collation changes in
the wild, but never a constraint corruption,Problems that people notice are good - it's the ones that they don't notice that cause real grief ;-)...Once you get into downstream effects of changes (whether they arerecorded in the database or elsewhere), I think it's basically beyond
our event horizon....I think we should make a clear distinction between
things that invalidate the correct working of the database, and more
nebulous effects that we can't possibly track in general.
I agree that PostgreSQL can't resolve the downstream changes, but that's a very subtle distinction. As a user, if an upgrade caused my data to no longer comply with my carefully architected and database enforced BI rules, I would definitely argue that the correct working of the database has been invalidated. (You can make technical arguments about the OS upgrading the library, but the fundamental issue is that my PostgreSQL database is broken.)
Well things like partition exclusion and even join elimination depend on constraints being consistent so I don't think it's as easy to write off as that either.
But it's true that we have to start somewhere and collation changes are much more likely to be spotted in indexes and cause much more visible issues.
You can probably argue that PostgreSQL and DB2 users look at the world differently, but that's why DB2 ended up shipping its own copies of the ICU library. Once a user creates an object using ICU vX, we made sure that version of the library was always available to avoid these problems.
This seems like a terrible idea in the open source world. Surely collation versioning means new ICU libraries can still provide the old collation rules so even if you update the library you can request the old version? We shouldn't need that actual old code with all its security holes and bugs just to get the old collation version.
On Mon, Sep 17, 2018 at 12:32 PM Greg Stark <stark@mit.edu> wrote:
This seems like a terrible idea in the open source world. Surely collation versioning means new ICU libraries can still provide the old collation rules so even if you update the library you can request the old version? We shouldn't need that actual old code with all its security holes and bugs just to get the old collation version.
We asked long and hard for this feature from the ICU team but they kept arguing it was too hard to do. There are apparently some tight couplings between the code and each version of CLDR. So the only way to support old collations is to ship the entire old library. (They even added make rules to allow the entire API to be version extended to accommodate this requirement.)
Even bug fixes are potentially problematic because the fix may alter how some code points collate. The ICU team won't (or at least wouldn't - been a few years since I dealt with them) guarantee any sort of backwards compatibility between code drops.
As an aside, they did look at making the CLDR data a separate data file that could be read by any version of the code (before finding there were too many dependencies). One thing that they discovered is that this approach didn't save much disk since the CLDR data is something like 90-95% of the library. So while it would have made the calling code a lot cleaner, it wasn't the huge footprint win we'd been hoping for.
On Mon, Sep 17, 2018 at 9:02 AM Stephen Frost <sfrost@snowman.net> wrote: > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > On Mon, Sep 17, 2018 at 6:13 AM Douglas Doole <dougdoole@gmail.com> wrote: > > > On Sun, Sep 16, 2018 at 1:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > > >> 3. Fix the tracking of when reindexes need to be rebuilt, so that you > > >> can't get it wrong (as you're alluding to above). > > > > > > I've mentioned this in the past, but didn't seem to get any traction, so I'll try it again ;-) > > > > Probably because we agree with you, but don't have all the answers :-) > > Agreed. > > > > The focus on indexes when a collation changes is, in my opinion, the least of the problems. You definitely have toworry about indexes, but they can be easily rebuilt. What about other places where collation is hardened into the system,such as constraints? > > > > We have to start somewhere and indexes are the first thing that people > > notice, and are much likely to actually be a problem (personally I've > > encountered many cases of index corruption due to collation changes in > > the wild, but never a constraint corruption, though I fully understand > > the theoretical concern). Several of us have observed specifically > > that the same problems apply to CHECK constraints and PARTITION > > boundaries, and there may be other things like that. You could > > imagine tracking collation dependencies on those, requiring a RECHECK > > or REPARTITION operation to update them after a depended-on collation > > version changes. > > > > Perhaps that suggests that there should be a more general way to store > > collation dependencies -- something more like pg_depend, rather than > > bolting something like indcollversion onto indexes and every other > > kind of catalog that might need it. I don't know. > > Agreed. If we start thinking about pg_depend then maybe we realize > that this all comes back to pg_attribute as the holder of the > column-level information and maybe what we should be thinking about is a > way to encode version information into the typmod for text-based > types... So to be more concrete: pg_depend could have a new column "refobjversion". Whenever indexes are created or rebuilt, we'd capture the current version string in the pg_depend rows that link index attributes and collations. Then we'd compare those against the current value when we first open an index and complain if they don't match. (In this model there would be no "collversion" column in the pg_collation catalog.) That'd leave a place for other kinds of database objects (CHECKs, PARTITIONS, ...) to store their version dependency, if someone later wants to add support for that. I'm not sure if my idea about updating the default collation row in newly created databases has legs though. Any thoughts on that? -- Thomas Munro http://www.enterprisedb.com
Greetings, * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > On Mon, Sep 17, 2018 at 9:02 AM Stephen Frost <sfrost@snowman.net> wrote: > > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > > On Mon, Sep 17, 2018 at 6:13 AM Douglas Doole <dougdoole@gmail.com> wrote: > > > > On Sun, Sep 16, 2018 at 1:20 AM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > > > >> 3. Fix the tracking of when reindexes need to be rebuilt, so that you > > > >> can't get it wrong (as you're alluding to above). > > > > > > > > I've mentioned this in the past, but didn't seem to get any traction, so I'll try it again ;-) > > > > > > Probably because we agree with you, but don't have all the answers :-) > > > > Agreed. > > > > > > The focus on indexes when a collation changes is, in my opinion, the least of the problems. You definitely have toworry about indexes, but they can be easily rebuilt. What about other places where collation is hardened into the system,such as constraints? > > > > > > We have to start somewhere and indexes are the first thing that people > > > notice, and are much likely to actually be a problem (personally I've > > > encountered many cases of index corruption due to collation changes in > > > the wild, but never a constraint corruption, though I fully understand > > > the theoretical concern). Several of us have observed specifically > > > that the same problems apply to CHECK constraints and PARTITION > > > boundaries, and there may be other things like that. You could > > > imagine tracking collation dependencies on those, requiring a RECHECK > > > or REPARTITION operation to update them after a depended-on collation > > > version changes. > > > > > > Perhaps that suggests that there should be a more general way to store > > > collation dependencies -- something more like pg_depend, rather than > > > bolting something like indcollversion onto indexes and every other > > > kind of catalog that might need it. I don't know. > > > > Agreed. If we start thinking about pg_depend then maybe we realize > > that this all comes back to pg_attribute as the holder of the > > column-level information and maybe what we should be thinking about is a > > way to encode version information into the typmod for text-based > > types... > > So to be more concrete: pg_depend could have a new column > "refobjversion". Whenever indexes are created or rebuilt, we'd > capture the current version string in the pg_depend rows that link > index attributes and collations. Then we'd compare those against the > current value when we first open an index and complain if they don't > match. (In this model there would be no "collversion" column in the > pg_collation catalog.) I'm really not sure why you're pushing to have this in pg_depend.. > That'd leave a place for other kinds of database objects (CHECKs, > PARTITIONS, ...) to store their version dependency, if someone later > wants to add support for that. Isn't what matters here where the data's stored, as in, in a column..? All of those would already have dependencies on the column so that they can be tracked back there. > I'm not sure if my idea about updating the default collation row in > newly created databases has legs though. Any thoughts on that? My initial reaction is that we should have a version included basically everywhere and then let users decide how they want to change it. For a new cluster, I'd agree with using the latest available (while allowing it to be chosen if a user wishes for something else) but I'm not sure I'd go farther than that. Thanks! Stephen
Attachment
On Wed, Sep 19, 2018 at 12:48 AM Stephen Frost <sfrost@snowman.net> wrote: > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > So to be more concrete: pg_depend could have a new column > > "refobjversion". Whenever indexes are created or rebuilt, we'd > > capture the current version string in the pg_depend rows that link > > index attributes and collations. Then we'd compare those against the > > current value when we first open an index and complain if they don't > > match. (In this model there would be no "collversion" column in the > > pg_collation catalog.) > > I'm really not sure why you're pushing to have this in pg_depend.. > > > That'd leave a place for other kinds of database objects (CHECKs, > > PARTITIONS, ...) to store their version dependency, if someone later > > wants to add support for that. > > Isn't what matters here where the data's stored, as in, in a column..? > > All of those would already have dependencies on the column so that they > can be tracked back there. Suppose I have a table "emp" and indexes "emp_firstname_idx" and "emp_lastname_idx". Suppose I created them in a sequence like this: 0: collation fr_CA has version "30" 1: create table emp (firstname text collate "fr_CA", lastname text collate "fr_CA"); 2: create index on emp(firstname); 3: [upgrade operating system]; now collation fr_CA has version "31" 4: create index on emp(lastname); Now I have two indexes, built when different versions of the collation were in effect. One of them is potentially corrupted, the other isn't. Where are you going to record that? Earlier I suggested that pg_index could have an indcollversion column, so that emp_firstname_idx's row would hold {"30"} and emp_lastname_idx's row would hold {"31"}. It would be captured at CREATE INDEX time, and after that the only way to change it would be to REINDEX, and whenever it disagrees with the current version according to the provider you'd get a warning that you can only clear by running REINDEX. Then I suggested that perhaps pg_depend might be a better place for it, because it would generalise to other kinds of object too. For example, suppose I create a constraint CHECK (foo < 'côté') [evil laugh]. The pg_depend row that links the constraint and the collation could record the current version as of the moment the constraint was defined. After an OS upgrade that changes the reported version, I'd see a warning whenever loading the check constraint, and the only way to clear it would be to drop and recreate the constraint. (I'm not proposing we do that, just trying to demonstrate that pg_depend might be a tidier and more general solution than adding 'collation version' columns holding arrays of version strings to multiple catalogs. So help me Codd.) Just an idea... -- Thomas Munro http://www.enterprisedb.com
Greetings, * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > On Wed, Sep 19, 2018 at 12:48 AM Stephen Frost <sfrost@snowman.net> wrote: > > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > > So to be more concrete: pg_depend could have a new column > > > "refobjversion". Whenever indexes are created or rebuilt, we'd > > > capture the current version string in the pg_depend rows that link > > > index attributes and collations. Then we'd compare those against the > > > current value when we first open an index and complain if they don't > > > match. (In this model there would be no "collversion" column in the > > > pg_collation catalog.) > > > > I'm really not sure why you're pushing to have this in pg_depend.. > > > > > That'd leave a place for other kinds of database objects (CHECKs, > > > PARTITIONS, ...) to store their version dependency, if someone later > > > wants to add support for that. > > > > Isn't what matters here where the data's stored, as in, in a column..? > > > > All of those would already have dependencies on the column so that they > > can be tracked back there. > > Suppose I have a table "emp" and indexes "emp_firstname_idx" and > "emp_lastname_idx". Suppose I created them in a sequence like this: > > 0: collation fr_CA has version "30" > 1: create table emp (firstname text collate "fr_CA", lastname text > collate "fr_CA"); > 2: create index on emp(firstname); > 3: [upgrade operating system]; now collation fr_CA has version "31" > 4: create index on emp(lastname); > > Now I have two indexes, built when different versions of the collation > were in effect. One of them is potentially corrupted, the other > isn't. Where are you going to record that? Earlier I suggested that > pg_index could have an indcollversion column, so that > emp_firstname_idx's row would hold {"30"} and emp_lastname_idx's row > would hold {"31"}. It would be captured at CREATE INDEX time, and > after that the only way to change it would be to REINDEX, and whenever > it disagrees with the current version according to the provider you'd > get a warning that you can only clear by running REINDEX. Then I > suggested that perhaps pg_depend might be a better place for it, > because it would generalise to other kinds of object too. For indexes, just like for tables, we have entries in pg_attribute where that information would go. > For example, suppose I create a constraint CHECK (foo < 'côté') [evil > laugh]. The pg_depend row that links the constraint and the collation > could record the current version as of the moment the constraint was > defined. After an OS upgrade that changes the reported version, I'd > see a warning whenever loading the check constraint, and the only way > to clear it would be to drop and recreate the constraint. (I'm not > proposing we do that, just trying to demonstrate that pg_depend might > be a tidier and more general solution than adding 'collation version' > columns holding arrays of version strings to multiple catalogs. So > help me Codd.) The CHECK constraint doesn't need to directly track that information- it should have a dependency on the column in the table and that's where the information would be recorded about the current collation version. Maybe I'm missing something but I have to admit that I feel like pg_depend is being looked at here because everything goes through it- but everything goes through it because it's simple and we just use it to get to other things that have the complete definition of the object. Lots and lots of things in pg_depend would have zero use for such a field and I'm a bit worried you'd possibly also get into cases where you've got different collation versions for the same object because of the different dependencies into it... even if you don't, you're duplicating that information into every dependency, aren't you? Thanks! Stephen
Attachment
The CHECK constraint doesn't need to directly track that information-
it should have a dependency on the column in the table and that's where
the information would be recorded about the current collation version.
Just to have fun throwing odd cases out, how would something like this be recorded?
Database default collation: en_US
CREATE TABLE t (c1 TEXT, c2 TEXT, c3 TEXT,
CHECK (c1 COLLATE "fr_FR" BETWEEN c2 COLLATE "fr_FR" AND c3 COLLATE "fr_FR"));
You could even be really warped and apply multiple collations on a single column in a single constraint.
Greetings, * Douglas Doole (dougdoole@gmail.com) wrote: > > The CHECK constraint doesn't need to directly track that information- > > it should have a dependency on the column in the table and that's where > > the information would be recorded about the current collation version. > > Just to have fun throwing odd cases out, how would something like this be > recorded? > > Database default collation: en_US > > CREATE TABLE t (c1 TEXT, c2 TEXT, c3 TEXT, > CHECK (c1 COLLATE "fr_FR" BETWEEN c2 COLLATE "fr_FR" AND c3 COLLATE > "fr_FR")); > > You could even be really warped and apply multiple collations on a single > column in a single constraint. Once it gets to an expression and not just a simple check, I'd think we'd record it in the expression.. Thanks! Stephen
Attachment
On Wed, Sep 19, 2018 at 10:09 AM Stephen Frost <sfrost@snowman.net> wrote: > * Douglas Doole (dougdoole@gmail.com) wrote: > > > The CHECK constraint doesn't need to directly track that information- > > > it should have a dependency on the column in the table and that's where > > > the information would be recorded about the current collation version. > > > > Just to have fun throwing odd cases out, how would something like this be > > recorded? > > > > Database default collation: en_US > > > > CREATE TABLE t (c1 TEXT, c2 TEXT, c3 TEXT, > > CHECK (c1 COLLATE "fr_FR" BETWEEN c2 COLLATE "fr_FR" AND c3 COLLATE > > "fr_FR")); > > > > You could even be really warped and apply multiple collations on a single > > column in a single constraint. > > Once it gets to an expression and not just a simple check, I'd think > we'd record it in the expression.. Maybe I misunderstood, but I don't think it makes sense to have a collation version "on the column in the table", because (1) that fails to capture the fact that two CHECK constraints that were defined at different times might have become dependent on two different versions (you created one constraint before upgrading and the other after, now the older one is invalidated and sounds the alarm but the second one is fine), and (2) the table itself doesn't care about collation versions since heap tables are unordered; there is no particular operation on the table that would be the correct time to update the collation version on a table/column. What we're trying to track is when objects that in some way depend on the version become invalidated, so wherever we store it there's going to have to be a version recorded per dependent object at its creation time, so that's either new columns on every interested catalog table, or ... -- Thomas Munro http://www.enterprisedb.com
Greetings, * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > On Wed, Sep 19, 2018 at 10:09 AM Stephen Frost <sfrost@snowman.net> wrote: > > * Douglas Doole (dougdoole@gmail.com) wrote: > > > > The CHECK constraint doesn't need to directly track that information- > > > > it should have a dependency on the column in the table and that's where > > > > the information would be recorded about the current collation version. > > > > > > Just to have fun throwing odd cases out, how would something like this be > > > recorded? > > > > > > Database default collation: en_US > > > > > > CREATE TABLE t (c1 TEXT, c2 TEXT, c3 TEXT, > > > CHECK (c1 COLLATE "fr_FR" BETWEEN c2 COLLATE "fr_FR" AND c3 COLLATE > > > "fr_FR")); > > > > > > You could even be really warped and apply multiple collations on a single > > > column in a single constraint. > > > > Once it gets to an expression and not just a simple check, I'd think > > we'd record it in the expression.. > > Maybe I misunderstood, but I don't think it makes sense to have a > collation version "on the column in the table", because (1) that fails > to capture the fact that two CHECK constraints that were defined at > different times might have become dependent on two different versions > (you created one constraint before upgrading and the other after, now > the older one is invalidated and sounds the alarm but the second one > is fine), and (2) the table itself doesn't care about collation > versions since heap tables are unordered; there is no particular > operation on the table that would be the correct time to update the > collation version on a table/column. What we're trying to track is > when objects that in some way depend on the version become > invalidated, so wherever we store it there's going to have to be a > version recorded per dependent object at its creation time, so that's > either new columns on every interested catalog table, or ... Today, we work out what operators to use for a given column based on the data type. This is why I was trying to get at the idea of using typmod earlier, but if we can't make that work then I'm inclined to try and figure out a way to get it as close as possible to being associated with the type. Yes, the heap is unordered, but the type *is* ordered and we track that with the type system. Maybe we just extend that somehow, rather than using the typmod or adding columns into catalogs where we store type information (such as pg_attribute). Perhaps typmod could be made larger to be able to support this, that might be another approach. No where in this does it strike me that it makes sense to push this into pg_depend though. Thanks! Stephen
Attachment
On Wed, Sep 19, 2018 at 1:16 PM Stephen Frost <sfrost@snowman.net> wrote: > * Thomas Munro (thomas.munro@enterprisedb.com) wrote: > > On Wed, Sep 19, 2018 at 10:09 AM Stephen Frost <sfrost@snowman.net> wrote: > > > * Douglas Doole (dougdoole@gmail.com) wrote: > > > > > The CHECK constraint doesn't need to directly track that information- > > > > > it should have a dependency on the column in the table and that's where > > > > > the information would be recorded about the current collation version. > > > > > > > > Just to have fun throwing odd cases out, how would something like this be > > > > recorded? > > > > > > > > Database default collation: en_US > > > > > > > > CREATE TABLE t (c1 TEXT, c2 TEXT, c3 TEXT, > > > > CHECK (c1 COLLATE "fr_FR" BETWEEN c2 COLLATE "fr_FR" AND c3 COLLATE > > > > "fr_FR")); > > > > > > > > You could even be really warped and apply multiple collations on a single > > > > column in a single constraint. > > > > > > Once it gets to an expression and not just a simple check, I'd think > > > we'd record it in the expression.. > > > > Maybe I misunderstood, but I don't think it makes sense to have a > > collation version "on the column in the table", because (1) that fails > > to capture the fact that two CHECK constraints that were defined at > > different times might have become dependent on two different versions > > (you created one constraint before upgrading and the other after, now > > the older one is invalidated and sounds the alarm but the second one > > is fine), and (2) the table itself doesn't care about collation > > versions since heap tables are unordered; there is no particular > > operation on the table that would be the correct time to update the > > collation version on a table/column. What we're trying to track is > > when objects that in some way depend on the version become > > invalidated, so wherever we store it there's going to have to be a > > version recorded per dependent object at its creation time, so that's > > either new columns on every interested catalog table, or ... > > Today, we work out what operators to use for a given column based on the > data type. This is why I was trying to get at the idea of using typmod > earlier, but if we can't make that work then I'm inclined to try and > figure out a way to get it as close as possible to being associated with > the type. > > Yes, the heap is unordered, but the type *is* ordered and we track that > with the type system. Maybe we just extend that somehow, rather than > using the typmod or adding columns into catalogs where we store type > information (such as pg_attribute). Perhaps typmod could be made larger > to be able to support this, that might be another approach. Can you show how this would look in the catalogs, for Doug's example above? There is no pg_attribute or similar that applies here. Perhaps you want to bury the versions inside the serialised expression tree? Or store it in a pair of arrays on the pg_constraint row? > No where in this does it strike me that it makes sense to push this into > pg_depend though. In my scheme, the pg_depend row that already exists to record the dependency between the pg_constraint row and the pg_collation row for "fr_FR" holds a refobjversion value captured at constraint creation time. Maybe that's a bit strange, but the alternatives I have thought of so far seemed ad hoc and strange too. Here's a Sunday afternoon rapid prototype of the concept, implemented for indexes and check constraints. Examples of the output you get when you access those database objects for the first time in each backend: WARNING: index "foo_i_idx" depends on collation 16385 version "30.0.1", but the current version is "30.0.2" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. WARNING: constraint "t_i_check" depends on collation 12018 version "30.0.1", but the current version is "30.0.2" DETAIL: The constraint may be corrupted due to changes in sort order. HINT: Drop and recreate the constraint to avoid the risk of corruption. I didn't try to tackle the default collation yet, so to try this you need to use non-default collations. Whether we'd actually want to do this for CHECK constraints or any of this, I don't know. It's theoretically the right thing to do, but most people probably don't want to be nagged to recreate (or recheck in some new way) all their constraints every time they do an OS upgrade, and in fact there is almost never anything actually wrong if they don't... unless they're unlucky. But I wanted to do this to show that it's a fairly general way to deal with dependencies between database objects and collation versions using the existing links between them in a relational sort of way. I guess you might want a command or tool to find all such problems proactively and recheck, reindex, repartition etc as required to make it shut up, and that should be quite easy to drive from this design. -- Thomas Munro http://www.enterprisedb.com
Attachment
- 0001-Remove-pg_collation.collversion.patch
- 0002-Add-pg_depend.refobjversion.patch
- 0003-Track-collation-versions-for-indexes.patch
- 0004-Track-collation-versions-for-CHECK-constraints.patch
- 0005-Use-glibc-version-in-lieu-of-collation-version-on-Li.patch
- 0006-Use-querylocale-to-get-collation-versions-on-FreeBSD.patch
On Tue, Sep 18, 2018 at 7:57 AM Douglas Doole <dougdoole@gmail.com> wrote: > On Mon, Sep 17, 2018 at 12:32 PM Greg Stark <stark@mit.edu> wrote: >> This seems like a terrible idea in the open source world. Surely collation versioning means new ICU libraries can stillprovide the old collation rules so even if you update the library you can request the old version? We shouldn't needthat actual old code with all its security holes and bugs just to get the old collation version. > > > We asked long and hard for this feature from the ICU team but they kept arguing it was too hard to do. There are apparentlysome tight couplings between the code and each version of CLDR. So the only way to support old collations is toship the entire old library. (They even added make rules to allow the entire API to be version extended to accommodatethis requirement.) I wonder if this would be best modelled by entirely separate collation entries with different OIDs, and possibly also separate collation providers. Considering that to handle this we'd need to figure out how link libicu.so.55, libicu.so.56, ... etc into the same backend, and yet they presumably have the same collation names, doing it as separate providers would create separate namespaces for their collcollate values and reflect the reality that they really are entirely independent providers. Admittedly that creates a whole can of worms for initdb-time catalog creation, package maintainers' jobs, how long old versions have to be supported and how you upgraded database objects to new ICU versions. This kind of "major" versioning with support for concurrently accessible major versions seems to be different from the kind of version changes that happen under your feet when libraries/collation definition files are updated. > Even bug fixes are potentially problematic because the fix may alter how some code points collate. The ICU team won't (orat least wouldn't - been a few years since I dealt with them) guarantee any sort of backwards compatibility between codedrops. Yeah, it seems like ICU is *also* subject to minor changes that happen under your feet, much like libc. For example maintenance release 60.2 (you can't install that at the same time as 60.1, but you can install it at the same time as 59.2). You'd be linked against libicu.so.60 (and thence libicudata.so.60), and it gets upgraded in place when you run the local equivalent of apt-get upgrade. -- Thomas Munro http://www.enterprisedb.com
It's been a bunch of years since I worked with ICU, so anything I say below may have changed in their code or be subject to mental bit rot.
On Sun, Sep 23, 2018 at 2:48 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote:
Considering that to handle this we'd need to figure out
how link libicu.so.55, libicu.so.56, ... etc into the same backend,
and yet they presumably have the same collation names,
There's an option when compiling ICU to version extend the API names. So, instead of calling ucol_open(), you'd call ucol_open_55() or ucol_open_56() then you can link to both libixu.so.55 and libicu.so.56 without getting name collisions.
The side effect of this is that it's the application's responsibility to figure out which version of ICU "en_US" should be routed to. In DB2, we started the collation names with UCAxxx (later changed to CLDRxxx) to let us distinguish which version of the API to call.
Admittedly that creates a whole can
of worms for initdb-time catalog creation, package maintainers' jobs,
how long old versions have to be supported and how you upgraded
database objects to new ICU versions.
Yep. We never come up with a good answer for that before I left IBM. At the time, DB2 only supported 2 or 3 version of ICU, so they were all shipped as part of the install bundle.
Long term, I think the only viable approach to supporting multiple versions of ICU is runtime loading of the libraries. Then it's up to the system administrator to make sure the necessary versions are installed on the system.
Yeah, it seems like ICU is *also* subject to minor changes that happen
under your feet, much like libc. For example maintenance release 60.2
(you can't install that at the same time as 60.1, but you can install
it at the same time as 59.2). You'd be linked against libicu.so.60
(and thence libicudata.so.60), and it gets upgraded in place when you
run the local equivalent of apt-get upgrade.
This always worried me because an unexpected collation change is so painful for a database. And I was never able to think of a way of reliably testing compatibility either because of ICU's ability to reorder and group characters when collating.
On Tue, Sep 25, 2018 at 4:26 AM Douglas Doole <dougdoole@gmail.com> wrote:> > On Sun, Sep 23, 2018 at 2:48 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote: >> Admittedly that creates a whole can >> of worms for initdb-time catalog creation, package maintainers' jobs, >> how long old versions have to be supported and how you upgraded >> database objects to new ICU versions. > > > Yep. We never come up with a good answer for that before I left IBM. At the time, DB2 only supported 2 or 3 version ofICU, so they were all shipped as part of the install bundle. > > Long term, I think the only viable approach to supporting multiple versions of ICU is runtime loading of the libraries.Then it's up to the system administrator to make sure the necessary versions are installed on the system. I wonder if we would be practically constrained to using the distro-supplied ICU (by their policies of not allowing packages to ship their own copies ICU); it seems like it. I wonder which distros allow multiple versions of ICU to be installed. I see that Debian 9.5 only has 57 in the default repo, but the major version is in the package name (what is the proper term for that kind of versioning?) and it doesn't declare a conflict with other versions, so that's promising. Poking around with nm I noticed also that both the RHEL and Debian ICU libraries have explicitly versioned symbol names like "ucol_strcollUTF8_57", which is also promising. FreeBSD seems to have used "--disable-renaming" and therefore defines only "ucol_strcollUTF8"; doh. This topic is discussed here: http://userguide.icu-project.org/design#TOC-ICU-Binary-Compatibility:-Using-ICU-as-an-Operating-System-Level-Library Personally I'm not planning to work on multi-version installation any time soon, I was just scoping out some basic facts about all this. I think the primary problem that affects most of our users is the shifting-under-your-feet problem, which we now see applies equally to libc and libicu. >> Yeah, it seems like ICU is *also* subject to minor changes that happen >> under your feet, much like libc. For example maintenance release 60.2 >> (you can't install that at the same time as 60.1, but you can install >> it at the same time as 59.2). You'd be linked against libicu.so.60 >> (and thence libicudata.so.60), and it gets upgraded in place when you >> run the local equivalent of apt-get upgrade. > > This always worried me because an unexpected collation change is so painful for a database. And I was never able to thinkof a way of reliably testing compatibility either because of ICU's ability to reorder and group characters when collating. I think the best we can do is to track versions per dependency (ie record it when the CHECK is created, when the index is created or rebuilt, ...) and generate loud warnings until you've dealt with each version dependency. That's why I've suggested we could consider sticking it on pg_depend (though I have apparently failed to convince Stephen so far). I think something like that is better than the current collversion design, which punts the problem to the DBA: "hey, human, there might be some problems, but I don't know where! Please tell me when you've fixed them by running ALTER COLLATION ... REFRESH VERSION!" instead of having the computer track of what actually needs to be done on an object-by-object basis and update the versions one-by-one automatically when the problems are resolved. -- Thomas Munro http://www.enterprisedb.com
On Mon, Sep 24, 2018 at 1:47 PM Thomas Munro <thomas.munro@enterprisedb.com> wrote: > Personally I'm not planning to work on multi-version installation any > time soon, I was just scoping out some basic facts about all this. I > think the primary problem that affects most of our users is the > shifting-under-your-feet problem, which we now see applies equally to > libc and libicu. Are we sure about that? Could it just be that ICU will fix bugs that cause their strcoll()-alike and strxfrm()-alike functions to give behavior that isn't consistent with the behavior required by the CLDR version in use? This seems like it might be a very useful distinction. We know that glibc had bugs that were caused by strxfrm() not agreeing with strcoll() -- that was behind the 9.5-era abbreviated keys issues. But that was actually a bug in an optimization in strcoll(), rather than a strxfrm() bug. strxfrm() gave the correct answer, which is to say the answer that was right according to the high level collation definition. It merely failed to be bug-compatible with strcoll(). What's ICU supposed to do about an issue like that? If we're going to continue to rely on the strxfrm() equivalent from ICU, then it seems to me that ICU should be able to change behaviors in a stable release, provided the behavior they're changing is down to a bug in their infrastructure, as opposed to an organic evolution in how some locale sorts text (CLDR update). My understanding is that ICU is designed to decouple technical issues with issues of concern to natural language experts, so we as an ICU client can limit ourselves to worrying about one of the two at any given time. -- Peter Geoghegan
Re: Thomas Munro 2018-09-24 <CAEepm=04PvEdmRmCCcn4c7ydDA=-G=uLe5vDdfJiqp58Jpi8Kw@mail.gmail.com> > I wonder if we would be practically constrained to using the > distro-supplied ICU (by their policies of not allowing packages to > ship their own copies ICU); it seems like it. I wonder which distros > allow multiple versions of ICU to be installed. I see that Debian 9.5 > only has 57 in the default repo, but the major version is in the > package name (what is the proper term for that kind of versioning?) > and it doesn't declare a conflict with other versions, so that's > promising. The point of the put-the-version/soname-into-the-package-name business is to allow co-installation of (mostly library) packages[*], so this is indeed possible with the ICU package on Debian. The bad news is that this applies to the binary package name only, the source package (from which the binaries are built) is only called "icu". As Debian only ships one version of a source package in a release, there can only be one libicu$version.deb in a release. (This means you can have libicu52.deb and libicu60.deb installed in parallel, but after upgrading, libicu52 won't have any installation source. You can either keep or remove the package, but not reinstall it.) The fix would be to include the version in the source package name as well, like postgresql-NN and llvm-toolchain-NN. (And then find a maintainer willing to maintain the bunch.) Christoph [*] now historical footnote: this wasn't the case with the libperl-5.xx packages which conflicted with each other, which is why upgrading Debian used to remove the postgresql-plperl-$oldmajor version on upgrade. This has now been fixed for the stretch->buster upgrade.
On 16/09/2018 10:19, Thomas Munro wrote: > 4. After creating a new database, update that row as appropriate in > the new database (!). Or find some other way to write a new table out > and switch it around, or something like that. That is, if you say > CREATE DATABASE foo LC_COLLATE = 'xx_XX', COLLATION_PROVIDER = libc > then those values somehow get written into the default pg_collation > row in the *new* database (so at that point it's not a simple copy of > the template database). I've been hatching this exact scheme since the very beginning, even thinking about using the background session functionality to do this. It would solve a lot of problems, but there is the question of exactly how to do that "(!)" part. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 16/09/2018 20:12, Douglas Doole wrote: > All this collation stuff is great, and I know users want it, but it > feels like were pushing them out of an airplane with a ripped parachute > every time the collation libraries change. Maybe they'll land safely or > maybe things will get very messy. At some point, a schema designer also needs to take some responsibility for making smart choices for longevity. It is known that collations can change, and the sort of changes that can happen are also generally understood. So if you want to use range partitioning on text fields, maybe you shouldn't, or at least choose the ranges conservatively. Similarly, maybe you shouldn't have timestamp range partition boundaries around DST changes or on the 29th of every month, and maybe you shouldn't partition float values at negative zero. Some ideas are better than others. We will help you recognize and fix breakage, but we can't prevent it altogether. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Fri, Sep 28, 2018 at 9:19 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 16/09/2018 10:19, Thomas Munro wrote: > > 4. After creating a new database, update that row as appropriate in > > the new database (!). Or find some other way to write a new table out > > and switch it around, or something like that. That is, if you say > > CREATE DATABASE foo LC_COLLATE = 'xx_XX', COLLATION_PROVIDER = libc > > then those values somehow get written into the default pg_collation > > row in the *new* database (so at that point it's not a simple copy of > > the template database). > > I've been hatching this exact scheme since the very beginning, even > thinking about using the background session functionality to do this. > It would solve a lot of problems, but there is the question of exactly > how to do that "(!)" part. If that turns out to be impractical, I guess the "status quo" option would be to add datcollprovider to pg_database. If we switch to per-index version tracking as I proposed upthread (dropping collversion), then the where-do-we-stick-the-default-collation's-version problem goes away. -- Thomas Munro http://www.enterprisedb.com
Re: Thomas Munro 2018-09-27 <CAEepm=0EVCF_Nj5uYV5f6xH34MK1Z4mCfb+Svn1yJ_zsx5tOFw@mail.gmail.com> > > > 4. After creating a new database, update that row as appropriate in > > > the new database (!). Or find some other way to write a new table out > > > and switch it around, or something like that. > > > > I've been hatching this exact scheme since the very beginning, even > > thinking about using the background session functionality to do this. > > It would solve a lot of problems, but there is the question of exactly > > how to do that "(!)" part. Making (!) work would also allow reassigning the "public" schema to the database owner. That would fix that gross security gap that is left with the default search_path, while still keeping usability. It would make a whole lot of sense to work on making this feasible. Christoph
On Fri, Sep 28, 2018 at 9:30 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 16/09/2018 20:12, Douglas Doole wrote: > > All this collation stuff is great, and I know users want it, but it > > feels like were pushing them out of an airplane with a ripped parachute > > every time the collation libraries change. Maybe they'll land safely or > > maybe things will get very messy. > > At some point, a schema designer also needs to take some responsibility > for making smart choices for longevity. It is known that collations can > change, and the sort of changes that can happen are also generally > understood. So if you want to use range partitioning on text fields, > maybe you shouldn't, or at least choose the ranges conservatively. > Similarly, maybe you shouldn't have timestamp range partition boundaries > around DST changes or on the 29th of every month, and maybe you > shouldn't partition float values at negative zero. Some ideas are > better than others. We will help you recognize and fix breakage, but we > can't prevent it altogether. Since there's a chance of an "unconference" session on locale versions tomorrow at PGCon, here's a fresh rebase of the patchset to add per-database-object collation version tracking. It doesn't handle default collations yet (not hard AFAIK, will try that soon), but it does work well enough to demonstrate the generate principal. I won't attach the CHECK support just yet, because it needs more work, but the point of it was to demonstrate that pg_depend can handle this for all kinds of database objects in one standard way, rather than sprinkling collation version stuff all over the place in pg_index, pg_constraint, etc, and I think it did that already. postgres=# create table t (k text collate "en-x-icu"); CREATE TABLE postgres=# create index on t(k); CREATE INDEX postgres=# select refobjversion from pg_depend where refobjversion != ''; refobjversion --------------- 153.72 (1 row) Mess with it artificially (or install a different version of ICU): postgres=# update pg_depend set refobjversion = '42' where refobjversion = '153.72'; UPDATE 1 In a new session, we get a warning when first loading the index because the version doesn't match: postgres=# select * from t where k = 'x'; psql: WARNING: index "t_k_idx" depends on collation 12711 version "42", but the current version is "153.72" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. k --- (0 rows) The warning can be cleared for the indexes on that one table like so: postgres=# reindex table t; REINDEX You can see that it's captured the new version: postgres=# select refobjversion from pg_depend where refobjversion != ''; refobjversion --------------- 153.72 (1 row) -- Thomas Munro https://enterprisedb.com
Attachment
On 2018-09-05 23:18, Thomas Munro wrote: > On Wed, Sep 5, 2018 at 12:10 PM Christoph Berg <myon@debian.org> wrote: >>> So, it's not ideal but perhaps worth considering on the grounds that >>> it's better than nothing? >> >> Ack. > > Ok, here's a little patch like that. > > postgres=# select collname, collcollate, collversion from pg_collation > where collname = 'en_NZ'; > collname | collcollate | collversion > ----------+-------------+------------- > en_NZ | en_NZ.utf8 | 2.24 > (1 row) After, um, briefly sleeping on this, I would like to go ahead with this. There is ongoing work to make ICU available globally, and as part of that I've also proposed a way to make the collation version tracking work on a database level. This here would be a useful piece on the overall picture. Independent of what becomes of the ICU effort, we could have glibc collation version tracking completely working for PG13. The only open question on this patch was whether it's a good version to use. I think based on subsequent discussions, there was the realization that this is the best we can do and better than nothing. In the patch, I would skip the configure test and just do #ifdef __GLIBC__ directly. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Thu, Oct 3, 2019 at 7:53 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 2018-09-05 23:18, Thomas Munro wrote: > > On Wed, Sep 5, 2018 at 12:10 PM Christoph Berg <myon@debian.org> wrote: > >>> So, it's not ideal but perhaps worth considering on the grounds that > >>> it's better than nothing? > >> > >> Ack. > > > > Ok, here's a little patch like that. > > > > postgres=# select collname, collcollate, collversion from pg_collation > > where collname = 'en_NZ'; > > collname | collcollate | collversion > > ----------+-------------+------------- > > en_NZ | en_NZ.utf8 | 2.24 > > (1 row) > > After, um, briefly sleeping on this, I would like to go ahead with this. > > There is ongoing work to make ICU available globally, and as part of > that I've also proposed a way to make the collation version tracking > work on a database level. > > This here would be a useful piece on the overall picture. Independent > of what becomes of the ICU effort, we could have glibc collation version > tracking completely working for PG13. +1 Also, better ideas about which objects to attach versions to can come along independently of this. > The only open question on this patch was whether it's a good version to > use. I think based on subsequent discussions, there was the realization > that this is the best we can do and better than nothing. > > In the patch, I would skip the configure test and just do > > #ifdef __GLIBC__ > > directly. Ok. Here's one like that. Also, a WIP patch for FreeBSD. Thanks, Thomas
Attachment
On 2019-10-03 14:25, Thomas Munro wrote: >> The only open question on this patch was whether it's a good version to >> use. I think based on subsequent discussions, there was the realization >> that this is the best we can do and better than nothing. >> >> In the patch, I would skip the configure test and just do >> >> #ifdef __GLIBC__ >> >> directly. > > Ok. Here's one like that. Pushed that. > Also, a WIP patch for FreeBSD. That looks promising. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On 2019-10-09 21:19, Peter Eisentraut wrote: > On 2019-10-03 14:25, Thomas Munro wrote: >>> The only open question on this patch was whether it's a good version to >>> use. I think based on subsequent discussions, there was the realization >>> that this is the best we can do and better than nothing. >>> >>> In the patch, I would skip the configure test and just do >>> >>> #ifdef __GLIBC__ >>> >>> directly. >> >> Ok. Here's one like that. > > Pushed that. Actually, I had to revert that because pg_dump and pg_upgrade tests need to be updated, but that seems doable. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Thu, Oct 10, 2019 at 8:38 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > On 2019-10-09 21:19, Peter Eisentraut wrote: > > On 2019-10-03 14:25, Thomas Munro wrote: > >>> The only open question on this patch was whether it's a good version to > >>> use. I think based on subsequent discussions, there was the realization > >>> that this is the best we can do and better than nothing. > >>> > >>> In the patch, I would skip the configure test and just do > >>> > >>> #ifdef __GLIBC__ > >>> > >>> directly. > >> > >> Ok. Here's one like that. > > > > Pushed that. > > Actually, I had to revert that because pg_dump and pg_upgrade tests need > to be updated, but that seems doable. [Returning from a couple of weeks mostly away from computers] Right, sorry about that. Here is a new version that fixes that test, and also gives credit to Christoph for the idea in the commit message. While testing pg_upgrade scenarios I noticed that initdb-created collations' versions are not preserved, potentially losing track of information about corrupted indexes. That's a preexisting condition, and probably well understood, but it made me realise that if we switch to per-database object (for example: per index) version tracking as mentioned up-thread, then we should probably preserve that information across pg_upgrade.
Attachment
Re: Thomas Munro 2019-10-11 <CA+hUKGKDe98DFWKJoS7e4Z+Oamzc-1sZfpL3V3PPgi1uNvQ1tw@mail.gmail.com> > While testing pg_upgrade scenarios I noticed that initdb-created > collations' versions are not preserved, potentially losing track of > information about corrupted indexes. That's a preexisting condition, > and probably well understood, but it made me realise that if we switch > to per-database object (for example: per index) version tracking as > mentioned up-thread, then we should probably preserve that information > across pg_upgrade. That would make much sense, yes. The whole problem is already complex enough, if we add another "but if you use pg_upgrade, you still need to do the tracking manually" footnote, users will be very confused. Christoph
On Fri, Oct 11, 2019 at 11:41 PM Thomas Munro <thomas.munro@gmail.com> wrote: > On Thu, Oct 10, 2019 at 8:38 AM Peter Eisentraut > <peter.eisentraut@2ndquadrant.com> wrote: > > Actually, I had to revert that because pg_dump and pg_upgrade tests need > > to be updated, but that seems doable. > > [Returning from a couple of weeks mostly away from computers] > > Right, sorry about that. Here is a new version that fixes that test, > and also gives credit to Christoph for the idea in the commit message. Here's a version with a small note added to the documentation. I'm planning to commit this tomorrow. To actually make this useful for most users, we need version tracking for the default collation. I noticed that the ICU-as-default patch[1] can do that for ICU collations (though I haven't looked closely yet). Currently, its change to get_collation_actual_version() for the default collation applies only when the default provider is ICU, but if you just take out that condition when rebasing it should do the right thing, I think? [1] https://www.postgresql.org/message-id/attachment/104646/v1-0002-Add-option-to-use-ICU-as-global-collation-provide_rebased.patch
Attachment
On Tue, Oct 15, 2019 at 5:39 PM Thomas Munro <thomas.munro@gmail.com> wrote: > Here's a version with a small note added to the documentation. I'm > planning to commit this tomorrow. Done. It's not much, but it's a start. Some things to do: * handle default collation (probably comes with CF entry 2256?) * preserve versions of initdb-created collations in pg_upgrade * ditch collversion and ALTER ... REFRESH VERSION and start tracking versions dependencies per-index (etc)
On Wed, Oct 16, 2019 at 5:33 PM Thomas Munro <thomas.munro@gmail.com> wrote: > On Tue, Oct 15, 2019 at 5:39 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > Here's a version with a small note added to the documentation. I'm > > planning to commit this tomorrow. > > Done. The buildfarm is telling me that I didn't test this with the full set of locales installed, so it fails on some systems. Will fix.
Hello Thomas, On Tue, May 28, 2019 at 9:00 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > Since there's a chance of an "unconference" session on locale versions > tomorrow at PGCon, here's a fresh rebase of the patchset to add > per-database-object collation version tracking. It doesn't handle > default collations yet (not hard AFAIK, will try that soon), but it > does work well enough to demonstrate the generate principal. I won't > attach the CHECK support just yet, because it needs more work, but the > point of it was to demonstrate that pg_depend can handle this for all > kinds of database objects in one standard way, rather than sprinkling > collation version stuff all over the place in pg_index, pg_constraint, > etc, and I think it did that already. Are you planning to continue working on it? For the record, that's something needed to be able to implement a filter in REINDEX command [1]. I'm not sending a review since the code isn't finished yet, but one issue with current approach is that the WARNING message recommending to issue a REINDEX can be issued when running the required REINDEX, which is at best unhelpful: # update pg_depend set refobjversion = 'a' || refobjversion where refobjversion != ''; # reindex table t1; WARNING: 01000: index "t1_val_idx" depends on collation 13330 version "a153.97.35.8", but the current version is "153.97.35.8" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. LOCATION: index_check_collation_version, index.c:1263 [1]: https://www.postgresql.org/message-id/a81069b1-fdaa-ff40-436e-7840bd639ccf%402ndquadrant.com
On Fri, Nov 1, 2019 at 2:21 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > Are you planning to continue working on it? For the record, that's > something needed to be able to implement a filter in REINDEX command > [1]. Bonjour Julien, Unfortunately I haven't had time to work on it seriously, but here's a quick rebase to get the proof-of-concept back into working shape. It's nice to see progress in other bits of the problem-space. I hope to have time to look at this patch set again soon, but if you or someone else would like hack on or think about it too, please feel free! Yes indeed this is exactly the same problem that you're trying to solve, approached from a different starting point. Here are some problems to think about: * We'd need to track dependencies on the default collation once we have versioning for that (see https://www.postgresql.org/message-id/flat/5e756dd6-0e91-d778-96fd-b1bcb06c161a%402ndquadrant.com). That is how most people actually consume collations out there in real life, and yet we don't normally track dependencies on the default collation and I don't know if that's simply a matter of ripping out all the code that looks like "xxx != DEFAULT_COLLATION_ID" in the dependency analysis code or if there's more to it. * Andres mentioned off-list that pg_depend rows might get blown away and recreated in some DDL circumstances. We need to look into that. * Another is that pg_upgrade won't preserve pg_depend rows, so you'd need some catalog manipulation (direct or via new DDL) to fix that. * Some have expressed doubt that pg_depend is the right place for this; let's see if any counter-proposals appear. > # reindex table t1; > WARNING: 01000: index "t1_val_idx" depends on collation 13330 version > "a153.97.35.8", but the current version is "153.97.35.8" > DETAIL: The index may be corrupted due to changes in sort order. > HINT: REINDEX to avoid the risk of corruption. > LOCATION: index_check_collation_version, index.c:1263 Duh. Yeah, that's stupid and needs to be fixed somehow.
Attachment
Hello Thomas, On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Fri, Nov 1, 2019 at 2:21 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > Are you planning to continue working on it? For the record, that's > > something needed to be able to implement a filter in REINDEX command > > [1]. > > Bonjour Julien, > > Unfortunately I haven't had time to work on it seriously, but here's a > quick rebase to get the proof-of-concept back into working shape. > It's nice to see progress in other bits of the problem-space. I hope > to have time to look at this patch set again soon, but if you or > someone else would like hack on or think about it too, please feel > free! Thanks! I already did some hack on it when looking at the code so I can try to make some progress. > Yes indeed this is exactly the same problem that you're trying to > solve, approached from a different starting point. > > Here are some problems to think about: > > * We'd need to track dependencies on the default collation once we > have versioning for that (see > https://www.postgresql.org/message-id/flat/5e756dd6-0e91-d778-96fd-b1bcb06c161a%402ndquadrant.com). > That is how most people actually consume collations out there in real > life, and yet we don't normally track dependencies on the default > collation and I don't know if that's simply a matter of ripping out > all the code that looks like "xxx != DEFAULT_COLLATION_ID" in the > dependency analysis code or if there's more to it. This isn't enough. What would remain is: - teach get_collation_version_for_oid() to return the default collation name, which is simple - have recordDependencyOnVersion() actually records the dependency, which wouldn't happen as the default collation is pinned. An easy fix would be to teach isObjectPinned() to ignore CollationRelationId / DEFAULT_COLLATION_OID, but that's ugly and would allow too many dependencies to be stored. Not pinning the default collation during initdb doesn't sound a good alternative either. Maybe adding a force flag or a new DependencyType that'd mean "normal but forced" would be ok? > * Andres mentioned off-list that pg_depend rows might get blown away > and recreated in some DDL circumstances. We need to look into that. > * Another is that pg_upgrade won't preserve pg_depend rows, so you'd > need some catalog manipulation (direct or via new DDL) to fix that. > * Some have expressed doubt that pg_depend is the right place for > this; let's see if any counter-proposals appear. When working on the REINDEX FILTER, I totally missed this thread and wrote a POC saving the version in pg_index. That's not ideal though, as you need to record multiple version strings. In my version I used a json type, using the collprovider as the key, but that's not enough for ICU as each collation can have a different version string. I'm not a huge fan of using pg_depend to record the version, but storing a collprovider/collname -> version per row in pg_index is definitely a no go, so I don't have any better counter-proposal. > > > # reindex table t1; > > WARNING: 01000: index "t1_val_idx" depends on collation 13330 version > > "a153.97.35.8", but the current version is "153.97.35.8" > > DETAIL: The index may be corrupted due to changes in sort order. > > HINT: REINDEX to avoid the risk of corruption. > > LOCATION: index_check_collation_version, index.c:1263 > > Duh. Yeah, that's stupid and needs to be fixed somehow. I don't have a clever solution for that either.
On Mon, Nov 4, 2019 at 11:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > Here are some problems to think about: > > > > * We'd need to track dependencies on the default collation once we > > have versioning for that [...] Another problem I just thought about is how to avoid discrepancy of collation version for indexes on shared objects, such as pg_database_datname_index.
On Tue, Nov 5, 2019 at 4:18 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Mon, Nov 4, 2019 at 11:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > Here are some problems to think about: > > > > > > * We'd need to track dependencies on the default collation once we > > > have versioning for that [...] > > Another problem I just thought about is how to avoid discrepancy of > collation version for indexes on shared objects, such as > pg_database_datname_index. I didn't look closely at the code, but I think when "name" recently became collation-aware (commit 586b98fd), it switched to using C_COLLATION_OID as its typcollation, and "C" doesn't need versioning, so I think it would only be a problem if there are shared catalogs that have "name" columns that have a non-type-default collation. There are none of those, and you can't create them, right? If there were, if we take this patch set to its logical conclusion, we'd also need pg_shdepend.refobjversion, but we don't need it AFAICS.
On Mon, Nov 4, 2019 at 11:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > * Some have expressed doubt that pg_depend is the right place for > > this; let's see if any counter-proposals appear. > > When working on the REINDEX FILTER, I totally missed this thread and > wrote a POC saving the version in pg_index. That's not ideal though, > as you need to record multiple version strings. In my version I used > a json type, using the collprovider as the key, but that's not enough > for ICU as each collation can have a different version string. I'm > not a huge fan of using pg_depend to record the version, but storing a > collprovider/collname -> version per row in pg_index is definitely a > no go, so I don't have any better counter-proposal. Yeah, I also thought about using pg_index directly, and was annoyed by the denormalisation you mention (an array of {collation, version}!?) and so I realised I wanted another table like they teach you at database school, but I also realised that there are other kinds of database objects that depend on collations and that can become corrupted if the collation definition changes. It was thinking about that that lead me to the idea of using something that can record version dependences on *any* database object, which brought me to the existing pg_depend table. Concretely, eventually we might want to support checks etc, as mentioned by Doug Doole and as I showed in an earlier version of this POC patch, though I removed it from the more recent patch set so we can focus on the more pressing problems. The check constraint idea leads to more questions like: "does this constraint *really* use any operators that truly depend on the collation definition?" (so CHECK (name > 'xxx') depends on name's collation, but CHECK (LENGTH(name) < 32) doesn't really), and I didn't want to be distracted by that rabbit hole. Here's the example message that came out of the earlier patch for posterity: WARNING: constraint "t_i_check" depends on collation 12018 version "30.0.1", but the current version is "30.0.2" DETAIL: The constraint may be corrupted due to changes in sort order. HINT: Drop and recreate the constraint to avoid the risk of corruption.
On Mon, Nov 4, 2019 at 11:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > When working on the REINDEX FILTER, I totally missed this thread and I created a new wiki page to try to track the various moving pieces here. Julien, Peter, Christoph, anyone interested, please feel free to update it or add more information. https://wiki.postgresql.org/wiki/Collations
On 2019-11-04 04:58, Thomas Munro wrote: > * We'd need to track dependencies on the default collation once we > have versioning for that (see > https://www.postgresql.org/message-id/flat/5e756dd6-0e91-d778-96fd-b1bcb06c161a%402ndquadrant.com). > That is how most people actually consume collations out there in real > life, and yet we don't normally track dependencies on the default > collation and I don't know if that's simply a matter of ripping out > all the code that looks like "xxx != DEFAULT_COLLATION_ID" in the > dependency analysis code or if there's more to it. As I was working on that lately, I came to the conclusion that we should get *this* patch done first. My patch for default collation versioning had the version of the default collation in the pg_collation record for the "default" collation. But that way you can't set the collation version during CREATE DATABASE. It's also pretty complicated (but not impossible) to get the collation version in template1 set during initdb. So you'd need a new mechanism, perhaps to store it in pg_database instead. So instead of going through all those complications of creating this new mechanism, only to rip it out again not much later, we should focus on moving the per-object tracking forward. That would solve these problems because you don't need to track the version at database creation time, only when you create objects using the collations. > * Some have expressed doubt that pg_depend is the right place for > this; let's see if any counter-proposals appear. The only alternative is to create a new catalog that contains exactly the same columns as pg_depend (minus deptype) plus the version. That would work but it would just create a lot of code duplication, I think. One thing I've been thinking about is whether this object-version concept could extend to other object types. For example, if someone changes the binary layout of a type, they could change the version of the type, and this catalog could track the type version in the column -> type dependency. Obviously, a lot more work would have to be done to make this work, but I think the concept of this catalog is sound. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Mon, Nov 4, 2019 at 9:59 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Tue, Nov 5, 2019 at 4:18 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Nov 4, 2019 at 11:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > Here are some problems to think about: > > > > > > > > * We'd need to track dependencies on the default collation once we > > > > have versioning for that [...] > > > > Another problem I just thought about is how to avoid discrepancy of > > collation version for indexes on shared objects, such as > > pg_database_datname_index. > > I didn't look closely at the code, but I think when "name" recently > became collation-aware (commit 586b98fd), it switched to using > C_COLLATION_OID as its typcollation, and "C" doesn't need versioning, > so I think it would only be a problem if there are shared catalogs > that have "name" columns that have a non-type-default collation. > There are none of those, and you can't create them, right? If there > were, if we take this patch set to its logical conclusion, we'd also > need pg_shdepend.refobjversion, but we don't need it AFAICS. That's entirely correct, I should have checked that.
On Mon, Nov 4, 2019 at 11:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Nov 4, 2019 at 4:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > Unfortunately I haven't had time to work on it seriously, but here's a > > quick rebase to get the proof-of-concept back into working shape. Thanks! I also removed the test for REFRESH VERSION command that was forgotten in the patch set, and run a pgindent. > > Here are some problems to think about: > > > > * We'd need to track dependencies on the default collation once we > > have versioning for that (see > > https://www.postgresql.org/message-id/flat/5e756dd6-0e91-d778-96fd-b1bcb06c161a%402ndquadrant.com). > > That is how most people actually consume collations out there in real > > life, and yet we don't normally track dependencies on the default > > collation and I don't know if that's simply a matter of ripping out > > all the code that looks like "xxx != DEFAULT_COLLATION_ID" in the > > dependency analysis code or if there's more to it. > > This isn't enough. What would remain is: > > - teach get_collation_version_for_oid() to return the default > collation name, which is simple > - have recordDependencyOnVersion() actually records the dependency, > which wouldn't happen as the default collation is pinned. > > An easy fix would be to teach isObjectPinned() to ignore > CollationRelationId / DEFAULT_COLLATION_OID, but that's ugly and would > allow too many dependencies to be stored. Not pinning the default > collation during initdb doesn't sound a good alternative either. > Maybe adding a force flag or a new DependencyType that'd mean "normal > but forced" would be ok? Attached 4th patch handles default collation. I went with an ignore_systempin flag in recordMultipleDependencies. > > > * Andres mentioned off-list that pg_depend rows might get blown away > > and recreated in some DDL circumstances. We need to look into that. I tried various flavour of DDL but I couldn't wipe out the pg_depend rows without having an index rebuild triggered (like changing the underlying column datatype). Do you have any scenario where the index rebuild wouldn't be triggered? > > * Another is that pg_upgrade won't preserve pg_depend rows, so you'd > > need some catalog manipulation (direct or via new DDL) to fix that. Attached 5th patch add a new "ALTER INDEX idx_name DEPENDS ON COLLATION coll_oid VERSION coll_version_text" that can only be executed in binary upgrade mode, and teach pg_dump to generate such commands (including for indexes created for constraints). One issue is that older versions don't have pg_depend information, so pg_dump can't find the dependencies to generate such commands and override the version with anything else. It means that the upgraded cluster will show all indexes as depending on the current collation provider version. I'm not sure if that's the best thing to do, or if we should change all pg_depend rows to mention "unknown" version or something like that. It would generate so much noise that it's probably not worth it. I didn't do anything for the spurious warning when running a reindex, and kept original approach of pg_depend catalog.
Attachment
On Thu, Nov 7, 2019 at 10:20 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > Attached 4th patch handles default collation. I went with an > ignore_systempin flag in recordMultipleDependencies. Thanks for working on this! I haven't looked closely or tested yet, but this seems reasonable. Obviously it assumes that the default provider is really "libc" in disguise for now, but Peter's other patch will extend that to cover ICU later. > > > * Andres mentioned off-list that pg_depend rows might get blown away > > > and recreated in some DDL circumstances. We need to look into that. > > I tried various flavour of DDL but I couldn't wipe out the pg_depend > rows without having an index rebuild triggered (like changing the > underlying column datatype). Do you have any scenario where the index > rebuild wouldn't be triggered? Ah, OK, if we only do that when the old index contents will also be destroyed, that's great news. > > > * Another is that pg_upgrade won't preserve pg_depend rows, so you'd > > > need some catalog manipulation (direct or via new DDL) to fix that. > > Attached 5th patch add a new "ALTER INDEX idx_name DEPENDS ON > COLLATION coll_oid VERSION coll_version_text" that can only be > executed in binary upgrade mode, and teach pg_dump to generate such > commands (including for indexes created for constraints). It's nice that you were able to make up a reasonable grammar out of existing keywords. I wonder if we should make this user accessible... it could be useful for expert users. If so, maybe it should use collation names, not OIDs? > One issue > is that older versions don't have pg_depend information, so pg_dump > can't find the dependencies to generate such commands and override the > version with anything else. It means that the upgraded cluster will > show all indexes as depending on the current collation provider > version. I'm not sure if that's the best thing to do, or if we should > change all pg_depend rows to mention "unknown" version or something > like that. It would generate so much noise that it's probably not > worth it. Right, so this is basically a policy decision: do we assume that all pre-13 indexes that depend on collations are potentially corrupted, or assume that they are not? The "correct" thing to do would be to assume they are potentially corrupted and complain until the user reindexes, but I think the pragmatic thing to do would be to assume that they're not and just let them adopt the current versions, even though it's a lie. I lean towards the pragmatic choice; we're trying to catch future problems, not give the entire user base a load of extra work to do on their next pg_upgrade for mostly theoretical reasons. (That said, given the new glibc versioning, we'll effectively be giving most of our user base a load of extra work to do on their next OS upgrade and that'll be a characteristic of PostgreSQL going forward, once the versioning-for-default-provider patch goes in.) Any other opinions? > I didn't do anything for the spurious warning when running a reindex, > and kept original approach of pg_depend catalog. I see three options: 1. Change all or some of index_open(), relation_open(), RelationIdGetRelation(), RelationBuildDesc() and RelationInitIndexAccessInfo() to take some kind of flag so we can say NO_COLLATION_VERSION_CHECK_PLEASE, and then have ReindexIndex() pass that flag down when opening it for the purpose of rebuilding it. 2. Use a global state to suppress these warnings while opening that index. Perhaps ReindexIndex() would call RelCacheWarnings(false) before index_open(), and use PG_FINALLY to make sure it restores warnings with RelCacheWarnings(true). (This is a less-code-churn bad-programming-style version of #1.) 3. Move the place that we run the collation version check. Instead of doing it in RelationInitIndexAccessInfo() so that it runs when the relation cache first loads the index, put it into a new routine RelationCheckValidity() and call that from ... I don't know, some other place that runs whenever we access indexes but not when we rebuild them. 3's probably a better idea, if you can find a reasonable place to call it from. I'm thinking some time around the time the executor acquires locks, but using a flag in the relcache entry to make sure it doesn't run the check again if there were no warnings last time (so one successful version check turns the extra work off for the rest of this relcache entry's lifetime). I think it'd be a feature, not a bug, if it gave you the warning every single time you executed a query using an index that has a mismatch... but a practical alternative would be to check only once per index and that probably makes more sense.
On Thu, Nov 7, 2019 at 1:27 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > As I was working on that lately, I came to the conclusion that we should > get *this* patch done first. Cool. Let's aim to get this into 13! > > * Some have expressed doubt that pg_depend is the right place for > > this; let's see if any counter-proposals appear. > > The only alternative is to create a new catalog that contains exactly > the same columns as pg_depend (minus deptype) plus the version. That > would work but it would just create a lot of code duplication, I think. Agreed. > One thing I've been thinking about is whether this object-version > concept could extend to other object types. For example, if someone > changes the binary layout of a type, they could change the version of > the type, and this catalog could track the type version in the column -> > type dependency. Obviously, a lot more work would have to be done to > make this work, but I think the concept of this catalog is sound. Interesting idea. Sounds like it requires version checks that actually stop you from using the dependent object, instead of emitting a few meek warnings.
On Fri, Nov 08, 2019 at 02:23:54PM +1300, Thomas Munro wrote: > Right, so this is basically a policy decision: do we assume that all > pre-13 indexes that depend on collations are potentially corrupted, or > assume that they are not? The "correct" thing to do would be to > assume they are potentially corrupted and complain until the user > reindexes, but I think the pragmatic thing to do would be to assume > that they're not and just let them adopt the current versions, even > though it's a lie. I lean towards the pragmatic choice; we're trying > to catch future problems, not give the entire user base a load of > extra work to do on their next pg_upgrade for mostly theoretical > reasons. (That said, given the new glibc versioning, we'll > effectively be giving most of our user base a load of extra work to do > on their next OS upgrade and that'll be a characteristic of PostgreSQL > going forward, once the versioning-for-default-provider patch goes > in.) Any other opinions? Matching an incorrect collation version on an index which physically uses something else does not strike me as a good idea to me because you may hide corruptions, and you would actually lose the reason why the corruption happened (did the version bump up from an incorrect one? Or what?). Could it be possible to mark any existing indexes with an unknown version or something like that? This way, we could just let the user decide what needs to be reindexed or not, and we need to offer an option to update the collation version from unknown to the latest one available. -- Michael
Attachment
On Fri, Nov 8, 2019 at 2:37 PM Michael Paquier <michael@paquier.xyz> wrote: > On Fri, Nov 08, 2019 at 02:23:54PM +1300, Thomas Munro wrote: > > Right, so this is basically a policy decision: do we assume that all > > pre-13 indexes that depend on collations are potentially corrupted, or > > assume that they are not? The "correct" thing to do would be to > > assume they are potentially corrupted and complain until the user > > reindexes, but I think the pragmatic thing to do would be to assume > > that they're not and just let them adopt the current versions, even > > though it's a lie. I lean towards the pragmatic choice; we're trying > > to catch future problems, not give the entire user base a load of > > extra work to do on their next pg_upgrade for mostly theoretical > > reasons. (That said, given the new glibc versioning, we'll > > effectively be giving most of our user base a load of extra work to do > > on their next OS upgrade and that'll be a characteristic of PostgreSQL > > going forward, once the versioning-for-default-provider patch goes > > in.) Any other opinions? > > Matching an incorrect collation version on an index which physically > uses something else does not strike me as a good idea to me because > you may hide corruptions, and you would actually lose the reason why > the corruption happened (did the version bump up from an incorrect > one? Or what?). Could it be possible to mark any existing indexes > with an unknown version or something like that? This way, we could > just let the user decide what needs to be reindexed or not, and we > need to offer an option to update the collation version from unknown > to the latest one available. Fair point. So we have three proposals: 1. Assume that pre-13 indexes that depend on collations are potentially corrupted and complain until they are reindexed. This could be done by having pg_upgrade run ALTER INDEX ... DEPENDS ON COLLATION "fr_FR" VERSION '' (empty string, or some other default value that we don't think is going to coincide with a real version). 2. Assume that pre-13 indexes are not corrupted. In the target 13 database, the index will be created in the catalogs with the provider's current version. 3. We don't know if pre-13 indexes are corrupted or not, and we'll record that with a special value just as in proposal #1, except that we could show a different hint for that special version value. It would tell you can you can either REINDEX, or run ALTER INDEX ... DEPENDS ON COLLATION "fr_FR" VERSION '34.0' if you believe the index to have been created with the current collation version on an older release of PostgreSQL that didn't track versions.
On Fri, 2019-11-08 at 15:04 +1300, Thomas Munro wrote: > So we have three proposals: > > 1. Assume that pre-13 indexes that depend on collations are > potentially corrupted and complain until they are reindexed. This > could be done by having pg_upgrade run ALTER INDEX ... DEPENDS ON > COLLATION "fr_FR" VERSION '' (empty string, or some other default > value that we don't think is going to coincide with a real version). > 2. Assume that pre-13 indexes are not corrupted. In the target 13 > database, the index will be created in the catalogs with the > provider's current version. > 3. We don't know if pre-13 indexes are corrupted or not, and we'll > record that with a special value just as in proposal #1, except that > we could show a different hint for that special version value. It > would tell you can you can either REINDEX, or run ALTER INDEX ... > DEPENDS ON COLLATION "fr_FR" VERSION '34.0' if you believe the index > to have been created with the current collation version on an older > release of PostgreSQL that didn't track versions. I think #1 is bad because it would frighten all users, even those who didn't upgrade their libc at all, only PostgreSQL. I don't think that shouting "wolf" for no real reason will improve trust in PostgreSQL. #2 is bad because it may hide pre-existing index corruption. #3 is the best proposal, but there is still the need to run ALTER INDEX on all affected indexes to keep PostgreSQL from nagging. Perhaps the situation could be improved with a pg_upgrade option --i-know-my-indexes-are-fine that causes a result like #2. Together with a bold note in the release notes, this may relieve the pain. Yours, Laurenz Albe
Re: Laurenz Albe 2019-11-08 <3c3b9ff84d21acf3188558928249d04db84ea2e9.camel@cybertec.at> > #3 is the best proposal, but there is still the need to run > ALTER INDEX on all affected indexes to keep PostgreSQL from nagging. > Perhaps the situation could be improved with a pg_upgrade option > --i-know-my-indexes-are-fine that causes a result like #2. > Together with a bold note in the release notes, this may relieve > the pain. Ack. We should also try to make the actual commands more accessible. Instead of having the user specify a version number we could as well determine from the current state of the system as in ALTER INDEX ... DEPENDS ON 'version-number-I-never-heard-of-before' could it just be ALTER INDEX ... COLLATION IS CURRENT or, given the general action to take is reindexing, how about a no-op reindex? REINDEX INDEX ... METADATA ONLY That might look less scary to the average end user. Do we even think people upgrade PG and the OS at the same time? pg_upgrade might frequently actually be invoked on an otherwise unchanged system, so we could even make "collations are fine" the default for pg_upgrade. And maybe have a switch like pg_upgrade --os-upgrade that reverses this. Christoph
On Fri, Nov 8, 2019 at 2:24 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Thu, Nov 7, 2019 at 10:20 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > Attached 4th patch handles default collation. I went with an > > ignore_systempin flag in recordMultipleDependencies. > > Thanks for working on this! I haven't looked closely or tested yet, > but this seems reasonable. Obviously it assumes that the default > provider is really "libc" in disguise for now, but Peter's other patch > will extend that to cover ICU later. Yes, that should require minimal changes here. > > > > > * Andres mentioned off-list that pg_depend rows might get blown away > > > > and recreated in some DDL circumstances. We need to look into that. > > > > I tried various flavour of DDL but I couldn't wipe out the pg_depend > > rows without having an index rebuild triggered (like changing the > > underlying column datatype). Do you have any scenario where the index > > rebuild wouldn't be triggered? > > Ah, OK, if we only do that when the old index contents will also be > destroyed, that's great news. > > > > > * Another is that pg_upgrade won't preserve pg_depend rows, so you'd > > > > need some catalog manipulation (direct or via new DDL) to fix that. > > > > Attached 5th patch add a new "ALTER INDEX idx_name DEPENDS ON > > COLLATION coll_oid VERSION coll_version_text" that can only be > > executed in binary upgrade mode, and teach pg_dump to generate such > > commands (including for indexes created for constraints). > > It's nice that you were able to make up a reasonable grammar out of > existing keywords. I wonder if we should make this user accessible... > it could be useful for expert users. If so, maybe it should use > collation names, not OIDs? I thought about it, but I'm wondering if it's a good idea to expose this to users. The command is not really POLA compliant, as what it actually mean is "update the recorded version for all existing pg_depend rows, if any, for this index and collation", while one could assume that it'll add a new pg_depend row if none exist. Ideally, users would only need to use command that says "trust me this index (or collation version) is actually compatible with this collation's current version" or similar, but not some user provided string. > > I didn't do anything for the spurious warning when running a reindex, > > and kept original approach of pg_depend catalog. > > I see three options: > > 1. Change all or some of index_open(), relation_open(), > RelationIdGetRelation(), RelationBuildDesc() and > RelationInitIndexAccessInfo() to take some kind of flag so we can say > NO_COLLATION_VERSION_CHECK_PLEASE, and then have ReindexIndex() pass > that flag down when opening it for the purpose of rebuilding it. > 2. Use a global state to suppress these warnings while opening that > index. Perhaps ReindexIndex() would call RelCacheWarnings(false) > before index_open(), and use PG_FINALLY to make sure it restores > warnings with RelCacheWarnings(true). (This is a less-code-churn > bad-programming-style version of #1.) > 3. Move the place that we run the collation version check. Instead > of doing it in RelationInitIndexAccessInfo() so that it runs when the > relation cache first loads the index, put it into a new routine > RelationCheckValidity() and call that from ... I don't know, some > other place that runs whenever we access indexes but not when we > rebuild them. > > 3's probably a better idea, if you can find a reasonable place to call > it from. I'm thinking some time around the time the executor acquires > locks, but using a flag in the relcache entry to make sure it doesn't > run the check again if there were no warnings last time (so one > successful version check turns the extra work off for the rest of this > relcache entry's lifetime). I think it'd be a feature, not a bug, if > it gave you the warning every single time you executed a query using > an index that has a mismatch... but a practical alternative would be > to check only once per index and that probably makes more sense. OTOH, 2 is more generic, and could maybe be a better way with Peter's idea of new catalog that would also fit other use cases?
On Fri, Nov 8, 2019 at 10:20 AM Christoph Berg <myon@debian.org> wrote: > > Re: Laurenz Albe 2019-11-08 <3c3b9ff84d21acf3188558928249d04db84ea2e9.camel@cybertec.at> > > #3 is the best proposal, but there is still the need to run > > ALTER INDEX on all affected indexes to keep PostgreSQL from nagging. > > Perhaps the situation could be improved with a pg_upgrade option > > --i-know-my-indexes-are-fine that causes a result like #2. > > Together with a bold note in the release notes, this may relieve > > the pain. > > Ack. +1 > We should also try to make the actual commands more accessible. > Instead of having the user specify a version number we could as well > determine from the current state of the system as in > ALTER INDEX ... DEPENDS ON 'version-number-I-never-heard-of-before' This one is needed for pg_upgrade on later version, but I agree that it shouldn't be exposed to users. > could it just be > ALTER INDEX ... COLLATION IS CURRENT this sounds like a better idea, though this should probably work at the collation lever rather than index level. I think that we should offer users this but with multiple filter, like: - mark all indexes' collation version dependencies as current version - mark all indexes' dependencies on a specific collation and collation version as current version - mark all indexes' dependencies on a specific collation (any version) as current version > or, given the general action to take is reindexing, how about a no-op reindex? > REINDEX INDEX ... METADATA ONLY > > That might look less scary to the average end user. This should be scary, as any misuse can lead to hidden corruption. If a user isn't sure of what to do, a plain REINDEX is the safe (and painful) way to go. > Do we even think people upgrade PG and the OS at the same time? > pg_upgrade might frequently actually be invoked on an otherwise > unchanged system, so we could even make "collations are fine" the > default for pg_upgrade. And maybe have a switch like pg_upgrade --os-upgrade > that reverses this. +1
Some more thoughts: 1. If you create an index on an expression that includes a COLLATE or a partial index that has one in the WHERE clause, you get bogus warnings: postgres=# create table t (v text); CREATE TABLE postgres=# create index on t(v) where v > 'hello' collate "en_NZ"; WARNING: index "t_v_idx3" depends on collation "en_NZ" version "", but the current version is "2.28" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. CREATE INDEX postgres=# create index on t((case when v < 'x' collate "en_NZ" then 'foo' else 'bar' end)); WARNING: index "t_case_idx" depends on collation "en_NZ" version "", but the current version is "2.28" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. CREATE INDEX That's because the 0003 patch only calls recordDependencyOnVersion() for simple attribute references. When recordDependencyOnSingleRelExpr() is called by index_create() to analyse ii_Expressions and ii_Predicate, it's going to have to be smart enough to detect collation references and record the versions. There is also some more code that ignores pinned collations hiding in there. This leads to the difficult question of how you recognise a real dependency on a collation's version in an expression. I have some vague ideas but haven't seriously looked into it yet. (The same question comes up for check constraint -> collation dependencies.) 2. If you create a composite type with a text attribute (with or without an explicit collation), and then create an index on a column of that type, we don't record the dependency. postgres=# create type my_type as (x text collate "en_NZ"); CREATE TYPE postgres=# create table t (v my_type); CREATE TABLE postgres=# create index on t(v); CREATE INDEX postgres=# select * from pg_depend where refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- (0 rows) I think create_index() will need to perform recursive analysis on composite types to look for text attributes, when they appear as simple attributes, and then add direct dependencies index -> collation to capture the versions. Then we might need to do the same for composite types hiding inside ii_Expressions and ii_Predicate (once we figure out what that really means). 3. Test t/002_pg_dump.pl in src/bin/pg_upgrade fails. 4. In the warning message we should show get_collation_name() instead of the OID.
On Sun, Nov 10, 2019 at 10:08 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > Some more thoughts: > > 1. If you create an index on an expression that includes a COLLATE or > a partial index that has one in the WHERE clause, you get bogus > warnings: > > postgres=# create table t (v text); > CREATE TABLE > postgres=# create index on t(v) where v > 'hello' collate "en_NZ"; > WARNING: index "t_v_idx3" depends on collation "en_NZ" version "", > but the current version is "2.28" > DETAIL: The index may be corrupted due to changes in sort order. > HINT: REINDEX to avoid the risk of corruption. > CREATE INDEX > > postgres=# create index on t((case when v < 'x' collate "en_NZ" then > 'foo' else 'bar' end)); > WARNING: index "t_case_idx" depends on collation "en_NZ" version "", > but the current version is "2.28" > DETAIL: The index may be corrupted due to changes in sort order. > HINT: REINDEX to avoid the risk of corruption. > CREATE INDEX > > That's because the 0003 patch only calls recordDependencyOnVersion() > for simple attribute references. When > recordDependencyOnSingleRelExpr() is called by index_create() to > analyse ii_Expressions and ii_Predicate, it's going to have to be > smart enough to detect collation references and record the versions. > There is also some more code that ignores pinned collations hiding in > there. > > This leads to the difficult question of how you recognise a real > dependency on a collation's version in an expression. I have some > vague ideas but haven't seriously looked into it yet. (The same > question comes up for check constraint -> collation dependencies.) Oh good point. A simple and exhaustive way to deal with that would be to teach recordMultipleDependencies() to override isObjectPinned() and retrieve the collation version if the referenced object is a collation and it's neither C or POSIX collation. It means that we could also remove the extra "version" argument and get rid of recordDependencyOnVersion to simply call recordMultipleDependencies in create_index for direct column references having a collation. Would it be ok to add this kind of knowledge in recordMultipleDependencies() or is it too hacky? > 2. If you create a composite type with a text attribute (with or > without an explicit collation), and then create an index on a column > of that type, we don't record the dependency. > > postgres=# create type my_type as (x text collate "en_NZ"); > CREATE TYPE > postgres=# create table t (v my_type); > CREATE TABLE > postgres=# create index on t(v); > CREATE INDEX > postgres=# select * from pg_depend where refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > (0 rows) > > I think create_index() will need to perform recursive analysis on > composite types to look for text attributes, when they appear as > simple attributes, and then add direct dependencies index -> collation > to capture the versions. Then we might need to do the same for > composite types hiding inside ii_Expressions and ii_Predicate (once we > figure out what that really means). Isn't that actually a bug? For instance such an index will have a 0 indcollation in pg_index, and according to pg_index documentation: " this contains the OID of the collation to use for the index, or zero if the column is not of a collatable data type." You can't use a COLLATE expression on such data type, but it still has a collation used. > 3. Test t/002_pg_dump.pl in src/bin/pg_upgrade fails. Apparently neither "make check" nor "make world" run this test :( This was broken due collversion support in pg_dump, I have fixed it locally. > 4. In the warning message we should show get_collation_name() instead > of the OID. +1, I also fixed it locally.
On Wed, Nov 13, 2019 at 3:27 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Sun, Nov 10, 2019 at 10:08 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > That's because the 0003 patch only calls recordDependencyOnVersion() > > for simple attribute references. When > > recordDependencyOnSingleRelExpr() is called by index_create() to > > analyse ii_Expressions and ii_Predicate, it's going to have to be > > smart enough to detect collation references and record the versions. > > There is also some more code that ignores pinned collations hiding in > > there. > > > > This leads to the difficult question of how you recognise a real > > dependency on a collation's version in an expression. I have some > > vague ideas but haven't seriously looked into it yet. (The same > > question comes up for check constraint -> collation dependencies.) > > Oh good point. A simple and exhaustive way to deal with that would be > to teach recordMultipleDependencies() to override isObjectPinned() and > retrieve the collation version if the referenced object is a collation > and it's neither C or POSIX collation. It means that we could also > remove the extra "version" argument and get rid of > recordDependencyOnVersion to simply call recordMultipleDependencies in > create_index for direct column references having a collation. > > Would it be ok to add this kind of knowledge in > recordMultipleDependencies() or is it too hacky? That doesn't seem like the right place; that's a raw data insertion function, though... I guess it does already have enough brains to skip pinned objects. Hmm. > > I think create_index() will need to perform recursive analysis on > > composite types to look for text attributes, when they appear as > > simple attributes, and then add direct dependencies index -> collation > > to capture the versions. Then we might need to do the same for > > composite types hiding inside ii_Expressions and ii_Predicate (once we > > figure out what that really means). > > Isn't that actually a bug? For instance such an index will have a 0 > indcollation in pg_index, and according to pg_index documentation: > > " this contains the OID of the collation to use for the index, or zero > if the column is not of a collatable data type." > > You can't use a COLLATE expression on such data type, but it still has > a collation used. I don't think it's a bug. The information is available, but you have to follow the graph to get it. Considering that the composite type could be something like CREATE TYPE my_type AS (fr_name text COLLATE "fr_CA", en_name text COLLATE "en_CA"), there is no single collation you could put into pg_index.indcollation anyway. As for pg_depend, it's currently enough for the index to depend on the type, and the type to depend on the collation, because the purpose of dependencies is to control dropping and dumping order, but for our new purpose we also need to create direct dependencies index -> "fr_CA", index -> "en_CA" so we can record the current versions. > > 3. Test t/002_pg_dump.pl in src/bin/pg_upgrade fails. > > Apparently neither "make check" nor "make world" run this test :( > This was broken due collversion support in pg_dump, I have fixed it > locally. make check-world
On Tue, Nov 12, 2019 at 10:16 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Wed, Nov 13, 2019 at 3:27 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Sun, Nov 10, 2019 at 10:08 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > That's because the 0003 patch only calls recordDependencyOnVersion() > > > for simple attribute references. When > > > recordDependencyOnSingleRelExpr() is called by index_create() to > > > analyse ii_Expressions and ii_Predicate, it's going to have to be > > > smart enough to detect collation references and record the versions. > > > There is also some more code that ignores pinned collations hiding in > > > there. [...] Indeed. Now, using a composite type in an expression index, I can see that eg. CREATE TYPE mytype AS (fr text COLLATE "fr-x-icu", en text COLLATE "en-x-icu"); CREATE TABLE test1(id integer, myval mytype); CREATE INDEX ON sometable (somecol) WHERE (mytype).fr_name = 'meh' does create a dependency on fr-x-icu collation, because collations are checked for FieldSelect nodes (which indeed ignores default collation), but eg. CREATE INDEX idx2 ON test1(id) WHERE myval = ('foo', 'bar'); won't, so I confirm that recordDependencyOnSingleRelExpr() isn't bullet proof either for finding collation dependencies. > > > I think create_index() will need to perform recursive analysis on > > > composite types to look for text attributes, when they appear as > > > simple attributes, and then add direct dependencies index -> collation > > > to capture the versions. Then we might need to do the same for > > > composite types hiding inside ii_Expressions and ii_Predicate (once we > > > figure out what that really means). I did write some code that can extract all collations that are used by a datatype, which seems to work as intended over many combinations of composite / array / domain types used in index simple attributes. I'm not sure if I should change find_expr_references_walker (called by recordDependencyOnExpr) to also track those new dependencies in ii_Expression and ii_Predicate, as it'll also add unneeded dependencies for other callers. And if I should add version detection there too or have recordMultipleDependencies() automatically take care of this. > > A simple and exhaustive way to deal with that would be > > to teach recordMultipleDependencies() to override isObjectPinned() and > > retrieve the collation version if the referenced object is a collation > > and it's neither C or POSIX collation > > > That doesn't seem like the right place; that's a raw data insertion > function, though... I guess it does already have enough brains to skip > pinned objects. Hmm. Another point is that unless we also do an additional check to see what relkind is referencing the collation, it'll record a version string for types and other objects. > > Isn't that actually a bug? For instance such an index will have a 0 > > indcollation in pg_index, and according to pg_index documentation: > > > > " this contains the OID of the collation to use for the index, or zero > > if the column is not of a collatable data type." > > > > You can't use a COLLATE expression on such data type, but it still has > > a collation used. > > I don't think it's a bug. The information is available, but you have > to follow the graph to get it. Considering that the composite type > could be something like CREATE TYPE my_type AS (fr_name text COLLATE > "fr_CA", en_name text COLLATE "en_CA"), there is no single collation > you could put into pg_index.indcollation anyway. As for pg_depend, > it's currently enough for the index to depend on the type, and the > type to depend on the collation, because the purpose of dependencies > is to control dropping and dumping order, but for our new purpose we > also need to create direct dependencies index -> "fr_CA", index -> > "en_CA" so we can record the current versions. Oh right, I didn't think about that. > > > 3. Test t/002_pg_dump.pl in src/bin/pg_upgrade fails. > > > > Apparently neither "make check" nor "make world" run this test :( > > This was broken due collversion support in pg_dump, I have fixed it > > locally. > > make check-world Thanks!
On Fri, Nov 8, 2019 at 5:40 PM Laurenz Albe <laurenz.albe@cybertec.at> wrote: > On Fri, 2019-11-08 at 15:04 +1300, Thomas Munro wrote: > > 3. We don't know if pre-13 indexes are corrupted or not, and we'll > > record that with a special value just as in proposal #1, except that > > we could show a different hint for that special version value. It > > would tell you can you can either REINDEX, or run ALTER INDEX ... > > DEPENDS ON COLLATION "fr_FR" VERSION '34.0' if you believe the index > > to have been created with the current collation version on an older > > release of PostgreSQL that didn't track versions. > #3 is the best proposal, but there is still the need to run > ALTER INDEX on all affected indexes to keep PostgreSQL from nagging. > Perhaps the situation could be improved with a pg_upgrade option > --i-know-my-indexes-are-fine that causes a result like #2. > Together with a bold note in the release notes, this may relieve > the pain. I suppose another reason to use such a switch would be if there is a change in the versioning scheme; for example, as of today in master we are using the glibc version, but a future glibc release might offer an interface to query the CLDR version it's using, and then a future release of PostgreSQL might get support for that, so the strings would change between major version of PostgreSQL but you might want to be able to tell pg_upgrade that your indexes are good.
On Tue, Nov 26, 2019 at 3:44 PM Thomas Munro <thomas.munro@gmail.com> wrote: > I suppose another reason to use such a switch would be if there is a > change in the versioning scheme; for example, as of today in master we > are using the glibc version, but a future glibc release might offer an > interface to query the CLDR version it's using, and then a future > release of PostgreSQL might get support for that, so the strings would > change between major version of PostgreSQL but you might want to be > able to tell pg_upgrade that your indexes are good. Yeah, I like #3 too. If we're going to the trouble to build all of this mechanism, it seems worth it to build the additional machinery to be precise about the difference between "looks like a problem" and "we don't know". -- Robert Haas EnterpriseDB: http://www.enterprisedb.com The Enterprise PostgreSQL Company
On Wed, Nov 27, 2019 at 04:09:57PM -0500, Robert Haas wrote: > Yeah, I like #3 too. If we're going to the trouble to build all of > this mechanism, it seems worth it to build the additional machinery to > be precise about the difference between "looks like a problem" and "we > don't know". Indeed, #3 sounds like a sensible way of doing things. The two others may cause random problems which are harder to actually detect and act on as we should avoid as much as possible a forced system-wide REINDEX after an upgrade to a post-13 PG. -- Michael
Attachment
On Thu, Nov 28, 2019 at 5:50 AM Michael Paquier <michael@paquier.xyz> wrote: > > On Wed, Nov 27, 2019 at 04:09:57PM -0500, Robert Haas wrote: > > Yeah, I like #3 too. If we're going to the trouble to build all of > > this mechanism, it seems worth it to build the additional machinery to > > be precise about the difference between "looks like a problem" and "we > > don't know". > > Indeed, #3 sounds like a sensible way of doing things. The two others > may cause random problems which are harder to actually detect and act > on as we should avoid as much as possible a forced system-wide REINDEX > after an upgrade to a post-13 PG. Thanks everyone for the feedback! Since there seems to be an agreement on #3, here's a proposal. What we could do is storing an empty string if the compatibility is unknown, and detect it in index_check_collation_version() to report a slightly different message. I'm assuming that not knowing the compatibility would be system-wide rather than per collation, so we could use an sql query like this: ALTER INDEX idx_name DEPENDS ON COLLATION UNKNOWN VERSION If adding (un)reserved keywords is not an issue, we could also instead use something along ALTER INDEX idx_name DEPENDS ON ALL COLLATIONS and/or ALL VERSIONS UNKNOWN, or switch to: ALTER INDEX idx_name ALTER [ COLLATION coll_name | ALL COLLATIONS ] DEPENDS ON [ UNKOWN VERSION | VERSION 'version_string' ] Obviously, specific versions would require a specific collation, and at least UNKNOWN VERSION would only be allowed in binary upgrade mode, and not documented. I have also some other ideas for additional DDL to let users deal with catalog update after a compatible collation library upgrade, but let's deal with that later. Then for pg_upgrade, we can add a --collations-are-binary-compatible switch or similar: If upgrading from pre-v13 - without the switch, we'd generate the VERSION UNKNOWN for all indexes during pg_dump in upgrade_mode - with the switch, do nothing as all indexes would already be pointing to the currently installed version If upgrading from post v13, the switch shouldn't be useful as versions will be restored, and if there was a collation library upgrade it should be handled manually, same as if such an upgrade is done without pg_upgrade-ing the cluster. I'd personally disallow it to avoid users to shoot themselves in the foot. Does this sounds sensible?
On Thu, Nov 28, 2019 at 8:08 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > What we could do is storing an empty string if the compatibility is > unknown, and detect it in index_check_collation_version() to report a > slightly different message. I'm assuming that not knowing the > compatibility would be system-wide rather than per collation, so we > could use an sql query like this: > > ALTER INDEX idx_name DEPENDS ON COLLATION UNKNOWN VERSION > > If adding (un)reserved keywords is not an issue, we could also instead > use something along ALTER INDEX idx_name DEPENDS ON ALL COLLATIONS > and/or ALL VERSIONS UNKNOWN, or switch to: Adding unreserved keywords isn't a huge issue, but it's nicer to avoid it if we can. Bloating the parser tables isn't that expensive, but neither is it free. Maybe spell it like this: ALTER INDEX idx_name DEPENDS ON COLLATION blah VERSION blah; -- I care about collations and I know which one and which version. ALTER INDEX idx_name DEPENDS ON SOME COLLATION; -- I care about collations but I don't know which one. ALTER INDEX idx_name DEPENDS ON NO COLLATION; -- I don't care about collations at all. -- Not sure if we need this. -- Robert Haas EnterpriseDB: http://www.enterprisedb.com The Enterprise PostgreSQL Company
On Mon, Dec 2, 2019 at 2:00 PM Robert Haas <robertmhaas@gmail.com> wrote: > > ALTER INDEX idx_name DEPENDS ON COLLATION blah VERSION blah; > -- I care about collations and I know which one and which version. > > ALTER INDEX idx_name DEPENDS ON SOME COLLATION; > -- I care about collations but I don't know which one. This seems a little bit ambiguous. I wouldn't expect this command to trash all recorded versions given how it's spelled. > ALTER INDEX idx_name DEPENDS ON NO COLLATION; > -- I don't care about collations at all. > -- Not sure if we need this. This should be an alias for "trust me all collation are ok"? It's certainly useful for collation library upgrade that don't break indexes, but I'd prefer to spell it something like "CURRENT VERSION". I'll also work on that, but preferably in a later patch as there'll be additional need (process all indexes with a given collation or collation version for instance). While looking at the list of keywords again, I think that "ANY" is a better candidate: ALTER INDEX idx_name DEPENDS ON [ ANY COLLATION | COLLATION blah ] [ UNKNOWN VERSION | VERSION blah ] or ALTER INDEX idx_name ALTER [ ANY COLLATION | COLLATION blah ] DEPENDS ON [ UNKNOWN VERSION | VERSION blah ] I like the 2nd one as it's more obvious that the command will only modify existing dependencies.
On Tue, Dec 3, 2019 at 9:38 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Dec 2, 2019 at 2:00 PM Robert Haas <robertmhaas@gmail.com> wrote: > > > > ALTER INDEX idx_name DEPENDS ON COLLATION blah VERSION blah; > > -- I care about collations and I know which one and which version. > > > > ALTER INDEX idx_name DEPENDS ON SOME COLLATION; > > -- I care about collations but I don't know which one. > > This seems a little bit ambiguous. I wouldn't expect this command to > trash all recorded versions given how it's spelled. > > > ALTER INDEX idx_name DEPENDS ON NO COLLATION; > > -- I don't care about collations at all. > > -- Not sure if we need this. > > This should be an alias for "trust me all collation are ok"? It's > certainly useful for collation library upgrade that don't break > indexes, but I'd prefer to spell it something like "CURRENT VERSION". > I'll also work on that, but preferably in a later patch as there'll be > additional need (process all indexes with a given collation or > collation version for instance). > > > While looking at the list of keywords again, I think that "ANY" is a > better candidate: > > ALTER INDEX idx_name DEPENDS ON [ ANY COLLATION | COLLATION blah ] [ > UNKNOWN VERSION | VERSION blah ] > or > ALTER INDEX idx_name ALTER [ ANY COLLATION | COLLATION blah ] DEPENDS > ON [ UNKNOWN VERSION | VERSION blah ] > > I like the 2nd one as it's more obvious that the command will only > modify existing dependencies. I'm attaching v4 versions, rebased and with the following modifications: - I implemented the ALTER INDEX name DEPENDS ON [ ANY COLLATION | COLLATION name ] [ UNKNOWN VERSION | VERSION blah ] syntax. Both are still only allowed in binary upgrade mode, so I didn't add documentation for those, or psql tab completion. - Those commands now requires the collation name rather than oid. This will be helpful if we want to make the commands above available for users, or some similar commands like marking an index depending on the current version for some specific collation - added the type regcollation to ease pg_dump work - unknown collation version is handled with a recorded empty string, and lead to a slightly different message - new "--collation-binary-compatible" documented option for pg_upgrade, leading to using a new and undocumented "--unknown-collations-binary-compatible" option for pg_dump. The new option in pg_dump only works in binary upgrade mode, and only prevents outputting the ALTER INDEX ... UNKNOWN VERSION commands. Known existing versions are always preserved. - dependencies for composite and other exotic types for regular index columns should now be correctly handled - dependencies for index expression and predicate will now track default collation, with additional support for composite types - to do so, I had to handle the collation version retrieval in recordMultipleDependencies() using a new "track_version" bool parameter, passed around in some functions. This seemed the best way to do so, as this is the common point in recordDependencyOnSingleRelExpr(), index_create() and others. The spurious messages when issuing a REINDEX is still not fixed. I'm also attaching an sql file that I used to check all cases of non-trivial collation dependencies I could think of.
Attachment
On Fri, Nov 8, 2019 at 2:24 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Thu, Nov 7, 2019 at 10:20 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > I didn't do anything for the spurious warning when running a reindex, > > and kept original approach of pg_depend catalog. > > I see three options: > > 1. Change all or some of index_open(), relation_open(), > RelationIdGetRelation(), RelationBuildDesc() and > RelationInitIndexAccessInfo() to take some kind of flag so we can say > NO_COLLATION_VERSION_CHECK_PLEASE, and then have ReindexIndex() pass > that flag down when opening it for the purpose of rebuilding it. > 2. Use a global state to suppress these warnings while opening that > index. Perhaps ReindexIndex() would call RelCacheWarnings(false) > before index_open(), and use PG_FINALLY to make sure it restores > warnings with RelCacheWarnings(true). (This is a less-code-churn > bad-programming-style version of #1.) > 3. Move the place that we run the collation version check. Instead > of doing it in RelationInitIndexAccessInfo() so that it runs when the > relation cache first loads the index, put it into a new routine > RelationCheckValidity() and call that from ... I don't know, some > other place that runs whenever we access indexes but not when we > rebuild them. > > 3's probably a better idea, if you can find a reasonable place to call > it from. I'm thinking some time around the time the executor acquires > locks, but using a flag in the relcache entry to make sure it doesn't > run the check again if there were no warnings last time (so one > successful version check turns the extra work off for the rest of this > relcache entry's lifetime). I think it'd be a feature, not a bug, if > it gave you the warning every single time you executed a query using > an index that has a mismatch... but a practical alternative would be > to check only once per index and that probably makes more sense. I tried to dig into approach #3. I think that trying to perform this check when the executor acquires locks won't work well with at least with partitioned table. I instead tried to handle that in get_relation_info(), adding a flag in the relcache to emit each warning only once per backend lifetime, and this seems to work quite well. I think that on top of that, we should make sure that non-full vacuum and analyze also emit such warnings, so that autovacuum can spam the logs too.
On Fri, Dec 6, 2019 at 10:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > I'm attaching v4 versions, rebased and with the following modifications: > > - I implemented the ALTER INDEX name DEPENDS ON [ ANY COLLATION | > COLLATION name ] [ UNKNOWN VERSION | VERSION blah ] syntax. Both are > still only allowed in binary upgrade mode, so I didn't add > documentation for those, or psql tab completion. > - Those commands now requires the collation name rather than oid. > This will be helpful if we want to make the commands above available > for users, or some similar commands like marking an index depending on > the current version for some specific collation > - added the type regcollation to ease pg_dump work > - unknown collation version is handled with a recorded empty string, > and lead to a slightly different message > - new "--collation-binary-compatible" documented option for > pg_upgrade, leading to using a new and undocumented > "--unknown-collations-binary-compatible" option for pg_dump. The new > option in pg_dump only works in binary upgrade mode, and only prevents > outputting the ALTER INDEX ... UNKNOWN VERSION commands. Known > existing versions are always preserved. > - dependencies for composite and other exotic types for regular index > columns should now be correctly handled > - dependencies for index expression and predicate will now track > default collation, with additional support for composite types > - to do so, I had to handle the collation version retrieval in > recordMultipleDependencies() using a new "track_version" bool > parameter, passed around in some functions. This seemed the best way > to do so, as this is the common point in > recordDependencyOnSingleRelExpr(), index_create() and others. > > The spurious messages when issuing a REINDEX is still not fixed. I'm > also attaching an sql file that I used to check all cases of > non-trivial collation dependencies I could think of. Hearing no objection in [1], attached v5 with following changes: - fix the spurious warnings by doing the version check in get_relation_info and vacuum_open_relation, and add a flag in RelationData to mark the check as already being done - change the IsCatalogRelation() check to IsSystemRelation() to also ignore toast indexes, as those can also be safely ignored too - add a new ALTER INDEX idxname DEPENDS ON COLLATION collname CURRENT VERSION to let users remove the warnings for safe library upgrade. Documentation and tab completion added If I'm not mistaken, all issues I was aware of are now fixed. [1] https://www.postgresql.org/message-id/CAOBaU_YbCQ6=8_VOdZY0v-cXX6+BkgScpNRmRjJzESdzv1SZMA@mail.gmail.com
Attachment
- 0003-Track-collation-versions-for-indexes-v5.patch
- 0001-Remove-pg_collation.collversion-v5.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v5.patch
- 0002-Add-pg_depend.refobjversion-v5.patch
- 0004-Implement-type-regcollation-v5.patch
- 0006-Add-a-new-ALTER-INDEX-name-DEPENDS-ON-COLLATION-name-v5.patch
On Thu, Dec 12, 2019 at 2:45 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > Hearing no objection in [1], attached v5 with following changes: > > - fix the spurious warnings by doing the version check in > get_relation_info and vacuum_open_relation, and add a flag in > RelationData to mark the check as already being done > - change the IsCatalogRelation() check to IsSystemRelation() to also > ignore toast indexes, as those can also be safely ignored too > - add a new ALTER INDEX idxname DEPENDS ON COLLATION collname CURRENT > VERSION to let users remove the warnings for safe library upgrade. > Documentation and tab completion added > > If I'm not mistaken, all issues I was aware of are now fixed. Thanks! This is some great progress and I'm feeling positive about getting this into PostgreSQL 13. I haven't (re)reviewed the code yet, but I played with it a bit and have some more feedback. There are some missing semi-colons on the ALTER INDEX statements in pg_dump.c that make the pg_upgrade test fail (at least, if LC_ALL is set). We create duplicate pg_depend records: postgres=# create table t (x text); CREATE TABLE postgres=# create index on t(x) where x > 'hello'; CREATE INDEX postgres=# select * from pg_depend where objid = 't_x_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- 1259 | 16424 | 0 | 3456 | 100 | 0 | 0:34.0 | n 1259 | 16424 | 0 | 3456 | 100 | 0 | 0:34.0 | n (2 rows) I wondered if that was harmless, but for one thing it causes duplicate warnings: postgres=# update pg_depend set refobjversion = 'BANANA' where refobjversion = '0:34.0'; UPDATE 2 [new session] postgres=# select count(*) from t; WARNING: index "t_x_idx" depends on collation "default" version "BANANA", but the current version is "0:34.0" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. WARNING: index "t_x_idx" depends on collation "default" version "BANANA", but the current version is "0:34.0" DETAIL: The index may be corrupted due to changes in sort order. HINT: REINDEX to avoid the risk of corruption. Here's another way to get a duplicate, and in this example you also get an unnecessary dependency on 100 "default" for this index: postgres=# create index on t(x collate "fr_FR") where x > 'helicopter' collate "fr_FR"; CREATE INDEX postgres=# select * from pg_depend where objid = 't_x_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- 1259 | 16460 | 0 | 3456 | 12603 | 0 | 0:34.0 | n 1259 | 16460 | 0 | 3456 | 12603 | 0 | 0:34.0 | n 1259 | 16460 | 0 | 3456 | 100 | 0 | 0:34.0 | n (3 rows) Or... maybe 100 should be there, by simple analysis of the x in the WHERE clause, but it's the same if you write x collate "fr_FR" > 'helicopter' collate "fr_FR", and in that case there are no expressions of collation "default" anywhere. The indirection through composite types works nicely: postgres=# create type foo_t as (en text collate "en_CA", fr text collate "fr_CA"); CREATE TYPE postgres=# create table t (foo foo_t); CREATE TABLE postgres=# create index on t(foo); CREATE INDEX postgres=# select * from pg_depend where objid = 't_foo_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- 1259 | 16444 | 0 | 3456 | 12554 | 0 | 0:34.0 | n 1259 | 16444 | 0 | 3456 | 12597 | 0 | 0:34.0 | n (2 rows) ... but again it shows the extra and technically unnecessary dependencies (only 12603 "fr_FR" is really needed): postgres=# create index on t(((foo).fr collate "fr_FR")); CREATE INDEX postgres=# select * from pg_depend where objid = 't_fr_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- 1259 | 16445 | 0 | 3456 | 12603 | 0 | 0:34.0 | n 1259 | 16445 | 0 | 3456 | 12597 | 0 | 0:34.0 | n 1259 | 16445 | 0 | 3456 | 12554 | 0 | 0:34.0 | n (3 rows) I check that nested types are examined recursively, as appropriate. I also tested domains, arrays, arrays of domains, expressions extracting an element from an array of a domain with an explicit collation, and the only problem I could find was more ways to get duplicates. Hmm... what else is there that can contain a collatable type...? Ranges! postgres=# create type myrange as range (subtype = text); CREATE TYPE postgres=# drop table t; DROP TABLE postgres=# create table t (x myrange); CREATE TABLE postgres=# create index on t(x); CREATE INDEX postgres=# select * from pg_depend where objid = 't_x_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- (0 rows) ... or perhaps, more realistically, a GIST index might actually be useful for range queries, and we're not capturing the dependency: postgres=# create index t_x_idx on t using gist (x); CREATE INDEX postgres=# select * from pg_depend where objid = 't_x_idx'::regclass and refobjversion != ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | refobjversion | deptype ---------+-------+----------+------------+----------+-------------+---------------+--------- (0 rows) The new syntax "ALTER INDEX i_name DEPENDS ON ANY COLLATION UNKNOWN VERSION" doesn't sound good to me, it's not "ANY" collation, it's a specific set of collations that we aren't listing. "ALTER INDEX i_name DEPENDS ON COLLATION * VERSION UNKNOWN", hrmph, no that's terrible... I'm not sure what would be better. I'm not sure if I like the idea of VACUUM reporting warnings or not. Hmm. To state more explicitly what's happening here, we're searching the expression trees for subexpresions that have a collation as part of their static type. We don't know which functions or operators are actually affected by the collation, though. For example, if an expression says "x IS NOT NULL" and x happens to be a subexpression of a type with a particular collation, we don't now that this expression's value can't possibly be affected by the collation version changing. So, the system will nag you to rebuild an index just because you mentioned it, even though the index can't be corrupted. To do better than that, I suppose we'd need declarations in the catalog to say which functions/operators are collation sensitive. Then, as a special case, there is the collation of the actual indexed value, because that will implicitly be used as input to the btree ops that would be collation sensitive. That's just a thought experiment: it seems like massive overkill to try to catalog collation sensitivity for a rather limited benefit, and I'm happy with the way you have it. More soon.
On Thu, Dec 12, 2019 at 5:00 PM Thomas Munro <thomas.munro@gmail.com> wrote: > Then, as a special case, there is the collation of the actual indexed > value, because that will implicitly be used as input to the btree ops > that would be collation sensitive. [...] Erm, but I shouldn't have to reindex my hash indexes (at least not until someone invents collation-based equality and therefore necessarily also collation-based hashing). How can we exclude that? amcanorder seems somehow right but also wrong.
Thomas Munro <thomas.munro@gmail.com> writes: > Erm, but I shouldn't have to reindex my hash indexes (at least not > until someone invents collation-based equality and therefore > necessarily also collation-based hashing). How can we exclude that? Um, we already invented that with nondeterministic collations, no? regards, tom lane
On Thu, Dec 12, 2019 at 6:32 PM Tom Lane <tgl@sss.pgh.pa.us> wrote: > Thomas Munro <thomas.munro@gmail.com> writes: > > Erm, but I shouldn't have to reindex my hash indexes (at least not > > until someone invents collation-based equality and therefore > > necessarily also collation-based hashing). How can we exclude that? > > Um, we already invented that with nondeterministic collations, no? Urghlgh, right, thanks, somehow I missed/forgot that that stuff already works for hashing (neat). So we do need to track collation version dependencies for hash indexes, but only for non-deterministic collations. I wonder how best to code that.
Hello Thomas, Thanks for looking at it! On Thu, Dec 12, 2019 at 5:01 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > We create duplicate pg_depend records: > > [...] > > I wondered if that was harmless That's the assumed behavior of recordMultipleDependencies: /* * Record the Dependency. Note we don't bother to check for * duplicate dependencies; there's no harm in them. */ We could add a check to skip duplicates for the "track_version == true" path, or switch to flags if we want to also skip duplicates in other cases, but it'll make recordMultipleDependencies a little bit more specialised. > but for one thing it causes duplicate warnings: Yes, that should be avoided. > Here's another way to get a duplicate, and in this example you also > get an unnecessary dependency on 100 "default" for this index: > > postgres=# create index on t(x collate "fr_FR") where x > 'helicopter' > collate "fr_FR"; > CREATE INDEX > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > and refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > 1259 | 16460 | 0 | 3456 | 12603 | 0 | > 0:34.0 | n > 1259 | 16460 | 0 | 3456 | 12603 | 0 | > 0:34.0 | n > 1259 | 16460 | 0 | 3456 | 100 | 0 | > 0:34.0 | n > (3 rows) > > Or... maybe 100 should be there, by simple analysis of the x in the > WHERE clause, but it's the same if you write x collate "fr_FR" > > 'helicopter' collate "fr_FR", and in that case there are no > expressions of collation "default" anywhere. Ah good point. That's because expression_tree_walker() will dig into CollateExpr->args and eventually reach the underlying Var. I don't see an easy way to avoid that while still properly recording the required dependency for an even more realistic index such as CREATE INDEX ON t(x COLLATE "fr_FR") WHERE x > ((x COLLATE "en_US" > 'helicopter' COLLATE "en_US")::text) collate "fr_FR"; and for instance not for CREATE INDEX ON t(x COLLATE "fr_FR") WHERE x > ((x COLLATE "en_US" || 'helicopter' COLLATE "en_US")) collate "fr_FR"; > The indirection through composite types works nicely: > > postgres=# create type foo_t as (en text collate "en_CA", fr text > collate "fr_CA"); > CREATE TYPE > postgres=# create table t (foo foo_t); > CREATE TABLE > postgres=# create index on t(foo); > CREATE INDEX > postgres=# select * from pg_depend where objid = 't_foo_idx'::regclass > and refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > 1259 | 16444 | 0 | 3456 | 12554 | 0 | > 0:34.0 | n > 1259 | 16444 | 0 | 3456 | 12597 | 0 | > 0:34.0 | n > (2 rows) > > ... but again it shows the extra and technically unnecessary > dependencies (only 12603 "fr_FR" is really needed): > > postgres=# create index on t(((foo).fr collate "fr_FR")); > CREATE INDEX > postgres=# select * from pg_depend where objid = 't_fr_idx'::regclass > and refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > 1259 | 16445 | 0 | 3456 | 12603 | 0 | > 0:34.0 | n > 1259 | 16445 | 0 | 3456 | 12597 | 0 | > 0:34.0 | n > 1259 | 16445 | 0 | 3456 | 12554 | 0 | > 0:34.0 | n > (3 rows) Yes :( > I check that nested types are examined recursively, as appropriate. I > also tested domains, arrays, arrays of domains, expressions extracting > an element from an array of a domain with an explicit collation, and > the only problem I could find was more ways to get duplicates. Hmm... > what else is there that can contain a collatable type...? Ranges! > > postgres=# create type myrange as range (subtype = text); > CREATE TYPE > postgres=# drop table t; > DROP TABLE > postgres=# create table t (x myrange); > CREATE TABLE > postgres=# create index on t(x); > CREATE INDEX > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > and refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > (0 rows) > > ... or perhaps, more realistically, a GIST index might actually be > useful for range queries, and we're not capturing the dependency: > > postgres=# create index t_x_idx on t using gist (x); > CREATE INDEX > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > and refobjversion != ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > refobjversion | deptype > ---------+-------+----------+------------+----------+-------------+---------------+--------- > (0 rows) Good catch :) I fixed it locally and checked that a gist index on a range with a subtype being a composite type does record the required dependencies. > The new syntax "ALTER INDEX i_name DEPENDS ON ANY COLLATION UNKNOWN > VERSION" doesn't sound good to me, it's not "ANY" collation, it's a > specific set of collations that we aren't listing. "ALTER INDEX > i_name DEPENDS ON COLLATION * VERSION UNKNOWN", hrmph, no that's > terrible... I'm not sure what would be better. Mmm, indeed. With a 3rd round in the existing keyword, how about "DEPENDS ON [ ANY ] REFERENCING COLLATION"? The ANY is mostly to avoid the need for plural. > I'm not sure if I like the idea of VACUUM reporting warnings or not. Hmm. Even if I add this in a IsAutoVacuumWorkerProcess? > To state more explicitly what's happening here, we're searching the > expression trees for subexpresions that have a collation as part of > their static type. We don't know which functions or operators are > actually affected by the collation, though. For example, if an > expression says "x IS NOT NULL" and x happens to be a subexpression of > a type with a particular collation, we don't now that this > expression's value can't possibly be affected by the collation version > changing. So, the system will nag you to rebuild an index just > because you mentioned it, even though the index can't be corrupted. > To do better than that, I suppose we'd need declarations in the > catalog to say which functions/operators are collation sensitive. Wouldn't that still be a problem for an absurd expression like WHERE length((val collate "en_US" > 'uh' collate "en_US")::text) > 0 And since we would still have to record a dependency on the collation in such case, we would need to have another magic value to distinguish "unknown" from "cannot cause corruption" collation version.
On Thu, Dec 12, 2019 at 3:36 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > Hello Thomas, > > Thanks for looking at it! > > On Thu, Dec 12, 2019 at 5:01 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > We create duplicate pg_depend records: > > > > [...] > > > > I wondered if that was harmless > > That's the assumed behavior of recordMultipleDependencies: > > /* > * Record the Dependency. Note we don't bother to check for > * duplicate dependencies; there's no harm in them. > */ > > We could add a check to skip duplicates for the "track_version == > true" path, or switch to flags if we want to also skip duplicates in > other cases, but it'll make recordMultipleDependencies a little bit > more specialised. > > > but for one thing it causes duplicate warnings: > > Yes, that should be avoided. > > > Here's another way to get a duplicate, and in this example you also > > get an unnecessary dependency on 100 "default" for this index: > > > > postgres=# create index on t(x collate "fr_FR") where x > 'helicopter' > > collate "fr_FR"; > > CREATE INDEX > > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > > and refobjversion != ''; > > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > > refobjversion | deptype > > ---------+-------+----------+------------+----------+-------------+---------------+--------- > > 1259 | 16460 | 0 | 3456 | 12603 | 0 | > > 0:34.0 | n > > 1259 | 16460 | 0 | 3456 | 12603 | 0 | > > 0:34.0 | n > > 1259 | 16460 | 0 | 3456 | 100 | 0 | > > 0:34.0 | n > > (3 rows) > > > > Or... maybe 100 should be there, by simple analysis of the x in the > > WHERE clause, but it's the same if you write x collate "fr_FR" > > > 'helicopter' collate "fr_FR", and in that case there are no > > expressions of collation "default" anywhere. > > Ah good point. That's because expression_tree_walker() will dig into > CollateExpr->args and eventually reach the underlying Var. I don't > see an easy way to avoid that while still properly recording the > required dependency for an even more realistic index such as > > CREATE INDEX ON t(x COLLATE "fr_FR") WHERE x > ((x COLLATE "en_US" > > 'helicopter' COLLATE "en_US")::text) collate "fr_FR"; > > and for instance not for > > CREATE INDEX ON t(x COLLATE "fr_FR") WHERE x > ((x COLLATE "en_US" || > 'helicopter' COLLATE "en_US")) collate "fr_FR"; > > > > The indirection through composite types works nicely: > > > > postgres=# create type foo_t as (en text collate "en_CA", fr text > > collate "fr_CA"); > > CREATE TYPE > > postgres=# create table t (foo foo_t); > > CREATE TABLE > > postgres=# create index on t(foo); > > CREATE INDEX > > postgres=# select * from pg_depend where objid = 't_foo_idx'::regclass > > and refobjversion != ''; > > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > > refobjversion | deptype > > ---------+-------+----------+------------+----------+-------------+---------------+--------- > > 1259 | 16444 | 0 | 3456 | 12554 | 0 | > > 0:34.0 | n > > 1259 | 16444 | 0 | 3456 | 12597 | 0 | > > 0:34.0 | n > > (2 rows) > > > > ... but again it shows the extra and technically unnecessary > > dependencies (only 12603 "fr_FR" is really needed): > > > > postgres=# create index on t(((foo).fr collate "fr_FR")); > > CREATE INDEX > > postgres=# select * from pg_depend where objid = 't_fr_idx'::regclass > > and refobjversion != ''; > > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > > refobjversion | deptype > > ---------+-------+----------+------------+----------+-------------+---------------+--------- > > 1259 | 16445 | 0 | 3456 | 12603 | 0 | > > 0:34.0 | n > > 1259 | 16445 | 0 | 3456 | 12597 | 0 | > > 0:34.0 | n > > 1259 | 16445 | 0 | 3456 | 12554 | 0 | > > 0:34.0 | n > > (3 rows) > > Yes :( > > > I check that nested types are examined recursively, as appropriate. I > > also tested domains, arrays, arrays of domains, expressions extracting > > an element from an array of a domain with an explicit collation, and > > the only problem I could find was more ways to get duplicates. Hmm... > > what else is there that can contain a collatable type...? Ranges! > > > > postgres=# create type myrange as range (subtype = text); > > CREATE TYPE > > postgres=# drop table t; > > DROP TABLE > > postgres=# create table t (x myrange); > > CREATE TABLE > > postgres=# create index on t(x); > > CREATE INDEX > > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > > and refobjversion != ''; > > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > > refobjversion | deptype > > ---------+-------+----------+------------+----------+-------------+---------------+--------- > > (0 rows) > > > > ... or perhaps, more realistically, a GIST index might actually be > > useful for range queries, and we're not capturing the dependency: > > > > postgres=# create index t_x_idx on t using gist (x); > > CREATE INDEX > > postgres=# select * from pg_depend where objid = 't_x_idx'::regclass > > and refobjversion != ''; > > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > > refobjversion | deptype > > ---------+-------+----------+------------+----------+-------------+---------------+--------- > > (0 rows) > > Good catch :) I fixed it locally and checked that a gist index on a > range with a subtype being a composite type does record the required > dependencies. > > > The new syntax "ALTER INDEX i_name DEPENDS ON ANY COLLATION UNKNOWN > > VERSION" doesn't sound good to me, it's not "ANY" collation, it's a > > specific set of collations that we aren't listing. "ALTER INDEX > > i_name DEPENDS ON COLLATION * VERSION UNKNOWN", hrmph, no that's > > terrible... I'm not sure what would be better. > > Mmm, indeed. With a 3rd round in the existing keyword, how about > "DEPENDS ON [ ANY ] REFERENCING COLLATION"? The ANY is mostly to > avoid the need for plural. > > > I'm not sure if I like the idea of VACUUM reporting warnings or not. Hmm. > > Even if I add this in a IsAutoVacuumWorkerProcess? > > > To state more explicitly what's happening here, we're searching the > > expression trees for subexpresions that have a collation as part of > > their static type. We don't know which functions or operators are > > actually affected by the collation, though. For example, if an > > expression says "x IS NOT NULL" and x happens to be a subexpression of > > a type with a particular collation, we don't now that this > > expression's value can't possibly be affected by the collation version > > changing. So, the system will nag you to rebuild an index just > > because you mentioned it, even though the index can't be corrupted. > > To do better than that, I suppose we'd need declarations in the > > catalog to say which functions/operators are collation sensitive. > > Wouldn't that still be a problem for an absurd expression like > > WHERE length((val collate "en_US" > 'uh' collate "en_US")::text) > 0 > > > And since we would still have to record a dependency on the collation > in such case, we would need to have another magic value to distinguish > "unknown" from "cannot cause corruption" collation version. PFA rebased v6, with the following changes: - collation for range types is handled - duplicated dependencies aren't recorded anymore - relation column underlying type's collation isn't recorded if it's used in an index expression and is directly under a CollateExpr node. This should be safe as the required dependency is already recorded for the relation's column, and should avoid most of the false positive warning. With this modification, the following use case: CREATE TABLE test (id integer, val text collate "en-x-icu"); CREATE INDEX ON test ( val collate "ga-x-icu" ) WHERE ((val collate "fr-x-icu") collate "es-x-icu") is not null; stores the following dependencies for collations: SELECT refobjid::regcollation, objid::regclass FROM pg_depend WHERE objid::regclass::text ILIKE 'test%' AND refclassid = 3456; refobjid | objid ------------+-------------- "en-x-icu" | test "ga-x-icu" | test_val_idx "fr-x-icu" | test_val_idx "es-x-icu" | test_val_idx (4 rows) Unless we add a distinct catalog for version dependencies or a specific magic value, we have to record the "fr-x-icu" and "ex-x-icu" dependencies. - for hash indexes, deterministic collations aren't track if it's a simple key column. I added a new "non_deterministic_only" parameter to GetTypeCollations() and modified the loop over key attributes in index_create(). With the previous example modified to be a hash index, "ga-x-icu" wouldn't be recorded.
Attachment
- 0001-Remove-pg_collation.collversion-v6.patch
- 0004-Implement-type-regcollation-v6.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v6.patch
- 0003-Track-collation-versions-for-indexes-v6.patch
- 0002-Add-pg_depend.refobjversion-v6.patch
- 0006-Add-a-new-ALTER-INDEX-name-DEPENDS-ON-COLLATION-name-v6.patch
On 2019-12-17 14:25, Julien Rouhaud wrote: > PFA rebased v6, with the following changes: Some thoughts on this patch set. I think we are all agreed on the general idea. 0001-0003 seem pretty much OK. Why is pg_depend.refobjversion of type "name" whereas the previous pg_collation.collversion was type "text"? Related to that, we previously used null to indicate an unknown collation version, and now it's an empty string. Also, this would limit collation versions to 63 characters. Perhaps not a problem right now, but if someone wants to implement Thomas's previous md5-the-file idea with sha256, we'll run out of space. For 0005, if the new commands are only to be used in binary upgrades, then they should be implemented as built-in functions instead of full DDL commands. There is precedent for that. The documentation snippet for this patch talks about upgrades from PG12 to later. But what about upgrades on platforms where we currently don't have collation versioning but might introduce it later (FreeBSD, Windows)? This needs to be generalized. For 0006 ("Add a new ALTER INDEX name DEPENDS ON COLLATION name CURRENT VERSION"), I find the syntax misleading. This command doesn't (or shouldn't) add a new dependency, it only changes the version of an existing dependency. The previously used syntax ALTER COLLATION / REFRESH VERSION is a better vocabulary, I think. I think this whole thing needs more tests. We are designing this delicate mechanism but have no real tests for it. We at least need to come up with a framework for how to test this automatically, so that we can add more test cases over time as people will invariably report issues when this hits the real world. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Tue, Jan 28, 2020 at 1:06 PM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > > On 2019-12-17 14:25, Julien Rouhaud wrote: > > PFA rebased v6, with the following changes: > > Some thoughts on this patch set. Thanks for looking at it! > I think we are all agreed on the general idea. > > 0001-0003 seem pretty much OK. Why is pg_depend.refobjversion of type > "name" whereas the previous pg_collation.collversion was type "text"? > Related to that, we previously used null to indicate an unknown > collation version, and now it's an empty string. That's what Thomas implemented when he started to work on it and I simply kept it that way until now. I'm assuming that it was simply to avoid wasting time on the varlena stuff while working on the prototype, so barring any objections I'll change to nullable text column in the next revision. > For 0005, if the new commands are only to be used in binary upgrades, > then they should be implemented as built-in functions instead of full > DDL commands. There is precedent for that. Oh, I wasn't aware of that. I can definitely use built-in functions instead, but some people previously argued that those command should be available even in non binary upgrade and I'm not clear on whether this is wanted or not. Do you have any thoughts on that? > The documentation snippet for this patch talks about upgrades from PG12 > to later. But what about upgrades on platforms where we currently don't > have collation versioning but might introduce it later (FreeBSD, > Windows)? This needs to be generalized. Good point, I'll try to improve that. > For 0006 ("Add a new ALTER INDEX name DEPENDS ON COLLATION name > CURRENT VERSION"), I find the syntax misleading. This command doesn't > (or shouldn't) add a new dependency, it only changes the version of an > existing dependency. The previously used syntax ALTER COLLATION / > REFRESH VERSION is a better vocabulary, I think. I agree and also complained about that syntax too. I'm however struggling on coming up with a syntax that makes it clear it's refreshing the version of a collation the index already depends on. E.g.: ALTER INDEX name ALTER COLLATION name REFRESH VERSION is still quite poor, but I don't have anything better. Do you have some better suggestion or should I go with that? > I think this whole thing needs more tests. We are designing this > delicate mechanism but have no real tests for it. We at least need to > come up with a framework for how to test this automatically, so that we > can add more test cases over time as people will invariably report > issues when this hits the real world. Indeed. I have some unlikely index test cases I'm for now using to validate the behavior, but didn't start a real test infrastructure. I'll also work on that for the next revision, although I'll need some more thinking on how to properly test the pg_upgrade part.
On Wed, Jan 29, 2020 at 9:58 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Tue, Jan 28, 2020 at 1:06 PM Peter Eisentraut > <peter.eisentraut@2ndquadrant.com> wrote: > > 0001-0003 seem pretty much OK. Why is pg_depend.refobjversion of type > > "name" whereas the previous pg_collation.collversion was type "text"? > > Related to that, we previously used null to indicate an unknown > > collation version, and now it's an empty string. > > That's what Thomas implemented when he started to work on it and I > simply kept it that way until now. I'm assuming that it was simply to > avoid wasting time on the varlena stuff while working on the > prototype, so barring any objections I'll change to nullable text > column in the next revision. Done > > The documentation snippet for this patch talks about upgrades from PG12 > > to later. But what about upgrades on platforms where we currently don't > > have collation versioning but might introduce it later (FreeBSD, > > Windows)? This needs to be generalized. > > Good point, I'll try to improve that. Done. > > I think this whole thing needs more tests. We are designing this > > delicate mechanism but have no real tests for it. We at least need to > > come up with a framework for how to test this automatically, so that we > > can add more test cases over time as people will invariably report > > issues when this hits the real world. > > Indeed. I have some unlikely index test cases I'm for now using to > validate the behavior, but didn't start a real test infrastructure. > I'll also work on that for the next revision, although I'll need some > more thinking on how to properly test the pg_upgrade part. So I added all tests I could think of to validate the correct behavior of all the new stuff. Mostly: - tests to make sure that we properly track a collation version for various case of collation hidden somewhere in index definitions - tests for pg_dump in binary upgrade mode to make sure that the collation version (or the lack of known version) is correctly preserved. I also modified pg_dump TAP tests to restore the binary dump on an instance in binary mode, redump it and rerun the related testsuite. While doing that I also realized that the previous support for unknown version for partly broken, as it's possible to end up with a database where only part of the collation versions are none. I fixed it, adding a new "DEPEND ON COLLATION x UNKNOWN VERSION" alternative for that case, with proper pg_dump support and required tests - new pg_dump TAP test mode with both --binary-upgrade and the new --unknown-collations-binary-compatible switch, to make sure that we don't dump the UNKNOWN VERSION orders when the --collation-binary-compatible pg_upgrade option is used - test for the ALTER INDEX name DEPENDS ON COLLATION name CURRENT VERSION To avoid too many platform dependent behavior, I restricted the tests for ICU collation only, with the required changes to ignore the tests when postgres isn't compile with ICU support. One exception is a couple of test to validate that we correctly add dependencies for default collation, as we for now only support libc default collation. It means that as written, the collate.icu.utf8 test will need an alternative output for glibc platforms (which I didn't added yet, as I'm sure there'll be other changes required, so let's avoid the pain of maintaining it for now), as I've been testing the expected file against macos. Note that I didn't change any syntax (or switched to native functions for the binary pg_dump) as it's still not clear to me what exactly should be implemented.
Attachment
- 0001-Remove-pg_collation.collversion-v7.patch
- 0003-Implement-type-regcollation-v7.patch
- 0002-Add-pg_depend.refobjversion-v7.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v7.patch
- 0004-Track-collation-versions-for-indexes-v7.patch
- 0006-Add-a-new-ALTER-INDEX-name-DEPENDS-ON-COLLATION-name-v7.patch
On Wed, Feb 05, 2020 at 05:17:25PM +0100, Julien Rouhaud wrote: > > Note that I didn't change any syntax (or switched to native functions > for the binary pg_dump) as it's still not clear to me what exactly > should be implemented. Hearing no complaints on the suggestions, I'm attaching v8 to address that: - pg_dump is now using a binary_upgrade_set_index_coll_version() function rather than plain DDL - the additional DDL is now of the form: ALTER INDEX name ALTER COLLATION name REFRESH VERSION I also added an alternate file for the collate.icu.utf8, so the build farm bot should turn green for the linux part.
Attachment
- 0001-Remove-pg_collation.collversion-v8.patch
- 0002-Add-pg_depend.refobjversion-v8.patch
- 0003-Implement-type-regcollation-v8.patch
- 0004-Track-collation-versions-for-indexes-v8.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v8.patch
- 0006-Add-a-new-ALTER-INDEX-name-ALTER-COLLATION-name-REFR-v8.patch
On Wed, 2020-02-12 at 20:13 +0100, Julien Rouhaud wrote: > On Wed, Feb 05, 2020 at 05:17:25PM +0100, Julien Rouhaud wrote: > > Note that I didn't change any syntax (or switched to native functions > > for the binary pg_dump) as it's still not clear to me what exactly > > should be implemented. > > Hearing no complaints on the suggestions, I'm attaching v8 to address that: > > - pg_dump is now using a binary_upgrade_set_index_coll_version() function > rather than plain DDL > - the additional DDL is now of the form: > ALTER INDEX name ALTER COLLATION name REFRESH VERSION > > I also added an alternate file for the collate.icu.utf8, so the build farm bot > should turn green for the linux part. diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml index 6d34dbb74e..8661b031e9 100644 --- a/doc/src/sgml/ref/alter_index.sgml +++ b/doc/src/sgml/ref/alter_index.sgml @@ -109,6 +110,18 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> </listitem> </varlistentry> + <varlistentry> + <term><literal>ALTER COLLATION</literal></term> + <listitem> + <para> + This form update the index existing dependency on a specific collation, + to specificy the the currently installed collation version is compatible + with the version used the last time the index was built. Be aware that + an incorrect use of this form can hide a corruption on the index. + </para> + </listitem> + </varlistentry> + <varlistentry> <term><literal>SET ( <replaceable class="parameter">storage_parameter</replaceable> = <replaceable class="parameter">value</replaceable>[, ... ] )</literal></term> <listitem> This description could do with some love. Perhaps: This command declares that the index is compatible with the currently installed version of the collations that determine its order. It is used to silence warnings caused by collation version incompatibilities and should be called after rebuilding the index or otherwise verifying its consistency. Be aware that incorrect use of this command can hide index corruption. I didn't study the patch in detail, but do I get it right that there will be no warnings about version incompatibilities with libc collations? Yours, Laurenz Albe
On Wed, Feb 12, 2020 at 08:55:06PM +0100, Laurenz Albe wrote: > On Wed, 2020-02-12 at 20:13 +0100, Julien Rouhaud wrote: > > On Wed, Feb 05, 2020 at 05:17:25PM +0100, Julien Rouhaud wrote: > > > Note that I didn't change any syntax (or switched to native functions > > > for the binary pg_dump) as it's still not clear to me what exactly > > > should be implemented. > > > > Hearing no complaints on the suggestions, I'm attaching v8 to address that: > > > > - pg_dump is now using a binary_upgrade_set_index_coll_version() function > > rather than plain DDL > > - the additional DDL is now of the form: > > ALTER INDEX name ALTER COLLATION name REFRESH VERSION > > > > I also added an alternate file for the collate.icu.utf8, so the build farm bot > > should turn green for the linux part. > > diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml > index 6d34dbb74e..8661b031e9 100644 > --- a/doc/src/sgml/ref/alter_index.sgml > +++ b/doc/src/sgml/ref/alter_index.sgml > @@ -109,6 +110,18 @@ ALTER INDEX ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> > </listitem> > </varlistentry> > > + <varlistentry> > + <term><literal>ALTER COLLATION</literal></term> > + <listitem> > + <para> > + This form update the index existing dependency on a specific collation, > + to specificy the the currently installed collation version is compatible > + with the version used the last time the index was built. Be aware that > + an incorrect use of this form can hide a corruption on the index. > + </para> > + </listitem> > + </varlistentry> > + > <varlistentry> > <term><literal>SET ( <replaceable class="parameter">storage_parameter</replaceable> = <replaceable class="parameter">value</replaceable>[, ... ] )</literal></term> > <listitem> > > This description could do with some love. Perhaps: > > This command declares that the index is compatible with the currently > installed version of the collations that determine its order. It is used > to silence warnings caused by collation > version incompatibilities and > should be called after rebuilding the index or otherwise verifying its > consistency. Be aware that incorrect use of this command can hide > index corruption. Thanks a lot, that's indeed way better! I'll add it in the round of patch. > I didn't study the patch in detail, but do I get it right that there will be no > warnings about version incompatibilities with libc collations? No, libc is also be supported (including the default collation), as long as we have a way to get the version. Unfortunately, that means only linux/glibc. I think that there was some previous discussion to work around that limitation for other systems, using some kind of hash of the underlying collation files, as Peter mentioned recently, but that's not part of this patchset.
On Thu, Feb 13, 2020 at 9:16 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Wed, Feb 12, 2020 at 08:55:06PM +0100, Laurenz Albe wrote: > > I didn't study the patch in detail, but do I get it right that there will be no > > warnings about version incompatibilities with libc collations? > > No, libc is also be supported (including the default collation), as long as we > have a way to get the version. Unfortunately, that means only linux/glibc. I > think that there was some previous discussion to work around that limitation > for other systems, using some kind of hash of the underlying collation files, > as Peter mentioned recently, but that's not part of this patchset. Yeah, this is about the cataloguing infrastructure part, to get the model and mechanisms right. To actually get version information from the underlying collation provider, there will need to be a series of per-OS projects. For glibc right now, it's done, but we just use the whole glibc version as a proxy (sadly we know this can give false positives and false negatives, but is expected to work a lot better than nothing). I hope we can get a proper CLDR version out of that library one day. For FreeBSD libc, I have patches, I just need more round tuits. For Windows, there is https://commitfest.postgresql.org/27/2351/ which I'm planning to commit soonish, after some more thought about the double-version thing. Then there is the "run a user-supplied script that gives me a version" concept, which might work and perhaps allow package maintainers to supply a script that works on each system. Again, that'd be a separate project. I guess there will probably always be some OSes that we can't get the data from so we'll probably always have to support "don't know" mode.
On Thu, Feb 13, 2020 at 09:44:40AM +1300, Thomas Munro wrote: > On Thu, Feb 13, 2020 at 9:16 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Wed, Feb 12, 2020 at 08:55:06PM +0100, Laurenz Albe wrote: > > > I didn't study the patch in detail, but do I get it right that there will be no > > > warnings about version incompatibilities with libc collations? > > > > No, libc is also be supported (including the default collation), as long as we > > have a way to get the version. Unfortunately, that means only linux/glibc. I > > think that there was some previous discussion to work around that limitation > > for other systems, using some kind of hash of the underlying collation files, > > as Peter mentioned recently, but that's not part of this patchset. > > Yeah, this is about the cataloguing infrastructure part, to get the > model and mechanisms right. To actually get version information from > the underlying collation provider, there will need to be a series of > per-OS projects. For glibc right now, it's done, but we just use the > whole glibc version as a proxy (sadly we know this can give false > positives and false negatives, but is expected to work a lot better > than nothing). I hope we can get a proper CLDR version out of that > library one day. For FreeBSD libc, I have patches, I just need more > round tuits. For Windows, there is > https://commitfest.postgresql.org/27/2351/ which I'm planning to > commit soonish, after some more thought about the double-version > thing. Then there is the "run a user-supplied script that gives me a > version" concept, which might work and perhaps allow package > maintainers to supply a script that works on each system. Again, > that'd be a separate project. Thanks for working on that, it'll be great improvements! > I guess there will probably always be > some OSes that we can't get the data from so we'll probably always > have to support "don't know" mode. I realized this morning that I didn't add test to validate that we emit the expected warnings in case of version mismatch. While adding some, I found that for the unknown versino, my code was actually testing the "versioning support for that lib on that system is now supported" and not "you apparently upgraded from pre-v13 with supported collation library versioning, and the version was marked as unknown". Attached v9 fixes the test to handle both cases. I also added TAP regression tests for version mismatch checking in the src/test/locale tests. This subdirectory wasn't included by default, probably because there was no "check" or "installcheck" target so building test-ctype was pointless, it's now included by default.
Attachment
- 0001-Remove-pg_collation.collversion-v9.patch
- 0002-Add-pg_depend.refobjversion-v9.patch
- 0003-Implement-type-regcollation-v9.patch
- 0004-Track-collation-versions-for-indexes-v9.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v9.patch
- 0006-Add-a-new-ALTER-INDEX-name-ALTER-COLLATION-name-REFR-v9.patch
On Thu, Feb 13, 2020 at 8:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > Hearing no complaints on the suggestions, I'm attaching v8 to address that: > > - pg_dump is now using a binary_upgrade_set_index_coll_version() function > rather than plain DDL > - the additional DDL is now of the form: > ALTER INDEX name ALTER COLLATION name REFRESH VERSION +1 A couple of thoughts: @@ -1115,21 +1117,44 @@ index_create(Relation heapRelation, ... + /* + * Get required distinct dependencies on collations for all index keys. + * Collations of directly referenced column in hash indexes can be + * skipped is they're deterministic. + */ for (i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++) { - if (OidIsValid(collationObjectId[i]) && - collationObjectId[i] != DEFAULT_COLLATION_OID) + Oid colloid = collationObjectId[i]; + + if (OidIsValid(colloid)) { - referenced.classId = CollationRelationId; - referenced.objectId = collationObjectId[i]; - referenced.objectSubId = 0; + if ((indexInfo->ii_Am != HASH_AM_OID) || + !get_collation_isdeterministic(colloid)) I still don't like the way catalog/index.c has hard-coded knowledge of HASH_AM_OID here. Although it errs on the side of the assuming that there *is* a version dependency (good), there is already another AM in the tree that could safely skip it for deterministic collations AFAIK: Bloom indexes. I suppose that any extension AM that is doing some kind of hashing would also like to be able to be able to opt out of collation version checking, when that is safe. The question is how to model that in our system... One way would be for each AM to declare whether it is affected by collations; the answer could be yes/maybe (default), no, only-non-deterministic-ones. But that still feels like the wrong level, not taking advantage of knowledge about operators. A better way might be to make declarations about that sort of thing in the catalog, somewhere in the vicinity of the operator classes, or maybe just to have hard coded knowledge about operator classes (ie making declarations in the manual about what eg hash functions are allowed to consult and when), and then check which of those an index depends on. I am not sure what would be best, I'd need to spend some time studying the am operator system. Perhaps for the first version of this feature, we should just add a new local function index_can_skip_collation_version_dependency(indexInfo, colloid) to encapsulate your existing logic, but add a comment that in future we might be able to support skipping in more cases through analysis of the catalogs. + <varlistentry> + <term><literal>ALTER COLLATION</literal></term> + <listitem> + <para> + This command declares that the index is compatible with the currently + installed version of the collations that determine its order. It is used + to silence warnings caused by collation version incompatibilities and + should be called after rebuilding the index or otherwise verifying its + consistency. Be aware that incorrect use of this command can hide index + corruption. + </para> + </listitem> + </varlistentry> This sounds like something that you need to do after you reindex, but that's not true, is it? This is something you can do *instead* of reindex, to make it shut up about versions. Shouldn't it be something like "... should be issued only if the ordering is known not to have changed since the index was built"? +-- Test ALTER INDEX name ALTER COLLATION name REFRESH VERSION +UPDATE pg_depend SET refobjversion = 'not a version' +WHERE refclassid = 'pg_collation'::regclass +AND objid::regclass::text = 'icuidx17_part' +AND refobjversion IS NOT NULL; +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; + objid +--------------- + icuidx17_part +(1 row) + +ALTER INDEX icuidx17_part ALTER COLLATION "en-x-icu" REFRESH VERSION; +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; + objid +------- +(0 rows) + Would it be better to put refobjversion = 'not a version' in the SELECT list, instead of the WHERE clause, with a WHERE clause that hits that one row, so that we can see that the row still exists after the REFRESH VERSION (while still hiding the unstable version string)?
On Mon, Feb 17, 2020 at 5:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Thu, Feb 13, 2020 at 8:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > Hearing no complaints on the suggestions, I'm attaching v8 to address that: > > > > - pg_dump is now using a binary_upgrade_set_index_coll_version() function > > rather than plain DDL > > - the additional DDL is now of the form: > > ALTER INDEX name ALTER COLLATION name REFRESH VERSION > > +1 > > A couple of thoughts: > > @@ -1115,21 +1117,44 @@ index_create(Relation heapRelation, > ... > + /* > + * Get required distinct dependencies on collations > for all index keys. > + * Collations of directly referenced column in hash > indexes can be > + * skipped is they're deterministic. > + */ > for (i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++) > { > - if (OidIsValid(collationObjectId[i]) && > - collationObjectId[i] != DEFAULT_COLLATION_OID) > + Oid colloid = collationObjectId[i]; > + > + if (OidIsValid(colloid)) > { > - referenced.classId = CollationRelationId; > - referenced.objectId = collationObjectId[i]; > - referenced.objectSubId = 0; > + if ((indexInfo->ii_Am != HASH_AM_OID) || > + > !get_collation_isdeterministic(colloid)) > > I still don't like the way catalog/index.c has hard-coded knowledge of > HASH_AM_OID here. Although it errs on the side of the assuming that > there *is* a version dependency (good) Oh, but it also means that it fails to create a versionless dependency, which is totally wrong. What we should do is instead setup a "track_version" flag to pass down. It also means that the current way I handled unknown version (empty string) vs unknown collation lib version (null) will be problematic, both for runtime check and pg_upgrade. I think we should record an empty string for both cases, and keep NULL for when explicitly no version has to be recorded (whether it's not a dependency on collation, or because the depender doesn't care about version). It also mean that I'm missing regression tests using such an access method. > there is already another AM in > the tree that could safely skip it for deterministic collations AFAIK: > Bloom indexes. I suppose that any extension AM that is doing some > kind of hashing would also like to be able to be able to opt out of > collation version checking, when that is safe. The question is how to > model that in our system... Oh indeed. > One way would be for each AM to declare whether it is affected by > collations; the answer could be yes/maybe (default), no, > only-non-deterministic-ones. But that still feels like the wrong > level, not taking advantage of knowledge about operators. On the other hand, would it be possible that some AM only supports collation-dependency-free operators while still internally relying on a stable sort order? > A better way might be to make declarations about that sort of thing in > the catalog, somewhere in the vicinity of the operator classes, or > maybe just to have hard coded knowledge about operator classes (ie > making declarations in the manual about what eg hash functions are > allowed to consult and when), and then check which of those an index > depends on. I am not sure what would be best, I'd need to spend some > time studying the am operator system. I think this will be required at some point anyway, if we want to eventually avoid warning about possible corruption when an expression/where clause isn't depending on the collation ordering. > Perhaps for the first version of this feature, we should just add a > new local function > index_can_skip_collation_version_dependency(indexInfo, colloid) to > encapsulate your existing logic, but add a comment that in future we > might be able to support skipping in more cases through analysis of > the catalogs. That'd be convenient, but would also break extensibility as bloom would get a preferential treatment (even if such AM doesn't already exist). > > + <varlistentry> > + <term><literal>ALTER COLLATION</literal></term> > + <listitem> > + <para> > + This command declares that the index is compatible with the currently > + installed version of the collations that determine its order. It is used > + to silence warnings caused by collation version incompatibilities and > + should be called after rebuilding the index or otherwise verifying its > + consistency. Be aware that incorrect use of this command can hide index > + corruption. > + </para> > + </listitem> > + </varlistentry> > > This sounds like something that you need to do after you reindex, but > that's not true, is it? This is something you can do *instead* of > reindex, to make it shut up about versions. Shouldn't it be something > like "... should be issued only if the ordering is known not to have > changed since the index was built"? Indeed. We should also probably explicitly mention that if the situation is unknown, REINDEX is the safe alternative to choose. > +-- Test ALTER INDEX name ALTER COLLATION name REFRESH VERSION > +UPDATE pg_depend SET refobjversion = 'not a version' > +WHERE refclassid = 'pg_collation'::regclass > +AND objid::regclass::text = 'icuidx17_part' > +AND refobjversion IS NOT NULL; > +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; > + objid > +--------------- > + icuidx17_part > +(1 row) > + > +ALTER INDEX icuidx17_part ALTER COLLATION "en-x-icu" REFRESH VERSION; > +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; > + objid > +------- > +(0 rows) > + > > Would it be better to put refobjversion = 'not a version' in the > SELECT list, instead of the WHERE clause, with a WHERE clause that > hits that one row, so that we can see that the row still exists after > the REFRESH VERSION (while still hiding the unstable version string)? Agreed, I'll change that.
On Tue, Feb 18, 2020 at 2:53 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Mon, Feb 17, 2020 at 5:58 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > On Thu, Feb 13, 2020 at 8:13 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > Hearing no complaints on the suggestions, I'm attaching v8 to address that: > > > > > > - pg_dump is now using a binary_upgrade_set_index_coll_version() function > > > rather than plain DDL > > > - the additional DDL is now of the form: > > > ALTER INDEX name ALTER COLLATION name REFRESH VERSION > > > > +1 > > > > A couple of thoughts: > > > > @@ -1115,21 +1117,44 @@ index_create(Relation heapRelation, > > ... > > + /* > > + * Get required distinct dependencies on collations > > for all index keys. > > + * Collations of directly referenced column in hash > > indexes can be > > + * skipped is they're deterministic. > > + */ > > for (i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++) > > { > > - if (OidIsValid(collationObjectId[i]) && > > - collationObjectId[i] != DEFAULT_COLLATION_OID) > > + Oid colloid = collationObjectId[i]; > > + > > + if (OidIsValid(colloid)) > > { > > - referenced.classId = CollationRelationId; > > - referenced.objectId = collationObjectId[i]; > > - referenced.objectSubId = 0; > > + if ((indexInfo->ii_Am != HASH_AM_OID) || > > + > > !get_collation_isdeterministic(colloid)) > > > > I still don't like the way catalog/index.c has hard-coded knowledge of > > HASH_AM_OID here. Although it errs on the side of the assuming that > > there *is* a version dependency (good) > > Oh, but it also means that it fails to create a versionless > dependency, which is totally wrong. What we should do is instead > setup a "track_version" flag to pass down. > > It also means that the current way I handled unknown version (empty > string) vs unknown collation lib version (null) will be problematic, > both for runtime check and pg_upgrade. I think we should record an > empty string for both cases, and keep NULL for when explicitly no > version has to be recorded (whether it's not a dependency on > collation, or because the depender doesn't care about version). Fixed this way. > It > also mean that I'm missing regression tests using such an access > method. Done > > there is already another AM in > > the tree that could safely skip it for deterministic collations AFAIK: > > Bloom indexes. I suppose that any extension AM that is doing some > > kind of hashing would also like to be able to be able to opt out of > > collation version checking, when that is safe. The question is how to > > model that in our system... > > Oh indeed. > > > One way would be for each AM to declare whether it is affected by > > collations; the answer could be yes/maybe (default), no, > > only-non-deterministic-ones. But that still feels like the wrong > > level, not taking advantage of knowledge about operators. > > On the other hand, would it be possible that some AM only supports > collation-dependency-free operators while still internally relying on > a stable sort order? > > > A better way might be to make declarations about that sort of thing in > > the catalog, somewhere in the vicinity of the operator classes, or > > maybe just to have hard coded knowledge about operator classes (ie > > making declarations in the manual about what eg hash functions are > > allowed to consult and when), and then check which of those an index > > depends on. I am not sure what would be best, I'd need to spend some > > time studying the am operator system. > > I think this will be required at some point anyway, if we want to > eventually avoid warning about possible corruption when an > expression/where clause isn't depending on the collation ordering. > > > Perhaps for the first version of this feature, we should just add a > > new local function > > index_can_skip_collation_version_dependency(indexInfo, colloid) to > > encapsulate your existing logic, but add a comment that in future we > > might be able to support skipping in more cases through analysis of > > the catalogs. > > That'd be convenient, but would also break extensibility as bloom > would get a preferential treatment (even if such AM doesn't already > exist). I added an index_depends_stable_coll_order() static function for now. > > + <varlistentry> > > + <term><literal>ALTER COLLATION</literal></term> > > + <listitem> > > + <para> > > + This command declares that the index is compatible with the currently > > + installed version of the collations that determine its order. It is used > > + to silence warnings caused by collation version incompatibilities and > > + should be called after rebuilding the index or otherwise verifying its > > + consistency. Be aware that incorrect use of this command can hide index > > + corruption. > > + </para> > > + </listitem> > > + </varlistentry> > > > > This sounds like something that you need to do after you reindex, but > > that's not true, is it? This is something you can do *instead* of > > reindex, to make it shut up about versions. Shouldn't it be something > > like "... should be issued only if the ordering is known not to have > > changed since the index was built"? > > Indeed. We should also probably explicitly mention that if the > situation is unknown, REINDEX is the safe alternative to choose. Done. > > +-- Test ALTER INDEX name ALTER COLLATION name REFRESH VERSION > > +UPDATE pg_depend SET refobjversion = 'not a version' > > +WHERE refclassid = 'pg_collation'::regclass > > +AND objid::regclass::text = 'icuidx17_part' > > +AND refobjversion IS NOT NULL; > > +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; > > + objid > > +--------------- > > + icuidx17_part > > +(1 row) > > + > > +ALTER INDEX icuidx17_part ALTER COLLATION "en-x-icu" REFRESH VERSION; > > +SELECT objid::regclass FROM pg_depend WHERE refobjversion = 'not a version'; > > + objid > > +------- > > +(0 rows) > > + > > > > Would it be better to put refobjversion = 'not a version' in the > > SELECT list, instead of the WHERE clause, with a WHERE clause that > > hits that one row, so that we can see that the row still exists after > > the REFRESH VERSION (while still hiding the unstable version string)? > > Agreed, I'll change that. And done. An induced change in the attached v10 is that pg_collation_actual_version() SQL function now also returns an empty string if the collation version is unknown. That's not strictly required, but it makes things more consistent and help writing queries that finds which indexes may be broken. That function's behavior wasn't documented for unknown version, so I also added some clarification.
Attachment
- 0003-Implement-type-regcollation-v10.patch
- 0001-Remove-pg_collation.collversion-v10.patch
- 0002-Add-pg_depend.refobjversion-v10.patch
- 0004-Track-collation-versions-for-indexes-v10.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v10.patch
- 0006-Add-a-new-ALTER-INDEX-name-ALTER-COLLATION-name-REFR-v10.patch
On Thu, Feb 27, 2020 at 3:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > [v10] Thanks. I'll do some more testing and review soon. It'd be really cool to get this into PG13. FYI cfbot said: +++ /home/travis/build/postgresql-cfbot/postgresql/src/test/regress/results/collate.icu.utf8.out 2020-02-26 14:45:52.114401999 +0000 ... - icuidx06_d_en_fr_ga | "default" | up to date + icuidx06_d_en_fr_ga | "default" | out of date
On Thu, Feb 27, 2020 at 04:10:14PM +1300, Thomas Munro wrote: > On Thu, Feb 27, 2020 at 3:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > [v10] > > Thanks. I'll do some more testing and review soon. It'd be really > cool to get this into PG13. Thanks! > > FYI cfbot said: > > +++ /home/travis/build/postgresql-cfbot/postgresql/src/test/regress/results/collate.icu.utf8.out > 2020-02-26 14:45:52.114401999 +0000 > ... > - icuidx06_d_en_fr_ga | "default" | up to date > + icuidx06_d_en_fr_ga | "default" | out of date Oh. It turns out that pg_collation_actual_version() isn't handling the default collation: # SELECT pg_collation_actual_version(100), pg_collation_actual_version(c.oid) FROM pg_database d JOIN pg_collation c on c.collname = d.datcollate WHERE datname = current_database(); pg_collation_actual_version | pg_collation_actual_version -----------------------------+----------------------------- <NULL> | 2.30 (1 row) Fixed in v11 by changing pg_collation_actual_version() to handle default collation too, as it seems a better behavior.
Attachment
- 0001-Remove-pg_collation.collversion-v11.patch
- 0002-Add-pg_depend.refobjversion-v11.patch
- 0003-Implement-type-regcollation-v11.patch
- 0004-Track-collation-versions-for-indexes-v11.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v11.patch
- 0006-Add-a-new-ALTER-INDEX-name-ALTER-COLLATION-name-REFR-v11.patch
On Thu, Feb 27, 2020 at 08:45:35AM +0100, Julien Rouhaud wrote: > On Thu, Feb 27, 2020 at 04:10:14PM +1300, Thomas Munro wrote: > > On Thu, Feb 27, 2020 at 3:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > [v10] > [...] > > Fixed in v11 by changing pg_collation_actual_version() to handle default > collation too, as it seems a better behavior. Rebased v12 due to conflict with the recent command tag commit (2f9661311b), no other changes.
Attachment
- 0001-Remove-pg_collation.collversion-v12.patch
- 0002-Add-pg_depend.refobjversion-v12.patch
- 0003-Implement-type-regcollation-v12.patch
- 0004-Track-collation-versions-for-indexes-v12.patch
- 0005-Preserve-index-dependencies-on-collation-during-pg_u-v12.patch
- 0006-Add-a-new-ALTER-INDEX-name-ALTER-COLLATION-name-REFR-v12.patch
On Wed, Mar 4, 2020 at 10:01 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Thu, Feb 27, 2020 at 08:45:35AM +0100, Julien Rouhaud wrote: > > On Thu, Feb 27, 2020 at 04:10:14PM +1300, Thomas Munro wrote: > > > On Thu, Feb 27, 2020 at 3:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > [v10] > > [...] > > > > Fixed in v11 by changing pg_collation_actual_version() to handle default > > collation too, as it seems a better behavior. > > Rebased v12 due to conflict with the recent command tag commit (2f9661311b), no > other changes. I'm still reviewing and testing the code, but here's a new patch set with a bunch of small changes to documentation, tests and commit messages: 0001-Remove-pg_collation.collversion-v13.patch * removed ALTER COLLATION ... REFRESH VERSION from the docs * removed ALTER COLLATION ... REFRESH VERSION from collate.linux.utf8.sql (oops, that wasn't running on my FreeBSD system, or on cfbot's Ubuntu image because it doesn't have "locales-all" installed; I will make a note to fix that on cfbot) 0002-Add-pg_depend.refobjversion-v13.patch * added new column to the documentation of the pg_depend catalog 0003-Implement-type-regcollation-v13.patch * added regcollation to a list of such types in datatype.sgml 0004-Track-collation-versions-for-indexes-v13.patch * added a note to the documentation's list of reasons why REINDEX might be needed 0005-Preserve-index-dependencies-on-collation-during--v13.patch * minor rewording of the docs, I hope you like it 0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS-v13.patch * minor rewording of the docs, I hope you like it 0007-doc-Add-Collation-Versions-section-v13.patch * new: a brief introduction to this topic
Attachment
- 0001-Remove-pg_collation.collversion-v13.patch
- 0002-Add-pg_depend.refobjversion-v13.patch
- 0003-Implement-type-regcollation-v13.patch
- 0004-Track-collation-versions-for-indexes-v13.patch
- 0005-Preserve-index-dependencies-on-collation-during--v13.patch
- 0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS-v13.patch
- 0007-doc-Add-Collation-Versions-section-v13.patch
On Wed, Mar 11, 2020 at 04:13:17PM +1300, Thomas Munro wrote: > On Wed, Mar 4, 2020 at 10:01 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Thu, Feb 27, 2020 at 08:45:35AM +0100, Julien Rouhaud wrote: > > > On Thu, Feb 27, 2020 at 04:10:14PM +1300, Thomas Munro wrote: > > > > On Thu, Feb 27, 2020 at 3:29 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > [v10] > > > [...] > > > > > > Fixed in v11 by changing pg_collation_actual_version() to handle default > > > collation too, as it seems a better behavior. > > > > Rebased v12 due to conflict with the recent command tag commit (2f9661311b), no > > other changes. > > I'm still reviewing and testing the code, but here's a new patch set > with a bunch of small changes to documentation, tests and commit > messages: Thanks a lot Thomas! FTR one of the patch has a minor conflict due to 3c173a53a82, so I'm attaching a v14 to make cfbot happy and also benefit from windows coverage just in case. I also tried to add some missing reviewers to the patches, I hope I didn't forget anyone. > > 0001-Remove-pg_collation.collversion-v13.patch > * removed ALTER COLLATION ... REFRESH VERSION from collate.linux.utf8.sql > (oops, that wasn't running on my FreeBSD system, or on cfbot's Ubuntu > image because it doesn't have "locales-all" installed; I will make a > note to fix that on cfbot) Wow I don't know how that happened since I did remove that in v2 ([1]). Thanks! > > 0002-Add-pg_depend.refobjversion-v13.patch > * added new column to the documentation of the pg_depend catalog > > 0003-Implement-type-regcollation-v13.patch > * added regcollation to a list of such types in datatype.sgml > > 0004-Track-collation-versions-for-indexes-v13.patch > * added a note to the documentation's list of reasons why REINDEX > might be needed > > 0005-Preserve-index-dependencies-on-collation-during--v13.patch > * minor rewording of the docs, I hope you like it > > 0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS-v13.patch > * minor rewording of the docs, I hope you like it > > 0007-doc-Add-Collation-Versions-section-v13.patch > * new: a brief introduction to this topic I'm quite happy with all the changes, and especially the new section about collation version in 0007. Minor gripe in pgugprade.sgml, as Peter E. mentioned in [2] the documentation shouldn't focus on pg13- / pg13+ upgrade only. Or should we keep that for when additional system will be supported post pg13? [1] https://www.postgresql.org/message-id/CAOBaU_aL%3D4f67L%2Bm2s28DmiaacZ%3DDn75BZY-HGmEq1WquGa-Jg%40mail.gmail.com [2] https://www.postgresql.org/message-id/3ede40e7-5799-7096-dc5f-d7beda8e7145%402ndquadrant.com
Attachment
- v14-0001-Remove-pg_collation.collversion.patch
- v14-0002-Add-pg_depend.refobjversion.patch
- v14-0003-Implement-type-regcollation.patch
- v14-0004-Track-collation-versions-for-indexes.patch
- v14-0005-Preserve-index-dependencies-on-collation-during-.patch
- v14-0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v14-0007-doc-Add-Collation-Versions-section.patch
On Wed, Mar 11, 2020 at 09:44:32AM +0100, Julien Rouhaud wrote: > > Thanks a lot Thomas! FTR one of the patch has a minor conflict due to > 3c173a53a82, so I'm attaching a v14 to make cfbot happy and also benefit from > windows coverage just in case. And v15 due to conflict with b08dee24a5 (Add pg_dump support for ALTER obj DEPENDS ON EXTENSION).
Attachment
- v15-0003-Implement-type-regcollation.patch
- v15-0001-Remove-pg_collation.collversion.patch
- v15-0002-Add-pg_depend.refobjversion.patch
- v15-0004-Track-collation-versions-for-indexes.patch
- v15-0005-Preserve-index-dependencies-on-collation-during-.patch
- v15-0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v15-0007-doc-Add-Collation-Versions-section.patch
On Thu, Mar 12, 2020 at 03:00:26PM +0100, Julien Rouhaud wrote: > And v15 due to conflict with b08dee24a5 (Add pg_dump support for ALTER obj > DEPENDS ON EXTENSION). I have looked at patches 0001~0003 in the set for now. 0001 looks clean to me. In patch 0002, you have the following addition: @@ -103,9 +103,10 @@ ORDER BY 1, 2; pg_class | relacl | aclitem[] pg_class | reloptions | text[] pg_class | relpartbound | pg_node_tree + pg_depend | refobjversion | text This comes from a regression test doing a sanity check to look for catalogs which have a toastable column but no toast tables. As an exception, it should be documented in the test's comment. Actually, does it need to be an exception? This does not depend on relation-level facilities so there should be no risk of recursive dependencies, though I have not looked in details at this part. + <para> + The only current use of <structfield>refobjversion</structfield> is to + record dependencies between indexes and collation versions. + </para> [...] + <row> + <entry><structfield>refobjversion</structfield></entry> + <entry><type>text</type></entry> + <entry></entry> + <entry> + An optional version for the referenced object; see text + </entry> + </row> Couldn't you merge both paragraphs here? Regarding patch 0003, it would be nice to include some tests independent on the rest and making use of the new functions. These normally go in regproc.sql. For example with a collation that needs double quotes as this is not obvious: =# select regcollation('"POSIX"'); regcollation -------------- "POSIX" (1 row) On top of that, this needs tests with to_regcollation() and tests with schema-qualified collations. Documentation for to_regcollation() is missing. And it looks that many parts of the documentation are missing an update. One example in datatype.sgml: Type <type>oid</type> represents an object identifier. There are also several alias types for <type>oid</type>: <type>regproc</type>, <type>regprocedure</type>, <type>regoper</type>, <type>regoperator</type>, <type>regclass</type>, <type>regtype</type>, <type>regrole</type>, <type>regnamespace</type>, <type>regconfig</type>, and <type>regdictionary</type>. <xref linkend="datatype-oid-table"/> shows an overview. At quick glance, there are more sections in need of a refresh.. -- Michael
Attachment
On Mon, Mar 16, 2020 at 04:57:38PM +0900, Michael Paquier wrote: > On Thu, Mar 12, 2020 at 03:00:26PM +0100, Julien Rouhaud wrote: > > And v15 due to conflict with b08dee24a5 (Add pg_dump support for ALTER obj > > DEPENDS ON EXTENSION). > > I have looked at patches 0001~0003 in the set for now. Thanks! > In patch 0002, you have the following addition: > @@ -103,9 +103,10 @@ ORDER BY 1, 2; > pg_class | relacl | aclitem[] > pg_class | reloptions | text[] > pg_class | relpartbound | pg_node_tree > + pg_depend | refobjversion | text > This comes from a regression test doing a sanity check to look for > catalogs which have a toastable column but no toast tables. As an > exception, it should be documented in the test's comment. Actually, > does it need to be an exception? This does not depend on > relation-level facilities so there should be no risk of recursive > dependencies, though I have not looked in details at this part. I totally missed that, and I agree that there's no need for an exception, so fixed. > + <para> > + The only current use of <structfield>refobjversion</structfield> is to > + record dependencies between indexes and collation versions. > + </para> > [...] > + <row> > + <entry><structfield>refobjversion</structfield></entry> > + <entry><type>text</type></entry> > + <entry></entry> > + <entry> > + An optional version for the referenced object; see text > + </entry> > + </row> > Couldn't you merge both paragraphs here? Done. > Regarding patch 0003, it would be nice to include some tests > independent on the rest and making use of the new functions. These > normally go in regproc.sql. For example with a collation that needs > double quotes as this is not obvious: > =# select regcollation('"POSIX"'); > regcollation > -------------- > "POSIX" > (1 row) > > On top of that, this needs tests with to_regcollation() and tests with > schema-qualified collations. Done too, using the same collation name, for both with and without schema qualification. > Documentation for to_regcollation() is missing. And it looks that > many parts of the documentation are missing an update. One example in > datatype.sgml: > Type <type>oid</type> represents an object identifier. There are also > several alias types for <type>oid</type>: <type>regproc</type>, > <type>regprocedure</type>, <type>regoper</type>, <type>regoperator</type>, > <type>regclass</type>, <type>regtype</type>, <type>regrole</type>, > <type>regnamespace</type>, <type>regconfig</type>, and > <type>regdictionary</type>. <xref linkend="datatype-oid-table"/> shows an > overview. > At quick glance, there are more sections in need of a refresh.. Indeed. I found missing reference in datatype.sgml; func.sgml and pgupgrade.sgml. v16 attached.
Attachment
- v16-0001-Remove-pg_collation.collversion.patch
- v16-0002-Add-pg_depend.refobjversion.patch
- v16-0003-Implement-type-regcollation.patch
- v16-0004-Track-collation-versions-for-indexes.patch
- v16-0005-Preserve-index-dependencies-on-collation-during-.patch
- v16-0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v16-0007-doc-Add-Collation-Versions-section.patch
On Mon, Mar 16, 2020 at 03:05:20PM +0100, Julien Rouhaud wrote: > On Mon, Mar 16, 2020 at 04:57:38PM +0900, Michael Paquier wrote: >> This comes from a regression test doing a sanity check to look for >> catalogs which have a toastable column but no toast tables. As an >> exception, it should be documented in the test's comment. Actually, >> does it need to be an exception? This does not depend on >> relation-level facilities so there should be no risk of recursive >> dependencies, though I have not looked in details at this part. > > I totally missed that, and I agree that there's no need for an exception, so > fixed. How long can actually be collation version strings? Note also 96cdeae, which makes sense for pg_depend to have one. >> Regarding patch 0003, it would be nice to include some tests >> independent on the rest and making use of the new functions. These >> normally go in regproc.sql. For example with a collation that needs >> double quotes as this is not obvious: >> =# select regcollation('"POSIX"'); >> regcollation >> -------------- >> "POSIX" >> (1 row) >> >> On top of that, this needs tests with to_regcollation() and tests with >> schema-qualified collations. > > > Done too, using the same collation name, for both with and without schema > qualification. It seems to me that you could add an extra test with a catalog that does not exist, making sure that NULL is returned: SELECT to_regtype('ng_catalog."POSIX"'); The other two cases are not really doable in regproc.sql as they would show up the encoding used in the error message, but there could be a point to include them in collate.icu.utf8.sql or equivalent. > Indeed. I found missing reference in datatype.sgml; func.sgml and > pgupgrade.sgml. That looks right. <entry> <indexterm><primary>pg_collation_actual_version</primary></indexterm> - <literal><function>pg_collation_actual_version(<type>oid</type>)</function></literal> + <literal><function>pg_collation_actual_version(<type>regcollation</type>)</function></literal> </entry> The function's input argument is not changed, why? Patch 0003 is visibly getting in shape, and that's an independent piece. I guess that Thomas is looking at that, so let's wait for his input. Note that patch 0002 fails to compile because it is missing to include utils/builtins.h for CStringGetTextDatum(), and that you cannot pass down a NameData to this API, because it needs a simple char string or you would need NameStr() or such. Anyway, it happens that you don't need recordDependencyOnVersion() at all, because it is removed by patch 0004 in the set, so you could just let it go. I am still looking at the rest as of 0004~0007, the largest pieces. -- Michael
Attachment
On Tue, Mar 17, 2020 at 03:37:49PM +0900, Michael Paquier wrote: > On Mon, Mar 16, 2020 at 03:05:20PM +0100, Julien Rouhaud wrote: > > On Mon, Mar 16, 2020 at 04:57:38PM +0900, Michael Paquier wrote: > >> This comes from a regression test doing a sanity check to look for > >> catalogs which have a toastable column but no toast tables. As an > >> exception, it should be documented in the test's comment. Actually, > >> does it need to be an exception? This does not depend on > >> relation-level facilities so there should be no risk of recursive > >> dependencies, though I have not looked in details at this part. > > > > I totally missed that, and I agree that there's no need for an exception, so > > fixed. > > How long can actually be collation version strings? Note also > 96cdeae, which makes sense for pg_depend to have one. Versions shouldn't be that long usually, but there were some previous discussions on how to try to come up with some workaround on systems that don't provide a version, using a hash of the underlying file or something like that. Using a hash value big enough to require toasting wouldn't make much sense, but it feels safer to be ready to handle any later use, whether for collation or other kind of objects > >> Regarding patch 0003, it would be nice to include some tests > >> independent on the rest and making use of the new functions. These > >> normally go in regproc.sql. For example with a collation that needs > >> double quotes as this is not obvious: > >> =# select regcollation('"POSIX"'); > >> regcollation > >> -------------- > >> "POSIX" > >> (1 row) > >> > >> On top of that, this needs tests with to_regcollation() and tests with > >> schema-qualified collations. > > > > > > Done too, using the same collation name, for both with and without schema > > qualification. > > It seems to me that you could add an extra test with a catalog that > does not exist, making sure that NULL is returned: > SELECT to_regtype('ng_catalog."POSIX"'); Agreed, I'll add that, but using a name that looks less like a typo :) > <entry> > <indexterm><primary>pg_collation_actual_version</primary></indexterm> > - <literal><function>pg_collation_actual_version(<type>oid</type>)</function></literal> > + <literal><function>pg_collation_actual_version(<type>regcollation</type>)</function></literal> > </entry> > The function's input argument is not changed, why? That's a mistake, will fix. > Patch 0003 is visibly getting in shape, and that's an independent > piece. I guess that Thomas is looking at that, so let's wait for his > input. > > Note that patch 0002 fails to compile because it is missing to include > utils/builtins.h for CStringGetTextDatum(), and that you cannot pass > down a NameData to this API, because it needs a simple char string or > you would need NameStr() or such. Anyway, it happens that you don't > need recordDependencyOnVersion() at all, because it is removed by > patch 0004 in the set, so you could just let it go. Ah good catch, I missed that during the NameData/text refactoring. I'll fix it anyway, better to have clean history.
On Tue, Mar 17, 2020 at 08:19:30AM +0100, Julien Rouhaud wrote: > On Tue, Mar 17, 2020 at 03:37:49PM +0900, Michael Paquier wrote: > > On Mon, Mar 16, 2020 at 03:05:20PM +0100, Julien Rouhaud wrote: > > > On Mon, Mar 16, 2020 at 04:57:38PM +0900, Michael Paquier wrote: > > > >> Regarding patch 0003, it would be nice to include some tests > > >> independent on the rest and making use of the new functions. These > > >> normally go in regproc.sql. For example with a collation that needs > > >> double quotes as this is not obvious: > > >> =# select regcollation('"POSIX"'); > > >> regcollation > > >> -------------- > > >> "POSIX" > > >> (1 row) > > >> > > >> On top of that, this needs tests with to_regcollation() and tests with > > >> schema-qualified collations. > > > > > > > > > Done too, using the same collation name, for both with and without schema > > > qualification. > > > > It seems to me that you could add an extra test with a catalog that > > does not exist, making sure that NULL is returned: > > SELECT to_regtype('ng_catalog."POSIX"'); > > > Agreed, I'll add that, but using a name that looks less like a typo :) Tests added, including one with an error output, as the not existing schema doesn't reveal the encoding. > > Note that patch 0002 fails to compile because it is missing to include > > utils/builtins.h for CStringGetTextDatum(), and that you cannot pass > > down a NameData to this API, because it needs a simple char string or > > you would need NameStr() or such. Anyway, it happens that you don't > > need recordDependencyOnVersion() at all, because it is removed by > > patch 0004 in the set, so you could just let it go. > > > Ah good catch, I missed that during the NameData/text refactoring. I'll fix it > anyway, better to have clean history. And this should be fixed too.
Attachment
- v16-0001-Remove-pg_collation.collversion.patch
- v16-0002-Add-pg_depend.refobjversion.patch
- v16-0003-Implement-type-regcollation.patch
- v16-0004-Track-collation-versions-for-indexes.patch
- v16-0005-Preserve-index-dependencies-on-collation-during-.patch
- v16-0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v16-0007-doc-Add-Collation-Versions-section.patch
Did we discuss the regcollation type? In the current patch set, it's only used in two places in a new regression test, where it can easily be replaced by a join. Do we need it? I realize we've been adding new reg* types lately; I'm not sure what the current idea is on that. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Re: Peter Eisentraut 2020-03-17 <fd8d4475-85ad-506f-2dda-f4d6e66785bc@2ndquadrant.com> > Did we discuss the regcollation type? In the current patch set, it's only > used in two places in a new regression test, where it can easily be replaced > by a join. Do we need it? > > I realize we've been adding new reg* types lately; I'm not sure what the > current idea is on that. Not sure if that's the case there, but reg* typecasts are very handy when used interactively in ad-hoc queries. Christoph
On Tue, Mar 17, 2020 at 05:31:47PM +0100, Christoph Berg wrote: > Re: Peter Eisentraut 2020-03-17 <fd8d4475-85ad-506f-2dda-f4d6e66785bc@2ndquadrant.com> > > Did we discuss the regcollation type? In the current patch set, it's only > > used in two places in a new regression test, where it can easily be replaced > > by a join. Do we need it? I originally wrote it for a previous version of the patchset, to shorten the pg_dump query, but that went out when I replaced the DDL command with native functions instead. It didn't seem to hurt to keep it, so I relied on it in the regression tests. > > I realize we've been adding new reg* types lately; I'm not sure what the > > current idea is on that. > > Not sure if that's the case there, but reg* typecasts are very handy > when used interactively in ad-hoc queries. +1. I'm obviously biased, but I find it quite useful when querying pg_depend, which may become more frequent once we start generating warnings about possibly corrupted indexes.
On Tue, Mar 17, 2020 at 06:43:51PM +0100, Julien Rouhaud wrote: > On Tue, Mar 17, 2020 at 05:31:47PM +0100, Christoph Berg wrote: >> Not sure if that's the case there, but reg* typecasts are very handy >> when used interactively in ad-hoc queries. > > +1. I'm obviously biased, but I find it quite useful when querying pg_depend, > which may become more frequent once we start generating warnings about possibly > corrupted indexes. That means less joins for lookup queries, and collations can be schema-qualified, so I would be in favor of adding it rather than not. Now, it is true as well that ::regcollation is not a mandatory requirement for the feature discussed on this thread. -- Michael
Attachment
On Tue, Mar 17, 2020 at 11:42:34AM +0100, Julien Rouhaud wrote: > On Tue, Mar 17, 2020 at 08:19:30AM +0100, Julien Rouhaud wrote: >> On Tue, Mar 17, 2020 at 03:37:49PM +0900, Michael Paquier wrote: >>> It seems to me that you could add an extra test with a catalog that >>> does not exist, making sure that NULL is returned: >>> SELECT to_regtype('ng_catalog."POSIX"'); >> >> >> Agreed, I'll add that, but using a name that looks less like a typo :) > > Tests added, including one with an error output, as the not existing schema > doesn't reveal the encoding. Yep. >> Ah good catch, I missed that during the NameData/text refactoring. I'll fix it >> anyway, better to have clean history. > > And this should be fixed too. Thanks. It would be good to be careful about the indentation. Certain parts of 0003 don't respect the core indentation. Not necessarily your job though. Other than that 0003 seems to be in good shape. @@ -54,6 +55,7 @@ recordDependencyOn(const ObjectAddress *depender, void recordMultipleDependencies(const ObjectAddress *depender, const ObjectAddress *referenced, + const char *version, int nreferenced, DependencyType behavior) Nit from patch 0002: the argument "version" should be fourth I think, keeping the number of referenced objects and the referenced objects close. And actually, this "version" argument is removed in patch 0004, replaced by the boolean track_version. (By reading the arguments below I'd rather keep *version). So, 0004 is the core of the changes. I have found a bug with the handling of refobjversion and pg_depend entries. When swapping the dependencies of the old and new indexes in index_concurrently_swap(), refobjversion remains set to the value of the old index. I used a manual UPDATE on pg_depend to emulate that with a past fake version string to emulate that (sneaky I know), but you would get the same behavior with an upgraded instance. refobjversion should be updated to the version of the new index. +void recordDependencyOnCollations(ObjectAddress *myself, + List *collations, + bool record_version) Incorrect declaration format. + if (track_version) + { + /* Only dependency on a collation is supported. */ + if (referenced->classId == CollationRelationId) + { + /* C and POSIX collations don't require tracking the version */ + if (referenced->objectId == C_COLLATION_OID || + referenced->objectId == POSIX_COLLATION_OID) + continue; I don't think that the API is right for this stuff, as you introduce collation-level knowledge into something which has been much more flexible until now. Wouldn't it be better to move the refobjversion string directly into ObjectAddress? + * Test if a record exists for the given depender and referenceds addresses. [...] + /* recordDependencyOnSingleRelExpr get rid of duplicate entries */ Typos. + /* XXX should we warn about "disappearing" versions? */ + if (current_version) What are disappearing version strings? + /* + * Perform version sanity checks on the relation underlying indexes if + * it's not a VACUUM FULL + */ + if (!(options & VACOPT_FULL) && onerel && !IsSystemRelation(onerel) && + onerel->rd_rel->relhasindex) Should this explain why? + /* Record collations from the type itself, or underlying in case of + * complex type. Note that if the direct parent is a CollateExpr + * node, there's no need to record the type underlying collation if Comment block format. +-- for key columns, hash indexes should record dependency on the collation but +-- not the version +CREATE INDEX icuidx18_hash_d_es ON collate_test USING hash (d_es); Why is that? The code in 0004 has no mention of that, and relies on this code path: +/* + * Returns whether the given index access method depend on a stable collation + * order. + */ +static bool +index_depends_stable_coll_order(Oid amoid) +{ + return (amoid != HASH_AM_OID && + strcmp(get_am_name(amoid), "bloom") != 0); +} And how is that even extensible for custom index AMs? There are other things than bloom out there. + /* + * We only care about dependencies on a specific collation if a valid Oid + * was given.= + */ [...] + /* + * do not issue UNKNOWN VERSION is caller specified that those are + * compatible + */ Typos from patch 5. - $self->logfile, '-o', "--cluster-name=$name", 'start'); + $self->logfile, '-o', $options, 'start'); This needs to actually be shaped with two separate arguments for --cluster-name or using quotes would not work properly if I recall correctly. Not your patch's fault, so I would fix that separately. -- Michael
Attachment
On Wed, Mar 18, 2020 at 04:55:25PM +0900, Michael Paquier wrote: > On Tue, Mar 17, 2020 at 11:42:34AM +0100, Julien Rouhaud wrote: > > On Tue, Mar 17, 2020 at 08:19:30AM +0100, Julien Rouhaud wrote: > > It would be good to be careful about the indentation. Certain parts > of 0003 don't respect the core indentation. Not necessarily your job > though. Other than that 0003 seems to be in good shape. I'll try to do a partial pgindent run on all patches before next patchset. > > @@ -54,6 +55,7 @@ recordDependencyOn(const ObjectAddress *depender, > void > recordMultipleDependencies(const ObjectAddress *depender, > const ObjectAddress *referenced, > + const char *version, > int nreferenced, > DependencyType behavior) > Nit from patch 0002: the argument "version" should be fourth I think, > keeping the number of referenced objects and the referenced objects > close. And actually, this "version" argument is removed in patch > 0004, replaced by the boolean track_version. (By reading the > arguments below I'd rather keep *version). > > So, 0004 is the core of the changes. I have found a bug with the > handling of refobjversion and pg_depend entries. When swapping the > dependencies of the old and new indexes in index_concurrently_swap(), > refobjversion remains set to the value of the old index. I used a > manual UPDATE on pg_depend to emulate that with a past fake version > string to emulate that (sneaky I know), but you would get the same > behavior with an upgraded instance. refobjversion should be updated > to the version of the new index. Oh good catch. I'll dig into it. > + if (track_version) > + { > + /* Only dependency on a collation is supported. */ > + if (referenced->classId == CollationRelationId) > + { > + /* C and POSIX collations don't require tracking the version */ > + if (referenced->objectId == C_COLLATION_OID || > + referenced->objectId == POSIX_COLLATION_OID) > + continue; > I don't think that the API is right for this stuff, as you introduce > collation-level knowledge into something which has been much more > flexible until now. Wouldn't it be better to move the refobjversion > string directly into ObjectAddress? We could, but we would then need to add code to retrieve the collation version in multiple places (at least RecordDependencyOnCollation and recordDependencyOnSingleRelExpr). I'm afraid that'll open room for bugs if some other places are missed, now or later, even more if more objects get a versionning support. > + * Test if a record exists for the given depender and referenceds addresses. > [...] > + /* recordDependencyOnSingleRelExpr get rid of duplicate entries */ > Typos. > > + /* XXX should we warn about "disappearing" versions? */ > + if (current_version) > What are disappearing version strings? A collation for which a version was previously recorded but that now doesn't report a version anymore. For instance if upgrading from glibc X.Y to X.Z changes gnu_get_libc_version() to return NULL, or if a new major pg version removes support for glibc (or other lib) versioning. It seems unlikely to happen, and if that happens there's nothing we can do anymore to warn about possible corruption anyway. > + /* > + * Perform version sanity checks on the relation underlying indexes if > + * it's not a VACUUM FULL > + */ > + if (!(options & VACOPT_FULL) && onerel && !IsSystemRelation(onerel) && > + onerel->rd_rel->relhasindex) > Should this explain why? I was assuming it's self explanatory, since VACUUM FULL is one of the 3 only ways to fix a possibly corrupt index (on top of REINDEX and ALTER INDEX ... ALTER COLLATION ... REFRESH VERSION). I can mention it if needed though. > > + /* Record collations from the type itself, or underlying in case of > + * complex type. Note that if the direct parent is a CollateExpr > + * node, there's no need to record the type underlying collation if > Comment block format. Oops, will fix. > +-- for key columns, hash indexes should record dependency on the collation but > +-- not the version > +CREATE INDEX icuidx18_hash_d_es ON collate_test USING hash (d_es); > Why is that? Because hash indexes don't rely on the sort order for the key columns? So even if the sort order changes the index won't get corrupted (unless it's a non deterministic collation of course). > The code in 0004 has no mention of that, and relies on > this code path: > +/* > + * Returns whether the given index access method depend on a stable collation > + * order. > + */ > +static bool > +index_depends_stable_coll_order(Oid amoid) > +{ > + return (amoid != HASH_AM_OID && > + strcmp(get_am_name(amoid), "bloom") != 0); > +} This is handled in index_create(): + /* + * For deterministic transaction, only track the version if the AM + * relies on a stable ordering. + */ + if (determ_colls) + { + bool track_version; + + track_version = index_depends_stable_coll_order(indexInfo->ii_Am); + + recordDependencyOnCollations(&myself, determ_colls, track_version); > And how is that even extensible for custom index AMs? There are other > things than bloom out there. That's not extensible, and that was discussed a month ago at https://www.postgresql.org/message-id/CA%2BhUKGJ-TqYomCAYgJt53_0b9KmfSyD2qW59xfzmZa3ftRJFzA%40mail.gmail.com. Thomas was in favor of handling that at the operator level, but it seems to me that this would require quite a lot of extra work (assuming that we'd need to find if the opclass handles any operator different from BTEqualStrategyNumber), but I'm still not sure that it's sufficient to prove that an AM doesn't internally rely on a stable ordering or not. So I'd be in favor of adding a new field in IndexAmRoutine for that. Without consensus on that, I choose the quickest approach. Do you have any opinion on that? > - $self->logfile, '-o', "--cluster-name=$name", 'start'); > + $self->logfile, '-o', $options, 'start'); > This needs to actually be shaped with two separate arguments for > --cluster-name or using quotes would not work properly if I recall > correctly. Not your patch's fault, so I would fix that separately. Ok!
On Wed, Mar 18, 2020 at 09:56:40AM +0100, Julien Rouhaud wrote: > On Wed, Mar 18, 2020 at 04:55:25PM +0900, Michael Paquier wrote: > > > > It would be good to be careful about the indentation. Certain parts > > of 0003 don't respect the core indentation. Not necessarily your job > > though. Other than that 0003 seems to be in good shape. > > I'll try to do a partial pgindent run on all patches before next patchset. I run a pgindent on all .[ch] files and kept only the relevant changes, for each patch, so this should now be fine. > > > > @@ -54,6 +55,7 @@ recordDependencyOn(const ObjectAddress *depender, > > void > > recordMultipleDependencies(const ObjectAddress *depender, > > const ObjectAddress *referenced, > > + const char *version, > > int nreferenced, > > DependencyType behavior) > > Nit from patch 0002: the argument "version" should be fourth I think, > > keeping the number of referenced objects and the referenced objects > > close. And actually, this "version" argument is removed in patch > > 0004, replaced by the boolean track_version. (By reading the > > arguments below I'd rather keep *version). I changed 0002 to have the version as the 4th argument just in case. > > So, 0004 is the core of the changes. I have found a bug with the > > handling of refobjversion and pg_depend entries. When swapping the > > dependencies of the old and new indexes in index_concurrently_swap(), > > refobjversion remains set to the value of the old index. I used a > > manual UPDATE on pg_depend to emulate that with a past fake version > > string to emulate that (sneaky I know), but you would get the same > > behavior with an upgraded instance. refobjversion should be updated > > to the version of the new index. > > Oh good catch. I'll dig into it. AFAICT it was only missing a call to index_update_collation_versions() in ReindexRelationConcurrently. I added regression tests to make sure that REINDEX, REINDEX [INDEX|TABLE] CONCURRENTLY and VACUUM FULL are doing what's expected. Given discussion in nearby threads, I obviously can't add tests for failed REINDEX CONCURRENTLY, so here's what's happening with a manual repro: =# CREATE TABLE t1(id integer, val text); CREATE =# CREATE INDEX ON t1(val COLLATE "fr-x-icu"); CREATE =# UPDATE pg_depend SET refobjversion = 'meh' WHERE refobjversion = '153.97'; UPDATE 1 =# REINDEX TABLE CONCURRENTLY t1 ; LOCATION: ReindexRelationConcurrently, indexcmds.c:2839 ^CCancel request sent ERROR: 57014: canceling statement due to user request LOCATION: ProcessInterrupts, postgres.c:3171 =# SELECT objid::regclass, indisvalid, refobjversion FROM pg_depend d JOIN pg_index i ON i.indexrelid = d.objid WHERE refobjversion IS NOT NULL; objid | indisvalid | refobjversion ------------------+------------+--------------- t1_val_idx_ccold | f | 153.97 t1_val_idx | t | meh (2 rows) =# REINDEX TABLE t1; WARNING: 0A000: cannot reindex invalid index "pg_toast.pg_toast_16418_index_ccold" on TOAST table, skipping LOCATION: reindex_relation, index.c:3987 REINDEX =# SELECT objid::regclass, indisvalid, refobjversion FROM pg_depend d JOIN pg_index i ON i.indexrelid = d.objid WHERE refobjversion IS NOT NULL; objid | indisvalid | refobjversion ------------------+------------+--------------- t1_val_idx_ccold | t | 153.97 t1_val_idx | t | 153.97 (2 rows) ISTM that it's working as intended. > > + if (track_version) > > + { > > + /* Only dependency on a collation is supported. */ > > + if (referenced->classId == CollationRelationId) > > + { > > + /* C and POSIX collations don't require tracking the version */ > > + if (referenced->objectId == C_COLLATION_OID || > > + referenced->objectId == POSIX_COLLATION_OID) > > + continue; > > I don't think that the API is right for this stuff, as you introduce > > collation-level knowledge into something which has been much more > > flexible until now. Wouldn't it be better to move the refobjversion > > string directly into ObjectAddress? > > We could, but we would then need to add code to retrieve the collation version > in multiple places (at least RecordDependencyOnCollation and > recordDependencyOnSingleRelExpr). I'm afraid that'll open room for bugs if > some other places are missed, now or later, even more if more objects get a > versionning support. No change here. > > + /* > > + * Perform version sanity checks on the relation underlying indexes if > > + * it's not a VACUUM FULL > > + */ > > + if (!(options & VACOPT_FULL) && onerel && !IsSystemRelation(onerel) && > > + onerel->rd_rel->relhasindex) > > Should this explain why? Explanation added. v17 attached, rebased against master (conflict since 8408e3a557).
Attachment
- v17-0001-Remove-pg_collation.collversion.patch
- v17-0002-Add-pg_depend.refobjversion.patch
- v17-0003-Implement-type-regcollation.patch
- v17-0004-Track-collation-versions-for-indexes.patch
- v17-0005-Preserve-index-dependencies-on-collation-during-.patch
- v17-0006-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v17-0007-doc-Add-Collation-Versions-section.patch
On 2020-03-17 18:43, Julien Rouhaud wrote: > On Tue, Mar 17, 2020 at 05:31:47PM +0100, Christoph Berg wrote: >> Re: Peter Eisentraut 2020-03-17<fd8d4475-85ad-506f-2dda-f4d6e66785bc@2ndquadrant.com> >>> Did we discuss the regcollation type? In the current patch set, it's only >>> used in two places in a new regression test, where it can easily be replaced >>> by a join. Do we need it? > > I originally wrote it for a previous version of the patchset, to shorten the > pg_dump query, but that went out when I replaced the DDL command with native > functions instead. It didn't seem to hurt to keep it, so I relied on it in the > regression tests. OK, I have committed the regcollation patch, and some surrounding cleanup of the reg* types documentation. Note that your patch updated the pg_upgrade documentation to say that tables with regcollation columns cannot be upgraded but didn't actually patch the pg_upgrade code to make that happen. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Wed, Mar 18, 2020 at 09:29:55PM +0100, Peter Eisentraut wrote: > On 2020-03-17 18:43, Julien Rouhaud wrote: > > On Tue, Mar 17, 2020 at 05:31:47PM +0100, Christoph Berg wrote: > > > Re: Peter Eisentraut 2020-03-17<fd8d4475-85ad-506f-2dda-f4d6e66785bc@2ndquadrant.com> > > > > Did we discuss the regcollation type? In the current patch set, it's only > > > > used in two places in a new regression test, where it can easily be replaced > > > > by a join. Do we need it? > > > > I originally wrote it for a previous version of the patchset, to shorten the > > pg_dump query, but that went out when I replaced the DDL command with native > > functions instead. It didn't seem to hurt to keep it, so I relied on it in the > > regression tests. > > OK, I have committed the regcollation patch, and some surrounding cleanup of > the reg* types documentation. Thanks! > Note that your patch updated the pg_upgrade documentation to say that tables > with regcollation columns cannot be upgraded but didn't actually patch the > pg_upgrade code to make that happen. Oh right, sorry for that I shouldn't have miss it:(
On Wed, Mar 18, 2020 at 09:29:55PM +0100, Peter Eisentraut wrote: > OK, I have committed the regcollation patch, and some surrounding cleanup of > the reg* types documentation. Thanks, Peter. -- Michael
Attachment
On Wed, Mar 18, 2020 at 04:35:43PM +0100, Julien Rouhaud wrote: > On Wed, Mar 18, 2020 at 09:56:40AM +0100, Julien Rouhaud wrote: > AFAICT it was only missing a call to index_update_collation_versions() in > ReindexRelationConcurrently. I added regression tests to make sure that > REINDEX, REINDEX [INDEX|TABLE] CONCURRENTLY and VACUUM FULL are doing what's > expected. If you add a call to index_update_collation_versions(), the old and invalid index will use the same refobjversion as the new index, which is the latest collation version of the system, no? If the operation is interrupted before the invalid index is dropped, then we would keep a confusing value for refobjversion, because the old invalid index does not rely on the new collation version, but on the old one. Hence, it seems to me that it would be correct to have the old invalid index either use an empty version string to say "we don't know" because the index is invalid anyway, or keep a reference to the old collation version intact. I think that the latter is much more useful for debugging issues when upgrading a subset of indexes if the operation is interrupted for a reason or another. > Given discussion in nearby threads, I obviously can't add tests for failed > REINDEX CONCURRENTLY, so here's what's happening with a manual repro: > > =# UPDATE pg_depend SET refobjversion = 'meh' WHERE refobjversion = '153.97'; > UPDATE 1 Updates to catalogs are not an existing practice in the core regression tests, so patches had better not do that. :p > =# REINDEX TABLE CONCURRENTLY t1 ; > LOCATION: ReindexRelationConcurrently, indexcmds.c:2839 > ^CCancel request sent > ERROR: 57014: canceling statement due to user request > LOCATION: ProcessInterrupts, postgres.c:3171 I guess that you used a second session here beginning a transaction before REINDEX CONCURRENTLY ran here so as it would stop after swapping dependencies, right? > =# SELECT objid::regclass, indisvalid, refobjversion > FROM pg_depend d > JOIN pg_index i ON i.indexrelid = d.objid > WHERE refobjversion IS NOT NULL; > objid | indisvalid | refobjversion > ------------------+------------+--------------- > t1_val_idx_ccold | f | 153.97 > t1_val_idx | t | meh > (2 rows) > > =# REINDEX TABLE t1; > WARNING: 0A000: cannot reindex invalid index "pg_toast.pg_toast_16418_index_ccold" on TOAST table, skipping > LOCATION: reindex_relation, index.c:3987 > REINDEX > > =# SELECT objid::regclass, indisvalid, refobjversion > FROM pg_depend d > JOIN pg_index i ON i.indexrelid = d.objid > WHERE refobjversion IS NOT NULL; > objid | indisvalid | refobjversion > ------------------+------------+--------------- > t1_val_idx_ccold | t | 153.97 > t1_val_idx | t | 153.97 > (2 rows) > > ISTM that it's working as intended. After a non-concurrent reindex, this information is right. However based on the output of your test here, after REINDEX CONCURRENTLY the information held in refobjversion is incorrect for t1_val_idx_ccold and t1_val_idx. They should be reversed. -- Michael
Attachment
On Thu, Mar 19, 2020 at 12:31:54PM +0900, Michael Paquier wrote: > On Wed, Mar 18, 2020 at 04:35:43PM +0100, Julien Rouhaud wrote: > > On Wed, Mar 18, 2020 at 09:56:40AM +0100, Julien Rouhaud wrote: > > AFAICT it was only missing a call to index_update_collation_versions() in > > ReindexRelationConcurrently. I added regression tests to make sure that > > REINDEX, REINDEX [INDEX|TABLE] CONCURRENTLY and VACUUM FULL are doing what's > > expected. > > If you add a call to index_update_collation_versions(), the old and > invalid index will use the same refobjversion as the new index, which > is the latest collation version of the system, no? If the operation > is interrupted before the invalid index is dropped, then we would keep > a confusing value for refobjversion, because the old invalid index > does not rely on the new collation version, but on the old one. > Hence, it seems to me that it would be correct to have the old invalid > index either use an empty version string to say "we don't know" > because the index is invalid anyway, or keep a reference to the old > collation version intact. I think that the latter is much more useful > for debugging issues when upgrading a subset of indexes if the > operation is interrupted for a reason or another. Indeed, I confused the _ccold and _ccnew indexes. So, the root cause is phase 4, more precisely the dependency swap in index_concurrently_swap. A possible fix would be to teach changeDependenciesOf() to preserve the dependency version. It'd be quite bit costly as this would mean an extra index search for each dependency row found. We could probably skip the lookup if the row have a NULL recorded version, as version should either be null or non null for both objects. I'm wondering if that's a good time to make changeDependenciesOf and changeDependenciesOn private, and instead expose a swapDependencies(classid, obj1, obj2) that would call both, as preserving the version doesn't really makes sense outside a switch. It's als oa good way to ensure that no CCI is performed in the middle. > > Given discussion in nearby threads, I obviously can't add tests for failed > > REINDEX CONCURRENTLY, so here's what's happening with a manual repro: > > > > =# UPDATE pg_depend SET refobjversion = 'meh' WHERE refobjversion = '153.97'; > > UPDATE 1 > > Updates to catalogs are not an existing practice in the core > regression tests, so patches had better not do that. :p I already heavily relied on that in the previous version of the patchset. The only possible alternative would be to switch to TAP tests, and constantly restart the instance in binary upgrade mode to be able to call binary_upgrade_set_index_coll_version. I'd prefer to avoid that if that's possible, as it'll make the test way more complex and quite unreadable. > > =# REINDEX TABLE CONCURRENTLY t1 ; > > LOCATION: ReindexRelationConcurrently, indexcmds.c:2839 > > ^CCancel request sent > > ERROR: 57014: canceling statement due to user request > > LOCATION: ProcessInterrupts, postgres.c:3171 > > I guess that you used a second session here beginning a transaction > before REINDEX CONCURRENTLY ran here so as it would stop after > swapping dependencies, right? Yes, sorry for eluding that. I'm using a SELECT FOR UPDATE, same scenario as the recent issue with TOAST tables with REINDEX CONCURRENTLY.
On Thu, Mar 19, 2020 at 08:12:47PM +0100, Julien Rouhaud wrote: > On Thu, Mar 19, 2020 at 12:31:54PM +0900, Michael Paquier wrote: > > On Wed, Mar 18, 2020 at 04:35:43PM +0100, Julien Rouhaud wrote: > > > On Wed, Mar 18, 2020 at 09:56:40AM +0100, Julien Rouhaud wrote: > > > AFAICT it was only missing a call to index_update_collation_versions() in > > > ReindexRelationConcurrently. I added regression tests to make sure that > > > REINDEX, REINDEX [INDEX|TABLE] CONCURRENTLY and VACUUM FULL are doing what's > > > expected. > > > > If you add a call to index_update_collation_versions(), the old and > > invalid index will use the same refobjversion as the new index, which > > is the latest collation version of the system, no? If the operation > > is interrupted before the invalid index is dropped, then we would keep > > a confusing value for refobjversion, because the old invalid index > > does not rely on the new collation version, but on the old one. > > Hence, it seems to me that it would be correct to have the old invalid > > index either use an empty version string to say "we don't know" > > because the index is invalid anyway, or keep a reference to the old > > collation version intact. I think that the latter is much more useful > > for debugging issues when upgrading a subset of indexes if the > > operation is interrupted for a reason or another. > > Indeed, I confused the _ccold and _ccnew indexes. So, the root cause is phase > 4, more precisely the dependency swap in index_concurrently_swap. > > A possible fix would be to teach changeDependenciesOf() to preserve the > dependency version. It'd be quite bit costly as this would mean an extra index > search for each dependency row found. We could probably skip the lookup if the > row have a NULL recorded version, as version should either be null or non null > for both objects. > > I'm wondering if that's a good time to make changeDependenciesOf and > changeDependenciesOn private, and instead expose a swapDependencies(classid, > obj1, obj2) that would call both, as preserving the version doesn't really > makes sense outside a switch. It's als oa good way to ensure that no CCI is > performed in the middle. Hearing no complaints, I implemented that approach in attached v18. Here's the new behavior for interrupted REINDEX CONCURRENTLY: # drop table if exists t1;create table t1(id integer, val text); create index on t1(val collate "fr-x-icu"); NOTICE: 00000: table "t1" does not exist, skipping DROP TABLE CREATE TABLE CREATE INDEX # update pg_depend set refobjversion = 'meh' where refobjversion = '153.97'; UPDATE 1 # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; objid | indisvalid | refobjversion ------------+------------+--------------- t1_val_idx | t | meh (1 row) (on another session: begin; select * from t1 for update;) # reindex table CONCURRENTLY t1; ^CCancel request sent ERROR: 57014: canceling statement due to user request # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; objid | indisvalid | refobjversion ------------------+------------+--------------- t1_val_idx_ccold | f | meh t1_val_idx | t | 153.97 (2 rows) # reindex table CONCURRENTLY t1; WARNING: 0A000: cannot reindex invalid index "public.t1_val_idx_ccold" concurrently, skipping WARNING: XX002: cannot reindex invalid index "pg_toast.pg_toast_16385_index_ccold" concurrently, skipping REINDEX # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; objid | indisvalid | refobjversion ------------------+------------+--------------- t1_val_idx_ccold | f | meh t1_val_idx | t | 153.97 (2 rows) # reindex table t1; WARNING: 0A000: cannot reindex invalid index "pg_toast.pg_toast_16385_index_ccold" on TOAST table, skipping REINDEX # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; objid | indisvalid | refobjversion ------------------+------------+--------------- t1_val_idx_ccold | t | 153.97 t1_val_idx | t | 153.97 (2 rows) I also rebased the patchset against master (so removing the regcollation patch), but no other changes otherwise, so there's still the direct updates on the catalog in the regressoin tests.
Attachment
- v18-0001-Remove-pg_collation.collversion.patch
- v18-0002-Add-pg_depend.refobjversion.patch
- v18-0003-Track-collation-versions-for-indexes.patch
- v18-0004-Preserve-index-dependencies-on-collation-during-.patch
- v18-0005-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v18-0006-doc-Add-Collation-Versions-section.patch
On Fri, Mar 20, 2020 at 02:52:33PM +0100, Julien Rouhaud wrote: > On Thu, Mar 19, 2020 at 08:12:47PM +0100, Julien Rouhaud wrote: > > On Thu, Mar 19, 2020 at 12:31:54PM +0900, Michael Paquier wrote: > > > On Wed, Mar 18, 2020 at 04:35:43PM +0100, Julien Rouhaud wrote: > > > > On Wed, Mar 18, 2020 at 09:56:40AM +0100, Julien Rouhaud wrote: > > > > AFAICT it was only missing a call to index_update_collation_versions() in > > > > ReindexRelationConcurrently. I added regression tests to make sure that > > > > REINDEX, REINDEX [INDEX|TABLE] CONCURRENTLY and VACUUM FULL are doing what's > > > > expected. > > > > > > If you add a call to index_update_collation_versions(), the old and > > > invalid index will use the same refobjversion as the new index, which > > > is the latest collation version of the system, no? If the operation > > > is interrupted before the invalid index is dropped, then we would keep > > > a confusing value for refobjversion, because the old invalid index > > > does not rely on the new collation version, but on the old one. > > > Hence, it seems to me that it would be correct to have the old invalid > > > index either use an empty version string to say "we don't know" > > > because the index is invalid anyway, or keep a reference to the old > > > collation version intact. I think that the latter is much more useful > > > for debugging issues when upgrading a subset of indexes if the > > > operation is interrupted for a reason or another. > > > > Indeed, I confused the _ccold and _ccnew indexes. So, the root cause is phase > > 4, more precisely the dependency swap in index_concurrently_swap. > > > > A possible fix would be to teach changeDependenciesOf() to preserve the > > dependency version. It'd be quite bit costly as this would mean an extra index > > search for each dependency row found. We could probably skip the lookup if the > > row have a NULL recorded version, as version should either be null or non null > > for both objects. > > > > I'm wondering if that's a good time to make changeDependenciesOf and > > changeDependenciesOn private, and instead expose a swapDependencies(classid, > > obj1, obj2) that would call both, as preserving the version doesn't really > > makes sense outside a switch. It's als oa good way to ensure that no CCI is > > performed in the middle. > > Hearing no complaints, I implemented that approach in attached v18. > > Here's the new behavior for interrupted REINDEX CONCURRENTLY: > > # drop table if exists t1;create table t1(id integer, val text); create index on t1(val collate "fr-x-icu"); > NOTICE: 00000: table "t1" does not exist, skipping > DROP TABLE > CREATE TABLE > CREATE INDEX > > # update pg_depend set refobjversion = 'meh' where refobjversion = '153.97'; > UPDATE 1 > > # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; > objid | indisvalid | refobjversion > ------------+------------+--------------- > t1_val_idx | t | meh > (1 row) > > (on another session: begin; select * from t1 for update;) > > # reindex table CONCURRENTLY t1; > ^CCancel request sent > ERROR: 57014: canceling statement due to user request > > # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; > objid | indisvalid | refobjversion > ------------------+------------+--------------- > t1_val_idx_ccold | f | meh > t1_val_idx | t | 153.97 > (2 rows) > > # reindex table CONCURRENTLY t1; > WARNING: 0A000: cannot reindex invalid index "public.t1_val_idx_ccold" concurrently, skipping > WARNING: XX002: cannot reindex invalid index "pg_toast.pg_toast_16385_index_ccold" concurrently, skipping > REINDEX > > # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; > objid | indisvalid | refobjversion > ------------------+------------+--------------- > t1_val_idx_ccold | f | meh > t1_val_idx | t | 153.97 > (2 rows) > > # reindex table t1; > WARNING: 0A000: cannot reindex invalid index "pg_toast.pg_toast_16385_index_ccold" on TOAST table, skipping > REINDEX > > # select objid::regclass, indisvalid, refobjversion from pg_depend d join pg_index i on i.indexrelid = d.objid where refobjversionis not null; > objid | indisvalid | refobjversion > ------------------+------------+--------------- > t1_val_idx_ccold | t | 153.97 > t1_val_idx | t | 153.97 > (2 rows) > > > I also rebased the patchset against master (so removing the regcollation > patch), but no other changes otherwise, so there's still the direct updates on > the catalog in the regressoin tests. Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign servers), v19 attached.
Attachment
On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > servers), v19 attached. > New rebase due to recent conflicts.
Attachment
On Fri, Apr 24, 2020 at 4:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > > servers), v19 attached. > > > > New rebase due to recent conflicts. New conflict, v21 attached.
Attachment
On Tue, May 5, 2020 at 5:14 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Fri, Apr 24, 2020 at 4:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > > > > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > > > servers), v19 attached. > > > > > > > New rebase due to recent conflicts. > > New conflict, v21 attached. New conflict, v22 attached.
Attachment
On Sat, May 23, 2020 at 08:58:45PM +0200, Julien Rouhaud wrote: > On Tue, May 5, 2020 at 5:14 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > On Fri, Apr 24, 2020 at 4:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > > On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > > > > > > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > > > > servers), v19 attached. > > > > > > > > > > New rebase due to recent conflicts. > > > > New conflict, v21 attached. > > New conflict, v22 attached. Recent conflict on the documentation, v23 attached.
Attachment
vOn Thu, Jun 11, 2020 at 08:42:46AM +0200, Julien Rouhaud wrote: > On Sat, May 23, 2020 at 08:58:45PM +0200, Julien Rouhaud wrote: > > On Tue, May 5, 2020 at 5:14 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > > On Fri, Apr 24, 2020 at 4:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > > > > On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > > > > > > > > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > > > > > servers), v19 attached. > > > > > > > > > > > > > New rebase due to recent conflicts. > > > > > > New conflict, v21 attached. > > > > New conflict, v22 attached. > > Recent conflict on the documentation, v23 attached. Same, v24 attached.
Attachment
On Wed, Jul 01, 2020 at 10:52:37AM +0200, Julien Rouhaud wrote: > vOn Thu, Jun 11, 2020 at 08:42:46AM +0200, Julien Rouhaud wrote: > > On Sat, May 23, 2020 at 08:58:45PM +0200, Julien Rouhaud wrote: > > > On Tue, May 5, 2020 at 5:14 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > > > > On Fri, Apr 24, 2020 at 4:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > > > > > > > > On Thu, Apr 02, 2020 at 03:00:45PM +0200, Julien Rouhaud wrote: > > > > > > > > > > > > Conflict since 2f9eb3132 (pg_dump: Allow dumping data of specific foreign > > > > > > servers), v19 attached. > > > > > > > > > > > > > > > > New rebase due to recent conflicts. > > > > > > > > New conflict, v21 attached. > > > > > > New conflict, v22 attached. > > > > Recent conflict on the documentation, v23 attached. > > Same, v24 attached. And the recent ObjectAddress refactoring just broke the patchset again, so v25 attached.
Attachment
On Thu, Jul 2, 2020 at 3:03 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > And the recent ObjectAddress refactoring just broke the patchset again, so v25 > attached. I found some more things to remove from pg_dump.c and collationcmds.c relating pg_collation.collversion. I also updated a couple of mentions of release 13 in the code and docs, and made some minor language improvements here and there. I still wish I had a better idea than this: +/* + * Returns whether the given index access method depend on a stable collation + * order. + */ +static bool +index_depends_stable_coll_order(Oid amoid) +{ + return (amoid != HASH_AM_OID && + strcmp(get_am_name(amoid), "bloom") != 0); +} I'm doing some more testing and looking for weird cases... More soon.
Attachment
On Wed, Jul 08, 2020 at 06:12:51PM +1200, Thomas Munro wrote: > I still wish I had a better idea than this: > > +/* > + * Returns whether the given index access method depend on a stable collation > + * order. > + */ > +static bool > +index_depends_stable_coll_order(Oid amoid) > +{ > + return (amoid != HASH_AM_OID && > + strcmp(get_am_name(amoid), "bloom") != 0); > +} > > I'm doing some more testing and looking for weird cases... More soon. Wouldn't the normal way to track that a new field in IndexAmRoutine? What you have here is not extensible. -- Michael
Attachment
On 2020-07-08 08:26, Michael Paquier wrote: > On Wed, Jul 08, 2020 at 06:12:51PM +1200, Thomas Munro wrote: >> I still wish I had a better idea than this: >> >> +/* >> + * Returns whether the given index access method depend on a stable collation >> + * order. >> + */ >> +static bool >> +index_depends_stable_coll_order(Oid amoid) >> +{ >> + return (amoid != HASH_AM_OID && >> + strcmp(get_am_name(amoid), "bloom") != 0); >> +} >> >> I'm doing some more testing and looking for weird cases... More soon. > > Wouldn't the normal way to track that a new field in IndexAmRoutine? > What you have here is not extensible. Yeah, this should be decided and communicated by the index AM somehow. Perhaps it would also make sense to let the index AM handle the differences between deterministic and nondeterministic collations. I don't know how the bloom AM works, though, to determine whether that makes sense. In order not to derail this patch set I think it would be okay for now to just include all index AMs in dependency tracking and invent a mechanism later that excludes hash and bloom in an extensible manner. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Thu, Jul 9, 2020 at 10:00 AM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > > On 2020-07-08 08:26, Michael Paquier wrote: > > On Wed, Jul 08, 2020 at 06:12:51PM +1200, Thomas Munro wrote: > >> I still wish I had a better idea than this: > >> > >> +/* > >> + * Returns whether the given index access method depend on a stable collation > >> + * order. > >> + */ > >> +static bool > >> +index_depends_stable_coll_order(Oid amoid) > >> +{ > >> + return (amoid != HASH_AM_OID && > >> + strcmp(get_am_name(amoid), "bloom") != 0); > >> +} > >> > >> I'm doing some more testing and looking for weird cases... More soon. > > > > Wouldn't the normal way to track that a new field in IndexAmRoutine? > > What you have here is not extensible. > > Yeah, this should be decided and communicated by the index AM somehow. > > Perhaps it would also make sense to let the index AM handle the > differences between deterministic and nondeterministic collations. I > don't know how the bloom AM works, though, to determine whether that > makes sense. > > In order not to derail this patch set I think it would be okay for now > to just include all index AMs in dependency tracking and invent a > mechanism later that excludes hash and bloom in an extensible manner. FTR I'll be happy to take care of that.
On Thu, Jul 9, 2020 at 11:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Thu, Jul 9, 2020 at 10:00 AM Peter Eisentraut > <peter.eisentraut@2ndquadrant.com> wrote: > > In order not to derail this patch set I think it would be okay for now > > to just include all index AMs in dependency tracking and invent a > > mechanism later that excludes hash and bloom in an extensible manner. > > FTR I'll be happy to take care of that. Ok, thanks! Let's go with that.
On Fri, Jul 10, 2020 at 12:15:44PM +1200, Thomas Munro wrote: > On Thu, Jul 9, 2020 at 11:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Thu, Jul 9, 2020 at 10:00 AM Peter Eisentraut > > <peter.eisentraut@2ndquadrant.com> wrote: > > > In order not to derail this patch set I think it would be okay for now > > > to just include all index AMs in dependency tracking and invent a > > > mechanism later that excludes hash and bloom in an extensible manner. > > > > FTR I'll be happy to take care of that. > > Ok, thanks! Let's go with that. Thanks! Here's a rebased v27 that removes the current approach to ignore indexes that don't rely on a stable ordering. I'll start a new thread on that matter once the infrastructure pieces will be committed.
Attachment
On Thu, Aug 13, 2020 at 9:52 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > Here's a rebased v27 that removes the current approach to ignore indexes that > don't rely on a stable ordering. I'll start a new thread on that matter once > the infrastructure pieces will be committed. Thanks Julien. I'm planning to do a bit more testing and review, and then hopefully commit this next week. If anyone else has objections to this design, now would be a good time to speak up.
On Fri, Aug 14, 2020 at 02:21:58PM +1200, Thomas Munro wrote: > Thanks Julien. I'm planning to do a bit more testing and review, and > then hopefully commit this next week. If anyone else has objections > to this design, now would be a good time to speak up. The design to use pg_depend for the version string and rely on an unknown state for indexes whose collations are unknown has a clear consensus, so nothing to say about that. It looks like this will benefit from using multi-INSERTs with pg_depend, actually. I have read through the patch, and there are a couple of portions that could be improved and/or simplified. /* - * Adjust all dependency records to come from a different object of the same type * Swap all dependencies of and on the old index to the new one, and + * vice-versa, while preserving any referenced version for the original owners. + * Note that a call to CommandCounterIncrement() would cause duplicate entries + * in pg_depend, so this should not be done. + */ +void +swapDependencies(Oid classId, Oid firstObjectId, Oid secondObjectId) +{ + changeDependenciesOf(classId, firstObjectId, secondObjectId, true); + changeDependenciesOn(classId, firstObjectId, secondObjectId); + + changeDependenciesOf(classId, secondObjectId, firstObjectId, true); + changeDependenciesOn(classId, secondObjectId, firstObjectId); +} The comment on top of the routine is wrong, as it could apply to something else than indexes. Anyway, I don't think there is much value in adding this API as the only part where this counts is relation swapping for reindex concurrently. It could also be possible that this breaks some extension code by making those static to pg_depend.c. -long +static long changeDependenciesOf(Oid classId, Oid oldObjectId, - Oid newObjectId) + Oid newObjectId, bool preserve_version) All the callers of changeDependenciesOf() set the new argument to true, making the false path dead, even if it just implies that the argument is null. I would suggest to keep the original function signature. If somebody needs a version where they don't want to preserve the version, it could just be added later. + * We don't want to record redundant depedencies that are used + * to track versions to avoid redundant warnings in case of s/depedencies/dependencies/ + /* + * XXX For deterministic transaction, se should only track the version + * if the AM relies on a stable ordering. + */ + if (determ_colls) + { + /* XXX check if the AM relies on a stable ordering */ + recordDependencyOnCollations(&myself, determ_colls, true); Some cleanup needed here? Wouldn't it be better to address the issues with stable ordering first? + /* recordDependencyOnSingleRelExpr get rid of duplicated entries */ s/get/gets/, incorrect grammar. + /* XXX should we warn about "disappearing" versions? */ + if (current_version) + { Something to do here? + /* + * We now support versioning for the underlying collation library on + * this system, or previous version is unknown. + */ + if (!version || (strcmp(version, "") == 0 && strcmp(current_version, + "") != 0)) Strange diff format here. +static char * +index_check_collation_version(const ObjectAddress *otherObject, + const char *version, + void *userdata) All the new functions in index.c should have more documentation and comments to explain what they do. + foreach(lc, collations) + { + ObjectAddress referenced; + + ObjectAddressSet(referenced, CollationRelationId, lfirst_oid(lc)); + + recordMultipleDependencies(myself, &referenced, 1, + DEPENDENCY_NORMAL, record_version); + } I think that you could just use an array of ObjectAddresses here, fill in a set of ObjectAddress objects and just call recordMultipleDependencies() for all of them? Just create a set using new_object_addresses(), register them with add_exact_object_address(), and then finish the job with record_object_address_dependencies(). -- Michael
Attachment
Hi Michael, On Fri, Aug 14, 2020 at 04:37:46PM +0900, Michael Paquier wrote: > On Fri, Aug 14, 2020 at 02:21:58PM +1200, Thomas Munro wrote: > > Thanks Julien. I'm planning to do a bit more testing and review, and > > then hopefully commit this next week. If anyone else has objections > > to this design, now would be a good time to speak up. > > The design to use pg_depend for the version string and rely on an > unknown state for indexes whose collations are unknown has a clear > consensus, so nothing to say about that. It looks like this will > benefit from using multi-INSERTs with pg_depend, actually. > > I have read through the patch, and there are a couple of portions that > could be improved and/or simplified. > > /* > - * Adjust all dependency records to come from a different object of the same type > * Swap all dependencies of and on the old index to the new one, and > + * vice-versa, while preserving any referenced version for the original owners. > + * Note that a call to CommandCounterIncrement() would cause duplicate entries > + * in pg_depend, so this should not be done. > + */ > +void > +swapDependencies(Oid classId, Oid firstObjectId, Oid secondObjectId) > +{ > + changeDependenciesOf(classId, firstObjectId, secondObjectId, true); > + changeDependenciesOn(classId, firstObjectId, secondObjectId); > + > + changeDependenciesOf(classId, secondObjectId, firstObjectId, true); > + changeDependenciesOn(classId, secondObjectId, firstObjectId); > +} > > The comment on top of the routine is wrong, as it could apply to > something else than indexes. Anyway, I don't think there is much > value in adding this API as the only part where this counts is > relation swapping for reindex concurrently. It could also be possible > that this breaks some extension code by making those static to > pg_depend.c. It seemed cleaner but ok, fixed. > > -long > +static long > changeDependenciesOf(Oid classId, Oid oldObjectId, > - Oid newObjectId) > + Oid newObjectId, bool preserve_version) > All the callers of changeDependenciesOf() set the new argument to > true, making the false path dead, even if it just implies that the > argument is null. I would suggest to keep the original function > signature. If somebody needs a version where they don't want to > preserve the version, it could just be added later. Fixed. > > + * We don't want to record redundant depedencies that are used > + * to track versions to avoid redundant warnings in case of > s/depedencies/dependencies/ > > + /* > + * XXX For deterministic transaction, se should only track the > version > + * if the AM relies on a stable ordering. > + */ > + if (determ_colls) > + { > + /* XXX check if the AM relies on a stable ordering */ > + recordDependencyOnCollations(&myself, determ_colls, true); > Some cleanup needed here? Wouldn't it be better to address the issues > with stable ordering first? Didn't we just agreed 3 mails ago to *not* take care of that in this patch, and add an extensible solution for that later? I kept the XXX comment to make it extra clear that this will be addressed. > > + /* recordDependencyOnSingleRelExpr get rid of duplicated > entries */ > s/get/gets/, incorrect grammar. Fixed. > > + /* XXX should we warn about "disappearing" versions? */ > + if (current_version) > + { > Something to do here? I'm not sure. This comment is to remind that we won't warn that an index might get broken if say gnu_get_libc_version() stop giving a version number at some point. I don't think that this will happen, but just in case there's a comment to keep it in mind. > + /* > + * We now support versioning for the underlying collation library on > + * this system, or previous version is unknown. > + */ > + if (!version || (strcmp(version, "") == 0 && strcmp(current_version, > + "") != 0)) > Strange diff format here. That's what pgindent has been doing for some time, ie. indent at the same level of the opening parenthesis. > > +static char * > +index_check_collation_version(const ObjectAddress *otherObject, > + const char *version, > + void *userdata) > All the new functions in index.c should have more documentation and > comments to explain what they do. Fixed. > > + foreach(lc, collations) > + { > + ObjectAddress referenced; > + > + ObjectAddressSet(referenced, CollationRelationId, lfirst_oid(lc)); > + > + recordMultipleDependencies(myself, &referenced, 1, > + DEPENDENCY_NORMAL, record_version); > + } > I think that you could just use an array of ObjectAddresses here, fill > in a set of ObjectAddress objects and just call > recordMultipleDependencies() for all of them? Just create a set using > new_object_addresses(), register them with add_exact_object_address(), > and then finish the job with record_object_address_dependencies(). Fixed.
Attachment
On Fri, Aug 14, 2020 at 11:02:35AM +0200, Julien Rouhaud wrote: > On Fri, Aug 14, 2020 at 04:37:46PM +0900, Michael Paquier wrote: >> + /* >> + * XXX For deterministic transaction, se should only track the >> version >> + * if the AM relies on a stable ordering. >> + */ >> + if (determ_colls) >> + { >> + /* XXX check if the AM relies on a stable ordering */ >> + recordDependencyOnCollations(&myself, determ_colls, true); >> Some cleanup needed here? Wouldn't it be better to address the issues >> with stable ordering first? > > Didn't we just agreed 3 mails ago to *not* take care of that in this patch, and > add an extensible solution for that later? I kept the XXX comment to make it > extra clear that this will be addressed. FWIW, I tend to prefer the approach where we put in place the necessary infrastructure first, and then have a feature rely on what we think is the most correct. This way, we avoid having any moment in the code history where we have something that we know from the start is not covered. The patch set needs a rebase. There are conflicts coming at least from pg_depend.c where I switched the code to use multi-INSERTs for catalog insertions. -- Michael
Attachment
On Mon, Sep 07, 2020 at 12:17:41PM +0900, Michael Paquier wrote: > On Fri, Aug 14, 2020 at 11:02:35AM +0200, Julien Rouhaud wrote: > > On Fri, Aug 14, 2020 at 04:37:46PM +0900, Michael Paquier wrote: > >> + /* > >> + * XXX For deterministic transaction, se should only track the > >> version > >> + * if the AM relies on a stable ordering. > >> + */ > >> + if (determ_colls) > >> + { > >> + /* XXX check if the AM relies on a stable ordering */ > >> + recordDependencyOnCollations(&myself, determ_colls, true); > >> Some cleanup needed here? Wouldn't it be better to address the issues > >> with stable ordering first? > > > > Didn't we just agreed 3 mails ago to *not* take care of that in this patch, and > > add an extensible solution for that later? I kept the XXX comment to make it > > extra clear that this will be addressed. > > FWIW, I tend to prefer the approach where we put in place the > necessary infrastructure first, and then have a feature rely on what > we think is the most correct. This way, we avoid having any moment in > the code history where we have something that we know from the start > is not covered. I usually agree with that approach, I'm just afraid that getting a consensus on the best way to do that will induce a lot of discussions, while this is probably a corner case due to general usage of hash and bloom indexes. Anyway, in order to make progress on that topic I attach an additional POC commit to add the required infrastructure to handle this case in v29-0001-Add-a-new-amnostablecollorder-flag-in-IndexAmRou.patch. Here's the rationale for this new flag, extracted from the patch's commit message: Add a new amnostablecollorder flag in IndexAmRoutine. This flag indicates if the access method does not rely on a stable collation ordering for deterministic collation, i.e. would not be corrupted if the underlying collation library changes its ordering. This is done this way to make sure that if any external access method isn't updated to correctly setup this flag it will be assumed to rely on a stable collation ordering as this should be the case for the majority of access methods. This flag will be useful for an upcoming commit that will add detection of possibly corrupted index due to changed collation library version. > > The patch set needs a rebase. There are conflicts coming at least > from pg_depend.c where I switched the code to use multi-INSERTs for > catalog insertions. Fixed.
Attachment
- v29-0001-Add-a-new-amnostablecollorder-flag-in-IndexAmRou.patch
- v29-0002-Remove-pg_collation.collversion.patch
- v29-0003-Add-pg_depend.refobjversion.patch
- v29-0004-Track-collation-versions-for-indexes.patch
- v29-0005-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v29-0006-Doc-Add-Collation-Versions-section.patch
Re: Julien Rouhaud > Here's the rationale for this new flag, extracted from the patch's commit > message: > > Add a new amnostablecollorder flag in IndexAmRoutine. > > This flag indicates if the access method does not rely on a stable collation > ordering for deterministic collation, i.e. would not be corrupted if the > underlying collation library changes its ordering. This is done this way to > make sure that if any external access method isn't updated to correctly setup > this flag it will be assumed to rely on a stable collation ordering as this > should be the case for the majority of access methods. > > This flag will be useful for an upcoming commit that will add detection of > possibly corrupted index due to changed collation library version. Hmm. Does that flag gain us much? What about non-collation locale changes that might still affect indexes like lower() and the citext extension? That still depends on locale changes, but that flag wouldn't be able to help with "this index is (not) affected by this locale change". IOW, I think we should aim at simply tracking the version, and leave it to the admin (with the help of supplied SQL queries) to either rebuild indexes or waive them. Or maybe I misunderstood the problem. Christoph
On Tue, Sep 08, 2020 at 09:33:26PM +0200, Christoph Berg wrote: > Re: Julien Rouhaud > > Here's the rationale for this new flag, extracted from the patch's commit > > message: > > > > Add a new amnostablecollorder flag in IndexAmRoutine. > > > > This flag indicates if the access method does not rely on a stable collation > > ordering for deterministic collation, i.e. would not be corrupted if the > > underlying collation library changes its ordering. This is done this way to > > make sure that if any external access method isn't updated to correctly setup > > this flag it will be assumed to rely on a stable collation ordering as this > > should be the case for the majority of access methods. > > > > This flag will be useful for an upcoming commit that will add detection of > > possibly corrupted index due to changed collation library version. > > Hmm. Does that flag gain us much? What about non-collation locale > changes that might still affect indexes like lower() and the citext > extension? That still depends on locale changes, but that flag > wouldn't be able to help with "this index is (not) affected by this > locale change". > > IOW, I think we should aim at simply tracking the version, and leave > it to the admin (with the help of supplied SQL queries) to either > rebuild indexes or waive them. > > Or maybe I misunderstood the problem. > I see your point, and indeed this isn't really clear how the flag will be used given this description. I guess that my idea is that how exactly an index depends on a stable collation ordering isn't part of this flag definition, as it should be the same for any access method. In the commit that uses the infrastructure, the lack of stable ordering requirement is only used for index key column, but not for any expression, whether on index key or qual, because as you mention there's no guarantee that the expression itself depends on a stable ordering or not. There could be some improvements done for some simple case (like maybe md5() is used often enough in index keys that it could be worth to detect), but nothing in done to attempt that for now.
On 2020-09-08 21:33, Christoph Berg wrote: > IOW, I think we should aim at simply tracking the version, and leave > it to the admin (with the help of supplied SQL queries) to either > rebuild indexes or waive them. It's certainly safer to track dependency for all indexes and then carefully create exceptions afterwards. -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Thu, Sep 10, 2020 at 6:52 PM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > > On 2020-09-08 21:33, Christoph Berg wrote: > > IOW, I think we should aim at simply tracking the version, and leave > > it to the admin (with the help of supplied SQL queries) to either > > rebuild indexes or waive them. > > It's certainly safer to track dependency for all indexes and then > carefully create exceptions afterwards. Do you mean storing the collation version even when those are not relevant, and let client code (or backend command) deal with it? This would require to store a dependency per index and column (or at least if it's a column or an expression to avoid bloating the dependencies too much), as it's otherwise impossible to know if a version mismatch can be safely ignored or not. I'm also wondering how much more complexity it would add to people who want to actively monitor such mismatch using SQL queries.
On 2020-09-08 16:45, Julien Rouhaud wrote: > I usually agree with that approach, I'm just afraid that getting a consensus on > the best way to do that will induce a lot of discussions, while this is > probably a corner case due to general usage of hash and bloom indexes. > > Anyway, in order to make progress on that topic I attach an additional POC > commit to add the required infrastructure to handle this case in > v29-0001-Add-a-new-amnostablecollorder-flag-in-IndexAmRou.patch. I'm confused now. I think we had mostly agreed on the v28 patch set, without this additional AM flag. There was still some discussion on what the AM flag's precise semantics should be. Do we want to work that out first? Btw., I'm uneasy about the term "stable collation order". "Stable" has an established meaning for sorting. It's really about whether the AM uses collations at all, right? -- Peter Eisentraut http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
On Tue, Sep 15, 2020 at 2:26 PM Peter Eisentraut <peter.eisentraut@2ndquadrant.com> wrote: > > On 2020-09-08 16:45, Julien Rouhaud wrote: > > I usually agree with that approach, I'm just afraid that getting a consensus on > > the best way to do that will induce a lot of discussions, while this is > > probably a corner case due to general usage of hash and bloom indexes. > > > > Anyway, in order to make progress on that topic I attach an additional POC > > commit to add the required infrastructure to handle this case in > > v29-0001-Add-a-new-amnostablecollorder-flag-in-IndexAmRou.patch. > > I'm confused now. I think we had mostly agreed on the v28 patch set, > without this additional AM flag. There was still some discussion on > what the AM flag's precise semantics should be. Do we want to work that > out first? That was my understanding too, but since Michael raised a concern I wrote some initial implementation for that part. I'm assuming that this new flag will raise some new discussion, and I hope this can be discussed later, or at least in parallel, without interfering with the rest of the patchset. > Btw., I'm uneasy about the term "stable collation order". "Stable" has > an established meaning for sorting. It's really about whether the AM > uses collations at all, right? Well, at the AM level I guess it's only about whether it's using some kind of sorting or not, as the collation information is really at the opclass level. It makes me realize that this approach won't be able to cope with an index built using (varchar|text)_pattern_ops, and that's probably something we should handle correctly.
On Thu, Sep 17, 2020 at 5:41 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Tue, Sep 15, 2020 at 2:26 PM Peter Eisentraut > <peter.eisentraut@2ndquadrant.com> wrote: > > I'm confused now. I think we had mostly agreed on the v28 patch set, > > without this additional AM flag. There was still some discussion on > > what the AM flag's precise semantics should be. Do we want to work that > > out first? > > That was my understanding too, but since Michael raised a concern I > wrote some initial implementation for that part. I'm assuming that > this new flag will raise some new discussion, and I hope this can be > discussed later, or at least in parallel, without interfering with the > rest of the patchset. If we always record dependencies we'll have the option to invent clever ways to ignore them during version checking in later releases. > > Btw., I'm uneasy about the term "stable collation order". "Stable" has > > an established meaning for sorting. It's really about whether the AM > > uses collations at all, right? > > Well, at the AM level I guess it's only about whether it's using some > kind of sorting or not, as the collation information is really at the > opclass level. It makes me realize that this approach won't be able > to cope with an index built using (varchar|text)_pattern_ops, and > that's probably something we should handle correctly. Hmm.
On Sun, Sep 20, 2020 at 6:36 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Thu, Sep 17, 2020 at 5:41 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Tue, Sep 15, 2020 at 2:26 PM Peter Eisentraut > > <peter.eisentraut@2ndquadrant.com> wrote: > > > I'm confused now. I think we had mostly agreed on the v28 patch set, > > > without this additional AM flag. There was still some discussion on > > > what the AM flag's precise semantics should be. Do we want to work that > > > out first? > > > > That was my understanding too, but since Michael raised a concern I > > wrote some initial implementation for that part. I'm assuming that > > this new flag will raise some new discussion, and I hope this can be > > discussed later, or at least in parallel, without interfering with the > > rest of the patchset. > > If we always record dependencies we'll have the option to invent > clever ways to ignore them during version checking in later releases. But in any case we need to record the dependencies for all collations right? The only difference is that we shouldn't record the collation version if there's no risk of corruption if the underlying sort order changes. So while I want to address this part in pg14, if that wasn't the case the problem would anyway be automatically fixed in the later version by doing a reindex I think, as the version would be cleared. There could still be a possible false positive warning in that case if the lib is updated, but users could clear it with the infrastructure proposed. Or alternatively if we add a new backend filter, say REINDEX (COLLATION NOT CURRENT), we could add there additional knowledge to ignore such cases. > > > Btw., I'm uneasy about the term "stable collation order". "Stable" has > > > an established meaning for sorting. It's really about whether the AM > > > uses collations at all, right? > > > > Well, at the AM level I guess it's only about whether it's using some > > kind of sorting or not, as the collation information is really at the > > opclass level. It makes me realize that this approach won't be able > > to cope with an index built using (varchar|text)_pattern_ops, and > > that's probably something we should handle correctly. > > Hmm. On the other hand the *_pattern_ops are entirely hardcoded, and I don't think that we'll ever have an extensible way to have this kind of magic exception. So maybe having a flag at the am level is acceptable?
On Sun, Sep 20, 2020 at 10:24:26AM +0800, Julien Rouhaud wrote: > > On the other hand the *_pattern_ops are entirely hardcoded, and I > don't think that we'll ever have an extensible way to have this kind > of magic exception. So maybe having a flag at the am level is > acceptable? Hearing no complaint, I kept the flag at the AM level and added hardcoded exceptions for the *_pattern_ops opclasses to avoid false positive as much as possible, and no false negative (at least that I'm aware of). I added many indexes to the regression tests to make sure that all the cases are correctly handled. Unfortunately, there's still one case that can't be fixed easily. Here's an example of such case: CREATE INDEX ON sometable ((collatable_col || collatable_col) text_pattern_ops) In this case when iterating over the key columns, the current patch notices that a dependency on the collation should be added but that the version shouldn't be tracked, as it's text_pattern_ops. But then the expression itself is processed, and it also see that a dependency on the collation should be addedd. However, it has no way to know that it should not update the previously recorded dependency to start tracking the version, as the expression could really depends on a stable order. So we end up with a single dependency (which is what we want I think), but which will report false positive warning in case of collation lib update. v30 attached.
Attachment
- v30-0001-Add-a-new-amnostablecollorder-flag-in-IndexAmRou.patch
- v30-0002-Remove-pg_collation.collversion.patch
- v30-0003-Add-pg_depend.refobjversion.patch
- v30-0004-Track-collation-versions-for-indexes.patch
- v30-0005-Add-ALTER-INDEX-.-ALTER-COLLATION-.-REFRESH-VERS.patch
- v30-0006-Doc-Add-Collation-Versions-section.patch
On Thu, Sep 24, 2020 at 9:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Sun, Sep 20, 2020 at 10:24:26AM +0800, Julien Rouhaud wrote: > > On the other hand the *_pattern_ops are entirely hardcoded, and I > > don't think that we'll ever have an extensible way to have this kind > > of magic exception. So maybe having a flag at the am level is > > acceptable? > > Hearing no complaint, I kept the flag at the AM level and added hardcoded > exceptions for the *_pattern_ops opclasses to avoid false positive as much as > possible, and no false negative (at least that I'm aware of). I added many > indexes to the regression tests to make sure that all the cases are correctly > handled. > > Unfortunately, there's still one case that can't be fixed easily. Here's an > example of such case: > > CREATE INDEX ON sometable ((collatable_col || collatable_col) text_pattern_ops) I think we should try to get the basic feature into the tree, and then look at these kinds of subtleties as later improvements. Here's a new version with the following changes: 1. Update the doc patch to mention that this stuff now works on Windows too (see commit 352f6f2d). 2. Drop non_deterministic_only argument for from GetTypeCollations(); it was unused. 3. Drop that "stable collation order" field at the AM level for now. This means that we'll warn you about collation versions changes for hash and bloom indexes, even when it's technically unnecessary, for now. The pattern ops stuff seems straightforward however, so let's keep that bit in the initial commit of the feature. That's a finite set of hard coded op classes which exist specifically to ignore collations.
Attachment
On Thu, Oct 22, 2020 at 8:00 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Thu, Sep 24, 2020 at 9:49 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Sun, Sep 20, 2020 at 10:24:26AM +0800, Julien Rouhaud wrote: > > > On the other hand the *_pattern_ops are entirely hardcoded, and I > > > don't think that we'll ever have an extensible way to have this kind > > > of magic exception. So maybe having a flag at the am level is > > > acceptable? > > > > Hearing no complaint, I kept the flag at the AM level and added hardcoded > > exceptions for the *_pattern_ops opclasses to avoid false positive as much as > > possible, and no false negative (at least that I'm aware of). I added many > > indexes to the regression tests to make sure that all the cases are correctly > > handled. > > > > Unfortunately, there's still one case that can't be fixed easily. Here's an > > example of such case: > > > > CREATE INDEX ON sometable ((collatable_col || collatable_col) text_pattern_ops) > > I think we should try to get the basic feature into the tree, and then > look at these kinds of subtleties as later improvements. Agreed. > Here's a new > version with the following changes: > > 1. Update the doc patch to mention that this stuff now works on > Windows too (see commit 352f6f2d). > 2. Drop non_deterministic_only argument for from GetTypeCollations(); > it was unused. > 3. Drop that "stable collation order" field at the AM level for now. > This means that we'll warn you about collation versions changes for > hash and bloom indexes, even when it's technically unnecessary, for > now. > > The pattern ops stuff seems straightforward however, so let's keep > that bit in the initial commit of the feature. That's a finite set of > hard coded op classes which exist specifically to ignore collations. Thanks a lot! I'm fine with all the changes. The "stable collation order" part would definitely benefit from more thoughts, so it's good if we can focus on that later. While reviewing the changes, I found a couple of minor issues (inherited from the previous versions). It's missing a free_objects_addresses in recordDependencyOnCollations, and there's a small typo. Inline diff: diff --git a/src/backend/catalog/dependency.c b/src/backend/catalog/dependency.c index cab552eb32..4680b4e538 100644 --- a/src/backend/catalog/dependency.c +++ b/src/backend/catalog/dependency.c @@ -1674,6 +1674,8 @@ recordDependencyOnCollations(ObjectAddress *myself, eliminate_duplicate_dependencies(addrs); recordMultipleDependencies(myself, addrs->refs, addrs->numrefs, DEPENDENCY_NORMAL, record_version); + + free_object_addresses(addrs); } /* diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c index 69978fb409..048a41f446 100644 --- a/src/backend/catalog/index.c +++ b/src/backend/catalog/index.c @@ -1154,7 +1154,7 @@ index_create(Relation heapRelation, colls_pattern_ops = list_difference_oid(colls_pattern_ops, colls); /* - * Record the dependencies for collation declares with any of the + * Record the dependencies for collation declared with any of the * *_pattern_ops opclass, without version tracking. */ if (colls_pattern_ops != NIL) Other than that it all looks good to me!
On Fri, Oct 23, 2020 at 2:07 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > While reviewing the changes, I found a couple of minor issues > (inherited from the previous versions). It's missing a > free_objects_addresses in recordDependencyOnCollations, and there's a > small typo. Inline diff: Thanks, fixed. I spent the past few days trying to simplify this patch further. Here's what I came up with: 1. Drop the function dependencyExists() and related code, which in earlier versions tried to avoid creating duplicate pg_depends rows by merging with existing rows. This was rather complicated, and there are not many duplicates anyway, and it's easier to suppress duplicate warnings at warning time (see do_collation_version_check()). (I'm not against working harder to make pg_depend rows unique, but it's not required for this and I didn't like that way of doing it.) 2. Use index_update_collation_versions() as the workhorse for REINDEX, binary_upgrade_set_index_coll_version() and ALTER INDEX ... ALTER COLLATION ... REFRESH_VERSION, instead of having multiple functions doing similar things. (I wondered about changing the REINDEX case to simply blow away all dependencies and re-do the analysis from scratch, which might be useful for future applications of refobjversion where the set of depended-on objects might change, but that's out of scope for now and could be added easily enough.) 3. Likewise, drop the function getDependencyVersion() and the modifications to changeDependenciesOf(); that was yet more catalog manipulation stuff, but I couldn't see why we don't just call index_update_collation_versions(newIndexId) after the CREATE INDEX CONCURRENTLY switcheroo step (see index_concurrently_swap()). 4. Drop track_version from find_expr_references_context, and also drop the pre-existing code that skipped default collations. I think it's easier to just let find_expr_references() collect everything, and leave it to later code to worry about whether to suppress "system pinned" stuff. It reduces the amount of code that has to know about refobjversion. 5. General code tidying, pgindent, wordsmithing etc. I'm not sure what I think about recordMultipleDependencies() being the function that knows how to fetch the version but I'm not sure if it's worth the refactoring effort to make ObjectAddresses (essentially a stretchy vector type) able to carry versions so we can pass that stuff in.
Attachment
On Sun, Oct 25, 2020 at 10:36 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Fri, Oct 23, 2020 at 2:07 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > While reviewing the changes, I found a couple of minor issues > > (inherited from the previous versions). It's missing a > > free_objects_addresses in recordDependencyOnCollations, and there's a > > small typo. Inline diff: > > Thanks, fixed. > > I spent the past few days trying to simplify this patch further. > Here's what I came up with: Thanks! > > 1. Drop the function dependencyExists() and related code, which in > earlier versions tried to avoid creating duplicate pg_depends rows by > merging with existing rows. This was rather complicated, and there > are not many duplicates anyway, and it's easier to suppress duplicate > warnings at warning time (see do_collation_version_check()). (I'm not > against working harder to make pg_depend rows unique, but it's not > required for this and I didn't like that way of doing it.) I didn't review all the changes yet, so I'll probably post a deeper review tomorrow. I'm not opposed to this new approach, as it indeed saves a lot of code. However, looking at do_collation_version_check(), it seems that you're saving the collation in context->checked_calls even if it didn't raise a WARNING. Since you can now have indexes with dependencies on a same collation with both version tracked and untracked (see for instance icuidx00_val_pattern_where in the regression tests), can't this hide corruption warning reports if the untracked version is found first? That can be easily fixed, so no objection to that approach of course.
On Sun, Oct 25, 2020 at 7:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > On Sun, Oct 25, 2020 at 10:36 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > > > On Fri, Oct 23, 2020 at 2:07 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > > > While reviewing the changes, I found a couple of minor issues > > > (inherited from the previous versions). It's missing a > > > free_objects_addresses in recordDependencyOnCollations, and there's a > > > small typo. Inline diff: > > > > Thanks, fixed. > > > > I spent the past few days trying to simplify this patch further. > > Here's what I came up with: > > Thanks! > > > > > 1. Drop the function dependencyExists() and related code, which in > > earlier versions tried to avoid creating duplicate pg_depends rows by > > merging with existing rows. This was rather complicated, and there > > are not many duplicates anyway, and it's easier to suppress duplicate > > warnings at warning time (see do_collation_version_check()). (I'm not > > against working harder to make pg_depend rows unique, but it's not > > required for this and I didn't like that way of doing it.) > > I didn't review all the changes yet, so I'll probably post a deeper > review tomorrow. I'm not opposed to this new approach, as it indeed > saves a lot of code. However, looking at > do_collation_version_check(), it seems that you're saving the > collation in context->checked_calls even if it didn't raise a WARNING. > Since you can now have indexes with dependencies on a same collation > with both version tracked and untracked (see for instance > icuidx00_val_pattern_where in the regression tests), can't this hide > corruption warning reports if the untracked version is found first? > That can be easily fixed, so no objection to that approach of course. I finish looking at the rest of the patches. I don't have much to say, it all looks good and I quite like how much useless code you got rid of!
On Tue, Oct 27, 2020 at 1:34 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Sun, Oct 25, 2020 at 7:13 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > I didn't review all the changes yet, so I'll probably post a deeper > > review tomorrow. I'm not opposed to this new approach, as it indeed > > saves a lot of code. However, looking at > > do_collation_version_check(), it seems that you're saving the > > collation in context->checked_calls even if it didn't raise a WARNING. > > Since you can now have indexes with dependencies on a same collation > > with both version tracked and untracked (see for instance > > icuidx00_val_pattern_where in the regression tests), can't this hide > > corruption warning reports if the untracked version is found first? > > That can be easily fixed, so no objection to that approach of course. Right, fixed. > I finish looking at the rest of the patches. I don't have much to > say, it all looks good and I quite like how much useless code you got > rid of! Thanks! I tested a bunch of permutations[1] of cross-version pg_update, with and without ICU, with and without libc version support, and fixed some problems I found in pg_dump: 1. We need to print OIDs as %u, not %d. Also, let's use '%u'::pg_catalog.oid to be consistent with nearby things. 2. We dump binary_upgrade_set_index_coll_version(<index>, NULL, ...) to blow away the new cluster's versions before we import the old versions. OK, but the function was marked STRICT... 3. We dump binary_upgrade_set_index_coll_version(<index>, <collation>, <version>), to import the old cluster's version, where <collation> is an OID. OK, but we need the new cluster's OID, not the old one, so it needs to be an expression like 'pg_catalog."fr_FR"'::regcollation (compare the other references to collations in the dump, which are all by name). 4. I didn't really like the use of '' for unknown. I figured out how to use NULL for that. [1] https://github.com/macdice/some_pg_upgrade_tests
Attachment
On Fri, Oct 30, 2020 at 1:20 AM Thomas Munro <thomas.munro@gmail.com> wrote: > 4. I didn't really like the use of '' for unknown. I figured out how > to use NULL for that. Hrmph. That logic didn't work for the pattern ops case. I fixed that, by partially reintroducing a special value, but this time restricting the code that knows about that to just pg_dump, and I used the value 'unknown', so really it's not special at all as far as the server is concerned and there is only one kind of warning message. Furthermore, I realised that I really don't like the policy of assuming that all text-related indexes imported from older releases need the "unknown" warning. That'll just make this feature unnecessarily noisy and unpopular when 14 comes out, essentially crying wolf, even though it's technically true that the collations in imported-from-before-14 indexes are of unknown version. Even worse, instructions might be shared around the internet to show how to shut the warnings up without reindexing, and then later when there really is a version change, someone might find those instructions and follow them! So I propose that the default should be to assume that indexes are not corrupted, unless you opt into the more pessimistic policy with --index-collation-versions-unknown. Done like that. I also realised that I don't like carrying a bunch of C code to support binary upgrades, when it's really just a hand-coded trivial UPDATE of pg_depend. Is there any reason pg_dump --binary-upgrade shouldn't just dump UPDATE statements, and make this whole feature a lot less mysterious, and shorter? Done like that. While testing on another OS that will be encountered in the build farm when I commit this, I realised that I needed to add --encoding=UTF8 to tests under src/bin/pg_dump and src/test/locale, because they now do things with ICU collations (if built with ICU support) and that only works with UTF8. Another option would be to find a way to skip those tests if the encoding is not UTF8. Hmm, I wonder if it's bad to effectively remove the testing that comes for free from buildfarm animals running this under non-UTF8 encodings; but if we actually valued that, I suppose we'd do it explicitly as another test pass with SQL_ASCII.
Attachment
On Sat, Oct 31, 2020 at 10:28 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Fri, Oct 30, 2020 at 1:20 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > 4. I didn't really like the use of '' for unknown. I figured out how > > to use NULL for that. > > Hrmph. That logic didn't work for the pattern ops case. I fixed > that, by partially reintroducing a special value, but this time > restricting the code that knows about that to just pg_dump, and I used > the value 'unknown', so really it's not special at all as far as the > server is concerned and there is only one kind of warning message. Ok, I'm fine with that. > Furthermore, I realised that I really don't like the policy of > assuming that all text-related indexes imported from older releases > need the "unknown" warning. That'll just make this feature > unnecessarily noisy and unpopular when 14 comes out, essentially > crying wolf, even though it's technically true that the collations in > imported-from-before-14 indexes are of unknown version. Even worse, > instructions might be shared around the internet to show how to shut > the warnings up without reindexing, and then later when there really > is a version change, someone might find those instructions and follow > them! So I propose that the default should be to assume that indexes > are not corrupted, unless you opt into the more pessimistic policy > with --index-collation-versions-unknown. Done like that. Yes, I was also worried about spamming this kind of messages after an upgrade. Note that this was initially planned for REL_13_STABLE, whose release date was very close to glibc 2.28, so at that time this would have been more likely to have a real corruption on the indexes. I'm fine with the new behavior. > I also realised that I don't like carrying a bunch of C code to > support binary upgrades, when it's really just a hand-coded trivial > UPDATE of pg_depend. Is there any reason pg_dump --binary-upgrade > shouldn't just dump UPDATE statements, and make this whole feature a > lot less mysterious, and shorter? Done like that. I just thought that it wouldn't be acceptable to do plain DML on the catalogs. If that's ok, then definitely this approach is better. > While testing on another OS that will be encountered in the build farm > when I commit this, I realised that I needed to add --encoding=UTF8 to > tests under src/bin/pg_dump and src/test/locale, because they now do > things with ICU collations (if built with ICU support) and that only > works with UTF8. Oh I didn't know that. > Another option would be to find a way to skip those > tests if the encoding is not UTF8. Hmm, I wonder if it's bad to > effectively remove the testing that comes for free from buildfarm > animals running this under non-UTF8 encodings; but if we actually > valued that, I suppose we'd do it explicitly as another test pass with > SQL_ASCII. I guess it would be better to keep checking non-UTF8 encodings, but the current approach looks quite random and I don't have any better suggestions. Note that v34 now fails when run on a without that don't have defined(__GLIBC__) (e.g. macos). The failure are in collate.icu.utf8.sql, of the form: - icuidx06_d_en_fr_ga | "default" | up to date + icuidx06_d_en_fr_ga | "default" | version not tracked Given the new approach, the only option I can see is to simply remove any attempt to cover the default collation in the tests. An alternative file would be a pain to maintain and it wouldn't bring any value apart from checking that the default collation is either always tracked or never, but not a mix of those.
On Mon, Nov 2, 2020 at 7:59 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > Note that v34 now fails when run on a without that don't have > defined(__GLIBC__) (e.g. macos). The failure are in > collate.icu.utf8.sql, of the form: > > - icuidx06_d_en_fr_ga | "default" | up to date > + icuidx06_d_en_fr_ga | "default" | version not tracked > > Given the new approach, the only option I can see is to simply remove > any attempt to cover the default collation in the tests. An > alternative file would be a pain to maintain and it wouldn't bring any > value apart from checking that the default collation is either always > tracked or never, but not a mix of those. Blah, right. Ok, I changed it to output XXX for "default". I did a bit more language clean up. I fixed the tab completion for ALTER INDEX ... ALTER COLLATION. I simplified a couple of tests. I dropped the pg_dump TAP test for now (I might see if I can find a simpler way to test refobjversion restoration later). I dropped the special handling for T_CollateExpr in find_expr_references_walker() (it wasn't affecting the test cases we have, and I wasn't entirely sure about it; do you see a problem?). I dropped the VACUUM-log-spam feature for now (I'm not against it, but it seems like an independent enough thing to not include in the initial commit). This brought the patch mercifully under 100kB. This is the version I'm planning to commit if you don't see anything else.
Attachment
On Mon, Nov 2, 2020 at 3:56 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Mon, Nov 2, 2020 at 7:59 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > Note that v34 now fails when run on a without that don't have > > defined(__GLIBC__) (e.g. macos). The failure are in > > collate.icu.utf8.sql, of the form: > > > > - icuidx06_d_en_fr_ga | "default" | up to date > > + icuidx06_d_en_fr_ga | "default" | version not tracked > > > > Given the new approach, the only option I can see is to simply remove > > any attempt to cover the default collation in the tests. An > > alternative file would be a pain to maintain and it wouldn't bring any > > value apart from checking that the default collation is either always > > tracked or never, but not a mix of those. > > Blah, right. Ok, I changed it to output XXX for "default". > > I did a bit more language clean up. I fixed the tab completion for > ALTER INDEX ... ALTER COLLATION. I simplified a couple of tests. I > dropped the pg_dump TAP test for now (I might see if I can find a > simpler way to test refobjversion restoration later). I dropped the > special handling for T_CollateExpr in find_expr_references_walker() > (it wasn't affecting the test cases we have, and I wasn't entirely > sure about it; do you see a problem?). I dropped the VACUUM-log-spam > feature for now (I'm not against it, but it seems like an independent > enough thing to not include in the initial commit). This brought the > patch mercifully under 100kB. This is the version I'm planning to > commit if you don't see anything else. Thanks a lot for the updated patch! I agree with dropping the T_CollateExpr test in find_exp_references_walker(). This was more a hack than anything, and it should be better addressed by an approach that can actually handle all cases rather than some random ones. I'm also ok with dropping the logging from VACUUM from the initial patch, but this seems like an important codepath to handle (and an easy one), so I hope we can address that afterwards. I just have a minor nit: + /* Do they match? */ + if (strcmp(current_version, version) != 0) + { + /* + * The version has changed, probably due to an OS/library upgrade or + * streaming replication between different OS/library versions. + */ + ereport(WARNING, + (errmsg("index \"%s\" depends on collation \"%s\" version \"%s\", but the current version is \"%s\"", + get_rel_name(context->relid), + get_collation_name(otherObject->objectId), + version, + current_version), + errdetail("The index may be corrupted due to changes in sort order."), + errhint("REINDEX to avoid the risk of corruption."))); + } + + /* Remember not to complain about this collation again. */ + context->checked_colls = lappend_oid(context->checked_colls, + otherObject->objectId); It's maybe not immediately obvious that it's safe to save the collation oid at that point, or that it'll always be. Maybe move it in the if branch above to make it extra clear? and also this will probably need an update: -#define CATALOG_VERSION_NO 202010291 +#define CATALOG_VERSION_NO 202011013
On Mon, Nov 2, 2020 at 10:28 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > + /* Remember not to complain about this collation again. */ > + context->checked_colls = lappend_oid(context->checked_colls, > + otherObject->objectId); > > It's maybe not immediately obvious that it's safe to save the > collation oid at that point, or that it'll always be. Maybe move it > in the if branch above to make it extra clear? Ok, moved and renamed, and finally pushed. Thanks for all the help!
On Mon, Nov 2, 2020 at 9:04 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Mon, Nov 2, 2020 at 10:28 PM Julien Rouhaud <rjuju123@gmail.com> wrote: > > + /* Remember not to complain about this collation again. */ > > + context->checked_colls = lappend_oid(context->checked_colls, > > + otherObject->objectId); > > > > It's maybe not immediately obvious that it's safe to save the > > collation oid at that point, or that it'll always be. Maybe move it > > in the if branch above to make it extra clear? > > Ok, moved and renamed, and finally pushed. Thanks for all the help! \o/ Thanks a lot Thomas!
On Tue, Nov 3, 2020 at 2:08 AM Julien Rouhaud <rjuju123@gmail.com> wrote: > On Mon, Nov 2, 2020 at 9:04 PM Thomas Munro <thomas.munro@gmail.com> wrote: > > Ok, moved and renamed, and finally pushed. Thanks for all the help! > > \o/ Thanks a lot Thomas! Hmm, a failure from dory (WIndows) during pg_upgrade: performing post-bootstrap initialization ... 2020-11-02 08:08:22.213 EST [5392] FATAL: could not get collation version for locale "English_United States.1252": error code 87 87 means invalid parameter. I'm surprised it got through various other tests and then failed here. Whelk (also Windows) passed using "German_Germany.1252". Hmm. I'll wait for more Windows systems to report.
Thomas Munro <thomas.munro@gmail.com> writes: > Hmm, a failure from dory (WIndows) during pg_upgrade: > performing post-bootstrap initialization ... 2020-11-02 08:08:22.213 > EST [5392] FATAL: could not get collation version for locale > "English_United States.1252": error code 87 > 87 means invalid parameter. I'm surprised it got through various > other tests and then failed here. Whelk (also Windows) passed using > "German_Germany.1252". Hmm. I'll wait for more Windows systems to > report. drongo just did it too, and it seems repeatable on dory. I'm not 100% sure, but I think the buildfarm's initial "check" step may be run under C locale while pg_upgrade sees whatever the machine's prevailing locale is. If that's correct, it seems like the simplest explanation is just that extraction of a collation version is busted for (some?) non-C locales on Windows. Could be something as dumb as spaces in the locale name being problematic. regards, tom lane
On Tue, Nov 3, 2020 at 6:51 AM Tom Lane <tgl@sss.pgh.pa.us> wrote: > Thomas Munro <thomas.munro@gmail.com> writes: > > Hmm, a failure from dory (WIndows) during pg_upgrade: > > > performing post-bootstrap initialization ... 2020-11-02 08:08:22.213 > > EST [5392] FATAL: could not get collation version for locale > > "English_United States.1252": error code 87 > > > 87 means invalid parameter. I'm surprised it got through various > > other tests and then failed here. Whelk (also Windows) passed using > > "German_Germany.1252". Hmm. I'll wait for more Windows systems to > > report. > > drongo just did it too, and it seems repeatable on dory. I'm not 100% > sure, but I think the buildfarm's initial "check" step may be run under C > locale while pg_upgrade sees whatever the machine's prevailing locale is. > If that's correct, it seems like the simplest explanation is just that > extraction of a collation version is busted for (some?) non-C locales on > Windows. Could be something as dumb as spaces in the locale name > being problematic. Fortunately David Rowley is able to repro this on his Windows box (it fails even with strings that are succeeding on the other BF machines), so we have something to work with. The name mangling that is done in get_iso_localename() looks pretty interesting... It does feel a bit like there is some other hidden environmental factor or setting here, because commit 352f6f2df60 tested OK on Juan Jose's machine too. Hopefully more soon.
On Tue, 3 Nov 2020 at 09:43, Thomas Munro <thomas.munro@gmail.com> wrote: > Fortunately David Rowley is able to repro this on his Windows box (it > fails even with strings that are succeeding on the other BF machines), > so we have something to work with. The name mangling that is done in > get_iso_localename() looks pretty interesting... It does feel a bit > like there is some other hidden environmental factor or setting here, > because commit 352f6f2df60 tested OK on Juan Jose's machine too. > Hopefully more soon. It seems to boil down to GetNLSVersionEx() not liking the "English_New Zealand.1252" string. The theory about it having a space does not seem to be a factor as if I change it to "English_Australia.1252", I get the same issue. Going by the docs in [1] and following the "local name" link to [2], there's a description there that mentions: "Generally, the pattern <language>-<REGION> is used.". So, if I just hack the code in get_collation_actual_version() to pass "en-NZ" to GetNLSVersionEx(), that works fine. In [3], Juan José was passing in en-US rather than these more weird Windows-specific locale strings, so the testing that code got when it went in didn't include seeing if something like "English_New Zealand.1252" would be accepted. The "English_New Zealand.1252" string seems to come from the setlocales() call in initdb via check_locale_name(LC_COLLATE, lc_collate, &canonname), and fundamentally setlocale(LC_COLLATE). I'm still a bit mystified why whelk seems unphased by this change. You can see from [4] that it must be passing "German_Germany.1252" to GetNLSVersionEx(). I've tested both on Windows 8.1 and Windows 10 and I can't get GetNLSVersionEx() to accept that. So maybe Windows 7 allowed these non-ISO formats? That theory seems to break down a bit when you see that walleye is perfectly happy on Windows 10 (MinGW64). You can see from [5] it mentions "The database cluster will be initialized with locale "English_United States.1252".". Running low on ideas for now, so thought I'd post this in case it someone thinks of something else. David [1] https://docs.microsoft.com/en-us/windows/win32/api/winnls/nf-winnls-getnlsversionex [2] https://docs.microsoft.com/en-us/windows/win32/intl/locale-names [3] https://www.postgresql.org/message-id/CAC+AXB0Eat3aLeTrbDoBB9jX863CU_+RSbgiAjcED5DcXoBoFQ@mail.gmail.com [4] https://buildfarm.postgresql.org/cgi-bin/show_stage_log.pl?nm=whelk&dt=2020-11-02%2020%3A41%3A40&stg=check-pg_upgrade [5] https://buildfarm.postgresql.org/cgi-bin/show_stage_log.pl?nm=walleye&dt=2020-11-02%2020%3A55%3A31&stg=check-pg_upgrade
On Tue, 3 Nov 2020 at 12:29, David Rowley <dgrowleyml@gmail.com> wrote: > Running low on ideas for now, so thought I'd post this in case it > someone thinks of something else. FWIW, the attached does fix the issue for me. It basically just calls the function that converts the windows-type "English_New Zealand.1252" locale name string into, e.g. "en_NZ". Then, since GetNLSVersionEx() wants yet another variant with a - rather than an _, I've just added a couple of lines to swap the _ for a -. There's a bit of extra work there since IsoLocaleName() just did the opposite, so perhaps doing it that way was lazy of me. I'd have invented some other function if I could have thought of a meaningful name for it, then just have the ISO version of it swap - for _. It would be good if this could also be tested on Visual Studio version 12 as I see IsoLocaleName() does something else for anything before 15. I only have 10 and 17 installed and I see we don't support anything before 12 on master per: "Unable to determine Visual Studio version: Visual Studio versions before 12.0 aren't supported. at L:/Projects/Postgres/d/src/tools/msvc/Mkvcbuild.pm line 93." David
Attachment
On Tue, Nov 3, 2020 at 1:51 PM David Rowley <dgrowleyml@gmail.com> wrote: > On Tue, 3 Nov 2020 at 12:29, David Rowley <dgrowleyml@gmail.com> wrote: > > Running low on ideas for now, so thought I'd post this in case it > > someone thinks of something else. > > FWIW, the attached does fix the issue for me. It basically just calls > the function that converts the windows-type "English_New Zealand.1252" > locale name string into, e.g. "en_NZ". Then, since GetNLSVersionEx() > wants yet another variant with a - rather than an _, I've just added a > couple of lines to swap the _ for a -. There's a bit of extra work > there since IsoLocaleName() just did the opposite, so perhaps doing it > that way was lazy of me. I'd have invented some other function if I > could have thought of a meaningful name for it, then just have the ISO > version of it swap - for _. Thanks! Hmm, it looks like Windows calls the hyphenated ISO language-country form a "tag". It makes me slightly nervous to ask for the version of a transformed name with the encoding stripped, but it does seem entirely plausible that it gives the answer we seek. I suppose if we were starting from a clean slate we might want to perform this transformation up front so that we have it in datcollate and then not have to think about the older form ever again. If we decided to do that going forward, the last trace of that problem would live in pg_upgrade. If we ever extend pg_import_system_collations() to cover Windows, we should make sure it captures the tag form. > It would be good if this could also be tested on Visual Studio version > 12 as I see IsoLocaleName() does something else for anything before > 15. I only have 10 and 17 installed and I see we don't support > anything before 12 on master per: I think others have mentioned that it might be time to drop some older Windows versions. I don't follow that stuff, so I've quietly added a name to the CC list and will hope for the best :-)
On Tue, Nov 3, 2020 at 4:39 AM Thomas Munro <thomas.munro@gmail.com> wrote:
On Tue, Nov 3, 2020 at 1:51 PM David Rowley <dgrowleyml@gmail.com> wrote:
> It would be good if this could also be tested on Visual Studio version
> 12 as I see IsoLocaleName() does something else for anything before
> 15. I only have 10 and 17 installed and I see we don't support
> anything before 12 on master per:
I think others have mentioned that it might be time to drop some older
Windows versions. I don't follow that stuff, so I've quietly added a
name to the CC list and will hope for the best :-)
There has been some talk about pushing _WIN32_WINNT to newer releases, but ended without an actual patch for doing so. Maybe we can revisit that in another thread.
Regards,
Juan José Santamaría Flecha
On Tue, Nov 3, 2020 at 4:38 PM Thomas Munro <thomas.munro@gmail.com> wrote: > On Tue, Nov 3, 2020 at 1:51 PM David Rowley <dgrowleyml@gmail.com> wrote: > > On Tue, 3 Nov 2020 at 12:29, David Rowley <dgrowleyml@gmail.com> wrote: > > > Running low on ideas for now, so thought I'd post this in case it > > > someone thinks of something else. > > > > FWIW, the attached does fix the issue for me. It basically just calls > > the function that converts the windows-type "English_New Zealand.1252" > > locale name string into, e.g. "en_NZ". Then, since GetNLSVersionEx() > > wants yet another variant with a - rather than an _, I've just added a > > couple of lines to swap the _ for a -. There's a bit of extra work > > there since IsoLocaleName() just did the opposite, so perhaps doing it > > that way was lazy of me. I'd have invented some other function if I > > could have thought of a meaningful name for it, then just have the ISO > > version of it swap - for _. > > Thanks! Hmm, it looks like Windows calls the hyphenated ISO > language-country form a "tag". It makes me slightly nervous to ask > for the version of a transformed name with the encoding stripped, but > it does seem entirely plausible that it gives the answer we seek. I > suppose if we were starting from a clean slate we might want to > perform this transformation up front so that we have it in datcollate > and then not have to think about the older form ever again. If we > decided to do that going forward, the last trace of that problem would > live in pg_upgrade. If we ever extend pg_import_system_collations() > to cover Windows, we should make sure it captures the tag form. So we have: 1. Windows locale names, like "English_United States.1252". Windows still returns these from setlocale(), so they finish up in datcollate, and yet some relevant APIs don't accept them, at least on some machines. 2. BCP 47/RFC 5646 language tags, like "en-US". Windows uses these in relevant new APIs, including the case in point. 3. Unix-style (XPG? ISO/IEC 15897?) locale names, like "en_US" ("language[_territory[.codeset]][@modifier]"). These are used for message catalogues. We have a VS2015+ way of converting from form 1 to form 2 (and thence 3 by s/-/_/), and an older way. Unfortunately, the new way looks a little too fuzzy: if i'm reading it right, search_locale_enum() might stop on either "en" or "en-AU", given "English_Australia", depending on the search order, no? This may be fine for the purpose of looking up error messages with gettext() (where there is only one English language message catalogue, we haven't got around to translating our errors into 'strayan yet), but it doesn't seem like a good way to look up the collation version; for all I know, "en" variants might change independently (I doubt it in practice, but in theory it's wrong). We want the same algorithm that Windows uses internally to resolve the old style name to a collation; in other words we probably want something more like the code path that they took away in VS2015 :-(.
Thomas Munro <thomas.munro@gmail.com> writes: > On Tue, Nov 3, 2020 at 4:38 PM Thomas Munro <thomas.munro@gmail.com> wrote: >> On Tue, Nov 3, 2020 at 1:51 PM David Rowley <dgrowleyml@gmail.com> wrote: >>> FWIW, the attached does fix the issue for me. It basically just calls >>> the function that converts the windows-type "English_New Zealand.1252" >>> locale name string into, e.g. "en_NZ". > We want the same algorithm that Windows uses internally to resolve the > old style name to a collation; in other words we probably want > something more like the code path that they took away in VS2015 :-(. Yeah. In the short run, though, it'd be nice to un-break the buildfarm. Maybe we could push David's code or something similar, and then contemplate better ways at leisure? regards, tom lane
On Wed, Nov 4, 2020 at 10:52 AM Tom Lane <tgl@sss.pgh.pa.us> wrote: > Thomas Munro <thomas.munro@gmail.com> writes: > > We want the same algorithm that Windows uses internally to resolve the > > old style name to a collation; in other words we probably want > > something more like the code path that they took away in VS2015 :-(. > > Yeah. In the short run, though, it'd be nice to un-break the buildfarm. > Maybe we could push David's code or something similar, and then > contemplate better ways at leisure? Ok, yeah, I'll do that in the next few hours.
Re: Thomas Munro > for all I know, "en" variants might change > independently (I doubt it in practice, but in theory it's wrong). Long before the glibc 2.28 incident, the same collation change had already happened twice, namely between RedHat 5 -> 6 -> 7, for de_DE.UTF-8 only. de_AT.UTF-8 and all other locales were unaffected. At the time I didn't connect the dots to check if Debian was affected as well, but of course later testing revealed it was since it was a change in glibc. (German blogpost: https://www.credativ.de/blog/postgresql/postgresql-und-inkompatible-deutsche-spracheigenschaften-in-centos-rhel/) Christoph
On Wed, Nov 4, 2020 at 10:56 AM Thomas Munro <thomas.munro@gmail.com> wrote: > On Wed, Nov 4, 2020 at 10:52 AM Tom Lane <tgl@sss.pgh.pa.us> wrote: > > Thomas Munro <thomas.munro@gmail.com> writes: > > > We want the same algorithm that Windows uses internally to resolve the > > > old style name to a collation; in other words we probably want > > > something more like the code path that they took away in VS2015 :-(. > > > > Yeah. In the short run, though, it'd be nice to un-break the buildfarm. > > Maybe we could push David's code or something similar, and then > > contemplate better ways at leisure? > > Ok, yeah, I'll do that in the next few hours. I can't bring myself to commit that, it's not really in the spirit of this data integrity feature, and it's not our business to second guess the relationship between different locale naming schemes through fuzzy logic. Instead, I propose to just neuter the feature if Windows decides it can't understand a locale names that it gave us. It should still work fine with something like initdb --lc-collate=en-US. Here's an untested patch. Thoughts?
Attachment
Thomas Munro <thomas.munro@gmail.com> writes: > I can't bring myself to commit that, it's not really in the spirit of > this data integrity feature, and it's not our business to second guess > the relationship between different locale naming schemes through fuzzy > logic. Instead, I propose to just neuter the feature if Windows > decides it can't understand a locale names that it gave us. It should > still work fine with something like initdb --lc-collate=en-US. Here's > an untested patch. Thoughts? Works for me, at least as a short-term solution. regards, tom lane
On Wed, 4 Nov 2020 at 14:21, Thomas Munro <thomas.munro@gmail.com> wrote: > > On Wed, Nov 4, 2020 at 10:56 AM Thomas Munro <thomas.munro@gmail.com> wrote: > > On Wed, Nov 4, 2020 at 10:52 AM Tom Lane <tgl@sss.pgh.pa.us> wrote: > > > Thomas Munro <thomas.munro@gmail.com> writes: > > > > We want the same algorithm that Windows uses internally to resolve the > > > > old style name to a collation; in other words we probably want > > > > something more like the code path that they took away in VS2015 :-(. > > > > > > Yeah. In the short run, though, it'd be nice to un-break the buildfarm. > > > Maybe we could push David's code or something similar, and then > > > contemplate better ways at leisure? > > > > Ok, yeah, I'll do that in the next few hours. > > I can't bring myself to commit that, it's not really in the spirit of > this data integrity feature, and it's not our business to second guess > the relationship between different locale naming schemes through fuzzy > logic. Instead, I propose to just neuter the feature if Windows > decides it can't understand a locale names that it gave us. It should > still work fine with something like initdb --lc-collate=en-US. Here's > an untested patch. Thoughts? I gave this a quick test. initdb works fine. I ran vcregress upgradecheck and it passes. With my default locale of English.New Zealand.1252 I get zero rows from: select * from pg_depend where coalesce(refobjversion,'') <> ''; if I initdb with --lc-collate=en-NZ, it works and I see: postgres=# select * from pg_depend where coalesce(refobjversion,'') <> ''; classid | objid | objsubid | refclassid | refobjid | refobjsubid | deptype | refobjversion ---------+-------+----------+------------+----------+-------------+---------+----------------- 2606 | 12512 | 0 | 3456 | 100 | 0 | n | 1538.14,1538.14 (1 row) David
On Wed, Nov 4, 2020 at 2:56 PM David Rowley <dgrowleyml@gmail.com> wrote: > initdb works fine. I ran vcregress upgradecheck and it passes. > > With my default locale of English.New Zealand.1252 I get zero rows from: > > select * from pg_depend where coalesce(refobjversion,'') <> ''; > > if I initdb with --lc-collate=en-NZ, it works and I see: > > postgres=# select * from pg_depend where coalesce(refobjversion,'') <> ''; > classid | objid | objsubid | refclassid | refobjid | refobjsubid | > deptype | refobjversion > ---------+-------+----------+------------+----------+-------------+---------+----------------- > 2606 | 12512 | 0 | 3456 | 100 | 0 | n > | 1538.14,1538.14 > (1 row) Thanks for all the help and testing! Pushed. If we don't come up with something better I'll need to figure out how to explain this in the manual. (Will no one rid us of these meddlesome old format locale names? It seems like pg_locale.c could drop a lot of rather unpleasant code if initdb, CREATE COLLATION, and CREATE DATABASE didn't allow them into the catalogue in the first place...)
On Tue, Nov 3, 2020 at 10:49 PM Thomas Munro <thomas.munro@gmail.com> wrote:
So we have:
1. Windows locale names, like "English_United States.1252". Windows
still returns these from setlocale(), so they finish up in datcollate,
and yet some relevant APIs don't accept them, at least on some
machines.
2. BCP 47/RFC 5646 language tags, like "en-US". Windows uses these
in relevant new APIs, including the case in point.
3. Unix-style (XPG? ISO/IEC 15897?) locale names, like "en_US"
("language[_territory[.codeset]][@modifier]"). These are used for
message catalogues.
We have a VS2015+ way of converting from form 1 to form 2 (and thence
3 by s/-/_/), and an older way. Unfortunately, the new way looks a
little too fuzzy: if i'm reading it right, search_locale_enum() might
stop on either "en" or "en-AU", given "English_Australia", depending
on the search order, no?
No, that is not the case. "English" could match any locale if the enumeration order was to be changed in the future, right now the order is a given (Language, Location), but "English_Australia" can only match "en-AU".
This may be fine for the purpose of looking
up error messages with gettext() (where there is only one English
language message catalogue, we haven't got around to translating our
errors into 'strayan yet), but it doesn't seem like a good way to look
up the collation version; for all I know, "en" variants might change
independently (I doubt it in practice, but in theory it's wrong). We
want the same algorithm that Windows uses internally to resolve the
old style name to a collation; in other words we probably want
something more like the code path that they took away in VS2015 :-(.
We could create a static table with the conversion based on what was discussed for commit a169155, please find attached a spreadsheet with the comparison. This would require maintenance as new LCIDs are released [1].
Regards,
Juan José Santamaría
Attachment
On Wed, Nov 04, 2020 at 08:44:15AM +0100, Juan José Santamaría Flecha wrote: > We could create a static table with the conversion based on what was > discussed for commit a169155, please find attached a spreadsheet with the > comparison. This would require maintenance as new LCIDs are released [1]. > > [1] > https://docs.microsoft.com/en-us/openspecs/windows_protocols/ms-lcid/70feba9f-294e-491e-b6eb-56532684c37f I am honestly not a fan of something like that as it has good chances to rot. -- Michael
Attachment
On Wed, Nov 4, 2020 at 4:11 PM Michael Paquier <michael@paquier.xyz> wrote: > > On Wed, Nov 04, 2020 at 08:44:15AM +0100, Juan José Santamaría Flecha wrote: > > We could create a static table with the conversion based on what was > > discussed for commit a169155, please find attached a spreadsheet with the > > comparison. This would require maintenance as new LCIDs are released [1]. > > > > [1] > > https://docs.microsoft.com/en-us/openspecs/windows_protocols/ms-lcid/70feba9f-294e-491e-b6eb-56532684c37f > > I am honestly not a fan of something like that as it has good chances > to rot. Same here.
On Tue, 2020-11-03 at 23:14 +0100, Christoph Berg wrote: > Re: Thomas Munro > > for all I know, "en" variants might change > > independently (I doubt it in practice, but in theory it's wrong). > > Long before the glibc 2.28 incident, the same collation change > had already happened twice, namely between RedHat 5 -> 6 -> 7, for > de_DE.UTF-8 only. de_AT.UTF-8 and all other locales were unaffected. > > At the time I didn't connect the dots to check if Debian was affected > as well, but of course later testing revealed it was since it was a > change in glibc. Yes, this is a persistent pain; I had several customers suffering from these issues too. I wish https://postgr.es/m/5e756dd6-0e91-d778-96fd-b1bcb06c161a%402ndquadrant.com hade made it into core. Yours, Laurenz Albe
On Wed, Nov 4, 2020 at 9:11 PM Michael Paquier <michael@paquier.xyz> wrote: > On Wed, Nov 04, 2020 at 08:44:15AM +0100, Juan José Santamaría Flecha wrote: > > We could create a static table with the conversion based on what was > > discussed for commit a169155, please find attached a spreadsheet with the > > comparison. This would require maintenance as new LCIDs are released [1]. > > > > [1] > > https://docs.microsoft.com/en-us/openspecs/windows_protocols/ms-lcid/70feba9f-294e-491e-b6eb-56532684c37f > > I am honestly not a fan of something like that as it has good chances > to rot. No opinion on that, other than that we'd surely want a machine readable version. As for *when* we use that information, I'm wondering if it would make sense to convert datcollate to a language tag in initdb, and also change pg_upgrade's equivalent_locale() function to consider "English_United States.*" and "en-US" to be equivalent when upgrading to 14 (which would then be the only point you'd ever have to have faith that we can convert the old style names to the new names correctly). I'm unlikely to work on this myself as I have other operating systems to fix, but I'll certainly be happy if somehow we can get versioning for default on Windows in PG14 and not have to come up with weasel words in the manual. Just by the way, I think Windows does one thing pretty nicely here: it has versions with a major and a minor part. If the minor part goes up, it means that they only added new code points, but didn't change the ordering of any existing code points, so in some circumstances you don't have to rebuild (which I think is the case for many Unicode updates, adding new Chinese characters or emojis or whatever). I thought about whether we should replace the strcmp() comparison with a call into provider-specific code, and in the case of Win32 locales it could maybe understand that. But there are two problems of limited surmountability: (1) You have an idex built with version 42.1, and now version 42.3 is present; OK, we can read this index, but if we write any new data, then a streaming replica that has 42.2 will think it's OK to read data, but it's not OK; so as soon as you write, you'd need to update the catalogue, which is quite complicated (cf enum types); (2) The whole theory only holds together if you didn't actually use any of the new codepoints introduced by 42.3 while the index said 42.1, yet PostgreSQL isn't validating the codepoints you use against the collation provider's internal map of valid code points. So I gave up with that line of thinking for now.
On Fri, Oct 4, 2019 at 1:25 AM Thomas Munro <thomas.munro@gmail.com> wrote: > Ok. Here's one like that. Also, a WIP patch for FreeBSD. Here's an updated patch for FreeBSD, which I'll sit on for a bit longer. It needs bleeding edge 13-CURRENT (due out Q1ish).
Attachment
On Mon, Mar 15, 2021 at 2:25 PM Thomas Munro <thomas.munro@gmail.com> wrote: > FYI I have added this as an open item for PostgreSQL 14. My default > action will be to document this limitation, if we can't come up with > something better in time. Here is a short doc update to explain the situation on Windows and close that open item. PS While trying to find official names to use to refer to the "en-US" and "English_United States.1252" forms, I came across these sentences in the Windows documentation[1], which support the idea already discussed of trying to prevent the latter format from ever entering our catalogs, in some future release: "The locale-name form is a short, IETF-standardized string; for example, en-US for English (United States) or bs-Cyrl-BA for Bosnian (Cyrillic, Bosnia and Herzegovina). These forms are preferred. [...]" "The language[_country-region[.code-page]] form is stored in the locale setting for a category when a language string, or language string and country or region string, is used to create the locale. [...] We do not recommend this form for locale strings embedded in code or serialized to storage, because these strings are more likely to be changed by an operating system update than the locale name form." [1] https://docs.microsoft.com/en-us/cpp/c-runtime-library/locale-names-languages-and-country-region-strings?view=msvc-160