Uploaded image for project: 'Teiid'
  1. Teiid
  2. TEIID-6080

A query with multi-"union all select" returns wrong data

XMLWordPrintable

    • Icon: Bug Bug
    • Resolution: Done
    • Icon: Blocker Blocker
    • 15.0.2, 16.0.1, 17.0
    • 15.0.1
    • Query Engine
    • None
    • Hide

      1. In PostgreSQL create the following tables using the following scripts:

      CREATE TABLE public.visits
      (
        channel_id character varying(1048000),
        channel_id_short character varying(1048000),
        campaign character varying(1048000),
        channel character varying(1048000),
        medium character varying(1048000),
        source character varying(1048000),
        keyword character varying(1048000),
        adgroup character varying(1048000),
        channel_category character varying(1048000)
      );
       
      INSERT INTO public.visits(
                  channel_id, channel_id_short, campaign, channel, medium, source, 
                  keyword, adgroup, channel_category)
          VALUES ('MD5MD5MD5MD5MD5MD5', null, 'InStream_yt', 'YouTube', 'xxx', 'dgdgdgd', '(not set)', 'Stream_Themen', null);
      

      and four empty tables:

      CREATE TABLE public.adcosts
      (
        channel_id character varying(1048000),
        channel_id_short character varying(1048000),
        campaign character varying(1048000),
        channel character varying(1048000),
        medium character varying(1048000),
        source character varying(1048000),
        keyword character varying(1048000),
        adgroup character varying(1048000),
        channel_category character varying(1048000)
      );
      
      CREATE TABLE public.email_campaigns
      (
        channel_id character varying(1048000),
        channel_id_short character varying(1048000),
        campaign character varying(1048000),
        channel character varying(1048000),
        medium character varying(1048000),
        source character varying(1048000),
        keyword character varying(1048000),
        adgroup character varying(1048000),
        channel_category character varying(1048000)
      );
      
      CREATE TABLE public.for_view
      (
        channel_id character varying(1048000),
        channel_id_short character varying(1048000),
        campaign character varying(1048000),
        channel character varying(1048000),
        medium character varying(1048000),
        source character varying(1048000),
        keyword character varying(1048000),
        adgroup character varying(1048000),
        channel_category character varying(1048000)
      );
      
      CREATE TABLE public.transaction_channel
      (
        channel_id character varying(1048000),
        channel_id_short character varying(1048000),
        campaign character varying(1048000),
        channel character varying(1048000),
        medium character varying(1048000),
        source character varying(1048000),
        keyword character varying(1048000),
        adgroup character varying(1048000),
        channel_category character varying(1048000)
      );
      

      2. Add PostgreSQL database configuration in standalone-teiid.xml:

                      <datasource jndi-name="java:/test_dwh_pg" pool-name="test_dwh_pg" enabled="true" use-java-context="true">
                          <connection-url>jdbc:postgresql://localhost:5432/test_dwh?charSet=utf8</connection-url>
                          <driver-class>org.postgresql.Driver</driver-class>
                          <driver>org.postgresql</driver>
                          <pool>
                              <min-pool-size>2</min-pool-size>
                              <max-pool-size>70</max-pool-size>
                              <prefill>false</prefill>
                              <use-strict-min>false</use-strict-min>
                              <flush-strategy>FailingConnectionOnly</flush-strategy>
                          </pool>
                          <security>
                              <user-name>xxxxx</user-name>
                              <password>xxxxx</password>
                          </security>
                          <validation>
                              <check-valid-connection-sql>select 0</check-valid-connection-sql>
                          </validation>
                          <timeout>
                              <blocking-timeout-millis>120000</blocking-timeout-millis>
                              <idle-timeout-minutes>5</idle-timeout-minutes>
                          </timeout>
                      </datasource>
      

      3. Add in test-vdb.xml java:/test_dwh_pg configured in the previous step as a data source:

          <model name="test_dwh_pg">
              <property name="importer.useFullSchemaName" value="false"/>
              <property name="importer.tableTypes" value="TABLE,VIEW"/>
              <property name="importer.importKeys" value="false"/>
              <source name="test_dwh_pg" translator-name="myPg" connection-jndi-name="java:/test_dwh_pg"/>
          </model>
          <translator name="myPg" type="postgresql">
              <property name="SupportsNativeQueries" value="true"/>
          </translator>
      

      4. Add in test-vdb.xml the following virtual procedure (procs schema):

          CREATE VIRTUAL PROCEDURE campaign_to_subchannel1() RETURNS
                (
      	     subchannel string
                )
                AS BEGIN
                END       
      
      Show
      1. In PostgreSQL create the following tables using the following scripts: CREATE TABLE public .visits ( channel_id character varying (1048000), channel_id_short character varying (1048000), campaign character varying (1048000), channel character varying (1048000), medium character varying (1048000), source character varying (1048000), keyword character varying (1048000), adgroup character varying (1048000), channel_category character varying (1048000) ); INSERT INTO public .visits( channel_id, channel_id_short, campaign, channel, medium, source , keyword, adgroup, channel_category) VALUES ( 'MD5MD5MD5MD5MD5MD5' , null , 'InStream_yt' , 'YouTube' , 'xxx' , 'dgdgdgd' , '( not set )' , 'Stream_Themen' , null ); and four empty tables: CREATE TABLE public .adcosts ( channel_id character varying (1048000), channel_id_short character varying (1048000), campaign character varying (1048000), channel character varying (1048000), medium character varying (1048000), source character varying (1048000), keyword character varying (1048000), adgroup character varying (1048000), channel_category character varying (1048000) ); CREATE TABLE public .email_campaigns ( channel_id character varying (1048000), channel_id_short character varying (1048000), campaign character varying (1048000), channel character varying (1048000), medium character varying (1048000), source character varying (1048000), keyword character varying (1048000), adgroup character varying (1048000), channel_category character varying (1048000) ); CREATE TABLE public .for_view ( channel_id character varying (1048000), channel_id_short character varying (1048000), campaign character varying (1048000), channel character varying (1048000), medium character varying (1048000), source character varying (1048000), keyword character varying (1048000), adgroup character varying (1048000), channel_category character varying (1048000) ); CREATE TABLE public .transaction_channel ( channel_id character varying (1048000), channel_id_short character varying (1048000), campaign character varying (1048000), channel character varying (1048000), medium character varying (1048000), source character varying (1048000), keyword character varying (1048000), adgroup character varying (1048000), channel_category character varying (1048000) ); 2. Add PostgreSQL database configuration in standalone-teiid.xml: <datasource jndi-name= "java:/test_dwh_pg" pool-name= "test_dwh_pg" enabled= "true" use-java-context= "true" > <connection-url> jdbc:postgresql://localhost:5432/test_dwh?charSet=utf8 </connection-url> <driver-class> org.postgresql.Driver </driver-class> <driver> org.postgresql </driver> <pool> <min-pool-size> 2 </min-pool-size> <max-pool-size> 70 </max-pool-size> <prefill> false </prefill> <use-strict-min> false </use-strict-min> <flush-strategy> FailingConnectionOnly </flush-strategy> </pool> <security> <user-name> xxxxx </user-name> <password> xxxxx </password> </security> <validation> <check-valid-connection-sql> select 0 </check-valid-connection-sql> </validation> <timeout> <blocking-timeout-millis> 120000 </blocking-timeout-millis> <idle-timeout-minutes> 5 </idle-timeout-minutes> </timeout> </datasource> 3. Add in test-vdb.xml java:/test_dwh_pg configured in the previous step as a data source: <model name= "test_dwh_pg" > <property name= "importer.useFullSchemaName" value= "false" /> <property name= "importer.tableTypes" value= "TABLE,VIEW" /> <property name= "importer.importKeys" value= "false" /> <source name= "test_dwh_pg" translator-name= "myPg" connection-jndi-name= "java:/test_dwh_pg" /> </model> <translator name= "myPg" type= "postgresql" > <property name= "SupportsNativeQueries" value= "true" /> </translator> 4. Add in test-vdb.xml the following virtual procedure (procs schema): CREATE VIRTUAL PROCEDURE campaign_to_subchannel1() RETURNS ( subchannel string ) AS BEGIN END
    • Undefined

      When running the following query:

          SELECT
              *
          FROM
              (
                  SELECT
                          email.campaign AS channel_id
                      FROM
                          test_dwh_pg.email_campaigns AS email
                          ,TABLE (
                              call procs.campaign_to_subchannel1 ()
                          ) email_channels
                  UNION
                  ALL SELECT
                          shop.channel_id AS channel_hash
                      FROM
                          test_dwh_pg.for_view AS shop
                  UNION
                  ALL SELECT
                          medium as channel_id
                      FROM
                          "test_dwh_pg.transaction_channel"
                  UNION
                  ALL SELECT
                          md5_hash as channel_id
                      FROM
                          (
                              SELECT
                                              medium AS md5_hash
                                  FROM
                                      "test_dwh_pg.visits"
                              UNION
                              SELECT
                                      medium md5_hash
                                  FROM
                                      "test_dwh_pg.adcosts"
                          ) tracked_channels
              ) AS channel_definition
      

      Teiid returns no rows though the test_dwh_pg.visits table contains data in the last union. Once we comment out any union (except first sub-union in the last union) Teiid returns the "xxx" result. For example:

      SELECT
              *
          FROM
              (
                  /*SELECT
                          email.campaign AS channel_id
                      FROM
                          test_dwh_pg.email_campaigns AS email
                          ,TABLE (
                              call procs.campaign_to_subchannel1 ()
                          ) email_channels
                  UNION
                  ALL*/ SELECT
                          shop.channel_id AS channel_hash
                      FROM
                          test_dwh_pg.for_view AS shop
                  UNION
                  ALL SELECT
                          medium as channel_id
                      FROM
                          "test_dwh_pg.transaction_channel"
                  UNION
                  ALL SELECT
                          md5_hash as channel_id
                      FROM
                          (
                              SELECT
                                              medium AS md5_hash
                                  FROM
                                      "test_dwh_pg.visits"
                              UNION
                              SELECT
                                      medium md5_hash
                                  FROM
                                      "test_dwh_pg.adcosts"
                          ) tracked_channels
              ) AS channel_definition
      

      will return the correct "xxx" result.
      Also if we change "UNION ALL SELECT" just to "UNION SELECT" Teiid will return the correct "xxx" result as well. rhn-engineering-shawkins I know that you're not active anymore on the project but it would be great to fix the bug.

              rhn-engineering-shawkins Steven Hawkins
              dalex005 Dmitrii Pogorelov
              Votes:
              0 Vote for this issue
              Watchers:
              2 Start watching this issue

                Created:
                Updated:
                Resolved: