Skip to content

Conversation

@bchoudhary6415
Copy link
Collaborator

This PR addresses issue #160

Support for FULL OUTER JOIN is now added to the IBM DB dialect for SQLAlchemy.

Testing

You can test the functionality using the example below. The expected output for each join type is also shown.

from sqlalchemy import create_engine, MetaData, Table, Column, Integer, String, select, insert, join, text

# Replace with your actual DSN
engine = create_engine("ibm_db_sa://userID:Password@host:PortNumber/DATABASE")

metadata = MetaData()

table1 = Table("t1_full_join_test", metadata,
    Column("id", Integer),
    Column("name", String(50))
)

table2 = Table("t2_full_join_test", metadata,
    Column("id", Integer),
    Column("value", String(50))
)

with engine.connect() as conn:
    metadata.create_all(conn)

    # Insert test data
    conn.execute(insert(table1), [{"id": 1, "name": "Alice"}, {"id": 2, "name": "Bob"}])
    conn.execute(insert(table2), [{"id": 2, "value": "X"}, {"id": 3, "value": "Y"}])

    def run_query(j, desc):
        stmt = select(
            table1.c.id.label("t1_id"),
            table1.c.name,
            table2.c.id.label("t2_id"),
            table2.c.value
        ).select_from(j)

        print(f"\n--- {desc} ---")
        print(stmt.compile(dialect=engine.dialect))
        rows = conn.execute(stmt).fetchall()
        for row in rows:
            print(row)

    # INNER JOIN
    j_inner = join(table1, table2, table1.c.id == table2.c.id)
    run_query(j_inner, "INNER JOIN")

    # LEFT OUTER JOIN
    j_left = join(table1, table2, table1.c.id == table2.c.id, isouter=True)
    run_query(j_left, "LEFT OUTER JOIN")

    # FULL OUTER JOIN
    j_full = join(table1, table2, table1.c.id == table2.c.id, full=True)
    run_query(j_full, "FULL OUTER JOIN")

    # Cleanup
    for tbl in (table1, table2):
        conn.execute(text(f"DROP TABLE {tbl.name}"))

Expected Output

--- INNER JOIN ---
SELECT t1_full_join_test.id AS t1_id, t1_full_join_test.name, t2_full_join_test.id AS t2_id, t2_full_join_test."value"
FROM t1_full_join_test INNER JOIN t2_full_join_test ON t1_full_join_test.id = t2_full_join_test.id
(2, 'Bob', 2, 'X')

--- LEFT OUTER JOIN ---
SELECT t1_full_join_test.id AS t1_id, t1_full_join_test.name, t2_full_join_test.id AS t2_id, t2_full_join_test."value"
FROM t1_full_join_test LEFT OUTER JOIN t2_full_join_test ON t1_full_join_test.id = t2_full_join_test.id
(2, 'Bob', 2, 'X')
(1, 'Alice', None, None)

--- FULL OUTER JOIN ---
SELECT t1_full_join_test.id AS t1_id, t1_full_join_test.name, t2_full_join_test.id AS t2_id, t2_full_join_test."value"
FROM t1_full_join_test FULL OUTER JOIN t2_full_join_test ON t1_full_join_test.id = t2_full_join_test.id
(1, 'Alice', None, None)
(2, 'Bob', 2, 'X')
(None, None, 3, 'Y')

Signed-off-by: Balram Choudhary <bchoudhary@rocketsoftware.com>
@bimalkjha bimalkjha merged commit 7980221 into ibmdb:master Aug 19, 2025
2 checks passed
@bchoudhary6415 bchoudhary6415 deleted the ibmdbsa_branch branch August 19, 2025 11:00
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

2 participants