ashb opened a new pull request, #23528:
URL: https://github.com/apache/airflow/pull/23528

   Rather than two sub-selects,
   
   For a _large_ database (27m TaskInstances, 2m DagRuns) this takes the
   time from 10minutes to around 3 minutes per table (we have 3) down to 3
   minutes per table. (All times on Postgres.)
   
   Before:
   
   ```sql
   SELECT
       count(*) AS count_1
   FROM (
       SELECT
           rendered_task_instance_fields.dag_id AS dag_id,
           rendered_task_instance_fields.task_id AS task_id,
           rendered_task_instance_fields.execution_date AS execution_date,
           rendered_task_instance_fields.rendered_fields AS rendered_fields,
           rendered_task_instance_fields.k8s_pod_yaml AS k8s_pod_yaml
       FROM rendered_task_instance_fields
       WHERE
           NOT (exists(SELECT
                           1
                       FROM task_instance
                       JOIN dag_run
                           ON dag_run.run_id = task_instance.run_id
                                   AND dag_run.dag_id = task_instance.dag_id
                       WHERE
                           rendered_task_instance_fields.dag_id = 
task_instance.dag_id
                           AND rendered_task_instance_fields.task_id = 
task_instance.task_id
                           AND rendered_task_instance_fields.execution_date = 
dag_run.execution_date
               ))
        ) AS anon_1
   ;
   ```
   
   After:
   
   ```sql
   CREATE TABLE _airflow_moved__2_3__dangling__rendered_task_instance_fields AS
   SELECT
     rendered_task_instance_fields.dag_id AS dag_id,
     rendered_task_instance_fields.task_id AS task_id,
     rendered_task_instance_fields.execution_date AS execution_date,
     rendered_task_instance_fields.rendered_fields AS rendered_fields,
     rendered_task_instance_fields.k8s_pod_yaml AS k8s_pod_yaml +
   FROM
     rendered_task_instance_fields
     LEFT OUTER JOIN dag_run ON rendered_task_instance_fields.dag_id = 
dag_run.dag_id
     AND rendered_task_instance_fields.execution_date = dag_run.execution_date
     LEFT OUTER JOIN task_instance ON dag_run.dag_id = task_instance.dag_id
     AND dag_run.run_id = task_instance.run_id
     AND rendered_task_instance_fields.task_id = task_instance.task_id
   WHERE
     task_instance.dag_id IS NULL
     OR dag_run.dag_id IS NULL
   ;
   ```
   
   <!--
   Thank you for contributing! Please make sure that your code changes
   are covered with tests. And in case of new features or big changes
   remember to adjust the documentation.
   
   Feel free to ping committers for the review!
   
   In case of existing issue, reference it using one of the following:
   
   closes: #ISSUE
   related: #ISSUE
   
   How to write a good git commit message:
   http://chris.beams.io/posts/git-commit/
   -->
   
   ---
   **^ Add meaningful description above**
   
   Read the **[Pull Request 
Guidelines](https://github.com/apache/airflow/blob/main/CONTRIBUTING.rst#pull-request-guidelines)**
 for more information.
   In case of fundamental code change, Airflow Improvement Proposal 
([AIP](https://cwiki.apache.org/confluence/display/AIRFLOW/Airflow+Improvements+Proposals))
 is needed.
   In case of a new dependency, check compliance with the [ASF 3rd Party 
License Policy](https://www.apache.org/legal/resolved.html#category-x).
   In case of backwards incompatible changes please leave a note in a 
newsfragement file, named `{pr_number}.significant.rst`, in 
[newsfragments](https://github.com/apache/airflow/tree/main/newsfragments).
   


-- 
This is an automated message from the Apache Git Service.
To respond to the message, please log on to GitHub and use the
URL above to go to the specific comment.

To unsubscribe, e-mail: [email protected]

For queries about this service, please contact Infrastructure at:
[email protected]

Reply via email to