Re: Why the index is not used ?

From: Paul McGarry <paul(at)paulmcgarry(dot)com>
To: ROS Didier <didier(dot)ros(at)edf(dot)fr>
Cc: "folarte(at)peoplecall(dot)com" <folarte(at)peoplecall(dot)com>, "pavel(dot)stehule(at)gmail(dot)com" <pavel(dot)stehule(at)gmail(dot)com>, "pgsql-sql(at)lists(dot)postgresql(dot)org" <pgsql-sql(at)lists(dot)postgresql(dot)org>, "pgsql-performance(at)lists(dot)postgresql(dot)org" <pgsql-performance(at)lists(dot)postgresql(dot)org>, "pgsql-general(at)lists(dot)postgresql(dot)org" <pgsql-general(at)lists(dot)postgresql(dot)org>
Subject: Re: Why the index is not used ?
Date: 2018-10-08 21:34:51
Message-ID: DA3AA6AB-804B-425F-998C-E8CBE5EA6B4E@paulmcgarry.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general pgsql-performance pgsql-sql

Hi Didier,

Yes, credit cards are a very specific space that probably gets people who are familiar with it going a bit. By the time you factor in general security practices, specific PCI requirements, your threat model and likely business requirements (needing relatively free access to parts of the card number) the acceptable solution space narrows considerably.

More generally though I’d recommend reading:

https://paragonie.com/blog/2017/05/building-searchable-encrypted-databases-with-php-and-sql

as (even if you aren’t using PHP) it discusses several strategies and what makes them good/bad for different use cases and how to implement them well.

I don’t think I’d consider the main solution discussed there particularly applicable to credit card data (mostly because the low entropy of card data makes it difficult to handle safely without additional per-row randomness added, though as always, consult your QSA) but it is generally interesting.

Paul

Sent from my iPhone

> On 9 Oct 2018, at 01:29, ROS Didier <didier(dot)ros(at)edf(dot)fr> wrote:
>
> Hi Paul
>
> Thank you very much for your feedback which is very informative.
> I understand that concerning the encryption of credit card numbers, it is imperative to respect the PCI DSS document. I am going to study it.
> However, I would like to say that I chose my example badly by using a table storing credit card numbers. In fact, my problem is more generic.
> I want to implement a solution that encrypts “sensitive” data and can retrieve data with good performance (by using an index).
> I find that the solution you propose is very interesting and I am going to test it.
>
> Best Regards
> Didier ROS
>
> De : paul(at)paulmcgarry(dot)com [mailto:paul(at)paulmcgarry(dot)com]
> Envoyé : lundi 8 octobre 2018 00:11
> À : ROS Didier <didier(dot)ros(at)edf(dot)fr>
> Cc : folarte(at)peoplecall(dot)com; pavel(dot)stehule(at)gmail(dot)com; pgsql-sql(at)lists(dot)postgresql(dot)org; pgsql-performance(at)lists(dot)postgresql(dot)org; pgsql-general(at)lists(dot)postgresql(dot)org
> Objet : Re: Why the index is not used ?
>
> Hi Didier,
>
> I’m sorry to tell you that you are probably doing something (ie handling/storing credit cards) which would mean you have to comply with PCI DSS requirements.
>
> As such you should probably have a QSA (auditor) who you can run any proposed solution by (so you know they will be comfortable with it when they do their audit).
>
> I think your current solution would be frowned upon because:
> - cards are effectively stored in plaintext in the index.
> - your encryption/decryption is being done in database, rather than by something with that as its sole role.
>
> People have already mentioned the former so I won’t go into it further
>
> But for the second part if someone can do a
>
> Select pgp_sym_decrypt(cc)
>
> then you are one sql injection away from having your card data stolen. You do have encryption, but in practice everything is available unencrypted so in practice the encryption is more of a tick in a box than an actual defence against bad things happening. In a properly segmented system even your DBA should not be able to access decrypted card data.
>
> You probably should look into doing something like:
>
> - store the first 6 and last 4 digits of the card unencrypted.
> - store the remaining card digits encrypted
> - have the encryption/decryption done by a seperate service called by your application code outside the db.
>
> You haven’t gone into what your requirements re search are (or I missed them) but while the above won’t give you a fast exact cc lookup in practice being able to search using the first 6 and last 4 can get you a small enough subset than can then be filtered after decrypting the middle.
>
> We are straying a little off PostgreSQL topic here but if you and/or your management aren’t already looking at PCI DSS compliance I’d strongly recommend you do so. It can seem like a pain but it is much better to take that pain up front rather than having to reengineer everything later. There are important security aspects it helps make sure you cover but maybe some business aspects (ie possible partners who won’t be able to deal with you without your compliance sign off documentation).
>
>
> The alternative, if storing cc data isn’t a core requirement, is to not store the credit card data at all. That is generally the best solution if it meets your needs, ie if you just want to accept payments then use a third party who is PCI compliant to handle the cc part.
>
> I hope that helps a little.
>
> Paul
>
>
>
>
> Sent from my iPhone
>
> On 8 Oct 2018, at 05:32, ROS Didier <didier(dot)ros(at)edf(dot)fr> wrote:
>
> Hi Francisco
>
> Thank you for your remark.
> You're right, but it's the only procedure I found to make search on encrypted fields with good response times (using index) !
>
> Regarding access to the file system, our servers are in protected network areas. few people can connect to it.
>
> it's not the best solution, but we have data encryption needs and good performance needs too. I do not know how to do it except the specified procedure..
> if anyone has any proposals to put this in place, I'm interested.
>
> Thanks in advance
>
> Best Regards
> Didier ROS
>
> -----Message d'origine-----
> De : folarte(at)peoplecall(dot)com [mailto:folarte(at)peoplecall(dot)com]
> Envoyé : dimanche 7 octobre 2018 17:58
> À : ROS Didier <didier(dot)ros(at)edf(dot)fr>
> Cc : pavel(dot)stehule(at)gmail(dot)com; pgsql-sql(at)lists(dot)postgresql(dot)org; pgsql-performance(at)lists(dot)postgresql(dot)org; pgsql-general(at)lists(dot)postgresql(dot)org
> Objet : Re: Why the index is not used ?
>
> ROS:
>
> On Sun, Oct 7, 2018 at 3:13 PM, ROS Didier <didier(dot)ros(at)edf(dot)fr> wrote:
> ....
>
> - INSERT INTO cartedecredit(username,cc) SELECT 'individu ' || x.id, pgp_sym_encrypt('test value ' || x.id, 'motdepasse','compress-algo=2, cipher-algo=aes256') FROM generate_series(1,100000) AS x(id);
> - CREATE INDEX idx_cartedecredit_cc02 ON cartedecredit(pgp_sym_decrypt(cc, 'motdepasse','compress-algo=2, cipher-algo=aes256'));
>
> If my french is not too rusty you are encrypting a credit-card, and then storing an UNENCRYPTED copy in the index. So, getting it from the server is trivial for anyone with filesystem access.
>
> Francisco Olarte.
>
>
>
> Ce message et toutes les pièces jointes (ci-après le 'Message') sont établis à l'intention exclusive des destinataires et les informations qui y figurent sont strictement confidentielles. Toute utilisation de ce Message non conforme à sa destination, toute diffusion ou toute publication totale ou partielle, est interdite sauf autorisation expresse.
>
> Si vous n'êtes pas le destinataire de ce Message, il vous est interdit de le copier, de le faire suivre, de le divulguer ou d'en utiliser tout ou partie. Si vous avez reçu ce Message par erreur, merci de le supprimer de votre système, ainsi que toutes ses copies, et de n'en garder aucune trace sur quelque support que ce soit. Nous vous remercions également d'en avertir immédiatement l'expéditeur par retour du message.
>
> Il est impossible de garantir que les communications par messagerie électronique arrivent en temps utile, sont sécurisées ou dénuées de toute erreur ou virus.
> ____________________________________________________
>
> This message and any attachments (the 'Message') are intended solely for the addressees. The information contained in this Message is confidential. Any use of information contained in this Message not in accord with its purpose, any dissemination or disclosure, either whole or partial, is prohibited except formal approval.
>
> If you are not the addressee, you may not copy, forward, disclose or use any part of it. If you have received this message in error, please delete it and all copies from your system and notify the sender immediately by return message.
>
> E-mail communication cannot be guaranteed to be timely secure, error or virus-free.
>
> Ce message et toutes les pièces jointes (ci-après le 'Message') sont établis à l'intention exclusive des destinataires et les informations qui y figurent sont strictement confidentielles. Toute utilisation de ce Message non conforme à sa destination, toute diffusion ou toute publication totale ou partielle, est interdite sauf autorisation expresse.
>
> Si vous n'êtes pas le destinataire de ce Message, il vous est interdit de le copier, de le faire suivre, de le divulguer ou d'en utiliser tout ou partie. Si vous avez reçu ce Message par erreur, merci de le supprimer de votre système, ainsi que toutes ses copies, et de n'en garder aucune trace sur quelque support que ce soit. Nous vous remercions également d'en avertir immédiatement l'expéditeur par retour du message.
>
> Il est impossible de garantir que les communications par messagerie électronique arrivent en temps utile, sont sécurisées ou dénuées de toute erreur ou virus.
> ____________________________________________________
>
> This message and any attachments (the 'Message') are intended solely for the addressees. The information contained in this Message is confidential. Any use of information contained in this Message not in accord with its purpose, any dissemination or disclosure, either whole or partial, is prohibited except formal approval.
>
> If you are not the addressee, you may not copy, forward, disclose or use any part of it. If you have received this message in error, please delete it and all copies from your system and notify the sender immediately by return message.
>
> E-mail communication cannot be guaranteed to be timely secure, error or virus-free.

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Adrian Klaver 2018-10-08 22:54:03 Re: FTS trigger works 1 at a time, but fails with bulk insert script
Previous Message Malik Rumi 2018-10-08 20:58:45 Re: FTS trigger works 1 at a time, but fails with bulk insert script

Browse pgsql-performance by date

  From Date Subject
Next Message James Coleman 2018-10-08 22:05:19 Re: Partial index plan/cardinality costing
Previous Message Tomas Vondra 2018-10-08 20:00:15 Re: Why the index is not used ?

Browse pgsql-sql by date

  From Date Subject
Next Message Gary Stainburn 2018-10-09 13:18:01 left outer join to pull in most recent record
Previous Message Tomas Vondra 2018-10-08 20:00:15 Re: Why the index is not used ?